├── .gitattributes
├── .github
└── workflows
│ ├── devskim.yml
│ └── powershell.yml
├── .gitignore
├── COPYING.txt
├── Direct_Framework.sln
├── Direct_Framework
├── BuildTools
│ ├── PostBuild.cmd
│ ├── PostBuild.ps1
│ ├── PreBuild.cmd
│ └── PreBuild.ps1
├── DeploymentScripts
│ ├── 1-PreDacpacDeployment
│ │ ├── Migrations
│ │ │ ├── Migration-1.9.1.0.sql
│ │ │ ├── Migration-1.9.2.0.sql
│ │ │ └── Migration-2.0.0.0.sql
│ │ └── PreDacpacDeployment.sql
│ ├── 2-PreDeployment
│ │ └── Script.PreDeployment.sql
│ ├── 3-PostDeployment
│ │ ├── Queue_Job_Batch.sql
│ │ ├── Queue_Job_Module.sql
│ │ ├── Script.PostDeployment.sql
│ │ ├── omd.BATCH.sql
│ │ ├── omd.BATCH_INSTANCE.sql
│ │ ├── omd.MODULE.sql
│ │ ├── omd.MODULE_INSTANCE.sql
│ │ ├── omd.MODULE_INSTANCE_EXECUTED_CODE.sql
│ │ ├── omd_metadata.AREA.sql
│ │ ├── omd_metadata.EVENT_TYPE.sql
│ │ ├── omd_metadata.EXECUTION_STATUS.sql
│ │ ├── omd_metadata.FRAMEWORK_METADATA.sql
│ │ ├── omd_metadata.FREQUENCY.sql
│ │ ├── omd_metadata.INTERNAL_PROCESSING_STATUS.sql
│ │ ├── omd_metadata.LAYER.sql
│ │ └── omd_metadata.NEXT_RUN_STATUS.sql
│ ├── 4-PostDacpacDeployment
│ │ └── PostDacpacDeployment.sql
│ └── readme.md
├── Direct_Framework.sqlproj
├── Functions
│ ├── omd.AddLogMessage.sql
│ ├── omd.CalculateChangeKey.sql
│ ├── omd.GetBatchIdByBatchInstanceId.sql
│ ├── omd.GetBatchIdByModuleInstanceId.sql
│ ├── omd.GetBatchIdByName.sql
│ ├── omd.GetBatchModuleActiveIndicatorValue.sql
│ ├── omd.GetDependency.sql
│ ├── omd.GetFailedBatchIdList.sql
│ ├── omd.GetModuleAreaByModuleId.sql
│ ├── omd.GetModuleIdByModuleInstanceId.sql
│ ├── omd.GetModuleIdByName.sql
│ ├── omd.GetModuleLoadWindowValue.sql
│ ├── omd.GetPreviousBatchInstanceDetails.sql
│ ├── omd.GetPreviousModuleInstanceDetails.sql
│ ├── omd_metadata.GetFrameworkVersion.sql
│ └── omd_processing.GetDependentTables.sql
├── Schemas
│ ├── omd.sql
│ ├── omd_metadata.sql
│ ├── omd_processing.sql
│ └── omd_reporting.sql
├── Stored Procedures
│ ├── omd.AddBatchToParentBatch.sql
│ ├── omd.AddMessageLogToEventLog.sql
│ ├── omd.AddModuleToBatch.sql
│ ├── omd.BatchEvaluation.sql
│ ├── omd.CreateBatchInstance.sql
│ ├── omd.CreateLoadWindow.sql
│ ├── omd.CreateModuleInstance.sql
│ ├── omd.EndDating.sql
│ ├── omd.GetBatch.sql
│ ├── omd.GetConsistencyTimestamp.sql
│ ├── omd.GetModule.sql
│ ├── omd.InsertIntoEventLog.sql
│ ├── omd.ModuleEvaluation.sql
│ ├── omd.PrintLog.sql
│ ├── omd.RegisterBatch.sql
│ ├── omd.RegisterModule.sql
│ ├── omd.RunBatch.sql
│ ├── omd.RunModule.sql
│ ├── omd.TableCondensing.sql
│ ├── omd.UpdateBatchInstance.sql
│ └── omd.UpdateModuleInstance.sql
├── Tables
│ ├── omd.BATCH.sql
│ ├── omd.BATCH_HIERARCHY.sql
│ ├── omd.BATCH_INSTANCE.sql
│ ├── omd.BATCH_MODULE.sql
│ ├── omd.BATCH_PARAMETER.sql
│ ├── omd.EVENT_LOG.sql
│ ├── omd.MODULE.sql
│ ├── omd.MODULE_INSTANCE.sql
│ ├── omd.MODULE_INSTANCE_EXECUTED_CODE.sql
│ ├── omd.MODULE_PARAMETER.sql
│ ├── omd.PARAMETER.sql
│ ├── omd.SOURCE_CONTROL.sql
│ ├── omd_metadata.AREA.sql
│ ├── omd_metadata.EVENT_TYPE.sql
│ ├── omd_metadata.EXECUTION_STATUS.sql
│ ├── omd_metadata.FRAMEWORK_METADATA.sql
│ ├── omd_metadata.FREQUENCY.sql
│ ├── omd_metadata.INTERNAL_PROCESSING_STATUS.sql
│ ├── omd_metadata.LAYER.sql
│ └── omd_metadata.NEXT_RUN_STATUS.sql
└── Views
│ ├── omd_processing.vw_QUEUE_BATCH_PROCESSING.sql
│ ├── omd_processing.vw_QUEUE_MODULE_PROCESSING.sql
│ ├── omd_reporting.vw_COMMON_ERRORS.sql
│ ├── omd_reporting.vw_CUMULATIVE_LOAD_TIME.sql
│ ├── omd_reporting.vw_EXCEPTIONS_BATCH.sql
│ ├── omd_reporting.vw_EXCEPTIONS_DISABLED_PROCESSES.sql
│ ├── omd_reporting.vw_EXCEPTIONS_LONG_RUNNING_PROCESSES.sql
│ ├── omd_reporting.vw_EXCEPTIONS_MODULE.sql
│ ├── omd_reporting.vw_EXCEPTIONS_NON_RUNNING_BATCHES.sql
│ ├── omd_reporting.vw_EXCEPTIONS_NON_RUNNING_MODULES.sql
│ ├── omd_reporting.vw_EXCEPTIONS_TABLE_CONSISTENCY.sql
│ ├── omd_reporting.vw_EXECUTION_EVENT_LOG.sql
│ ├── omd_reporting.vw_EXECUTION_LOG_BATCH_INSTANCE.sql
│ ├── omd_reporting.vw_EXECUTION_LOG_MODULE_INSTANCE.sql
│ └── omd_reporting.vw_MODULE_FAILURES.sql
├── Documentation
├── Documentation.md
├── Images
│ ├── BatchEvaluation.png
│ ├── Components.png
│ ├── DIRECT_Framework.png
│ ├── Execution.png
│ ├── Instantiation.png
│ ├── LogicalModel.png
│ ├── ModuleEvaluation.png
│ ├── Orchestration.png
│ ├── RunBatch.png
│ └── RunModule.png
├── Installation.md
├── MermaidChart
│ ├── BatchEvaluation.mmd
│ ├── ModuleEvalation.mmd
│ ├── RunBatch.mmd
│ └── RunModule.mmd
├── Model.md
└── PowerPoint
│ └── Images.pptx
├── Example_Scripts
├── Controls
│ └── Batches-without-parents.sql
├── Maintenance
│ ├── DIRECT_Clear_BATCH_entries.sql
│ ├── DIRECT_Clear_MODULE_entries.sql
│ ├── DIRECT_Non_Execution_Exception_Check.sql
│ ├── DIRECT_Recent_Executions.sql
│ ├── DIRECT_Runtime_Exception_Check.sql
│ └── Generic_Table_Row_Count.sql
├── README.md
└── Samples
│ └── module-wrapper-example.sql
├── README.md
├── Reference_Databases
├── Reference_Databases.sqlproj
└── readme.md
└── Testing
└── DirectRegressionTests.sql
/.gitattributes:
--------------------------------------------------------------------------------
1 | ###############################################################################
2 | # Set default behavior to automatically normalize line endings.
3 | ###############################################################################
4 | * text=auto
5 |
6 | ###############################################################################
7 | # Set default behavior for command prompt diff.
8 | #
9 | # This is need for earlier builds of msysgit that does not have it on by
10 | # default for csharp files.
11 | # Note: This is only used by command line
12 | ###############################################################################
13 | #*.cs diff=csharp
14 |
15 | ###############################################################################
16 | # Set the merge driver for project and solution files
17 | #
18 | # Merging from the command prompt will add diff markers to the files if there
19 | # are conflicts (Merging from VS is not affected by the settings below, in VS
20 | # the diff markers are never inserted). Diff markers may cause the following
21 | # file extensions to fail to load in VS. An alternative would be to treat
22 | # these files as binary and thus will always conflict and require user
23 | # intervention with every merge. To do so, just uncomment the entries below
24 | ###############################################################################
25 | #*.sln merge=binary
26 | #*.csproj merge=binary
27 | #*.vbproj merge=binary
28 | #*.vcxproj merge=binary
29 | #*.vcproj merge=binary
30 | #*.dbproj merge=binary
31 | #*.fsproj merge=binary
32 | #*.lsproj merge=binary
33 | #*.wixproj merge=binary
34 | #*.modelproj merge=binary
35 | #*.sqlproj merge=binary
36 | #*.wwaproj merge=binary
37 |
38 | ###############################################################################
39 | # behavior for image files
40 | #
41 | # image files are treated as binary by default.
42 | ###############################################################################
43 | #*.jpg binary
44 | #*.png binary
45 | #*.gif binary
46 |
47 | ###############################################################################
48 | # diff behavior for common document formats
49 | #
50 | # Convert binary document formats to text before diffing them. This feature
51 | # is only available from the command line. Turn it on by uncommenting the
52 | # entries below.
53 | ###############################################################################
54 | #*.doc diff=astextplain
55 | #*.DOC diff=astextplain
56 | #*.docx diff=astextplain
57 | #*.DOCX diff=astextplain
58 | #*.dot diff=astextplain
59 | #*.DOT diff=astextplain
60 | #*.pdf diff=astextplain
61 | #*.PDF diff=astextplain
62 | #*.rtf diff=astextplain
63 | #*.RTF diff=astextplain
64 |
--------------------------------------------------------------------------------
/.github/workflows/devskim.yml:
--------------------------------------------------------------------------------
1 | # Run a Microsoft DevSkim code security scan on the codebase
2 | # upload the results to the GitHub Security tab
3 | # https://github.com/microsoft/DevSkim
4 |
5 | name: DevSkim
6 |
7 | on:
8 | push:
9 | branches: [ "main" ]
10 | pull_request:
11 | branches: [ "main" ]
12 | schedule:
13 | - cron: '15 0 * * 0'
14 |
15 | jobs:
16 | lint:
17 | name: DevSkim
18 | runs-on: ubuntu-latest
19 | permissions:
20 | actions: read
21 | contents: read
22 | security-events: write
23 | steps:
24 | - name: Checkout code
25 | uses: actions/checkout@v4
26 |
27 | - name: Run Msft DevSkim scanner
28 | uses: microsoft/DevSkim-Action@v1
29 |
30 | - name: Upload DevSkim scan results sarif to GitHub Security tab
31 | uses: github/codeql-action/upload-sarif@v3
32 | with:
33 | sarif_file: devskim-results.sarif
34 |
--------------------------------------------------------------------------------
/.github/workflows/powershell.yml:
--------------------------------------------------------------------------------
1 | # This workflow uses actions that are not certified by GitHub.
2 | # They are provided by a third-party and are governed by
3 | # separate terms of service, privacy policy, and support
4 | # documentation.
5 | #
6 | # https://github.com/microsoft/action-psscriptanalyzer
7 | # For more information on PSScriptAnalyzer in general, see
8 | # https://github.com/PowerShell/PSScriptAnalyzer
9 |
10 | name: PSScriptAnalyzer
11 |
12 | on:
13 | push:
14 | branches: [ "main" ]
15 | pull_request:
16 | branches: [ "main" ]
17 | schedule:
18 | - cron: '27 18 * * 4'
19 |
20 | permissions:
21 | contents: read
22 |
23 | jobs:
24 | build:
25 | permissions:
26 | contents: read # for actions/checkout to fetch code
27 | security-events: write # for github/codeql-action/upload-sarif to upload SARIF results
28 | actions: read # only required for a private repository by github/codeql-action/upload-sarif to get the Action run status
29 | name: PSScriptAnalyzer
30 | runs-on: ubuntu-latest
31 | steps:
32 | - uses: actions/checkout@v4
33 |
34 | - name: Run PSScriptAnalyzer
35 | uses: microsoft/psscriptanalyzer-action@6b2948b1944407914a58661c49941824d149734f
36 | with:
37 | # Check https://github.com/microsoft/action-psscriptanalyzer for more info about the options.
38 | # The below set up runs PSScriptAnalyzer to your entire repository and runs some basic security rules.
39 | path: .\
40 | recurse: true
41 | # Include your own basic security rules. Removing this option will run all the rules
42 | includeRule: '"PSAvoidGlobalAliases", "PSAvoidUsingConvertToSecureStringWithPlainText"'
43 | output: results.sarif
44 |
45 | # Upload the SARIF file generated in the previous step
46 | - name: Upload SARIF results file
47 | uses: github/codeql-action/upload-sarif@v3
48 | with:
49 | sarif_file: results.sarif
50 |
--------------------------------------------------------------------------------
/.gitignore:
--------------------------------------------------------------------------------
1 | ## Ignore Visual Studio temporary files, build results, and
2 | ## files generated by popular Visual Studio add-ons.
3 | ##
4 | ## Get latest from https://github.com/github/gitignore/blob/main/VisualStudio.gitignore
5 |
6 | # User-specific files
7 | *.rsuser
8 | *.suo
9 | *.user
10 | *.userosscache
11 | *.sln.docstates
12 |
13 | # User-specific files (MonoDevelop/Xamarin Studio)
14 | *.userprefs
15 |
16 | # Mono auto generated files
17 | mono_crash.*
18 |
19 | # Build results
20 | [Dd]ebug/
21 | [Dd]ebugPublic/
22 | [Rr]elease/
23 | [Rr]eleases/
24 | x64/
25 | x86/
26 | [Ww][Ii][Nn]32/
27 | [Aa][Rr][Mm]/
28 | [Aa][Rr][Mm]64/
29 | bld/
30 | [Bb]in/
31 | [Oo]bj/
32 | [Ll]og/
33 | [Ll]ogs/
34 |
35 | # Visual Studio 2015/2017 cache/options directory
36 | .vs/
37 | # Uncomment if you have tasks that create the project's static files in wwwroot
38 | #wwwroot/
39 |
40 | # Visual Studio 2017 auto generated files
41 | Generated\ Files/
42 |
43 | # MSTest test Results
44 | [Tt]est[Rr]esult*/
45 | [Bb]uild[Ll]og.*
46 |
47 | # NUnit
48 | *.VisualState.xml
49 | TestResult.xml
50 | nunit-*.xml
51 |
52 | # Build Results of an ATL Project
53 | [Dd]ebugPS/
54 | [Rr]eleasePS/
55 | dlldata.c
56 |
57 | # Benchmark Results
58 | BenchmarkDotNet.Artifacts/
59 |
60 | # .NET Core
61 | project.lock.json
62 | project.fragment.lock.json
63 | artifacts/
64 |
65 | # ASP.NET Scaffolding
66 | ScaffoldingReadMe.txt
67 |
68 | # StyleCop
69 | StyleCopReport.xml
70 |
71 | # Files built by Visual Studio
72 | *_i.c
73 | *_p.c
74 | *_h.h
75 | *.ilk
76 | *.meta
77 | *.obj
78 | *.iobj
79 | *.pch
80 | *.pdb
81 | *.ipdb
82 | *.pgc
83 | *.pgd
84 | *.rsp
85 | *.sbr
86 | *.tlb
87 | *.tli
88 | *.tlh
89 | *.tmp
90 | *.tmp_proj
91 | *_wpftmp.csproj
92 | *.log
93 | *.tlog
94 | *.vspscc
95 | *.vssscc
96 | .builds
97 | *.pidb
98 | *.svclog
99 | *.scc
100 |
101 | # Chutzpah Test files
102 | _Chutzpah*
103 |
104 | # Visual C++ cache files
105 | ipch/
106 | *.aps
107 | *.ncb
108 | *.opendb
109 | *.opensdf
110 | *.sdf
111 | *.cachefile
112 | *.VC.db
113 | *.VC.VC.opendb
114 |
115 | # Visual Studio profiler
116 | *.psess
117 | *.vsp
118 | *.vspx
119 | *.sap
120 |
121 | # Visual Studio Trace Files
122 | *.e2e
123 |
124 | # TFS 2012 Local Workspace
125 | $tf/
126 |
127 | # Guidance Automation Toolkit
128 | *.gpState
129 |
130 | # ReSharper is a .NET coding add-in
131 | _ReSharper*/
132 | *.[Rr]e[Ss]harper
133 | *.DotSettings.user
134 |
135 | # TeamCity is a build add-in
136 | _TeamCity*
137 |
138 | # DotCover is a Code Coverage Tool
139 | *.dotCover
140 |
141 | # AxoCover is a Code Coverage Tool
142 | .axoCover/*
143 | !.axoCover/settings.json
144 |
145 | # Coverlet is a free, cross platform Code Coverage Tool
146 | coverage*.json
147 | coverage*.xml
148 | coverage*.info
149 |
150 | # Visual Studio code coverage results
151 | *.coverage
152 | *.coveragexml
153 |
154 | # NCrunch
155 | _NCrunch_*
156 | .*crunch*.local.xml
157 | nCrunchTemp_*
158 |
159 | # MightyMoose
160 | *.mm.*
161 | AutoTest.Net/
162 |
163 | # Web workbench (sass)
164 | .sass-cache/
165 |
166 | # Installshield output folder
167 | [Ee]xpress/
168 |
169 | # DocProject is a documentation generator add-in
170 | DocProject/buildhelp/
171 | DocProject/Help/*.HxT
172 | DocProject/Help/*.HxC
173 | DocProject/Help/*.hhc
174 | DocProject/Help/*.hhk
175 | DocProject/Help/*.hhp
176 | DocProject/Help/Html2
177 | DocProject/Help/html
178 |
179 | # Click-Once directory
180 | publish/
181 |
182 | # Publish Web Output
183 | *.[Pp]ublish.xml
184 | *.azurePubxml
185 | # Note: Comment the next line if you want to checkin your web deploy settings,
186 | # but database connection strings (with potential passwords) will be unencrypted
187 | *.pubxml
188 | *.publishproj
189 |
190 | # Microsoft Azure Web App publish settings. Comment the next line if you want to
191 | # checkin your Azure Web App publish settings, but sensitive information contained
192 | # in these scripts will be unencrypted
193 | PublishScripts/
194 |
195 | # NuGet Packages
196 | *.nupkg
197 | # NuGet Symbol Packages
198 | *.snupkg
199 | # The packages folder can be ignored because of Package Restore
200 | **/[Pp]ackages/*
201 | # except build/, which is used as an MSBuild target.
202 | !**/[Pp]ackages/build/
203 | # Uncomment if necessary however generally it will be regenerated when needed
204 | #!**/[Pp]ackages/repositories.config
205 | # NuGet v3's project.json files produces more ignorable files
206 | *.nuget.props
207 | *.nuget.targets
208 |
209 | # Microsoft Azure Build Output
210 | csx/
211 | *.build.csdef
212 |
213 | # Microsoft Azure Emulator
214 | ecf/
215 | rcf/
216 |
217 | # Windows Store app package directories and files
218 | AppPackages/
219 | BundleArtifacts/
220 | Package.StoreAssociation.xml
221 | _pkginfo.txt
222 | *.appx
223 | *.appxbundle
224 | *.appxupload
225 |
226 | # Visual Studio cache files
227 | # files ending in .cache can be ignored
228 | *.[Cc]ache
229 | # but keep track of directories ending in .cache
230 | !?*.[Cc]ache/
231 |
232 | # Others
233 | ClientBin/
234 | ~$*
235 | *~
236 | *.dbmdl
237 | *.dbproj.schemaview
238 | *.jfm
239 | *.pfx
240 | *.publishsettings
241 | orleans.codegen.cs
242 |
243 | # Including strong name files can present a security risk
244 | # (https://github.com/github/gitignore/pull/2483#issue-259490424)
245 | #*.snk
246 |
247 | # Since there are multiple workflows, uncomment next line to ignore bower_components
248 | # (https://github.com/github/gitignore/pull/1529#issuecomment-104372622)
249 | #bower_components/
250 |
251 | # RIA/Silverlight projects
252 | Generated_Code/
253 |
254 | # Backup & report files from converting an old project file
255 | # to a newer Visual Studio version. Backup files are not needed,
256 | # because we have git ;-)
257 | _UpgradeReport_Files/
258 | Backup*/
259 | UpgradeLog*.XML
260 | UpgradeLog*.htm
261 | ServiceFabricBackup/
262 | *.rptproj.bak
263 |
264 | # SQL Server files
265 | *.mdf
266 | *.ldf
267 | *.ndf
268 |
269 | # Business Intelligence projects
270 | *.rdl.data
271 | *.bim.layout
272 | *.bim_*.settings
273 | *.rptproj.rsuser
274 | *- [Bb]ackup.rdl
275 | *- [Bb]ackup ([0-9]).rdl
276 | *- [Bb]ackup ([0-9][0-9]).rdl
277 |
278 | # Microsoft Fakes
279 | FakesAssemblies/
280 |
281 | # GhostDoc plugin setting file
282 | *.GhostDoc.xml
283 |
284 | # Node.js Tools for Visual Studio
285 | .ntvs_analysis.dat
286 | node_modules/
287 |
288 | # Visual Studio 6 build log
289 | *.plg
290 |
291 | # Visual Studio 6 workspace options file
292 | *.opt
293 |
294 | # Visual Studio 6 auto-generated workspace file (contains which files were open etc.)
295 | *.vbw
296 |
297 | # Visual Studio 6 auto-generated project file (contains which files were open etc.)
298 | *.vbp
299 |
300 | # Visual Studio 6 workspace and project file (working project files containing files to include in project)
301 | *.dsw
302 | *.dsp
303 |
304 | # Visual Studio 6 technical files
305 | *.ncb
306 | *.aps
307 |
308 | # Visual Studio LightSwitch build output
309 | **/*.HTMLClient/GeneratedArtifacts
310 | **/*.DesktopClient/GeneratedArtifacts
311 | **/*.DesktopClient/ModelManifest.xml
312 | **/*.Server/GeneratedArtifacts
313 | **/*.Server/ModelManifest.xml
314 | _Pvt_Extensions
315 |
316 | # Paket dependency manager
317 | .paket/paket.exe
318 | paket-files/
319 |
320 | # FAKE - F# Make
321 | .fake/
322 |
323 | # CodeRush personal settings
324 | .cr/personal
325 |
326 | # Python Tools for Visual Studio (PTVS)
327 | __pycache__/
328 | *.pyc
329 |
330 | # Cake - Uncomment if you are using it
331 | # tools/**
332 | # !tools/packages.config
333 |
334 | # Tabs Studio
335 | *.tss
336 |
337 | # Telerik's JustMock configuration file
338 | *.jmconfig
339 |
340 | # BizTalk build output
341 | *.btp.cs
342 | *.btm.cs
343 | *.odx.cs
344 | *.xsd.cs
345 |
346 | # OpenCover UI analysis results
347 | OpenCover/
348 |
349 | # Azure Stream Analytics local run output
350 | ASALocalRun/
351 |
352 | # MSBuild Binary and Structured Log
353 | *.binlog
354 |
355 | # NVidia Nsight GPU debugger configuration file
356 | *.nvuser
357 |
358 | # MFractors (Xamarin productivity tool) working folder
359 | .mfractor/
360 |
361 | # Local History for Visual Studio
362 | .localhistory/
363 |
364 | # Visual Studio History (VSHistory) files
365 | .vshistory/
366 |
367 | # BeatPulse healthcheck temp database
368 | healthchecksdb
369 |
370 | # Backup folder for Package Reference Convert tool in Visual Studio 2017
371 | MigrationBackup/
372 |
373 | # Ionide (cross platform F# VS Code tools) working folder
374 | .ionide/
375 |
376 | # Fody - auto-generated XML schema
377 | FodyWeavers.xsd
378 |
379 | # VS Code files for those working on multiple tools
380 | .vscode/*
381 | !.vscode/settings.json
382 | !.vscode/tasks.json
383 | !.vscode/launch.json
384 | !.vscode/extensions.json
385 | *.code-workspace
386 |
387 | # Local History for Visual Studio Code
388 | .history/
389 |
390 | # Windows Installer files from build outputs
391 | *.cab
392 | *.msi
393 | *.msix
394 | *.msm
395 | *.msp
396 |
397 | # JetBrains Rider
398 | *.sln.iml
399 |
400 | # DIRECT OPTION - Specifically include only the reference dacpacs in the repo,
401 | # so they can be directly referenced in project without requiring a separate build
402 | # The build process has a preprocess step that builds the references,
403 | # so including these are optional depending on the development and deploymetn workflow used
404 | # Also consider the build configuration used, the following is for a Debug build
405 |
406 | # !Direct_Framework/Reference_Databases/[Bb]in
407 | # !Direct_Framework/Reference_Databases/[Bb]in/[Dd]ebug/
408 | # Direct_Framework/Reference_Databases/[Bb]in/[Dd]ebug/*
409 | # !Direct_Framework/Reference_Databases/bin/Debug/master.dacpac
410 | # !Direct_Framework/Reference_Databases/bin/Debug/msdb.dacpac
411 | /.vscode
412 |
--------------------------------------------------------------------------------
/COPYING.txt:
--------------------------------------------------------------------------------
1 | GNU LESSER GENERAL PUBLIC LICENSE
2 | Version 3, 29 June 2007
3 |
4 | Copyright (C) 2007 Free Software Foundation, Inc.
5 | Everyone is permitted to copy and distribute verbatim copies
6 | of this license document, but changing it is not allowed.
7 |
8 |
9 | This version of the GNU Lesser General Public License incorporates
10 | the terms and conditions of version 3 of the GNU General Public
11 | License, supplemented by the additional permissions listed below.
12 |
13 | 0. Additional Definitions.
14 |
15 | As used herein, "this License" refers to version 3 of the GNU Lesser
16 | General Public License, and the "GNU GPL" refers to version 3 of the GNU
17 | General Public License.
18 |
19 | "The Library" refers to a covered work governed by this License,
20 | other than an Application or a Combined Work as defined below.
21 |
22 | An "Application" is any work that makes use of an interface provided
23 | by the Library, but which is not otherwise based on the Library.
24 | Defining a subclass of a class defined by the Library is deemed a mode
25 | of using an interface provided by the Library.
26 |
27 | A "Combined Work" is a work produced by combining or linking an
28 | Application with the Library. The particular version of the Library
29 | with which the Combined Work was made is also called the "Linked
30 | Version".
31 |
32 | The "Minimal Corresponding Source" for a Combined Work means the
33 | Corresponding Source for the Combined Work, excluding any source code
34 | for portions of the Combined Work that, considered in isolation, are
35 | based on the Application, and not on the Linked Version.
36 |
37 | The "Corresponding Application Code" for a Combined Work means the
38 | object code and/or source code for the Application, including any data
39 | and utility programs needed for reproducing the Combined Work from the
40 | Application, but excluding the System Libraries of the Combined Work.
41 |
42 | 1. Exception to Section 3 of the GNU GPL.
43 |
44 | You may convey a covered work under sections 3 and 4 of this License
45 | without being bound by section 3 of the GNU GPL.
46 |
47 | 2. Conveying Modified Versions.
48 |
49 | If you modify a copy of the Library, and, in your modifications, a
50 | facility refers to a function or data to be supplied by an Application
51 | that uses the facility (other than as an argument passed when the
52 | facility is invoked), then you may convey a copy of the modified
53 | version:
54 |
55 | a) under this License, provided that you make a good faith effort to
56 | ensure that, in the event an Application does not supply the
57 | function or data, the facility still operates, and performs
58 | whatever part of its purpose remains meaningful, or
59 |
60 | b) under the GNU GPL, with none of the additional permissions of
61 | this License applicable to that copy.
62 |
63 | 3. Object Code Incorporating Material from Library Header Files.
64 |
65 | The object code form of an Application may incorporate material from
66 | a header file that is part of the Library. You may convey such object
67 | code under terms of your choice, provided that, if the incorporated
68 | material is not limited to numerical parameters, data structure
69 | layouts and accessors, or small macros, inline functions and templates
70 | (ten or fewer lines in length), you do both of the following:
71 |
72 | a) Give prominent notice with each copy of the object code that the
73 | Library is used in it and that the Library and its use are
74 | covered by this License.
75 |
76 | b) Accompany the object code with a copy of the GNU GPL and this license
77 | document.
78 |
79 | 4. Combined Works.
80 |
81 | You may convey a Combined Work under terms of your choice that,
82 | taken together, effectively do not restrict modification of the
83 | portions of the Library contained in the Combined Work and reverse
84 | engineering for debugging such modifications, if you also do each of
85 | the following:
86 |
87 | a) Give prominent notice with each copy of the Combined Work that
88 | the Library is used in it and that the Library and its use are
89 | covered by this License.
90 |
91 | b) Accompany the Combined Work with a copy of the GNU GPL and this license
92 | document.
93 |
94 | c) For a Combined Work that displays copyright notices during
95 | execution, include the copyright notice for the Library among
96 | these notices, as well as a reference directing the user to the
97 | copies of the GNU GPL and this license document.
98 |
99 | d) Do one of the following:
100 |
101 | 0) Convey the Minimal Corresponding Source under the terms of this
102 | License, and the Corresponding Application Code in a form
103 | suitable for, and under terms that permit, the user to
104 | recombine or relink the Application with a modified version of
105 | the Linked Version to produce a modified Combined Work, in the
106 | manner specified by section 6 of the GNU GPL for conveying
107 | Corresponding Source.
108 |
109 | 1) Use a suitable shared library mechanism for linking with the
110 | Library. A suitable mechanism is one that (a) uses at run time
111 | a copy of the Library already present on the user's computer
112 | system, and (b) will operate properly with a modified version
113 | of the Library that is interface-compatible with the Linked
114 | Version.
115 |
116 | e) Provide Installation Information, but only if you would otherwise
117 | be required to provide such information under section 6 of the
118 | GNU GPL, and only to the extent that such information is
119 | necessary to install and execute a modified version of the
120 | Combined Work produced by recombining or relinking the
121 | Application with a modified version of the Linked Version. (If
122 | you use option 4d0, the Installation Information must accompany
123 | the Minimal Corresponding Source and Corresponding Application
124 | Code. If you use option 4d1, you must provide the Installation
125 | Information in the manner specified by section 6 of the GNU GPL
126 | for conveying Corresponding Source.)
127 |
128 | 5. Combined Libraries.
129 |
130 | You may place library facilities that are a work based on the
131 | Library side by side in a single library together with other library
132 | facilities that are not Applications and are not covered by this
133 | License, and convey such a combined library under terms of your
134 | choice, if you do both of the following:
135 |
136 | a) Accompany the combined library with a copy of the same work based
137 | on the Library, uncombined with any other library facilities,
138 | conveyed under the terms of this License.
139 |
140 | b) Give prominent notice with the combined library that part of it
141 | is a work based on the Library, and explaining where to find the
142 | accompanying uncombined form of the same work.
143 |
144 | 6. Revised Versions of the GNU Lesser General Public License.
145 |
146 | The Free Software Foundation may publish revised and/or new versions
147 | of the GNU Lesser General Public License from time to time. Such new
148 | versions will be similar in spirit to the present version, but may
149 | differ in detail to address new problems or concerns.
150 |
151 | Each version is given a distinguishing version number. If the
152 | Library as you received it specifies that a certain numbered version
153 | of the GNU Lesser General Public License "or any later version"
154 | applies to it, you have the option of following the terms and
155 | conditions either of that published version or of any later version
156 | published by the Free Software Foundation. If the Library as you
157 | received it does not specify a version number of the GNU Lesser
158 | General Public License, you may choose any version of the GNU Lesser
159 | General Public License ever published by the Free Software Foundation.
160 |
161 | If the Library as you received it specifies that a proxy can decide
162 | whether future versions of the GNU Lesser General Public License shall
163 | apply, that proxy's public statement of acceptance of any version is
164 | permanent authorization for you to choose that version for the
165 | Library.
--------------------------------------------------------------------------------
/Direct_Framework.sln:
--------------------------------------------------------------------------------
1 |
2 | Microsoft Visual Studio Solution File, Format Version 12.00
3 | # Visual Studio Version 16
4 | VisualStudioVersion = 16.0.30011.22
5 | MinimumVisualStudioVersion = 10.0.40219.1
6 | Project("{00D1A9C2-B5F0-4AF3-8072-F6C62B433612}") = "Direct_Framework", "Direct_Framework\Direct_Framework.sqlproj", "{B88FF268-22F9-4416-9E36-CFE598D243EB}"
7 | EndProject
8 | Global
9 | GlobalSection(SolutionConfigurationPlatforms) = preSolution
10 | Debug|Any CPU = Debug|Any CPU
11 | Release|Any CPU = Release|Any CPU
12 | EndGlobalSection
13 | GlobalSection(ProjectConfigurationPlatforms) = postSolution
14 | {B88FF268-22F9-4416-9E36-CFE598D243EB}.Debug|Any CPU.ActiveCfg = Debug|Any CPU
15 | {B88FF268-22F9-4416-9E36-CFE598D243EB}.Debug|Any CPU.Build.0 = Debug|Any CPU
16 | {B88FF268-22F9-4416-9E36-CFE598D243EB}.Debug|Any CPU.Deploy.0 = Debug|Any CPU
17 | {B88FF268-22F9-4416-9E36-CFE598D243EB}.Release|Any CPU.ActiveCfg = Release|Any CPU
18 | {B88FF268-22F9-4416-9E36-CFE598D243EB}.Release|Any CPU.Build.0 = Release|Any CPU
19 | {B88FF268-22F9-4416-9E36-CFE598D243EB}.Release|Any CPU.Deploy.0 = Release|Any CPU
20 | EndGlobalSection
21 | GlobalSection(SolutionProperties) = preSolution
22 | HideSolutionNode = FALSE
23 | EndGlobalSection
24 | GlobalSection(ExtensibilityGlobals) = postSolution
25 | SolutionGuid = {1D595639-B2AF-46CC-ACFE-47E95ADB9198}
26 | EndGlobalSection
27 | EndGlobal
28 |
--------------------------------------------------------------------------------
/Direct_Framework/BuildTools/PostBuild.cmd:
--------------------------------------------------------------------------------
1 | @ECHO OFF
2 |
3 | rem Debug cmd for post-build event
4 | ECHO *** CMD - Post-Build Event: Building 'Direct_Framework' project...
5 |
6 | rem Run the post-build PowerShell script
7 | pwsh -ExecutionPolicy Bypass -NoProfile -NonInteractive -file "%~dp0\PostBuild.ps1" -WorkingDirectory "%~dp0"
8 |
--------------------------------------------------------------------------------
/Direct_Framework/BuildTools/PostBuild.ps1:
--------------------------------------------------------------------------------
1 | ################################################################################################################################################################
2 | # # DATABASE PROJECT POST-BUILD PWSH SCRIPT
3 | ################################################################################################################################################################
4 |
5 | Write-Host "*** PWSH/ps1 - Post-Build Event: process starting..." -ForegroundColor Green
6 |
7 | ################################################################################################################################################################
8 | # Add tasks and steps here as needed
9 |
10 | # placeholder...
11 |
12 | ################################################################################################################################################################
13 | Write-Host "*** PWSH/ps1 - Post-Build Event: process completed..." -ForegroundColor Green
14 |
15 |
--------------------------------------------------------------------------------
/Direct_Framework/BuildTools/PreBuild.cmd:
--------------------------------------------------------------------------------
1 | @ECHO OFF
2 |
3 | rem Debug cmd for post-build event
4 | ECHO *** CMD - Pre-Build Event: Building 'Direct_Framework' project...
5 |
6 | rem Run the pre-build PowerShell script
7 | pwsh -ExecutionPolicy Bypass -NoProfile -NonInteractive -File %~dp0\PreBuild.ps1 -path %~dp0
8 |
--------------------------------------------------------------------------------
/Direct_Framework/BuildTools/PreBuild.ps1:
--------------------------------------------------------------------------------
1 | ################################################################################################################################################################
2 | # DATABASE PROJECT PRE-BUILD PWSH SCRIPT
3 | ################################################################################################################################################################
4 |
5 | param([string]$path)
6 |
7 | Write-Host "The pwsh path param is: '$path'"
8 | Set-Location $path
9 | Write-Host "The pwsh working directory/location is:"
10 | Get-Location | Write-Host
11 |
12 | Write-Host "*** PWSH/ps1 - Pre-Build Event: process starting..." -ForegroundColor Green
13 |
14 | ################################################################################################################################################################
15 | # Build the reference project so that the reference dacpacs are restored
16 |
17 | # Change active folder to the reference project
18 | Set-Location "$path\..\..\Reference_Databases"
19 |
20 | Get-Location | Write-Host
21 |
22 | # Run the dotnet build command to restore the reference dacpacs
23 | dotnet build
24 |
25 | # return to the original folder for further processing as needed...
26 | Set-Location -
27 |
28 | ################################################################################################################################################################
29 | # Add tasks and steps here as needed
30 |
31 | # OPTIONAL run pre-dacpac deployment script using sqlcmd
32 | # Use this to validate pre-dacpac deployment scripts from inside the project build process
33 |
34 | # script assumes using the new go version
35 | # https://github.com/microsoft/go-sqlcmd
36 | # https://learn.microsoft.com/en-au/sql/tools/sqlcmd/sqlcmd-utility
37 | # Install through:
38 | # - winget install sqlcmd
39 |
40 | if($false)
41 | {
42 | Write-Host "Running integrated pre-dacpac deployment script testing execution..."
43 |
44 | # Change active folder to the reference project
45 | Set-Location "$path\..\DeploymentScripts\1-PreDacpacDeployment"
46 |
47 | # Target server and Database *NOT* parameterised here...
48 | Get-Location | Write-Host
49 | sqlcmd -S . -d DIRECT_Framework -E -Q "SELECT @@VERSION;"
50 | sqlcmd -S . -d DIRECT_Framework -E -i PreDacpacDeployment.sql
51 |
52 | # return to the original folder for further processing as needed...
53 | Set-Location -
54 | }
55 | else
56 | {
57 | Write-Host "Skipping integrated pre-dacpac deployment script testing execution..."
58 | }
59 |
60 | ################################################################################################################################################################
61 | Write-Host "*** PWSH/ps1 - Pre-Build Event: process completed..." -ForegroundColor Green
62 |
63 |
--------------------------------------------------------------------------------
/Direct_Framework/DeploymentScripts/1-PreDacpacDeployment/Migrations/Migration-1.9.1.0.sql:
--------------------------------------------------------------------------------
1 | PRINT 'Migrating DIRECT Framework to 1.9.1.0'
2 |
3 | BEGIN TRY
4 | BEGIN TRANSACTION
5 | -- Migration code goes here
6 |
7 | -- Placeholder...
8 |
9 | -- Set new version as last step
10 | UPDATE [omd_metadata].[FRAMEWORK_METADATA]
11 | SET [VALUE] = '1.9.1.0'
12 | WHERE [CODE] = 'DIRECT_VERSION'
13 |
14 | PRINT 'Migration to 1.9.1.0 Completed'
15 |
16 | COMMIT TRANSACTION
17 |
18 | END TRY
19 | BEGIN CATCH
20 |
21 | IF @@TRANCOUNT > 0
22 | BEGIN
23 | ROLLBACK TRANSACTION
24 | END
25 |
26 | PRINT ERROR_MESSAGE()
27 | PRINT 'Migration failed'
28 |
29 | RETURN
30 |
31 | END CATCH
32 |
--------------------------------------------------------------------------------
/Direct_Framework/DeploymentScripts/1-PreDacpacDeployment/Migrations/Migration-1.9.2.0.sql:
--------------------------------------------------------------------------------
1 | PRINT 'Migrating DIRECT Framework to 1.9.2.0'
2 |
3 | BEGIN TRY
4 | BEGIN TRANSACTION
5 | -- Migration code goes here
6 |
7 | -- Placeholder...
8 |
9 | -- Set new version as last step
10 | UPDATE [omd_metadata].[FRAMEWORK_METADATA]
11 | SET [VALUE] = '1.9.2.0'
12 | WHERE [CODE] = 'DIRECT_VERSION'
13 |
14 | PRINT 'Migration to 1.9.2.0 Completed'
15 |
16 | COMMIT TRANSACTION
17 |
18 | END TRY
19 | BEGIN CATCH
20 |
21 | IF @@TRANCOUNT > 0
22 | BEGIN
23 | ROLLBACK TRANSACTION
24 | END
25 |
26 | PRINT ERROR_MESSAGE()
27 | PRINT 'Migration failed'
28 |
29 | RETURN
30 |
31 | END CATCH
32 |
--------------------------------------------------------------------------------
/Direct_Framework/DeploymentScripts/1-PreDacpacDeployment/Migrations/Migration-2.0.0.0.sql:
--------------------------------------------------------------------------------
1 | PRINT 'Migrating DIRECT Framework to 2.0.0.0'
2 |
3 | BEGIN TRY
4 | BEGIN TRANSACTION
5 | -- Migration code goes here
6 |
7 | -- Placeholder...
8 |
9 | -- Set new version as last step
10 | UPDATE [omd_metadata].[FRAMEWORK_METADATA]
11 | SET [VALUE] = '2.0.0.0'
12 | WHERE [CODE] = 'DIRECT_VERSION'
13 |
14 | PRINT 'Migration to 2.0.0.0 Completed'
15 |
16 | COMMIT TRANSACTION
17 |
18 | END TRY
19 | BEGIN CATCH
20 |
21 | IF @@TRANCOUNT > 0
22 | BEGIN
23 | ROLLBACK TRANSACTION
24 | END
25 |
26 | PRINT ERROR_MESSAGE()
27 | PRINT 'Migration failed'
28 |
29 | RETURN
30 |
31 | END CATCH
32 |
--------------------------------------------------------------------------------
/Direct_Framework/DeploymentScripts/1-PreDacpacDeployment/PreDacpacDeployment.sql:
--------------------------------------------------------------------------------
1 | /*******************************************************************************
2 | * Pre-Dacpac Deployment Script
3 | *******************************************************************************
4 | *
5 | * Used for migrations that need to be run before the dacpac is deployed
6 | * This script is executed by the pipeline before the call to deploy the dacpac
7 | * For non-Dacpac deployments/non-pipeline processes, this script can be run
8 | * manually, or as part of a separate deployment script
9 | * To allow easy execution of a dependency chain, this script should be
10 | * idempotent and use the database versioning to determine what steps to run
11 | * Currently it is a sqlcmd mode script that calls other scripts for each
12 | * required upgrade step
13 | * Version control in the metadata table tracks the current version of the
14 | * database, which is/should be used to determine which migration scripts to
15 | * run, if and when needed...
16 | ******************************************************************************/
17 |
18 | -- The DACPAC version/The current version of the code being deployed
19 | -- If a migration is required this should include the migration code from the
20 | -- previous version to this/the current version
21 | DECLARE @CurrentVersion NVARCHAR(10) = '2.0.0.0'
22 |
23 | -- placeholder contents...
24 | PRINT 'Pre-Dacpac Deployment Script Starting'
25 | PRINT 'Current Version: ' + @CurrentVersion
26 |
27 | -- Check that we are connected to an existing database and can run queries
28 | -- this should gracefully deal with deploying a new instance of the database
29 | -- For a pipeline, this would possibly be a previous step that then decides to run this
30 | -- A dacpac deployment can create a target database in Azure SQL db, but that
31 | -- process is not the better option. Make sure to create the database in a more
32 | -- controlled manner, and then deploy the dacpac to it.
33 |
34 | -- Check if a main table exists, and assume it is initial deployment if not
35 |
36 | IF NOT EXISTS (
37 | SELECT NULL
38 | FROM INFORMATION_SCHEMA.TABLES
39 | WHERE
40 | TABLE_SCHEMA = 'omd'
41 | AND TABLE_NAME = 'BATCH'
42 | )
43 | BEGIN
44 | PRINT '''[omd].[BATCH]'' table does not exist, script assumes this is an initial deploy'
45 | PRINT 'Skipping script execution'
46 |
47 | GOTO EndOfProcedure
48 | END
49 |
50 | PRINT '''[omd].[BATCH]'' table exists, script assumes this is an incremental deploy'
51 |
52 | -- Check that the version function is available
53 | IF EXISTS (
54 | SELECT NULL
55 | FROM INFORMATION_SCHEMA.ROUTINES
56 | WHERE
57 | SPECIFIC_SCHEMA = 'omd_metadata'
58 | AND SPECIFIC_NAME = 'GetFrameworkVersion'
59 | AND ROUTINE_TYPE = 'FUNCTION'
60 | )
61 | BEGIN
62 |
63 | PRINT '''[omd_metadata].[GetFrameworkVersion]'' function exists, script assumes this is an incremental deploy on v2+'
64 |
65 | -- If all is ok, get the current version of the database
66 | DECLARE @DirectVersion NVARCHAR(10) = [omd_metadata].[GetFrameworkVersion]();
67 |
68 | IF @DirectVersion IS NULL
69 | BEGIN
70 | PRINT 'version function exists but is not returning a value, script assumes corruption'
71 | PRINT 'Aborting pre-processing.'
72 |
73 | GOTO EndOfProcedureFailure
74 |
75 | END
76 | ELSE
77 | BEGIN
78 | PRINT 'Target database DIRECT Framework version is ' + @DirectVersion
79 | END
80 |
81 | -- Run through each migration script in order, if needed
82 | -- do proper semantic versioning comparison here...
83 |
84 | IF @DirectVersion > @CurrentVersion
85 | BEGIN
86 | PRINT 'Database is already at a higher version ' + @CurrentVersion
87 | PRINT 'this script is an older version than the current database'
88 | PRINT 'Downgrading throught this script is not possible'
89 | PRINT 'Aborting pre-processing'
90 |
91 | GOTO EndOfProcedure
92 |
93 | END
94 |
95 | IF @DirectVersion = @CurrentVersion
96 | BEGIN
97 | PRINT 'Database is already at version ' + @CurrentVersion
98 | PRINT 'No pre-dacpac migration required'
99 | PRINT 'Aborting pre-processing'
100 |
101 | GOTO EndOfProcedure
102 |
103 | END
104 |
105 | IF @DirectVersion < @CurrentVersion
106 |
107 | BEGIN
108 | PRINT 'Database is at version ' + @DirectVersion
109 | PRINT 'Migration required to version ' + @CurrentVersion
110 |
111 | -- sequence through the migrations as needed
112 | -- this is an example
113 | -- point migrations should be rolled up to higher versions when available
114 |
115 | IF @DirectVersion = '1.9.0.0'
116 | BEGIN
117 | PRINT 'Running migration 1.9.0.0 to version 1.9.1.0'
118 | :r ./Migrations/Migration-1.9.1.0.sql
119 | -- Check that upgrade was successful
120 | END
121 |
122 | SET @DirectVersion = [omd_metadata].[GetFrameworkVersion]();
123 |
124 | IF @DirectVersion = '1.9.1.0'
125 | BEGIN
126 | PRINT 'Running migration 1.9.1.0 to version 1.9.2.0'
127 | :r ./Migrations/Migration-1.9.2.0.sql
128 | -- Check that upgrade was successful
129 | END
130 |
131 | SET @DirectVersion = [omd_metadata].[GetFrameworkVersion]();
132 |
133 | IF @DirectVersion = '1.9.2.0'
134 | BEGIN
135 | PRINT 'Running migration 1.9.2.0 to version 2.0.0.0'
136 | :r ./Migrations/Migration-2.0.0.0.sql
137 | -- Check that upgrade was successful
138 | END
139 |
140 | END
141 |
142 | GOTO EndOfProcedureSuccess
143 |
144 | END
145 | ELSE
146 | BEGIN
147 | PRINT 'Metadata table or framerwork version function not found'
148 | PRINT 'Assume this is an incremental deploy on v1 or a non-DIRECT database'
149 | PRINT 'Automated upgrades from v1 currently not supported'
150 | PRINT 'Please add the required migration code to the GitHub repo'
151 | PRINT 'Aborting pre-processing'
152 |
153 | GOTO EndOfProcedureFailure
154 |
155 | END
156 |
157 | -- Error/Failure
158 | EndOfProcedureFailure:
159 |
160 | PRINT 'Pre-Dacpac Deployment Script aborted'
161 |
162 | GOTO EndOfProcedure
163 |
164 | -- Success
165 | EndOfProcedureSuccess:
166 |
167 | PRINT 'Pre-Dacpac Deployment Script completed'
168 |
169 | GOTO EndOfProcedure
170 |
171 | -- End
172 | EndOfProcedure:
173 |
--------------------------------------------------------------------------------
/Direct_Framework/DeploymentScripts/2-PreDeployment/Script.PreDeployment.sql:
--------------------------------------------------------------------------------
1 | /*******************************************************************************
2 | * Pre-Deployment Script Template
3 | *******************************************************************************
4 | *
5 | * This file contains SQL statements that will be prepended to the build script.
6 | * This is executed by SqlPackage/DacFx before the DACPAC has been deployed
7 | * to the target database. The results are not included in the state compare.
8 | *
9 | * https://github.com/microsoft/DacFx
10 | * https://aka.ms/sqlpackage-ref
11 | *
12 | * Use SQLCMD syntax to include a file in the pre-deployment script.
13 | * Example: :r .\myfile.sql
14 | *
15 | * Use SQLCMD syntax to reference a variable in the pre-deployment script.
16 | * Example: :setvar TableName MyTable
17 | * SELECT * FROM [$(TableName)]
18 | ******************************************************************************/
19 |
20 | PRINT 'Pre-Deployment Script Starting'
21 |
22 | -- placeholder contents...
23 | PRINT 'Doing nothing...'
24 | -- Do some setup, migration or prepare work as part of pre-deployment
25 | -- :r .\SomeScriptFile.sql
26 |
27 | PRINT 'Pre-Deployment Script Completed'
28 |
--------------------------------------------------------------------------------
/Direct_Framework/DeploymentScripts/3-PostDeployment/Queue_Job_Batch.sql:
--------------------------------------------------------------------------------
1 | /*******************************************************************************
2 | * [omd].[Queue_Job_Batch]
3 | *******************************************************************************
4 | *
5 | * https://github.com/data-solution-automation-engine/DIRECT
6 | *
7 | * DIRECT Framework v2.0 Stored Procedures
8 | *
9 | *******************************************************************************
10 | * !! THIS IS A MSDB-BASED PROCESS, !!
11 | * !! IT ONLY WORKS ON ON-PREMISES TYPE SQL SERVERS !!
12 | *******************************************************************************
13 | *
14 | * Process:
15 | * TODO: tba
16 | *
17 | * Purpose:
18 | * TODO: tba
19 | *
20 | * Input:
21 | * - TODO: tba
22 | *
23 | * Returns:
24 | * - TODO: tba
25 | *
26 | * Usage:
27 |
28 | TODO: tba
29 |
30 | *
31 | ******************************************************************************/
32 |
33 | USE [msdb]
34 | GO
35 |
36 | IF EXISTS (SELECT name FROM msdb.dbo.sysjobs WHERE name='Queue_Batch')
37 | EXEC msdb.dbo.sp_delete_job @job_name='Queue_Batch', @delete_unused_schedule=1
38 |
39 | BEGIN TRANSACTION
40 | DECLARE @ReturnCode INT
41 | SELECT @ReturnCode = 0
42 |
43 | IF NOT EXISTS (SELECT name FROM msdb.dbo.syscategories WHERE name=N'[Uncategorized (Local)]' AND category_class=1)
44 | BEGIN
45 | EXEC @ReturnCode = msdb.dbo.sp_add_category @class=N'JOB', @type=N'LOCAL', @name=N'[Uncategorized (Local)]'
46 | IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
47 |
48 | END
49 |
50 | DECLARE @jobId BINARY(16)
51 | EXEC @ReturnCode = msdb.dbo.sp_add_job @job_name=N'Queue_Batch',
52 | @enabled=1,
53 | @notify_level_eventlog=0,
54 | @notify_level_email=0,
55 | @notify_level_netsend=0,
56 | @notify_level_page=0,
57 | @delete_level=0,
58 | @description=N'No description available.',
59 | @category_name=N'[Uncategorized (Local)]',
60 | @owner_login_name=N'sa', @job_id = @jobId OUTPUT
61 | IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
62 |
63 | EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'Continuous_Integration',
64 | @step_id=1,
65 | @cmdexec_success_code=0,
66 | @on_success_action=1,
67 | @on_success_step_id=0,
68 | @on_fail_action=2,
69 | @on_fail_step_id=0,
70 | @retry_attempts=0,
71 | @retry_interval=0,
72 | @os_run_priority=0, @subsystem=N'TSQL',
73 | @command=N'/*
74 | Create a temporary in-memory stored procedure that can be used to return the number of currently running processes as per the control framework.
75 | */
76 | CREATE OR ALTER PROCEDURE #runningJobs
77 | @NUMBER_OF_RUNNING_PROCESSES INT OUTPUT
78 | AS
79 | (
80 | SELECT @NUMBER_OF_RUNNING_PROCESSES = (SELECT COUNT(*) FROM [Direct_Framework].omd.BATCH_INSTANCE WHERE EXECUTION_STATUS_CODE=''Executing'')
81 | )
82 | GO
83 |
84 | DECLARE @DEBUG_FLAG INT = 1; -- Debug is enabled by default
85 | DECLARE @MAX_CONCURRENCY INT = 2 -- Determines how many processes can be run in parallel / concurrent
86 | DECLARE @NUMBER_OF_RUNNING_PROCESSES INT = 0;
87 | DECLARE @NUMBER_OF_QUEUED_PROCESSES INT = 0;
88 | DECLARE @DELAY_TIME VARCHAR(8) = ''00:00:05'' -- This is the time the queue waits upon detecting concurrency
89 | DECLARE @PROCESS_NAME as VARCHAR(256);
90 | DECLARE @CURRENT_TIMESTAMP VARCHAR(19);
91 | DECLARE @PRINT_MESSAGE VARCHAR(1000);
92 | DECLARE @SQL_STRING NVARCHAR(4000);
93 | DECLARE @ModuleInstanceIdColumnName NVARCHAR(256) = ''AUDIT_TRAIL_ID'';
94 |
95 | WHILE 1 = 1
96 | BEGIN
97 | --Only execute the queue order when the number of executing processes is smaller than the maximum concurrency parameters
98 | EXEC #runningJobs @NUMBER_OF_RUNNING_PROCESSES OUTPUT
99 |
100 | SELECT @CURRENT_TIMESTAMP = (SELECT CAST(SYSUTCDATETIME() AS NVARCHAR(19)))
101 | SELECT @NUMBER_OF_QUEUED_PROCESSES = (SELECT COUNT(*) AS NUMBER_OF_QUEUED_PROCESSED FROM [Direct_Framework].[omd_processing].[vw_QUEUE_BATCH_PROCESSING])
102 |
103 | IF @DEBUG_FLAG = 1 PRINT ''@NUMBER_OF_RUNNING_PROCESSES= ''+CAST (@NUMBER_OF_RUNNING_PROCESSES AS VARCHAR(10))
104 | IF @DEBUG_FLAG = 1 PRINT ''@MAX_CONCURRENCY= ''+CAST (@MAX_CONCURRENCY AS VARCHAR(10))
105 | IF @DEBUG_FLAG = 1 PRINT ''@CURRENT_TIMESTAMP = ''+ @CURRENT_TIMESTAMP
106 | IF @DEBUG_FLAG = 1 PRINT ''@NUMBER_OF_QUEUED_PROCESSES = ''+ +CAST (@NUMBER_OF_QUEUED_PROCESSES AS VARCHAR(10))
107 |
108 | --Whenever the number of jobs exceeds the parameter, wait for a bit (as per the delay time)
109 | WHILE (@NUMBER_OF_RUNNING_PROCESSES >= @MAX_CONCURRENCY)
110 | BEGIN
111 | IF @DEBUG_FLAG =1
112 | BEGIN
113 | SET @PRINT_MESSAGE = ''WAITFOR ''+@DELAY_TIME+'', currently still @NUMBER_OF_RUNNING_PROCESSES at ''+CAST (@NUMBER_OF_RUNNING_PROCESSES AS VARCHAR(10))
114 | RAISERROR (@PRINT_MESSAGE, 0, 1) WITH NOWAIT; -- Raise Error used to flush to the debug window immediately, PRINT has a large delay
115 | END
116 |
117 | WAITFOR DELAY @DELAY_TIME -- Perform the wait / delay.
118 | EXEC #runningJobs @NUMBER_OF_RUNNING_PROCESSES OUTPUT -- Check again if the next process is good to g.
119 | END
120 |
121 | IF @DEBUG_FLAG =1 PRINT ''After wait @NUMBER_OF_RUNNING_PROCESSES= ''+CAST (@NUMBER_OF_RUNNING_PROCESSES AS VARCHAR(10))
122 | IF @DEBUG_FLAG =1 PRINT ''After wait @MAX_CONCURRENCY= ''+CAST (@MAX_CONCURRENCY AS VARCHAR(10))
123 | IF @DEBUG_FLAG =1 PRINT ''After wait @CURRENT_TIMESTAMP = ''+ @CURRENT_TIMESTAMP
124 |
125 | -- When a spot becomes available, run the process from the queue
126 | SELECT TOP 1 @PROCESS_NAME = BATCH_CODE
127 | FROM
128 | (
129 | -- Select the Batch that hasn''t run the longest (oldest age)
130 | SELECT BATCH_CODE, END_TIMESTAMP
131 | FROM [Direct_Framework].[omd_processing].[vw_QUEUE_BATCH_PROCESSING]
132 | ) batchQueue
133 | ORDER BY END_TIMESTAMP ASC
134 |
135 | SET @PRINT_MESSAGE = ''Running process: ''+@PROCESS_NAME
136 |
137 | IF @DEBUG_FLAG =1 RAISERROR (@PRINT_MESSAGE, 0, 1) WITH NOWAIT
138 | BEGIN TRY
139 | EXEC [Direct_Framework].[omd].[RunBatch]
140 | @BatchCode = @PROCESS_NAME, @ModuleInstanceIdColumnName = @ModuleInstanceIdColumnName
141 | END TRY
142 | BEGIN CATCH
143 | SET @PROCESS_NAME = SUBSTRING(@PROCESS_NAME,1,LEN(@PROCESS_NAME)-5)
144 | SET @SQL_STRING = N''UPDATE [Direct_Framework].omd.BATCH SET ACTIVE_INDICATOR=''''N'''' WHERE BATCH_CODE=''''''+@PROCESS_NAME+''''''''
145 | SET @PRINT_MESSAGE = ''ERROR EXECUTING JOB: ''+@PROCESS_NAME+'' DEACTIVATE QUERY: ''+@SQL_STRING+''''
146 | RAISERROR (@PRINT_MESSAGE, 0, 1) WITH NOWAIT
147 | EXECUTE sp_executesql @SQL_STRING
148 | END CATCH
149 |
150 | -- Also functions as delayer
151 | -- This is mandatory! Otherwise processes will be spawned too fast! This prevents the same process to be kicked off many times before OMD has had the chance to register
152 | WAITFOR DELAY ''00:00:05''
153 | END
154 |
155 | DROP PROCEDURE #runningJobs',
156 | @database_name=N'master',
157 | @output_file_name=N'D:\Logs\Job_Master',
158 | @flags=2
159 | IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
160 | EXEC @ReturnCode = msdb.dbo.sp_update_job @job_id = @jobId, @start_step_id = 1
161 | IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
162 | EXEC @ReturnCode = msdb.dbo.sp_add_jobserver @job_id = @jobId, @server_name = N'(local)'
163 | IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
164 | COMMIT TRANSACTION
165 | GOTO EndSave
166 | QuitWithRollback:
167 | IF (@@TRANCOUNT > 0) ROLLBACK TRANSACTION
168 | EndSave:
169 | GO
170 |
--------------------------------------------------------------------------------
/Direct_Framework/DeploymentScripts/3-PostDeployment/Queue_Job_Module.sql:
--------------------------------------------------------------------------------
1 | /*******************************************************************************
2 | * [omd].[Queue_Job_Module]
3 | *******************************************************************************
4 | *
5 | * https://github.com/data-solution-automation-engine/DIRECT
6 | *
7 | * DIRECT Framework v2.0 Stored Procedures
8 | *
9 | *******************************************************************************
10 | * !! THIS IS A MSDB-BASED PROCESS, !!
11 | * !! IT ONLY WORKS ON ON-PREMISES TYPE SQL SERVERS !!
12 | *******************************************************************************
13 | *
14 | * Process:
15 | * TODO: tba
16 | *
17 | * Purpose:
18 | * TODO: tba
19 | *
20 | * Input:
21 | * - TODO: tba
22 | *
23 | * Returns:
24 | * - TODO: tba
25 | *
26 | * Usage:
27 |
28 | TODO: tba
29 |
30 | *
31 | ******************************************************************************/
32 |
33 | USE [msdb]
34 | GO
35 |
36 | IF EXISTS (SELECT name FROM msdb.dbo.sysjobs WHERE name='Queue_Module')
37 | BEGIN
38 | EXEC msdb.dbo.sp_delete_job @job_name='Queue_Module', @delete_unused_schedule=1
39 | END
40 |
41 | BEGIN TRANSACTION
42 | DECLARE @ReturnCode INT
43 | SELECT @ReturnCode = 0
44 |
45 | IF NOT EXISTS (SELECT name FROM msdb.dbo.syscategories WHERE name=N'[Uncategorized (Local)]' AND category_class=1)
46 | BEGIN
47 | EXEC @ReturnCode = msdb.dbo.sp_add_category @class=N'JOB', @type=N'LOCAL', @name=N'[Uncategorized (Local)]'
48 | IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
49 | END
50 |
51 | DECLARE @jobId BINARY(16)
52 | EXEC @ReturnCode = msdb.dbo.sp_add_job @job_name=N'Queue_Module',
53 | @enabled=1,
54 | @notify_level_eventlog=0,
55 | @notify_level_email=0,
56 | @notify_level_netsend=0,
57 | @notify_level_page=0,
58 | @delete_level=0,
59 | @description=N'No description available.',
60 | @category_name=N'[Uncategorized (Local)]',
61 | @owner_login_name=N'sa', @job_id = @jobId OUTPUT
62 |
63 | IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
64 |
65 | EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'Continuous_Integration',
66 | @step_id=1,
67 | @cmdexec_success_code=0,
68 | @on_success_action=1,
69 | @on_success_step_id=0,
70 | @on_fail_action=2,
71 | @on_fail_step_id=0,
72 | @retry_attempts=0,
73 | @retry_interval=0,
74 | @os_run_priority=0, @subsystem=N'TSQL',
75 | @command=N'/*
76 | Create a temporary in-memory stored procedure that can be used to return the number of currently running processes as per the control framework.
77 | */
78 | CREATE OR ALTER PROCEDURE #runningJobs
79 | @NUMBER_OF_RUNNING_PROCESSES INT OUTPUT
80 | AS
81 | (
82 | SELECT @NUMBER_OF_RUNNING_PROCESSES = (SELECT COUNT(*) FROM [Direct_Framework].omd.MODULE_INSTANCE WHERE EXECUTION_STATUS_CODE=''Executing'')
83 | )
84 | GO
85 |
86 | DECLARE @DEBUG_FLAG INT = 1; -- Debug is enabled by default
87 | DECLARE @MAX_CONCURRENCY INT = 2 -- Determines how many processes can be run in parallel / concurrent
88 | DECLARE @NUMBER_OF_RUNNING_PROCESSES INT = 0;
89 | DECLARE @NUMBER_OF_QUEUED_PROCESSES INT = 0;
90 | DECLARE @DELAY_TIME VARCHAR(8) = ''00:00:05'' -- This is the time the queue waits upon detecting concurrency
91 | DECLARE @PROCESS_NAME as VARCHAR(256);
92 | DECLARE @CURRENT_TIMESTAMP VARCHAR(19);
93 | DECLARE @PRINT_MESSAGE VARCHAR(1000);
94 | DECLARE @SQL_STRING NVARCHAR(4000);
95 | DECLARE @ModuleInstanceIdColumnName NVARCHAR(256) = ''AUDIT_TRAIL_ID'';
96 |
97 | WHILE 1 = 1
98 | BEGIN
99 | --Only execute the queue order when the number of executing processes is smaller than the maximum concurrency parameters
100 | EXEC #runningJobs @NUMBER_OF_RUNNING_PROCESSES OUTPUT
101 |
102 | SELECT @CURRENT_TIMESTAMP = (SELECT CAST(SYSUTCDATETIME() AS NVARCHAR(19)))
103 | SELECT @NUMBER_OF_QUEUED_PROCESSES = (SELECT COUNT(*) AS NUMBER_OF_QUEUED_PROCESSED FROM [Direct_Framework].[omd_processing].[vw_QUEUE_MODULE_PROCESSING])
104 |
105 | IF @DEBUG_FLAG = 1 PRINT ''@NUMBER_OF_RUNNING_PROCESSES= ''+CAST (@NUMBER_OF_RUNNING_PROCESSES AS VARCHAR(10))
106 | IF @DEBUG_FLAG = 1 PRINT ''@MAX_CONCURRENCY= ''+CAST (@MAX_CONCURRENCY AS VARCHAR(10))
107 | IF @DEBUG_FLAG = 1 PRINT ''@CURRENT_TIMESTAMP = ''+ @CURRENT_TIMESTAMP
108 | IF @DEBUG_FLAG = 1 PRINT ''@NUMBER_OF_QUEUED_PROCESSES = ''+ +CAST (@NUMBER_OF_QUEUED_PROCESSES AS VARCHAR(10))
109 |
110 | --Whenever the number of jobs exceeds the parameter, wait for a bit (as per the delay time)
111 | WHILE (@NUMBER_OF_RUNNING_PROCESSES >= @MAX_CONCURRENCY)
112 | BEGIN
113 | IF @DEBUG_FLAG =1
114 | BEGIN
115 | SET @PRINT_MESSAGE = ''WAITFOR ''+@DELAY_TIME+'', currently still @NUMBER_OF_RUNNING_PROCESSES at ''+CAST (@NUMBER_OF_RUNNING_PROCESSES AS VARCHAR(10))
116 | RAISERROR (@PRINT_MESSAGE, 0, 1) WITH NOWAIT; -- Raise Error used to flush to the debug window immediately, PRINT has a large delay
117 | END
118 |
119 | WAITFOR DELAY @DELAY_TIME -- Perform the wait / delay.
120 | EXEC #runningJobs @NUMBER_OF_RUNNING_PROCESSES OUTPUT -- Check again if the next process is good to g.
121 | END
122 |
123 | IF @DEBUG_FLAG =1 PRINT ''After wait @NUMBER_OF_RUNNING_PROCESSES= ''+CAST (@NUMBER_OF_RUNNING_PROCESSES AS VARCHAR(10))
124 | IF @DEBUG_FLAG =1 PRINT ''After wait @MAX_CONCURRENCY= ''+CAST (@MAX_CONCURRENCY AS VARCHAR(10))
125 | IF @DEBUG_FLAG =1 PRINT ''After wait @CURRENT_TIMESTAMP = ''+ @CURRENT_TIMESTAMP
126 |
127 | -- When a spot becomes available, run the process from the queue
128 | SELECT TOP 1 @PROCESS_NAME = MODULE_CODE
129 | FROM
130 | (
131 | -- Select the Module that has not run the longest (oldest age)
132 | SELECT MODULE_CODE, END_TIMESTAMP
133 | FROM [Direct_Framework].[omd_processing].[vw_QUEUE_MODULE_PROCESSING]
134 | ) moduleQueue
135 | ORDER BY END_TIMESTAMP ASC
136 |
137 | IF @PROCESS_NAME IS NULL
138 | BEGIN
139 | SET @PRINT_MESSAGE = ''No process was selected / available from the queue'';
140 | END
141 | ELSE
142 | BEGIN
143 |
144 | SET @PRINT_MESSAGE = ''Running process: ''+@PROCESS_NAME
145 |
146 | IF @DEBUG_FLAG =1 RAISERROR (@PRINT_MESSAGE, 0, 1) WITH NOWAIT
147 | BEGIN TRY
148 | EXEC [Direct_Framework].[omd].[RunModule] @ModuleCode = @PROCESS_NAME, @ModuleInstanceIdColumnName = @ModuleInstanceIdColumnName
149 | END TRY
150 | BEGIN CATCH
151 | SET @PROCESS_NAME = SUBSTRING(@PROCESS_NAME,1,LEN(@PROCESS_NAME)-5)
152 | SET @SQL_STRING = N''UPDATE [Direct_Framework].omd.MODULE SET ACTIVE_INDICATOR=''''N'''' WHERE MODULE_CODE=''''''+@PROCESS_NAME+''''''''
153 | SET @PRINT_MESSAGE = ''ERROR EXECUTING JOB: ''+@PROCESS_NAME+'' DEACTIVATE QUERY: ''+@SQL_STRING+''''
154 | RAISERROR (@PRINT_MESSAGE, 0, 1) WITH NOWAIT
155 | EXECUTE sp_executesql @SQL_STRING
156 | END CATCH
157 | END
158 |
159 | --Also functions as delayer
160 | -- This is mandatory! Otherwise processes will be spawned too fast! This prevents the same process to be kicked off many times before OMD has had the chance to register
161 | WAITFOR DELAY ''00:00:05''
162 | END
163 |
164 | DROP PROCEDURE #runningJobs',
165 | @database_name=N'master',
166 | @output_file_name=N'D:\Logs\Job_Master',
167 | @flags=2
168 |
169 | IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
170 | EXEC @ReturnCode = msdb.dbo.sp_update_job @job_id = @jobId, @start_step_id = 1
171 | IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
172 | EXEC @ReturnCode = msdb.dbo.sp_add_jobserver @job_id = @jobId, @server_name = N'(local)'
173 | IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
174 |
175 | COMMIT TRANSACTION
176 | GOTO EndSave
177 |
178 | QuitWithRollback:
179 | IF (@@TRANCOUNT > 0) ROLLBACK TRANSACTION
180 |
181 | EndSave:
182 |
183 | GO
184 |
--------------------------------------------------------------------------------
/Direct_Framework/DeploymentScripts/3-PostDeployment/Script.PostDeployment.sql:
--------------------------------------------------------------------------------
1 | /*******************************************************************************
2 | * Post-Deployment Script
3 | *******************************************************************************
4 | *
5 | * This file contains SQL statements that will be appended to the build script.
6 | * This is executed by SqlPackage/DacFx after the DACPAC has been deployed
7 | * to the target database.
8 | *
9 | * https://github.com/microsoft/DacFx
10 | * https://aka.ms/sqlpackage-ref
11 | *
12 | * Use SQLCMD syntax to include a file in the post-deployment script.
13 | * Example: :r .\myfile.sql
14 | *
15 | * Use SQLCMD syntax to reference a variable in the post-deployment script.
16 | * Example: :setvar TableName MyTable
17 | * SELECT * FROM [$(TableName)]
18 | ******************************************************************************/
19 |
20 | -- Reference data for metadata tables, run in dependency order
21 | :r .\omd_metadata.LAYER.sql
22 | :r .\omd_metadata.AREA.sql
23 | :r .\omd_metadata.EVENT_TYPE.sql
24 | :r .\omd_metadata.EXECUTION_STATUS.sql
25 | :r .\omd_metadata.NEXT_RUN_STATUS.sql
26 | :r .\omd_metadata.INTERNAL_PROCESSING_STATUS.sql
27 | :r .\omd_metadata.FREQUENCY.sql
28 | :r .\omd_metadata.FRAMEWORK_METADATA.sql
29 |
30 | -- Base operational placeholders, run in dependency order
31 | :r .\omd.BATCH.sql
32 | :r .\omd.BATCH_INSTANCE.sql
33 | :r .\omd.MODULE.sql
34 | :r .\omd.MODULE_INSTANCE.sql
35 | :r .\omd.MODULE_INSTANCE_EXECUTED_CODE.sql
36 |
37 | -- Orchestration Process Queuing
38 | -- Traditional on-premises SQL server/Local SQL Server instance, or Azure Managed Instance deployments only:
39 | -- :r .\Queue_Job_Batch.sql
40 | -- :r .\Queue_Job_Module.sql
41 |
--------------------------------------------------------------------------------
/Direct_Framework/DeploymentScripts/3-PostDeployment/omd.BATCH.sql:
--------------------------------------------------------------------------------
1 | /*******************************************************************************
2 | * https://github.com/data-solution-automation-engine/DIRECT
3 | * Reference data insert and update script
4 | * DIRECT Framework v2.0
5 | *
6 | * [omd].[BATCH]
7 | *
8 | ******************************************************************************/
9 |
10 | SET NOCOUNT ON;
11 | SET IDENTITY_INSERT [omd].[BATCH] ON;
12 |
13 | DECLARE @tblMerge TABLE(
14 | [BATCH_ID] INT NOT NULL,
15 | [BATCH_CODE] NVARCHAR (1000) NOT NULL,
16 | [BATCH_TYPE] NVARCHAR (100) NULL,
17 | [FREQUENCY_CODE] NVARCHAR (100) NOT NULL,
18 | [BATCH_DESCRIPTION] NVARCHAR (4000) NULL,
19 | [ACTIVE_INDICATOR] CHAR (1) NOT NULL
20 | );
21 |
22 | INSERT INTO @tblMerge
23 | (
24 | [BATCH_ID],
25 | [BATCH_CODE],
26 | [BATCH_TYPE],
27 | [FREQUENCY_CODE],
28 | [BATCH_DESCRIPTION],
29 | [ACTIVE_INDICATOR]
30 | )
31 | VALUES
32 | (0, N'Default Batch', N'Maintenance', N'On-demand', N'Placeholder value for disconnected Batch runs', N'Y')
33 |
34 | MERGE [omd].[BATCH] AS TARGET
35 | USING @tblMerge AS src
36 | ON TARGET.[BATCH_ID] = src.[BATCH_ID]
37 |
38 | WHEN MATCHED THEN
39 | UPDATE
40 | SET [BATCH_CODE] = src.[BATCH_CODE],
41 | [BATCH_TYPE] = src.[BATCH_TYPE],
42 | [FREQUENCY_CODE] = src.[FREQUENCY_CODE],
43 | [BATCH_DESCRIPTION] = src.[BATCH_DESCRIPTION],
44 | [ACTIVE_INDICATOR] = src.[ACTIVE_INDICATOR]
45 |
46 | WHEN NOT MATCHED THEN
47 | INSERT
48 | (
49 | [BATCH_ID],
50 | [BATCH_CODE],
51 | [BATCH_TYPE],
52 | [FREQUENCY_CODE],
53 | [BATCH_DESCRIPTION],
54 | [ACTIVE_INDICATOR]
55 | )
56 | VALUES
57 | (
58 | [BATCH_ID],
59 | [BATCH_CODE],
60 | [BATCH_TYPE],
61 | [FREQUENCY_CODE],
62 | [BATCH_DESCRIPTION],
63 | [ACTIVE_INDICATOR]
64 | );
65 |
66 | SET IDENTITY_INSERT [omd].[BATCH] OFF;
67 |
68 | GO
69 |
--------------------------------------------------------------------------------
/Direct_Framework/DeploymentScripts/3-PostDeployment/omd.BATCH_INSTANCE.sql:
--------------------------------------------------------------------------------
1 | /*******************************************************************************
2 | * https://github.com/data-solution-automation-engine/DIRECT
3 | * Reference data insert and update script
4 | * DIRECT Framework v2.0
5 | *
6 | * [omd].[BATCH_INSTANCE]
7 | *
8 | ******************************************************************************/
9 |
10 | SET NOCOUNT ON;
11 | SET IDENTITY_INSERT [omd].[BATCH_INSTANCE] ON;
12 |
13 | DECLARE @tblMerge TABLE(
14 | [BATCH_INSTANCE_ID] BIGINT NOT NULL
15 | ,[BATCH_ID] INT NOT NULL
16 | ,[PARENT_BATCH_INSTANCE_ID] BIGINT NOT NULL
17 | ,[START_TIMESTAMP] DATETIME2 NOT NULL
18 | ,[END_TIMESTAMP] DATETIME2 NULL
19 | ,[INTERNAL_PROCESSING_CODE] NVARCHAR (100) NOT NULL
20 | ,[NEXT_RUN_STATUS_CODE] NVARCHAR (100) NOT NULL
21 | ,[EXECUTION_STATUS_CODE] NVARCHAR (100) NOT NULL
22 | ,[EXECUTION_CONTEXT] NVARCHAR (4000) NULL
23 | );
24 |
25 | INSERT INTO @tblMerge
26 | (
27 | [BATCH_INSTANCE_ID]
28 | ,[BATCH_ID]
29 | ,[PARENT_BATCH_INSTANCE_ID]
30 | ,[START_TIMESTAMP]
31 | ,[END_TIMESTAMP]
32 | ,[INTERNAL_PROCESSING_CODE]
33 | ,[NEXT_RUN_STATUS_CODE]
34 | ,[EXECUTION_STATUS_CODE]
35 | ,[EXECUTION_CONTEXT]
36 | )
37 | VALUES
38 | (
39 | 0 -- [BATCH_INSTANCE_ID]
40 | ,0 -- [BATCH_ID]
41 | ,0 -- [PARENT_BATCH_INSTANCE_ID]
42 | ,CAST(N'0001-01-01T00:00:00.000' AS DATETIME2) -- [START_TIMESTAMP]
43 | ,CAST(N'9999-12-31T00:00:00.000' AS DATETIME2) -- [END_TIMESTAMP]
44 | ,N'Proceed' -- [INTERNAL_PROCESSING_CODE]
45 | ,N'Proceed' -- [NEXT_RUN_STATUS_CODE]
46 | ,N'Succeeded' -- [EXECUTION_STATUS_CODE]
47 | ,N'' -- [EXECUTION_CONTEXT]
48 | )
49 |
50 | MERGE [omd].[BATCH_INSTANCE] AS TARGET
51 | USING @tblMerge AS src
52 | ON TARGET.[BATCH_INSTANCE_ID] = src.[BATCH_INSTANCE_ID]
53 |
54 | WHEN MATCHED THEN
55 | UPDATE
56 | SET
57 | [BATCH_ID] = src.[BATCH_ID]
58 | ,[PARENT_BATCH_INSTANCE_ID] = src.[PARENT_BATCH_INSTANCE_ID]
59 | ,[START_TIMESTAMP] = src.[START_TIMESTAMP]
60 | ,[END_TIMESTAMP] = src.[END_TIMESTAMP]
61 | ,[INTERNAL_PROCESSING_CODE] = src.[INTERNAL_PROCESSING_CODE]
62 | ,[NEXT_RUN_STATUS_CODE] = src.[NEXT_RUN_STATUS_CODE]
63 | ,[EXECUTION_STATUS_CODE] = src.[EXECUTION_STATUS_CODE]
64 | ,[EXECUTION_CONTEXT] = src.[EXECUTION_CONTEXT]
65 |
66 | WHEN NOT MATCHED THEN
67 | INSERT
68 | (
69 | [BATCH_INSTANCE_ID]
70 | ,[BATCH_ID]
71 | ,[PARENT_BATCH_INSTANCE_ID]
72 | ,[START_TIMESTAMP]
73 | ,[END_TIMESTAMP]
74 | ,[INTERNAL_PROCESSING_CODE]
75 | ,[NEXT_RUN_STATUS_CODE]
76 | ,[EXECUTION_STATUS_CODE]
77 | ,[EXECUTION_CONTEXT]
78 | )
79 | VALUES
80 | (
81 | [BATCH_INSTANCE_ID]
82 | ,[BATCH_ID]
83 | ,[PARENT_BATCH_INSTANCE_ID]
84 | ,[START_TIMESTAMP]
85 | ,[END_TIMESTAMP]
86 | ,[INTERNAL_PROCESSING_CODE]
87 | ,[NEXT_RUN_STATUS_CODE]
88 | ,[EXECUTION_STATUS_CODE]
89 | ,[EXECUTION_CONTEXT]
90 | );
91 |
92 | SET IDENTITY_INSERT [omd].[BATCH_INSTANCE] OFF;
93 |
94 | GO
95 |
--------------------------------------------------------------------------------
/Direct_Framework/DeploymentScripts/3-PostDeployment/omd.MODULE.sql:
--------------------------------------------------------------------------------
1 | /*******************************************************************************
2 | * https://github.com/data-solution-automation-engine/DIRECT
3 | * Reference data insert and update script
4 | * DIRECT Framework v2.0
5 | *
6 | * [omd].[MODULE]
7 | *
8 | ******************************************************************************/
9 |
10 | SET NOCOUNT ON;
11 | SET IDENTITY_INSERT [omd].[MODULE] ON;
12 |
13 | DECLARE @tblMerge TABLE(
14 | [MODULE_ID] INT NOT NULL,
15 | [MODULE_CODE] NVARCHAR (1000) NOT NULL,
16 | [MODULE_DESCRIPTION] NVARCHAR (4000) NOT NULL,
17 | [MODULE_TYPE] NVARCHAR (100) NOT NULL,
18 | [DATA_OBJECT_SOURCE] NVARCHAR (1000) NOT NULL,
19 | [DATA_OBJECT_TARGET] NVARCHAR (1000) NOT NULL,
20 | [AREA_CODE] NVARCHAR (100) NOT NULL,
21 | [FREQUENCY_CODE] NVARCHAR (100) NOT NULL,
22 | [ACTIVE_INDICATOR] CHAR (1) NOT NULL,
23 | [EXECUTABLE] NVARCHAR (MAX) NOT NULL
24 | );
25 |
26 | INSERT INTO @tblMerge
27 | (
28 | [MODULE_ID],
29 | [MODULE_CODE],
30 | [MODULE_DESCRIPTION],
31 | [MODULE_TYPE],
32 | [DATA_OBJECT_SOURCE],
33 | [DATA_OBJECT_TARGET],
34 | [AREA_CODE],
35 | [FREQUENCY_CODE],
36 | [ACTIVE_INDICATOR],
37 | [EXECUTABLE]
38 | )
39 | VALUES
40 | (
41 | 0,
42 | N'Default Module',
43 | N'Placeholder value for disconnected Module runs',
44 | N'DataLogistics',
45 | N'N/A',
46 | N'N/A',
47 | N'Maintenance',
48 | N'On-demand',
49 | 'Y',
50 | N'SELECT NULL'
51 | )
52 |
53 | MERGE [omd].[MODULE] AS TARGET
54 | USING @tblMerge AS src
55 | ON TARGET.[MODULE_ID] = src.[MODULE_ID]
56 |
57 | WHEN MATCHED THEN
58 | UPDATE
59 | SET
60 | [MODULE_CODE] = src.[MODULE_CODE],
61 | [MODULE_DESCRIPTION] = src.[MODULE_DESCRIPTION],
62 | [MODULE_TYPE] = src.[MODULE_TYPE],
63 | [DATA_OBJECT_SOURCE] = src.[DATA_OBJECT_SOURCE],
64 | [DATA_OBJECT_TARGET] = src.[DATA_OBJECT_TARGET],
65 | [AREA_CODE] = src.[AREA_CODE],
66 | [FREQUENCY_CODE] = src.[FREQUENCY_CODE],
67 | [ACTIVE_INDICATOR] = src.[ACTIVE_INDICATOR],
68 | [EXECUTABLE] = src.[EXECUTABLE]
69 |
70 | WHEN NOT MATCHED THEN
71 | INSERT
72 | (
73 | [MODULE_ID],
74 | [MODULE_CODE],
75 | [MODULE_DESCRIPTION],
76 | [MODULE_TYPE],
77 | [DATA_OBJECT_SOURCE],
78 | [DATA_OBJECT_TARGET],
79 | [AREA_CODE],
80 | [FREQUENCY_CODE],
81 | [ACTIVE_INDICATOR],
82 | [EXECUTABLE]
83 | )
84 | VALUES
85 | (
86 | [MODULE_ID],
87 | [MODULE_CODE],
88 | [MODULE_DESCRIPTION],
89 | [MODULE_TYPE],
90 | [DATA_OBJECT_SOURCE],
91 | [DATA_OBJECT_TARGET],
92 | [AREA_CODE],
93 | [FREQUENCY_CODE],
94 | [ACTIVE_INDICATOR],
95 | [EXECUTABLE]
96 | );
97 |
98 | SET IDENTITY_INSERT [omd].[MODULE] OFF;
99 |
100 | GO
101 |
--------------------------------------------------------------------------------
/Direct_Framework/DeploymentScripts/3-PostDeployment/omd.MODULE_INSTANCE.sql:
--------------------------------------------------------------------------------
1 | /*******************************************************************************
2 | * https://github.com/data-solution-automation-engine/DIRECT
3 | * Reference data insert and update script
4 | * DIRECT Framework v2.0
5 | *
6 | * [omd].[MODULE_INSTANCE]
7 | *
8 | ******************************************************************************/
9 |
10 | SET NOCOUNT ON;
11 |
12 | SET IDENTITY_INSERT [omd].[MODULE_INSTANCE] ON;
13 |
14 | DECLARE @tblMerge TABLE
15 | (
16 | [MODULE_INSTANCE_ID] BIGINT NOT NULL,
17 | [MODULE_ID] INT NOT NULL,
18 | [BATCH_INSTANCE_ID] BIGINT NOT NULL,
19 | [START_TIMESTAMP] DATETIME2 NOT NULL,
20 | [END_TIMESTAMP] DATETIME2 NULL,
21 | [INTERNAL_PROCESSING_CODE] NVARCHAR (100) NOT NULL,
22 | [NEXT_RUN_STATUS_CODE] NVARCHAR (100) NOT NULL,
23 | [EXECUTION_STATUS_CODE] NVARCHAR (100) NOT NULL,
24 | [EXECUTION_CONTEXT] NVARCHAR (4000) NULL,
25 | [ROWS_INPUT] INT NULL,
26 | [ROWS_INSERTED] INT NULL,
27 | [ROWS_UPDATED] INT NULL,
28 | [ROWS_DELETED] INT NULL,
29 | [ROWS_DISCARDED] INT NULL,
30 | [ROWS_REJECTED] INT NULL,
31 | [EXECUTED_CODE_CHECKSUM] VARBINARY(64) NULL
32 | );
33 |
34 | INSERT INTO @tblMerge
35 | (
36 | [MODULE_INSTANCE_ID],
37 | [MODULE_ID],
38 | [BATCH_INSTANCE_ID],
39 | [START_TIMESTAMP],
40 | [END_TIMESTAMP],
41 | [INTERNAL_PROCESSING_CODE],
42 | [NEXT_RUN_STATUS_CODE],
43 | [EXECUTION_STATUS_CODE],
44 | [EXECUTION_CONTEXT],
45 | [ROWS_INPUT],
46 | [ROWS_INSERTED],
47 | [ROWS_UPDATED],
48 | [ROWS_DELETED],
49 | [ROWS_DISCARDED],
50 | [ROWS_REJECTED],
51 | [EXECUTED_CODE_CHECKSUM]
52 | )
53 | VALUES
54 | (
55 | 0, -- [MODULE_INSTANCE_ID]
56 | 0, -- [MODULE_ID]
57 | 0, -- [BATCH_INSTANCE_ID]
58 | CAST(N'0001-01-01T00:00:00.000' AS DATETIME2), -- [START_TIMESTAMP]
59 | CAST(N'9999-12-31T00:00:00.000' AS DATETIME2), -- [END_TIMESTAMP]
60 | N'Proceed', -- [INTERNAL_PROCESSING_CODE]
61 | N'Proceed', -- [NEXT_RUN_STATUS_CODE]
62 | N'Succeeded', -- [EXECUTION_STATUS_CODE]
63 | N'N/A', -- [EXECUTION_CONTEXT]
64 | 0, -- [ROWS_INPUT]
65 | 0, -- [ROWS_INSERTED]
66 | 0, -- [ROWS_UPDATED]
67 | 0, -- [ROWS_DELETED]
68 | 0, -- [ROWS_DISCARDED]
69 | 0, -- [ROWS_REJECTED]
70 |
71 | -- special mapping of null or empty query to a 0-hash placeholder in the
72 | -- omd.MODULE_INSTANCE_EXECUTED_CODE table
73 | CONVERT(VARBINARY(64), REPLICATE(0x00, 64)) -- [EXECUTED_CODE_CHECKSUM]
74 | )
75 |
76 | MERGE [omd].[MODULE_INSTANCE] AS TARGET
77 | USING @tblMerge AS src
78 | ON TARGET.[BATCH_INSTANCE_ID] = src.[BATCH_INSTANCE_ID]
79 |
80 | WHEN MATCHED THEN
81 | UPDATE
82 | SET
83 | [MODULE_ID] = src.[MODULE_ID],
84 | [BATCH_INSTANCE_ID] = src.[BATCH_INSTANCE_ID],
85 | [START_TIMESTAMP] = src.[START_TIMESTAMP],
86 | [END_TIMESTAMP] = src.[END_TIMESTAMP],
87 | [INTERNAL_PROCESSING_CODE] = src.[INTERNAL_PROCESSING_CODE],
88 | [NEXT_RUN_STATUS_CODE] = src.[NEXT_RUN_STATUS_CODE],
89 | [EXECUTION_STATUS_CODE] = src.[EXECUTION_STATUS_CODE],
90 | [EXECUTION_CONTEXT] = src.[EXECUTION_CONTEXT],
91 | [ROWS_INPUT] = src.[ROWS_INPUT],
92 | [ROWS_INSERTED] = src.[ROWS_INSERTED],
93 | [ROWS_UPDATED] = src.[ROWS_UPDATED],
94 | [ROWS_DELETED] = src.[ROWS_DELETED],
95 | [ROWS_DISCARDED] = src.[ROWS_DISCARDED],
96 | [ROWS_REJECTED] = src.[ROWS_REJECTED],
97 | [EXECUTED_CODE_CHECKSUM] = src.[EXECUTED_CODE_CHECKSUM]
98 |
99 | WHEN NOT MATCHED THEN
100 | INSERT
101 | (
102 | [MODULE_INSTANCE_ID],
103 | [MODULE_ID],
104 | [BATCH_INSTANCE_ID],
105 | [START_TIMESTAMP],
106 | [END_TIMESTAMP],
107 | [INTERNAL_PROCESSING_CODE],
108 | [NEXT_RUN_STATUS_CODE],
109 | [EXECUTION_STATUS_CODE],
110 | [EXECUTION_CONTEXT],
111 | [ROWS_INPUT],
112 | [ROWS_INSERTED],
113 | [ROWS_UPDATED],
114 | [ROWS_DELETED],
115 | [ROWS_DISCARDED],
116 | [ROWS_REJECTED],
117 | [EXECUTED_CODE_CHECKSUM]
118 | )
119 | VALUES
120 | (
121 | [MODULE_INSTANCE_ID],
122 | [MODULE_ID],
123 | [BATCH_INSTANCE_ID],
124 | [START_TIMESTAMP],
125 | [END_TIMESTAMP],
126 | [INTERNAL_PROCESSING_CODE],
127 | [NEXT_RUN_STATUS_CODE],
128 | [EXECUTION_STATUS_CODE],
129 | [EXECUTION_CONTEXT],
130 | [ROWS_INPUT],
131 | [ROWS_INSERTED],
132 | [ROWS_UPDATED],
133 | [ROWS_DELETED],
134 | [ROWS_DISCARDED],
135 | [ROWS_REJECTED],
136 | [EXECUTED_CODE_CHECKSUM]
137 | );
138 |
139 | SET IDENTITY_INSERT [omd].[MODULE_INSTANCE] OFF;
140 |
141 | GO
142 |
--------------------------------------------------------------------------------
/Direct_Framework/DeploymentScripts/3-PostDeployment/omd.MODULE_INSTANCE_EXECUTED_CODE.sql:
--------------------------------------------------------------------------------
1 | /*******************************************************************************
2 | * https://github.com/data-solution-automation-engine/DIRECT
3 | * Reference data insert and update script
4 | * DIRECT Framework v2.0
5 | *
6 | * [omd].[MODULE_INSTANCE_EXECUTED_CODE]
7 | *
8 | ******************************************************************************/
9 |
10 | SET NOCOUNT ON;
11 |
12 | DECLARE @tblMerge TABLE
13 | (
14 | [CHECKSUM] VARBINARY(64) NOT NULL,
15 | [EXECUTED_CODE] NVARCHAR(MAX) NOT NULL
16 | );
17 |
18 | INSERT INTO @tblMerge
19 | (
20 | [CHECKSUM],
21 | [EXECUTED_CODE]
22 | )
23 | VALUES
24 | (
25 | -- special 0-hash key placeholder for null or empty code
26 | CONVERT(VARBINARY(64), REPLICATE(0x00, 64)), -- [CHECKSUM],
27 | N'' -- [EXECUTED_CODE]
28 | )
29 |
30 | MERGE [omd].[MODULE_INSTANCE_EXECUTED_CODE] AS TARGET
31 | USING @tblMerge AS src
32 | ON TARGET.[CHECKSUM] = src.[CHECKSUM]
33 |
34 | WHEN MATCHED THEN
35 | UPDATE
36 | SET
37 | [EXECUTED_CODE] = src.[EXECUTED_CODE]
38 |
39 | WHEN NOT MATCHED THEN
40 | INSERT
41 | (
42 | [CHECKSUM], [EXECUTED_CODE]
43 | )
44 | VALUES
45 | (
46 | [CHECKSUM], [EXECUTED_CODE]
47 | );
48 |
49 | GO
50 |
--------------------------------------------------------------------------------
/Direct_Framework/DeploymentScripts/3-PostDeployment/omd_metadata.AREA.sql:
--------------------------------------------------------------------------------
1 | /*******************************************************************************
2 | * https://github.com/data-solution-automation-engine/DIRECT
3 | * Reference data insert and update script
4 | * DIRECT Framework v2.0
5 | *
6 | * Reference metadata table AREA stores areas and layers information.
7 | *
8 | * This script is used to insert and update reference data on deployment.
9 | * Any bespoke event types added manually to the target will be retained,
10 | * as long as the keys differ.
11 | *
12 | * To maintain a clean CI/CD process, consider using this script to manage
13 | * all reference data for event types.
14 | *
15 | * [omd_metadata].[AREA]
16 | *
17 | ******************************************************************************/
18 |
19 | SET NOCOUNT ON;
20 |
21 | DECLARE @tblMerge TABLE(
22 | [AREA_CODE] NVARCHAR (100) NOT NULL PRIMARY KEY CLUSTERED,
23 | [LAYER_CODE] NVARCHAR (100) NOT NULL,
24 | [AREA_DESCRIPTION] NVARCHAR (4000) NULL
25 | );
26 |
27 | INSERT INTO @tblMerge([AREA_CODE], [LAYER_CODE], [AREA_DESCRIPTION])
28 | VALUES
29 | (N'HELPER', N'Presentation', N'The Helper Area'),
30 | (N'INT', N'Integration', N'The Base Integration Area'),
31 | (N'INTPR', N'Integration', N'The Derived Integration Area'),
32 | (N'LND', N'Staging', N'The Landing Area of the Staging Layer'),
33 | (N'Maintenance', N'Maintenance', N'Internal Data Solution'),
34 | (N'PRES', N'Presentation', N'The Access Area'),
35 | (N'PSA', N'Staging', N'The Persistent Staging Area'),
36 | (N'STG', N'Staging', N'The Staging Area of the Staging Layer'),
37 | (N'SYNC', N'Staging', N'Synchronization of the production History Area of the Staging Layer for build and test')
38 |
39 | MERGE [omd_metadata].[AREA] AS TARGET
40 | USING @tblMerge AS src
41 | ON TARGET.[AREA_CODE] = src.[AREA_CODE]
42 |
43 | WHEN MATCHED THEN
44 | UPDATE
45 | SET [LAYER_CODE] = src.[LAYER_CODE],
46 | [AREA_DESCRIPTION] = src.[AREA_DESCRIPTION]
47 |
48 | WHEN NOT MATCHED THEN
49 | INSERT ([AREA_CODE]
50 | ,[LAYER_CODE]
51 | ,[AREA_DESCRIPTION])
52 | VALUES ([AREA_CODE]
53 | ,[LAYER_CODE]
54 | ,[AREA_DESCRIPTION]);
55 |
56 | GO
57 |
--------------------------------------------------------------------------------
/Direct_Framework/DeploymentScripts/3-PostDeployment/omd_metadata.EVENT_TYPE.sql:
--------------------------------------------------------------------------------
1 | /*******************************************************************************
2 | * https://github.com/data-solution-automation-engine/DIRECT
3 | * Reference data insert and update script
4 | * DIRECT Framework v2.0
5 | *
6 | * Reference metadata table EVENT_TYPE stores event type codes and descriptions.
7 | * This script is used to insert and update reference data on deployment.
8 | * Any bespoke event types added manually to the target will be retained,
9 | * as long as the keys differ.
10 | * To maintain a clean CI/CD process, consider using this script to manage
11 | * all reference data for event types.
12 | *
13 | * [omd_metadata].[EVENT_TYPE]
14 | *
15 | ******************************************************************************/
16 |
17 | SET NOCOUNT ON;
18 |
19 | DECLARE @tblMerge TABLE(
20 | [EVENT_TYPE_CODE] NVARCHAR (100) NOT NULL PRIMARY KEY CLUSTERED,
21 | [EVENT_TYPE_CODE_DESCRIPTION] NVARCHAR (4000) NULL
22 | );
23 |
24 | INSERT INTO @tblMerge([EVENT_TYPE_CODE], [EVENT_TYPE_CODE_DESCRIPTION])
25 | VALUES
26 | (N'1', N'Infrastructure error.'),
27 | (N'2', N'Internal data integration process error or system generated event.'),
28 | (N'3', N'Custom exception handling that has been implemented in code (Error Bitmaps).')
29 |
30 | MERGE [omd_metadata].[EVENT_TYPE] AS TARGET
31 | USING @tblMerge AS src
32 | ON TARGET.[EVENT_TYPE_CODE] = src.[EVENT_TYPE_CODE]
33 |
34 | WHEN MATCHED THEN
35 | UPDATE
36 | SET [EVENT_TYPE_CODE_DESCRIPTION] = src.[EVENT_TYPE_CODE_DESCRIPTION]
37 |
38 | WHEN NOT MATCHED THEN
39 | INSERT ([EVENT_TYPE_CODE]
40 | ,[EVENT_TYPE_CODE_DESCRIPTION])
41 | VALUES ([EVENT_TYPE_CODE]
42 | ,[EVENT_TYPE_CODE_DESCRIPTION]);
43 |
44 | GO
45 |
--------------------------------------------------------------------------------
/Direct_Framework/DeploymentScripts/3-PostDeployment/omd_metadata.EXECUTION_STATUS.sql:
--------------------------------------------------------------------------------
1 | /*******************************************************************************
2 | * https://github.com/data-solution-automation-engine/DIRECT
3 | * Reference data insert and update script
4 | * DIRECT Framework v2.0
5 |
6 | * Reference metadata table EXECUTION_STATUS stores execution status codes and descriptions.
7 | * This script is used to insert and update reference data on deployment.
8 | * Any bespoke execution status codes added manually to the target will be retained,
9 | * as long as the keys differ.
10 | * To maintain a clean CI/CD process, consider using this script to manage
11 | * all reference data for execution status codes.
12 | *
13 | * [omd_metadata].[EXECUTION_STATUS]
14 | *
15 | ******************************************************************************/
16 |
17 | SET NOCOUNT ON;
18 |
19 | DECLARE @tblMerge TABLE(
20 | [EXECUTION_STATUS_CODE] NVARCHAR (100) NOT NULL PRIMARY KEY CLUSTERED,
21 | [EXECUTION_STATUS_DESCRIPTION] NVARCHAR (4000) NULL
22 | );
23 |
24 | INSERT INTO @tblMerge([EXECUTION_STATUS_CODE], [EXECUTION_STATUS_DESCRIPTION])
25 | VALUES
26 | (N'Aborted', N'An abort is an attempted execution which led to the instance unable to start. Abort means that the process did not run, but was supposed to. This is typically the result of incorrect configuration or race conditions in the orchestration. The most common reasons for an abort is that another instance of the same Batch or Module is already running. The same logical unit of processing can never run more than once at the same time to maintain data consistency. If this situation is detected the second process will abort before any data is processed. The Module (Instance) was executed from a parent Batch (Instance) but not registered as such in the Batch/Module relationship.'),
27 | (N'Cancelled', N'The cancelled (skipped) status code indicates that the instance was attempted to be executed, but that the control framework found that it was not necessary to run the process. This can be due to Modules or Batches being disabled in the framework using the Active Indicator. Disabling processes can be done at Batch, Batch/Module and Module level. Another common scenario is that, when Batches are restarted, earlier successful Modules in that Batch will not be reprocessed. These Module Instances will be skipped / cancelled until the full Batch has completed successfully. This is to prevents data loss.'),
28 | (N'Executing', N'The instance is currently running (executing). This is a transient state only, for when the process is actually running. As soon as it is completed this code will be updated to one of the end-state execution codes.'),
29 | (N'Failed', N'The instance is no longer running after completing with failures.'),
30 | (N'Succeeded', N'The instance is no longer running after successful completion of the process.')
31 |
32 | MERGE [omd_metadata].[EXECUTION_STATUS] AS TARGET
33 | USING @tblMerge AS src
34 | ON TARGET.[EXECUTION_STATUS_CODE] = src.[EXECUTION_STATUS_CODE]
35 |
36 | WHEN MATCHED THEN
37 | UPDATE
38 | SET [EXECUTION_STATUS_DESCRIPTION] = src.[EXECUTION_STATUS_DESCRIPTION]
39 |
40 | WHEN NOT MATCHED THEN
41 | INSERT ([EXECUTION_STATUS_CODE]
42 | ,[EXECUTION_STATUS_DESCRIPTION])
43 | VALUES ([EXECUTION_STATUS_CODE]
44 | ,[EXECUTION_STATUS_DESCRIPTION]);
45 |
46 | GO
47 |
--------------------------------------------------------------------------------
/Direct_Framework/DeploymentScripts/3-PostDeployment/omd_metadata.FRAMEWORK_METADATA.sql:
--------------------------------------------------------------------------------
1 | /*******************************************************************************
2 | * https://github.com/data-solution-automation-engine/DIRECT
3 | * Reference data insert and update script
4 | * DIRECT Framework v2.0
5 | *
6 | * Reference metadata table FRAMEWORK_METADATA stores metadata information.
7 | * This script is used to insert and update reference data on deployment.
8 | * Any bespoke metadata added manually to the target will be retained,
9 | * as long as the keys differ.
10 | * To maintain a clean CI/CD process, consider using this script to manage
11 | * all reference data for metadata.
12 | *
13 | * [omd_metadata].[FRAMEWORK_METADATA]
14 | *
15 | ******************************************************************************/
16 |
17 | SET NOCOUNT ON;
18 |
19 | DECLARE @tblMerge TABLE(
20 | [CODE] NVARCHAR (100) NOT NULL PRIMARY KEY CLUSTERED,
21 | [VALUE] NVARCHAR (4000) NULL,
22 | [GROUP] NVARCHAR (100) NOT NULL,
23 | [DESCRIPTION] NVARCHAR (4000) NULL,
24 | [ACTIVE_INDICATOR] CHAR(1) NOT NULL
25 | );
26 |
27 | INSERT INTO @tblMerge([CODE], [VALUE], [GROUP], [DESCRIPTION], [ACTIVE_INDICATOR])
28 | VALUES
29 | (N'DIRECT_VERSION', N'2.0.0.0', N'SYSTEM_METADATA', N'The current version of the DIRECT Framework and database', 'Y')
30 |
31 | MERGE [omd_metadata].[FRAMEWORK_METADATA] AS TARGET
32 | USING @tblMerge AS src
33 | ON TARGET.[CODE] = src.[CODE]
34 |
35 | WHEN MATCHED THEN
36 | UPDATE
37 | SET [VALUE] = src.[VALUE],
38 | [GROUP] = src.[GROUP],
39 | [DESCRIPTION] = src.[DESCRIPTION],
40 | [ACTIVE_INDICATOR] = src.[ACTIVE_INDICATOR]
41 |
42 | WHEN NOT MATCHED THEN
43 | INSERT ([CODE]
44 | ,[VALUE]
45 | ,[GROUP]
46 | ,[DESCRIPTION]
47 | ,[ACTIVE_INDICATOR])
48 | VALUES ([CODE]
49 | ,[VALUE]
50 | ,[GROUP]
51 | ,[DESCRIPTION]
52 | ,[ACTIVE_INDICATOR]);
53 |
54 | GO
55 |
--------------------------------------------------------------------------------
/Direct_Framework/DeploymentScripts/3-PostDeployment/omd_metadata.FREQUENCY.sql:
--------------------------------------------------------------------------------
1 | /*******************************************************************************
2 | * https://github.com/data-solution-automation-engine/DIRECT
3 | * Reference data insert and update script
4 | * DIRECT Framework v2.0
5 | *
6 | * Reference metadata table FREQUENCY stores frequency information.
7 | * This table is used to define the frequency of the processing unit.
8 | * This script is used to insert and update reference data on deployment.
9 | * Any bespoke frequency added manually to the target will be retained,
10 | * as long as the keys differ.
11 | * To maintain a clean CI/CD process, consider using this script to manage
12 | * all reference data for frequency.
13 | *
14 | * [omd_metadata].[FREQUENCY]
15 | *
16 | ******************************************************************************/
17 |
18 | SET NOCOUNT ON;
19 |
20 | DECLARE @tblMerge TABLE(
21 | [FREQUENCY_CODE] NVARCHAR (100) NOT NULL PRIMARY KEY CLUSTERED,
22 | [FREQUENCY_DESCRIPTION] NVARCHAR (4000) NOT NULL
23 | );
24 |
25 | INSERT INTO @tblMerge([FREQUENCY_CODE], [FREQUENCY_DESCRIPTION])
26 | VALUES
27 | (N'Continuous', N'Continuously running integration processing unit.'),
28 | (N'Triggered', N'Event triggered processing unit.'),
29 | (N'On-demand', N'On-demand processing unit.'),
30 | (N'Scheduled', N'Scheduled processing unit.')
31 |
32 | MERGE [omd_metadata].[FREQUENCY] AS TARGET
33 | USING @tblMerge AS src
34 | ON TARGET.[FREQUENCY_CODE] = src.[FREQUENCY_CODE]
35 |
36 | WHEN MATCHED THEN
37 | UPDATE
38 | SET [FREQUENCY_DESCRIPTION] = src.[FREQUENCY_DESCRIPTION]
39 |
40 | WHEN NOT MATCHED THEN
41 | INSERT ([FREQUENCY_CODE], [FREQUENCY_DESCRIPTION])
42 | VALUES ([FREQUENCY_CODE], [FREQUENCY_DESCRIPTION]);
43 |
44 | GO
45 |
--------------------------------------------------------------------------------
/Direct_Framework/DeploymentScripts/3-PostDeployment/omd_metadata.INTERNAL_PROCESSING_STATUS.sql:
--------------------------------------------------------------------------------
1 | /*******************************************************************************
2 | * https://github.com/data-solution-automation-engine/DIRECT
3 | * Reference data insert and update script
4 | * DIRECT Framework v2.0
5 | *
6 | * Reference metadata table INTERNAL_PROCESSING_STATUS stores internal processing status codes and descriptions.
7 | *
8 | * This script is used to insert and update reference data on deployment.
9 | * Any bespoke internal processing status codes added manually to the target will be retained,
10 | * as long as the keys differ.
11 | * To maintain a clean CI/CD process, consider using this script to manage
12 | * all reference data for internal processing status codes.
13 | *
14 | * [omd_metadata].[INTERNAL_PROCESSING_STATUS]
15 | *
16 | ******************************************************************************/
17 |
18 | SET NOCOUNT ON;
19 |
20 | DECLARE @tblMerge TABLE(
21 | [INTERNAL_PROCESSING_STATUS_CODE] NVARCHAR (100) NOT NULL PRIMARY KEY CLUSTERED,
22 | [INTERNAL_PROCESSING_STATUS_DESCRIPTION] NVARCHAR (4000) NULL
23 | );
24 |
25 | INSERT INTO @tblMerge([INTERNAL_PROCESSING_STATUS_CODE], [INTERNAL_PROCESSING_STATUS_DESCRIPTION])
26 | VALUES
27 | (N'Abort', N'This exception case indicates that the instance in question was executed, but that another instance of the same Batch or Module is already running (see also the equivalent Execution Status Code for additional detail). This is one of the checks performed before the regular process (Module and/or Batch) can continue. If this situation occurs, all processing should stop; no data should be processed. The process will use the Internal Processing Status `Abort` to trigger the Module/Batch `Abort` event which sets the Execution Status Code to `Cancelled`, ending the process gracefully.'),
28 | (N'Cancel', N'The instance evaluation has determined that it is not necessary to run this process (see also the equivalent Execution Status Code for additional detail). As with Abort, if the Internal Process Status code is `Cancel` then all further processing should stop after the Execution Status Code has also been updated to `Cancel`.'),
29 | (N'Proceed', N'The instance can continue on to the next processing. This is the default internal processing value; each process step will evaluate the Internal Process Status code and continue only if it is set to `Proceed`. After the pre-processing has been completed the `Proceed` value is the flag that is required to initiate the main process.'),
30 | (N'Rollback', N'The `Rollback` code is only temporarily set during rollback execution in the Module Evaluation event. This is essentially for debugging purposes. After the rollback is completed the Internal Processing Status will be set to `Proceed` again to enable the continuation of the process.');
31 |
32 | MERGE [omd_metadata].[INTERNAL_PROCESSING_STATUS] AS TARGET
33 | USING @tblMerge AS src
34 | ON TARGET.[INTERNAL_PROCESSING_STATUS_CODE] = src.[INTERNAL_PROCESSING_STATUS_CODE]
35 | WHEN MATCHED THEN
36 | UPDATE
37 | SET [INTERNAL_PROCESSING_STATUS_DESCRIPTION] = src.[INTERNAL_PROCESSING_STATUS_DESCRIPTION]
38 | WHEN NOT MATCHED THEN
39 | INSERT ([INTERNAL_PROCESSING_STATUS_CODE]
40 | ,[INTERNAL_PROCESSING_STATUS_DESCRIPTION])
41 | VALUES ([INTERNAL_PROCESSING_STATUS_CODE]
42 | ,[INTERNAL_PROCESSING_STATUS_DESCRIPTION]);
43 |
44 | GO
45 |
--------------------------------------------------------------------------------
/Direct_Framework/DeploymentScripts/3-PostDeployment/omd_metadata.LAYER.sql:
--------------------------------------------------------------------------------
1 | /*******************************************************************************
2 | * https://github.com/data-solution-automation-engine/DIRECT
3 | * Reference data insert and update script
4 | * DIRECT Framework v2.0
5 | *
6 | * Reference metadata table LAYER stores layer information.
7 | *
8 | * This script is used to insert and update reference data on deployment.
9 | * Any bespoke layers added manually to the target will be retained,
10 | * as long as the keys differ.
11 | * To maintain a clean CI/CD process, consider using this script to manage
12 | * all reference data for layers.
13 | *
14 | * [omd_metadata].[LAYER]
15 | *
16 | ******************************************************************************/
17 |
18 | SET NOCOUNT ON;
19 |
20 | DECLARE @tblMerge TABLE(
21 | [LAYER_CODE] NVARCHAR (100) NOT NULL PRIMARY KEY CLUSTERED,
22 | [LAYER_DESCRIPTION] NVARCHAR (4000) NULL
23 | );
24 |
25 | INSERT INTO @tblMerge([LAYER_CODE], [LAYER_DESCRIPTION])
26 | VALUES
27 | (N'Integration', N'The Integration Layer'),
28 | (N'Presentation', N'The Presentation Layer'),
29 | (N'Staging', N'The Staging Layer'),
30 | (N'Maintenance', N'Internal Data Solution')
31 |
32 | MERGE [omd_metadata].[LAYER] AS TARGET
33 | USING @tblMerge AS src
34 | ON TARGET.[LAYER_CODE] = src.[LAYER_CODE]
35 | WHEN MATCHED THEN
36 | UPDATE
37 | SET [LAYER_DESCRIPTION] = src.[LAYER_DESCRIPTION]
38 | WHEN NOT MATCHED THEN
39 | INSERT ([LAYER_CODE]
40 | ,[LAYER_DESCRIPTION])
41 | VALUES ([LAYER_CODE]
42 | ,[LAYER_DESCRIPTION]);
43 |
44 | GO
45 |
--------------------------------------------------------------------------------
/Direct_Framework/DeploymentScripts/3-PostDeployment/omd_metadata.NEXT_RUN_STATUS.sql:
--------------------------------------------------------------------------------
1 | /*******************************************************************************
2 | * https://github.com/data-solution-automation-engine/DIRECT
3 | * Reference data insert and update script
4 | * DIRECT Framework v2.0
5 | *
6 | * Reference metadata table NEXT_RUN_STATUS stores next run status codes and descriptions.
7 | * This script is used to insert and update reference data on deployment.
8 | * Any bespoke next run status codes added manually to the target will be retained,
9 | * as long as the keys differ.
10 | * To maintain a clean CI/CD process, consider using this script to manage
11 | * all reference data for next run status codes.
12 | *
13 | * [omd_metadata].[NEXT_RUN_STATUS]
14 | *
15 | ******************************************************************************/
16 |
17 | SET NOCOUNT ON;
18 |
19 | DECLARE @tblMerge TABLE(
20 | [NEXT_RUN_STATUS_CODE] NVARCHAR (100) NOT NULL PRIMARY KEY CLUSTERED,
21 | [NEXT_RUN_STATUS_CODE_DESCRIPTION] NVARCHAR (4000) NULL
22 | );
23 |
24 | INSERT INTO @tblMerge([NEXT_RUN_STATUS_CODE], [NEXT_RUN_STATUS_CODE_DESCRIPTION])
25 | VALUES
26 | (N'Cancel', N'Administrators can manually set this code to for the Next Run Status (i.e. this will not be automatically set by the DIRECT controls) to force a one-off skip of the instance.'),
27 | (N'Proceed', N'The `Proceed` code will direct the next run of the Batch/Module to continue processing. This is the default value. Each process step will evaluate the Internal Process Status Code and continue only if it was set to `Proceed`. After the rollback has been completed the `Proceed` value is the code that is required to initiate the main process.'),
28 | (N'Rollback', N'When a current (running) Instance fails the Next Run Status for that Instance is updated to `Rollback` to signal the next run to initiate a rollback procedure. At the same time, the Execution Status Code for the current Instance will be set to `Failed`. Administrators can manually change the Next Run Status value for an Instance to `Rollback` if they want to force a rollback when the next run starts.')
29 |
30 | MERGE [omd_metadata].[NEXT_RUN_STATUS] AS TARGET
31 | USING @tblMerge AS src
32 | ON TARGET.[NEXT_RUN_STATUS_CODE] = src.[NEXT_RUN_STATUS_CODE]
33 | WHEN MATCHED THEN
34 | UPDATE
35 | SET [NEXT_RUN_STATUS_CODE_DESCRIPTION] = src.[NEXT_RUN_STATUS_CODE_DESCRIPTION]
36 | WHEN NOT MATCHED THEN
37 | INSERT ([NEXT_RUN_STATUS_CODE]
38 | ,[NEXT_RUN_STATUS_CODE_DESCRIPTION])
39 | VALUES ([NEXT_RUN_STATUS_CODE]
40 | ,[NEXT_RUN_STATUS_CODE_DESCRIPTION]);
41 |
42 | GO
43 |
--------------------------------------------------------------------------------
/Direct_Framework/DeploymentScripts/4-PostDacpacDeployment/PostDacpacDeployment.sql:
--------------------------------------------------------------------------------
1 | /*******************************************************************************
2 | * Post-Dacpac Deployment Script
3 | *******************************************************************************
4 | *
5 | * This file contains SQL statements that are expected to run
6 | * after the database deployment finishes.
7 | *
8 | * This needs to be called from the deployment pipeline
9 | * after the dacpac deployment is complete.
10 | *
11 | * It is not part of the database project or the database project deployment.
12 | *
13 | ******************************************************************************/
14 |
15 | -- placeholder contents...
16 | print 'Post-Dacpac Deployment Script Starting'
17 |
18 | print 'Doing nothing...'
19 |
20 | print 'Post-Dacpac Deployment Script Completed'
21 |
--------------------------------------------------------------------------------
/Direct_Framework/DeploymentScripts/readme.md:
--------------------------------------------------------------------------------
1 | # Deployment Scripts
2 |
3 | Deployment scripts are used in DIRECT to allow for extended actions during deployments.
4 |
5 | Certain scripts and certain actions need to run at different times during the deployment process.
6 |
7 | The deployment scripts are broken down into 4 different folders to allow for this.
8 |
9 | The scripts can either be run outside of the Dacpac process, by the CD pipeline, or inside the Dacpac process, by the Dacpac process itself.
10 |
11 | The main script currently in use is the PostDeployment script, which populated the lookup tables with required base data.
12 |
13 | Deployment scripts folders:
14 |
15 | * 1-PreDacpacDeployment
16 | * 2-PreDeployment
17 | * 3-PostDeployment
18 | * 4-PostDacpacDeployment
19 |
20 | ## 1-PreDacpacDeployment
21 |
22 | This folder contains scripts that are run before the Dacpac process starts.
23 |
24 | These scripts need to be configured to be run by the CD pipeline.
25 |
26 | ## 2-PreDeployment
27 |
28 | This folder contains scripts that are run by the Dacpac process at the start of processing the Dacpac.
29 |
30 | ## 3-PostDeployment
31 |
32 | This folder contains scripts that are run by the Dacpac process at the end of processing the Dacpac.
33 |
34 | ## 4-PostDacpacDeployment
35 |
36 | This folder contains scripts that are run after the Dacpac process has completed.
37 |
38 | These scripts need to be configured be to run by the CD pipeline.
39 |
--------------------------------------------------------------------------------
/Direct_Framework/Functions/omd.AddLogMessage.sql:
--------------------------------------------------------------------------------
1 | /*******************************************************************************
2 | * [omd].[AddLogMessage]
3 | *******************************************************************************
4 | *
5 | * https://github.com/data-solution-automation-engine/DIRECT
6 | *
7 | * DIRECT model v2.0
8 | *
9 | * Purpose:
10 | * Add a row to the Message Log, by concatenating the input message with
11 | * a severity and timestamp as a JSON object in the MessageLog JSON array.
12 | *
13 | * Input:
14 | * - Severity (e.g. INFO, WARNING, ERROR)
15 | * - Timesetamp
16 | * - Log Message Key (a key to identify the message)
17 | * - Log Message (the message to add to the log)
18 | * - Message Log (the existing message log)
19 | *
20 | * Returns:
21 | * - Message Log (with the new message appended)
22 | *
23 | * Usage:
24 | *
25 |
26 | DECLARE @LogMessage NVARCHAR(MAX);
27 | DECLARE @MessageLog NVARCHAR(MAX);
28 |
29 | SET @LogMessage = 'The parsing of ''2319'' as event code failed';
30 | SET @MessageLog =
31 | [omd].[AddLogMessage]
32 | ('WARNING', DEFAULT, N'Value Parsing', @LogMessage, @MessageLog)
33 |
34 | SELECT @MessageLog;
35 |
36 | *
37 | ******************************************************************************/
38 |
39 | CREATE FUNCTION [omd].[AddLogMessage]
40 | (
41 | @Severity NVARCHAR(100), -- The severity of the message (e.g. INFO, WARNING, ERROR)
42 | @Timestamp DATETIME2, -- The timestamp of the message
43 | @LogMessageKey NVARCHAR(1000), -- The key of the message to add to the Log
44 | @LogMessage NVARCHAR(MAX), -- The Message to add to the Log
45 | @MessageLog NVARCHAR(MAX) -- The existing Message Log (Json array of Json objects)
46 | )
47 | RETURNS NVARCHAR(MAX) AS
48 |
49 | BEGIN
50 |
51 | IF @LogMessage IS NULL
52 | BEGIN
53 | SET @LogMessage = 'N/A'
54 | END
55 |
56 | IF @MessageLog IS NULL OR TRIM(@MessageLog) = ''
57 | BEGIN
58 | SET @MessageLog = '[]'
59 | END
60 |
61 | DECLARE
62 | @TimestampString NVARCHAR(MAX),
63 | @SeverityString NVARCHAR(MAX),
64 | @LogMessageKeyString NVARCHAR(MAX)
65 |
66 | -- Set parameters to valid values, including defaulting missing ones
67 | SET @TimestampString = CAST(STRING_ESCAPE(FORMAT(ISNULL(@Timestamp, SYSUTCDATETIME()), 'yyyy-MM-dd HH:mm:ss.fffffff'), 'json') AS NVARCHAR(MAX));
68 | SET @SeverityString = CAST(STRING_ESCAPE(ISNULL(@Severity, 'INFO'), 'json') AS NVARCHAR(MAX));
69 | SET @LogMessageKey = CAST(STRING_ESCAPE(ISNULL(@LogMessageKey, ''), 'json') AS NVARCHAR(MAX));
70 | SET @LogMessage = CAST(STRING_ESCAPE(ISNULL(@LogMessage, ''), 'json') AS NVARCHAR(MAX));
71 |
72 | -- Declare ouput variable and populate it with the new message log
73 | DECLARE @NewMessageLog NVARCHAR(MAX) =
74 | (
75 | -- New node into the existing Json array
76 | SELECT
77 | JSON_QUERY(
78 | JSON_MODIFY(
79 | @MessageLog,
80 | 'append $',
81 | JSON_QUERY(
82 | CONCAT(
83 | '{',
84 | '"severity": "', @SeverityString, '",',
85 | '"timestamp": "', @TimestampString, '",',
86 | '"key": "', @LogMessageKey, '",',
87 | '"message": "', @LogMessage, '"',
88 | '}'
89 | )
90 | )
91 | )
92 | )
93 | )
94 |
95 | -- Return the resulting new message log
96 | RETURN @NewMessageLog
97 | END
98 |
--------------------------------------------------------------------------------
/Direct_Framework/Functions/omd.CalculateChangeKey.sql:
--------------------------------------------------------------------------------
1 | CREATE FUNCTION [omd].[CalculateChangeKey]
2 | (
3 | @change_timestamp DATETIME2,
4 | @insert_module_id INT,
5 | @insert_row_id INT
6 | )
7 | RETURNS NUMERIC(38, 0) AS
8 | BEGIN
9 |
10 | -- =============================================
11 | -- Function: Calculate Change Key
12 | -- Description: TODO: tba...
13 | -- =============================================
14 |
15 | RETURN (
16 | ------------------------------------------------------------------------------
17 | SELECT
18 | convert(NUMERIC(38, 0),
19 | left(replace(replace(replace(replace(
20 | convert(CHAR(27), cast(@change_timestamp AS DATETIME2)), '-', ''), ' ', ''), ':', ''), '.', ''), 21)
21 | + right('0000000000' + convert(VARCHAR(38), @insert_module_id), 10) --,len(2147483647)
22 | + right('0000000' + convert(VARCHAR(38), @insert_row_id), 7)
23 | ) AS OMD_CHANGE_KEY
24 | ------------------------------------------------------------------------------
25 | )
26 | END
27 |
--------------------------------------------------------------------------------
/Direct_Framework/Functions/omd.GetBatchIdByBatchInstanceId.sql:
--------------------------------------------------------------------------------
1 | CREATE FUNCTION [omd].[GetBatchIdByBatchInstanceId]
2 | (
3 | @BatchInstanceId INT -- An instance of the Batch.
4 | )
5 | RETURNS INT AS
6 |
7 | -- =============================================
8 | -- Function: Get Batch Id (by Batch Instance Id)
9 | -- Description: Takes the Batch instance id as input and returns the Batch Id as registered in the framework
10 | -- =============================================
11 |
12 | BEGIN
13 | -- Declare ouput variable
14 |
15 | DECLARE @BatchId INT =
16 | (
17 | SELECT DISTINCT BatchInstance.BATCH_ID
18 | FROM omd.BATCH_INSTANCE BatchInstance
19 | WHERE BatchInstance.BATCH_INSTANCE_ID = @BatchInstanceId
20 | )
21 |
22 | -- SET @BatchId = COALESCE(@BatchId,0) -- << line removed to catch NULL for incorrect @BatchInstanceId
23 |
24 | -- Return the result of the function
25 | RETURN @BatchId
26 | END
27 |
--------------------------------------------------------------------------------
/Direct_Framework/Functions/omd.GetBatchIdByModuleInstanceId.sql:
--------------------------------------------------------------------------------
1 | CREATE FUNCTION [omd].[GetBatchIdByModuleInstanceId]
2 | (
3 | @ModuleInstanceId INT -- An instance of the module.
4 | )
5 | RETURNS INT AS
6 |
7 | -- =============================================
8 | -- Function: Get Batch Id (by Module Instance Id)
9 | -- Description: Takes the module instance id as input and returns the Batch Id as registered in the framework
10 | -- =============================================
11 |
12 | BEGIN
13 | -- Declare ouput variable
14 |
15 | DECLARE @BatchId INT =
16 | (
17 | SELECT DISTINCT batchInstance.BATCH_ID
18 | FROM omd.MODULE_INSTANCE moduleInstance
19 | JOIN omd.BATCH_INSTANCE batchInstance ON moduleInstance.BATCH_INSTANCE_ID = batchInstance.BATCH_INSTANCE_ID
20 | WHERE moduleInstance.MODULE_INSTANCE_ID = @ModuleInstanceId
21 | )
22 |
23 | -- SET @BatchId = COALESCE(@BatchId,0) -- << line removed to catch NULL for incorrect @ModuleInstanceId
24 |
25 | -- Return the result of the function
26 | RETURN @BatchId
27 | END
28 |
--------------------------------------------------------------------------------
/Direct_Framework/Functions/omd.GetBatchIdByName.sql:
--------------------------------------------------------------------------------
1 | CREATE FUNCTION [omd].[GetBatchIdByName]
2 | (
3 | @BatchCode NVARCHAR(1000) -- The name of the batch, as identified in the BATCH_CODE attribute in the BATCH table.
4 | )
5 | RETURNS INT AS
6 |
7 | -- =============================================
8 | -- Function: Get Batch Id (by code/name)
9 | -- Description: Takes the batch code as input and returns the Batch ID as registered in the framework
10 | -- =============================================
11 |
12 | BEGIN
13 |
14 | DECLARE @BatchId INT =
15 | (
16 | SELECT b.BATCH_ID
17 | FROM [omd].[BATCH] b
18 | WHERE b.BATCH_CODE = @BatchCode
19 | )
20 |
21 | RETURN @BatchId
22 |
23 | END
24 |
--------------------------------------------------------------------------------
/Direct_Framework/Functions/omd.GetBatchModuleActiveIndicatorValue.sql:
--------------------------------------------------------------------------------
1 | CREATE FUNCTION [omd].[GetBatchModuleActiveIndicatorValue]
2 | (
3 | @BatchId INT,
4 | @ModuleId INT
5 | )
6 | RETURNS CHAR(1) AS
7 |
8 | -- =============================================
9 | -- Function: Get the Batch/Module active/inactive flag.
10 | -- Description: Retrieve the Active Indicator (flag)
11 | -- for a Batch / Module combination.
12 | -- =============================================
13 |
14 | BEGIN
15 | -- Declare ouput variable
16 |
17 | DECLARE @ActiveIndicator CHAR(1)
18 |
19 | SET @ActiveIndicator =
20 | (
21 | --SELECT
22 | -- MIN(ACTIVE_INDICATOR)
23 | --FROM
24 | --(
25 | SELECT TOP 1 ACTIVE_INDICATOR
26 | FROM omd.BATCH_MODULE
27 | WHERE BATCH_ID = @BatchId AND MODULE_ID = @ModuleId
28 | --UNION
29 | ---- Return U for Unknown if there is nothing,
30 | ---- to give at least a result row for further processing
31 | --SELECT 'U'
32 | --) sub
33 | )
34 |
35 | -- Return the result of the function
36 | RETURN COALESCE(@ActiveIndicator, 'U')
37 | END
38 |
--------------------------------------------------------------------------------
/Direct_Framework/Functions/omd.GetDependency.sql:
--------------------------------------------------------------------------------
1 | CREATE FUNCTION [dbo].[GetDependency]
2 | (
3 | @SchemaName VARCHAR(128),
4 | @Table VARCHAR(128),
5 | @UseFullyQualifiedName CHAR(1) = 'Y'
6 | )
7 | RETURNS VARCHAR(MAX) AS
8 |
9 | -- =============================================
10 | -- Function: Get Dependency
11 | -- Description: TODO: tba...
12 | -- =============================================
13 |
14 | BEGIN
15 |
16 | DECLARE @Output VARCHAR(MAX)
17 |
18 | IF @UseFullyQualifiedName = 'Y'
19 | BEGIN
20 | SELECT @Output =
21 | ''''+
22 | stuff
23 | (
24 | (
25 | SELECT DISTINCT ', ' + '[' + referenced_database_name+'].'+ '[' + referenced_schema_name+'].' + '[' + referenced_entity_name + ']'
26 | FROM sys.sql_expression_dependencies t2
27 | WHERE referencing_id = OBJECT_ID(N''+@SchemaName+'.'+@Table+'')
28 | FOR XML PATH('')
29 | ),
30 | 1,
31 | 1,
32 | ''
33 | )
34 | + ''''
35 | END
36 | ELSE
37 | BEGIN
38 | SELECT @Output =
39 | ''''+
40 | stuff
41 | (
42 | (
43 | SELECT DISTINCT ', ' + referenced_entity_name
44 | FROM sys.sql_expression_dependencies t2
45 | WHERE referencing_id = OBJECT_ID(N''+@SchemaName+'.'+@Table+'')
46 | FOR XML PATH('')
47 | ),
48 | 1,
49 | 1,
50 | ''
51 | )
52 | + ''''
53 | END
54 |
55 | SELECT @Output = LTRIM(RTRIM(@Output));
56 |
57 | RETURN @Output;
58 |
59 | END
60 |
--------------------------------------------------------------------------------
/Direct_Framework/Functions/omd.GetFailedBatchIdList.sql:
--------------------------------------------------------------------------------
1 | CREATE FUNCTION [omd].[GetFailedBatchIdList]
2 | (
3 | @BatchId INT -- The array of previously failed Batch process relative to the input Batch Id.
4 | )
5 | RETURNS VARCHAR(MAX) AS
6 |
7 | -- =============================================
8 | -- Function: Get the list (array) of failed Batch Ids.
9 | -- Description: Takes the Batch Id as input and returns the failures prior to the current run (from the last previously successful execution).
10 | -- In other words, the failed execution between the last succesful run and the current one.
11 | -- =============================================
12 |
13 | BEGIN
14 |
15 | DECLARE @BatchIdArray VARCHAR(MAX);
16 |
17 | SELECT @BatchIdArray =
18 | CAST('(' +
19 | STUFF(
20 | (
21 | SELECT ',' + CAST(BATCH_INSTANCE_ID AS VARCHAR(20))
22 | FROM [omd].[BATCH_INSTANCE]
23 | WHERE BATCH_ID = @BatchId
24 | AND
25 | (
26 | BATCH_INSTANCE_ID >
27 | (
28 | SELECT MAX(BATCH_INSTANCE_ID)
29 | FROM [omd].[BATCH_INSTANCE]
30 | WHERE
31 | BATCH_ID = @BatchId
32 | AND
33 | (EXECUTION_STATUS_CODE = N'Succeeded' AND NEXT_RUN_STATUS_CODE = N'Proceed')
34 | )
35 | OR
36 | (
37 | SELECT COUNT(BATCH_INSTANCE_ID)
38 | FROM [omd].[BATCH_INSTANCE]
39 | WHERE BATCH_ID = @BatchId
40 | AND (EXECUTION_STATUS_CODE = N'Succeeded' AND NEXT_RUN_STATUS_CODE = N'Proceed')
41 | ) = 0
42 | )
43 | AND EXECUTION_STATUS_CODE <> N'Executing'
44 | ORDER BY BATCH_INSTANCE_ID
45 | FOR XML PATH ('')
46 | ),1,1,''
47 | ) + ')' AS VARCHAR(MAX)
48 | )
49 |
50 | RETURN @BatchIdArray;
51 | END
52 |
--------------------------------------------------------------------------------
/Direct_Framework/Functions/omd.GetModuleAreaByModuleId.sql:
--------------------------------------------------------------------------------
1 | CREATE FUNCTION [omd].[GetModuleAreaByModuleId]
2 | (
3 | @ModuleId INT -- The identifier of the Module (PK).
4 | )
5 | RETURNS VARCHAR(255) AS
6 |
7 | -- =============================================
8 | -- Function: Get Module Area (by Id)
9 | -- Description: Takes the module id as input and returns the area code as registered in the framework
10 | -- =============================================
11 |
12 | BEGIN
13 | -- Declare ouput variable
14 |
15 | DECLARE @ModuleArea VARCHAR(255) =
16 | (
17 | SELECT [module].[AREA_CODE]
18 | FROM [omd].[MODULE] module
19 | WHERE MODULE_ID = @ModuleId
20 | )
21 |
22 | SET @ModuleArea = COALESCE(@ModuleArea,'N/A')
23 |
24 | -- Return the result of the function
25 | RETURN @ModuleArea
26 | END
27 |
--------------------------------------------------------------------------------
/Direct_Framework/Functions/omd.GetModuleIdByModuleInstanceId.sql:
--------------------------------------------------------------------------------
1 |
2 | CREATE FUNCTION [omd].[GetModuleIdByModuleInstanceId]
3 | (
4 | @ModuleInstanceId INT -- An instance of the module.
5 | )
6 | RETURNS INT AS
7 |
8 | -- =============================================
9 | -- Function: Get Module Id (by Module Instance Id)
10 | -- Description: Takes the module instance id as input and returns the Module Id as registered in the framework
11 | -- =============================================
12 |
13 | BEGIN
14 | -- Declare ouput variable
15 |
16 | DECLARE @ModuleId INT =
17 | (
18 | SELECT DISTINCT mi.MODULE_ID
19 | FROM [omd].[MODULE_INSTANCE] mi
20 | WHERE mi.MODULE_INSTANCE_ID = @ModuleInstanceId
21 | )
22 |
23 | -- SET @ModuleId = COALESCE(@ModuleId,0) -- << line removed to catch NULL for incorrect @ModuleInstanceId
24 |
25 | -- Return the result of the function
26 | RETURN @ModuleId
27 | END
28 |
--------------------------------------------------------------------------------
/Direct_Framework/Functions/omd.GetModuleIdByName.sql:
--------------------------------------------------------------------------------
1 | CREATE FUNCTION omd.GetModuleIdByName
2 | (
3 | @ModuleCode VARCHAR(255) -- The name of the module, as identified in the MODULE_CODE attribute in the MODULE table.
4 | )
5 | RETURNS VARCHAR(255) AS
6 |
7 | -- =============================================
8 | -- Function: Get Module Id (by name)
9 | -- Description: Takes the module code as input and returns the Module ID as registered in the framework
10 | -- =============================================
11 |
12 | BEGIN
13 | -- Declare ouput variable
14 |
15 | DECLARE @ModuleId INT =
16 | (
17 | SELECT m.MODULE_ID
18 | FROM [omd].[MODULE] m
19 | WHERE m.MODULE_CODE = @ModuleCode
20 | )
21 |
22 | -- Return the result of the function
23 | RETURN @ModuleId
24 | END
25 |
--------------------------------------------------------------------------------
/Direct_Framework/Functions/omd.GetModuleLoadWindowValue.sql:
--------------------------------------------------------------------------------
1 | CREATE FUNCTION [omd].[GetModuleLoadWindowValue]
2 | (
3 | @ModuleId INT,
4 | @start_or_end TINYINT
5 | )
6 | RETURNS DATETIME2(7) AS
7 |
8 | -- =============================================
9 | -- Function: The GetModuleLoadWindowValue retrieves the start or end value as currently available in the source control table.
10 | -- Description: The from part of the load window can be selected by providing the parameter value 1,
11 | -- and 2 is for the closing of the window - the end datetime.
12 | --
13 | -- Example usage:
14 | --
15 | -- DECLARE @START_VALUE DATETIME2(7) =
16 | -- [omd].[GetModuleLoadWindowValue]((SELECT MODULE_ID FROM [omd].MODULE WHERE MODULE_CODE=''), 1)
17 | --
18 | -- PRINT @START_VALUE
19 | --
20 | -- Load windows can be created via Stored Procedure [omd].[CreateLoadWindow]
21 | --
22 | -- =============================================
23 |
24 | BEGIN
25 | DECLARE @result DATETIME2(7)
26 |
27 | IF @start_or_end = 1
28 | BEGIN
29 | SELECT @result= START_VALUE
30 | FROM
31 | (
32 | SELECT
33 | sct.MODULE_INSTANCE_ID,
34 | START_VALUE,
35 | END_VALUE,
36 | ROW_NUMBER() OVER (PARTITION BY modinst.MODULE_ID ORDER BY INSERT_TIMESTAMP DESC) AS ROW_NR
37 | FROM [omd].[SOURCE_CONTROL] sct
38 | JOIN [omd].[MODULE_INSTANCE] modinst ON sct.MODULE_INSTANCE_ID = modinst.MODULE_INSTANCE_ID
39 | WHERE modinst.MODULE_ID = @ModuleId
40 | ) ranksub
41 | WHERE ROW_NR=1
42 | END
43 | ELSE IF @start_or_end = 2
44 | BEGIN
45 | SELECT @result= END_VALUE
46 | FROM
47 | (
48 | SELECT
49 | sct.MODULE_INSTANCE_ID,
50 | START_VALUE,
51 | END_VALUE,
52 | ROW_NUMBER() OVER (PARTITION BY modinst.MODULE_ID ORDER BY INSERT_TIMESTAMP DESC) AS ROW_NR
53 | FROM [omd].[SOURCE_CONTROL] sct
54 | JOIN [omd].[MODULE_INSTANCE] modinst ON sct.MODULE_INSTANCE_ID = modinst.MODULE_INSTANCE_ID
55 | WHERE modinst.MODULE_ID = @ModuleId
56 | ) ranksub
57 | WHERE ROW_NR=1
58 | END
59 | RETURN @result
60 | END
61 |
--------------------------------------------------------------------------------
/Direct_Framework/Functions/omd.GetPreviousBatchInstanceDetails.sql:
--------------------------------------------------------------------------------
1 | CREATE FUNCTION [omd].[GetPreviousBatchInstanceDetails]
2 | (
3 | @BatchId INT
4 | )
5 | RETURNS TABLE AS
6 |
7 | -- =============================================
8 | -- Function: GetPreviousBatchInstanceDetails
9 | -- Description: TODO: tba...
10 | -- =============================================
11 |
12 | RETURN
13 | (
14 | SELECT
15 | ISNULL(MAX(A.EXECUTION_STATUS_CODE),'Succeeded') AS PREVIOUS_EXECUTION_STATUS_CODE,
16 | ISNULL(MAX(A.NEXT_RUN_STATUS_CODE),'Proceed') AS PREVIOUS_NEXT_RUN_STATUS
17 | FROM
18 | (
19 | SELECT
20 | NEXT_RUN_STATUS_CODE,
21 | EXECUTION_STATUS_CODE
22 | FROM omd.BATCH_INSTANCE
23 | WHERE
24 | BATCH_ID = @BatchId
25 | AND
26 | END_TIMESTAMP =
27 | (select MAX(END_TIMESTAMP) from omd.BATCH_INSTANCE where BATCH_ID = @BatchId)
28 | ) A
29 | )
30 |
--------------------------------------------------------------------------------
/Direct_Framework/Functions/omd.GetPreviousModuleInstanceDetails.sql:
--------------------------------------------------------------------------------
1 | CREATE FUNCTION [omd].[GetPreviousModuleInstanceDetails]
2 | (
3 | @ModuleId INT,
4 | @BatchId INT
5 | )
6 | RETURNS TABLE AS
7 |
8 | /*******************************************************************************
9 | * [omd].[GetPreviousModuleInstanceDetails]
10 | *******************************************************************************
11 | *
12 | * https://github.com/data-solution-automation-engine/DIRECT
13 | *
14 | * DIRECT model v2.0
15 | *
16 | *
17 | * Purpose: Returns details about the most recent completed execution of a specified module within a specific batch context.
18 | * If no such instance exists, a default placeholder value is returned.
19 | * This information can be used for determining module execution eligibility.
20 | * The function retrieves the latest completed module instance based on the execution status and batch context.
21 | *
22 | * Inputs:
23 | * - @ModuleId (INT): The ID of the module for which execution details are requested.
24 | * - @BatchId (INT): The ID of the batch in which the module was executed. A value of 0 indicates standalone (non-batch) execution.
25 | *
26 | * Outputs:
27 | * A single-row table containing the following fields:
28 | * - LastBatchInstanceID: ID of the most recent batch instance.
29 | * - LastModuleInstanceID: ID of the most recent module instance.
30 | * - LastStartTimestamp: Start time of the last module execution.
31 | * - LastEndTimestamp: End time of the last module execution.
32 | * - LastExecutionStatus: Execution status code of the last module run.
33 | * - LastNextExecutionFlag: Indicator suggesting the next action (e.g., 'Proceed').
34 | * - LastModuleInstanceIDList: Comma-separated list of relevant module instance IDs after the last successful run.
35 | * - ActiveIndicator: Flag indicating whether the module is active (ACTIVE_INDICATOR from the MODULE table).
36 | *
37 | * Usage:
38 | *
39 | *******************************************************************************/
40 |
41 | RETURN
42 | (
43 | SELECT TOP 1
44 | ISNULL(MAX(LastBatchInstanceID),-1) AS [LastBatchInstanceID]
45 | ,ISNULL(MAX(LastModuleInstanceID),-1) AS [LastModuleInstanceID]
46 | ,ISNULL(MAX(LastStartTimestamp),'1900-01-01') AS [LastStartTimestamp]
47 | ,MAX(LastEndTimestamp) AS [LastEndTimestamp]
48 | ,ISNULL(MAX(LastExecutionStatus),'I') AS [LastExecutionStatus]
49 | ,ISNULL(MAX(LastNextRunStatusCode),'Proceed') AS [LastNextExecutionFlag]
50 | ,ISNULL(MAX(LastModuleInstanceIDList),'-1') AS [LastModuleInstanceIDList]
51 | ,(SELECT ACTIVE_INDICATOR FROM [omd].[MODULE] WHERE MODULE_ID = @ModuleId) AS [ActiveIndicator]
52 | FROM
53 | (
54 | (
55 | SELECT
56 | A.BATCH_INSTANCE_ID AS [LastBatchInstanceID],
57 | A.MODULE_INSTANCE_ID AS [LastModuleInstanceID],
58 | A.START_TIMESTAMP AS [LastStartTimestamp],
59 | A.END_TIMESTAMP AS [LastEndTimestamp],
60 | A.EXECUTION_STATUS_CODE AS [LastExecutionStatus],
61 | A.NEXT_RUN_STATUS_CODE AS [LastNextRunStatusCode],
62 | (
63 | SELECT Cast(
64 | '(' +
65 | STUFF
66 | (
67 | (
68 | SELECT ',' + CAST(MODULE_INSTANCE_ID AS VARCHAR(20))
69 | FROM [omd].[MODULE_INSTANCE] MI
70 | LEFT JOIN [omd].[BATCH_INSTANCE] BI
71 | ON MI.BATCH_INSTANCE_ID = BI.BATCH_INSTANCE_ID
72 | WHERE MI.MODULE_ID = @ModuleId
73 | AND ISNULL(BI.BATCH_ID, 0) = @BatchId --only instance from the same batch / 0
74 | AND MI.MODULE_INSTANCE_ID >
75 | (
76 | -- Find the last successful module run/batch run depending on if it is executed by a batch or not
77 | SELECT COALESCE(MAX(MODULE_INSTANCE_ID), 0)
78 | FROM omd.MODULE_INSTANCE SUB_MI
79 | LEFT JOIN omd.BATCH_INSTANCE SUB_BI
80 | ON SUB_MI.BATCH_INSTANCE_ID = SUB_BI.BATCH_INSTANCE_ID
81 | WHERE SUB_MI.MODULE_ID = @ModuleId
82 | AND COALESCE(SUB_BI.BATCH_ID, 0) = @BatchId --only instance from the same batch / 0
83 | AND
84 | (
85 | (
86 | -- last successful module run without a batch
87 | @BatchId = 0
88 | AND SUB_MI.EXECUTION_STATUS_CODE = N'Succeeded'
89 | AND SUB_MI.NEXT_RUN_STATUS_CODE = N'Proceed'
90 | )
91 | OR
92 | (
93 | -- last successful batch run
94 | @BatchId <> 0
95 | AND SUB_BI.EXECUTION_STATUS_CODE = N'Succeeded'
96 | )
97 | )
98 | )
99 | AND MI.EXECUTION_STATUS_CODE NOT IN (N'Executing', N'Aborted')
100 | FOR XML PATH ('') -- convert list module id to single variable
101 | )
102 | ,1,1,''
103 | )
104 | + ')' AS VARCHAR(MAX)
105 | )
106 | ) AS [LastModuleInstanceIDList]
107 |
108 | FROM omd.MODULE_INSTANCE A
109 | WHERE A.MODULE_INSTANCE_ID =
110 | (
111 | (
112 | SELECT MAX(MODULE_INSTANCE_ID)
113 | FROM [omd].[MODULE_INSTANCE] WMI
114 | LEFT JOIN [omd].[BATCH_INSTANCE] WBI
115 | ON WMI.BATCH_INSTANCE_ID = WBI.BATCH_INSTANCE_ID
116 | WHERE WMI.MODULE_ID = @ModuleId
117 | AND WMI.EXECUTION_STATUS_CODE NOT IN (N'Executing', N'Aborted')
118 | AND COALESCE(WBI.BATCH_ID, 0) = @BatchId --only instance from the same batch / 0
119 | )
120 | )
121 | )
122 |
123 | UNION ALL -- return if there is nothing, to give at least a result.
124 |
125 | SELECT NULL, NULL, NULL, NULL, NULL, NULL, NULL
126 |
127 | ) AS sub1
128 | )
129 |
--------------------------------------------------------------------------------
/Direct_Framework/Functions/omd_metadata.GetFrameworkVersion.sql:
--------------------------------------------------------------------------------
1 | CREATE FUNCTION [omd_metadata].[GetFrameworkVersion]()
2 |
3 | RETURNS NVARCHAR(100) AS
4 |
5 | -- =============================================
6 | -- Function: Get Framework Version
7 | -- Description: queries the metadata table to get the current version
8 | -- =============================================
9 |
10 | BEGIN
11 |
12 | DECLARE @Version NVARCHAR(100) =
13 | (
14 | SELECT md.[VALUE]
15 | FROM [omd_metadata].[FRAMEWORK_METADATA] md
16 | WHERE md.[CODE] = 'DIRECT_VERSION'
17 | )
18 |
19 | RETURN @Version
20 |
21 | END
22 |
--------------------------------------------------------------------------------
/Direct_Framework/Functions/omd_processing.GetDependentTables.sql:
--------------------------------------------------------------------------------
1 | CREATE FUNCTION [omd_processing].[GetDependentTables]
2 | (
3 | @schema_name sysname,
4 | @object_name sysname
5 | )
6 |
7 | RETURNS @rtnTbl TABLE
8 | (
9 | referenced_schema_name sysname NOT NULL,
10 | referenced_object_name sysname NOT NULL
11 | )
12 |
13 | -- =============================================
14 | -- Function: Returns the underlying tables on which the specified object depends.
15 | -- - If the provided object is a table, then will simply reflect that table name.
16 | -- Description: - Works recursively where found dependencies which are not a table.
17 | -- - As this procedure does not traverse dependencies through packages. Only local tables
18 | -- which are accessed by the query which loads the specified target are returned.
19 | -- =============================================
20 |
21 | AS
22 |
23 | BEGIN
24 | -----------------------------------------------------------------------------------------------------------
25 | WITH allDeps
26 | AS
27 | (
28 | SELECT
29 | sql_expression_dependencies.referencing_id,
30 | object_schema_name(sql_expression_dependencies.referencing_id) AS referencing_schema_name,
31 | object_name(sql_expression_dependencies.referencing_id) AS referencing_entity_name,
32 | pre_calc.referenced_schema_name,
33 | sql_expression_dependencies.referenced_entity_name,
34 | objects.[type_desc] AS referenced_type_desc
35 | FROM sys.sql_expression_dependencies
36 | OUTER APPLY
37 | (
38 | SELECT
39 | coalesce(sql_expression_dependencies.referenced_database_name, db_name()) AS referenced_database_name,
40 | coalesce (sql_expression_dependencies.referenced_schema_name, 'dbo') AS referenced_schema_name
41 | ) pre_calc
42 | INNER JOIN sys.objects ON objects.[object_id] = sql_expression_dependencies.referenced_id
43 | WHERE pre_calc.referenced_database_name = db_name() /* object dependencies are expected to never be cross-database */
44 | AND object_schema_name(sql_expression_dependencies.referencing_id) NOT LIKE N'omd%'
45 | AND object_schema_name(sql_expression_dependencies.referencing_id) NOT IN (N'tSQLt')
46 | AND object_schema_name(sql_expression_dependencies.referencing_id) NOT LIKE N'test%'
47 | AND NOT EXISTS
48 | (
49 | /* excluded table self-dependencies, such as from calculated columns */
50 | SELECT NULL
51 | FROM sys.objects start_type
52 | WHERE start_type.[object_id] = sql_expression_dependencies.referencing_id
53 | AND start_type.[type_desc] IN ('USER_TABLE', 'SYNONYM')
54 | )
55 | GROUP BY
56 | sql_expression_dependencies.referencing_id,
57 | pre_calc.referenced_schema_name,
58 | sql_expression_dependencies.referenced_entity_name,
59 | objects.[type_desc]
60 | ),
61 | recursiveCTE
62 | AS
63 | (
64 | SELECT referencing_schema_name, referencing_entity_name, referenced_schema_name, referenced_entity_name, referenced_type_desc
65 | FROM allDeps
66 | WHERE allDeps.referencing_id = object_id(@schema_name + N'.' + @object_name)
67 | UNION ALL
68 | SELECT
69 | recursiveCTE.referencing_schema_name AS referencing_schema_name,
70 | recursiveCTE.referencing_entity_name AS referencing_entity_name,
71 | allDeps.referenced_schema_name,
72 | allDeps.referenced_entity_name,
73 | allDeps.referenced_type_desc
74 | FROM recursiveCTE
75 | INNER JOIN allDeps
76 | ON allDeps.referencing_schema_name = recursiveCTE.referenced_schema_name
77 | AND allDeps.referencing_entity_name = recursiveCTE.referenced_entity_name
78 | WHERE recursiveCTE.referenced_type_desc NOT IN ('USER_TABLE', 'SYNONYM')
79 | )
80 |
81 | /* add to returned results table */
82 | INSERT INTO @rtnTbl
83 | SELECT
84 | referenced_schema_name AS REFERENCED_SCHEMA_NAME,
85 | referenced_entity_name AS REFERENCED_OBJECT_NAME
86 | FROM recursiveCTE
87 | WHERE recursiveCTE.referenced_type_desc IN ('USER_TABLE', 'SYNONYM')
88 |
89 | UNION
90 |
91 | SELECT @schema_name AS REFERENCED_SCHEMA_NAME, @object_name AS REFERENCED_OBJECT_NAME
92 | FROM sys.tables
93 | WHERE tables.[object_id] = object_id(@schema_name + N'.' + @object_name)
94 |
95 | UNION
96 |
97 | SELECT @schema_name AS REFERENCED_SCHEMA_NAME, @object_name AS REFERENCED_OBJECT_NAME
98 | FROM sys.synonyms
99 | WHERE synonyms.[object_id] = object_id(@schema_name + N'.' + @object_name);
100 |
101 | RETURN;
102 | -----------------------------------------------------------------------------------------------------------
103 | END
104 |
--------------------------------------------------------------------------------
/Direct_Framework/Schemas/omd.sql:
--------------------------------------------------------------------------------
1 | CREATE SCHEMA [omd]
2 | AUTHORIZATION [dbo];
3 |
--------------------------------------------------------------------------------
/Direct_Framework/Schemas/omd_metadata.sql:
--------------------------------------------------------------------------------
1 | CREATE SCHEMA [omd_metadata]
2 | AUTHORIZATION [dbo];
3 |
--------------------------------------------------------------------------------
/Direct_Framework/Schemas/omd_processing.sql:
--------------------------------------------------------------------------------
1 | CREATE SCHEMA [omd_processing]
2 | AUTHORIZATION [dbo];
3 |
--------------------------------------------------------------------------------
/Direct_Framework/Schemas/omd_reporting.sql:
--------------------------------------------------------------------------------
1 | CREATE SCHEMA [omd_reporting]
2 | AUTHORIZATION [dbo];
3 |
--------------------------------------------------------------------------------
/Direct_Framework/Stored Procedures/omd.AddMessageLogToEventLog.sql:
--------------------------------------------------------------------------------
1 | /*******************************************************************************
2 | * [omd].[AddMessageLogToEventLog]
3 | *******************************************************************************
4 | *
5 | * https://github.com/data-solution-automation-engine/DIRECT
6 | *
7 | * DIRECT model v2.0
8 | *
9 | * Purpose:
10 | * tba
11 | *
12 | * Inputs:
13 | * - Message Log
14 | *
15 | * Output:
16 | * - tba
17 | *
18 | * Usage:
19 | *
20 | ******************************************************************************
21 |
22 | tba
23 |
24 | *
25 | ******************************************************************************/
26 |
27 | CREATE PROCEDURE [omd].[AddMessageLogToEventLog]
28 | (
29 | -- Mandatory Parameters
30 | @MessageLog NVARCHAR(MAX)
31 | )
32 | AS
33 | BEGIN
34 | SET NOCOUNT ON;
35 | SET ANSI_WARNINGS OFF;
36 |
37 | PRINT 'todo: omd.AddMessageLogToEventLog';
38 |
39 | END
40 |
--------------------------------------------------------------------------------
/Direct_Framework/Stored Procedures/omd.GetBatch.sql:
--------------------------------------------------------------------------------
1 | /*******************************************************************************
2 | * [omd].[GetBatch]
3 | *******************************************************************************
4 | *
5 | * https://github.com/data-solution-automation-engine/DIRECT
6 | *
7 | * DIRECT model v2.0
8 | *
9 | * Purpose:
10 | * Gets attributes for an existing Batch by name (Batch Code)
11 | *
12 | * Inputs:
13 | * - Batch Code
14 | * - Debug Flag (Y/N, defaults to N)
15 | *
16 | * Outputs as resultset 0:
17 | * - Batch Id
18 | * - Batch Code
19 | * - Batch Type
20 | * - Frequency Code
21 | * - Active Indicator
22 | * - Batch Description
23 | *
24 | * Output variables:
25 | * - Success Indicator (Y/N)
26 | * - Message Log
27 | *
28 | * Usage:
29 | *
30 | *******************************************************************************
31 |
32 | EXEC [omd].[GetBatch]
33 | @BatchCode = 'MyExistingBatch'
34 |
35 | *******************************************************************************
36 | *
37 | ******************************************************************************/
38 |
39 | CREATE PROCEDURE [omd].[GetBatch]
40 | (
41 | -- Mandatory parameters
42 | @BatchCode NVARCHAR(1000),
43 | -- Optional parameters
44 | @Debug CHAR(1) = 'N',
45 | -- Output parameters
46 | @BatchDetails NVARCHAR(MAX) = NULL OUTPUT,
47 | @SuccessIndicator CHAR(1) = 'N' OUTPUT,
48 | @MessageLog NVARCHAR(MAX) = NULL OUTPUT
49 | )
50 | AS
51 | BEGIN TRY
52 | SET NOCOUNT ON;
53 | SET ANSI_WARNINGS OFF; -- Suppress NULL elimination warning within SET operation.
54 |
55 | -- Default output logging setup
56 | DECLARE @SpName NVARCHAR(100) = N'[' + OBJECT_SCHEMA_NAME(@@PROCID) + '].[' + OBJECT_NAME(@@PROCID) + ']';
57 | DECLARE @DirectVersion NVARCHAR(10) = [omd_metadata].[GetFrameworkVersion]();
58 | DECLARE @StartTimestamp DATETIME = SYSUTCDATETIME();
59 | DECLARE @StartTimestampString NVARCHAR(20) = FORMAT(@StartTimestamp, 'yyyy-MM-dd HH:mm:ss.fffffff');
60 | DECLARE @EndTimestamp DATETIME = NULL;
61 | DECLARE @EndTimestampString NVARCHAR(20) = N'';
62 | DECLARE @LogMessage NVARCHAR(MAX);
63 |
64 | -- Log standard metadata
65 | SET @LogMessage = @SpName;
66 | SET @MessageLog = [omd].[AddLogMessage](DEFAULT, DEFAULT, N'Procedure', @LogMessage, @MessageLog)
67 | SET @LogMessage = @DirectVersion;
68 | SET @MessageLog = [omd].[AddLogMessage](DEFAULT, DEFAULT, N'Version',@LogMessage, @MessageLog)
69 | SET @LogMessage = @StartTimestampString;
70 | SET @MessageLog = [omd].[AddLogMessage](DEFAULT, DEFAULT, N'Start Timestamp', @LogMessage, @MessageLog)
71 |
72 | -- Log parameters
73 | SET @LogMessage = @BatchCode;
74 | SET @MessageLog = [omd].[AddLogMessage](DEFAULT, DEFAULT, N'Parameter @BatchCode', @LogMessage, @MessageLog)
75 |
76 | -- Process variables
77 | DECLARE @EventDetail NVARCHAR(4000);
78 | DECLARE @EventReturnCode INT;
79 | SET @SuccessIndicator = 'N' -- Ensure the process starts as not successful, so that is updated accordingly when it is.
80 |
81 | /*******************************************************************************
82 | * Start of main process
83 | ******************************************************************************/
84 |
85 | DECLARE @Results TABLE (
86 | [BATCH_ID] INT NULL,
87 | [BATCH_CODE] NVARCHAR (1000) NULL,
88 | [BATCH_TYPE] NVARCHAR (100) NULL,
89 | [FREQUENCY_CODE] NVARCHAR (100) NULL,
90 | [ACTIVE_INDICATOR] CHAR (1) NULL,
91 | [BATCH_DESCRIPTION] NVARCHAR (4000) NULL
92 | )
93 |
94 | INSERT INTO @Results
95 | SELECT
96 | [BATCH_ID],
97 | [BATCH_CODE],
98 | [BATCH_TYPE],
99 | [FREQUENCY_CODE],
100 | [ACTIVE_INDICATOR],
101 | [BATCH_DESCRIPTION]
102 | FROM
103 | [omd].[BATCH]
104 | WHERE
105 | [BATCH_CODE] = @BatchCode;
106 |
107 | IF EXISTS (SELECT 1 FROM @Results)
108 | BEGIN
109 | SET @SuccessIndicator = 'Y';
110 | SET @LogMessage = 'Batch with Code ''' + @BatchCode + ''' was found.'
111 | SET @MessageLog = [omd].[AddLogMessage]('INFO', DEFAULT, N'Batch Found', @LogMessage, @MessageLog)
112 |
113 | END
114 | ELSE
115 | BEGIN
116 | SET @SuccessIndicator = 'N';
117 | SET @LogMessage = 'No Batch with Code ''' + @BatchCode + ''' was found.'
118 | SET @MessageLog = [omd].[AddLogMessage]('ERROR', DEFAULT, N'Error Message', @LogMessage, @MessageLog)
119 | END
120 |
121 | /*******************************************************************************
122 | * Return Resultset
123 | ******************************************************************************/
124 |
125 | SELECT *
126 | FROM @Results;
127 |
128 | /*******************************************************************************
129 | * EndOfProcedure Label
130 | ******************************************************************************/
131 |
132 | EndOfProcedure:
133 |
134 | SET @EndTimestamp = SYSUTCDATETIME();
135 | SET @EndTimestampString = FORMAT(@EndTimestamp, 'yyyy-MM-dd HH:mm:ss.fffffff');
136 | SET @LogMessage = @EndTimestampString;
137 | SET @MessageLog = [omd].[AddLogMessage](DEFAULT, DEFAULT, N'End Timestamp', @LogMessage, @MessageLog)
138 | SET @LogMessage = DATEDIFF(SECOND, @StartTimestamp, @EndTimestamp);
139 | SET @MessageLog = [omd].[AddLogMessage](DEFAULT, DEFAULT, N'Elapsed Time (s)', @LogMessage, @MessageLog)
140 |
141 | IF @Debug = 'Y'
142 | BEGIN
143 | EXEC [omd].[PrintMessageLog] @MessageLog;
144 | END
145 |
146 | END TRY
147 | BEGIN CATCH
148 | -- SP-wide error handler and logging
149 | SET @SuccessIndicator = 'N'
150 | SET @LogMessage = @SuccessIndicator;
151 | SET @MessageLog = [omd].[AddLogMessage](DEFAULT, DEFAULT, N'Parameter @SuccessIndicator', @LogMessage, @MessageLog)
152 |
153 | DECLARE @ErrorMessage NVARCHAR(4000);
154 | DECLARE @ErrorSeverity INT;
155 | DECLARE @ErrorState INT;
156 | DECLARE @ErrorProcedure NVARCHAR(128);
157 | DECLARE @ErrorNumber INT;
158 | DECLARE @ErrorLine INT;
159 |
160 | SELECT
161 | @ErrorMessage = COALESCE(ERROR_MESSAGE(), 'No Message' ),
162 | @ErrorSeverity = COALESCE(ERROR_SEVERITY(), -1 ),
163 | @ErrorState = COALESCE(ERROR_STATE(), -1 ),
164 | @ErrorProcedure = COALESCE(ERROR_PROCEDURE(), 'No Procedure' ),
165 | @ErrorLine = COALESCE(ERROR_LINE(), -1 ),
166 | @ErrorNumber = COALESCE(ERROR_NUMBER(), -1 );
167 |
168 | IF @Debug = 'Y'
169 | BEGIN
170 | PRINT 'Error in ''' + @SpName + ''''
171 | PRINT 'Error Message: ' + @ErrorMessage
172 | PRINT 'Error Severity: ' + CONVERT(NVARCHAR(10), @ErrorSeverity)
173 | PRINT 'Error State: ' + CONVERT(NVARCHAR(10), @ErrorState)
174 | PRINT 'Error Procedure: ' + @ErrorProcedure
175 | PRINT 'Error Line: ' + CONVERT(NVARCHAR(10), @ErrorLine)
176 | PRINT 'Error Number: ' + CONVERT(NVARCHAR(10), @ErrorNumber)
177 | PRINT 'SuccessIndicator: '+ @SuccessIndicator
178 |
179 | -- Spool message log
180 | EXEC [omd].[PrintMessageLog] @MessageLog;
181 |
182 | END
183 |
184 | SET @EventDetail = 'Error in ''' + COALESCE(@SpName,'N/A') + ''' from ''' + COALESCE(@ErrorProcedure,'N/A') + ''' at line ''' + CONVERT(NVARCHAR(10), COALESCE(@ErrorLine,'N/A')) + ''': '+ CHAR(10) + COALESCE(@ErrorMessage,'N/A');
185 | SET @EventReturnCode = ERROR_NUMBER();
186 |
187 | EXEC [omd].[InsertIntoEventLog]
188 | @EventDetail = @EventDetail,
189 | @EventReturnCode = @EventReturnCode;
190 |
191 | THROW
192 | END CATCH
193 |
--------------------------------------------------------------------------------
/Direct_Framework/Stored Procedures/omd.GetModule.sql:
--------------------------------------------------------------------------------
1 | /*******************************************************************************
2 | * [omd].[GetModule]
3 | *******************************************************************************
4 | *
5 | * https://github.com/data-solution-automation-engine/DIRECT
6 | *
7 | * DIRECT model v2.0
8 | *
9 | * Purpose:
10 | * Gets attributes for an existing Module by name (Module Code)
11 | * Supports easier retrieval of longer Module attributes than selection
12 | * for certain clients.
13 | *
14 | * Inputs:
15 | * - Module Code
16 | * - Debug Flag (Y/N, defaults to N)
17 | *
18 | * Outputs as resultset 0:
19 | * - Module Id
20 | * - Module Code
21 | * - Module Type
22 | * - Data Object Source
23 | * - Data Object Target
24 | * - Area Code
25 | * - Frequency Code
26 | * - Active Indicator
27 | * - Module Description
28 | * - Executable
29 | *
30 | * Output variables:
31 | * - Success Indicator (Y/N)
32 | * - Message Log
33 | *
34 | * Usage:
35 | *
36 | *******************************************************************************
37 |
38 | EXEC [omd].[GetModule] @ModuleCode = 'MyExistingModule'
39 |
40 | *******************************************************************************
41 | *
42 | ******************************************************************************/
43 |
44 | CREATE PROCEDURE [omd].[GetModule]
45 | (
46 | -- Mandatory parameters
47 | @ModuleCode NVARCHAR(1000),
48 | -- Optional parameters
49 | @Debug CHAR(1) = 'N',
50 | -- Output parameters
51 | @SuccessIndicator CHAR(1) = 'N' OUTPUT,
52 | @MessageLog NVARCHAR(MAX) = NULL OUTPUT
53 | )
54 | AS
55 | BEGIN TRY
56 | SET NOCOUNT ON;
57 | SET ANSI_WARNINGS OFF; -- Suppress NULL elimination warning within SET operation.
58 |
59 | -- Default output logging setup
60 | DECLARE @SpName NVARCHAR(100) = N'[' + OBJECT_SCHEMA_NAME(@@PROCID) + '].[' + OBJECT_NAME(@@PROCID) + ']';
61 | DECLARE @DirectVersion NVARCHAR(10) = [omd_metadata].[GetFrameworkVersion]();
62 | DECLARE @StartTimestamp DATETIME = SYSUTCDATETIME();
63 | DECLARE @StartTimestampString NVARCHAR(20) = FORMAT(@StartTimestamp, 'yyyy-MM-dd HH:mm:ss.fffffff');
64 | DECLARE @EndTimestamp DATETIME = NULL;
65 | DECLARE @EndTimestampString NVARCHAR(20) = N'';
66 | DECLARE @LogMessage NVARCHAR(MAX);
67 |
68 | -- Log standard metadata
69 | SET @LogMessage = @SpName;
70 | SET @MessageLog = [omd].[AddLogMessage](DEFAULT, DEFAULT, N'Procedure', @LogMessage, @MessageLog)
71 | SET @LogMessage = @DirectVersion;
72 | SET @MessageLog = [omd].[AddLogMessage](DEFAULT, DEFAULT, N'Version',@LogMessage, @MessageLog)
73 | SET @LogMessage = @StartTimestampString;
74 | SET @MessageLog = [omd].[AddLogMessage](DEFAULT, DEFAULT, N'Start Timestamp', @LogMessage, @MessageLog)
75 |
76 | -- Log parameters
77 | SET @LogMessage = @ModuleCode;
78 | SET @MessageLog = [omd].[AddLogMessage](DEFAULT, DEFAULT, N'Parameter @ModuleCode', @LogMessage, @MessageLog)
79 |
80 | -- Process variables
81 | DECLARE @EventDetail NVARCHAR(4000);
82 | DECLARE @EventReturnCode INT;
83 | SET @SuccessIndicator = 'N' -- Ensure the process starts as not successful, so that is updated accordingly when it is.
84 |
85 | /*******************************************************************************
86 | * Start of main process
87 | ******************************************************************************/
88 |
89 | DECLARE @Results TABLE (
90 | [MODULE_ID] INT NULL,
91 | [MODULE_CODE] NVARCHAR (1000) NULL,
92 | [MODULE_TYPE] NVARCHAR (100) NULL,
93 | [DATA_OBJECT_SOURCE] NVARCHAR (1000) NULL,
94 | [DATA_OBJECT_TARGET] NVARCHAR (1000) NULL,
95 | [AREA_CODE] NVARCHAR (100) NULL,
96 | [FREQUENCY_CODE] NVARCHAR (100) NULL,
97 | [ACTIVE_INDICATOR] CHAR (1) NULL,
98 | [MODULE_DESCRIPTION] NVARCHAR (4000) NULL,
99 | [EXECUTABLE] NVARCHAR (MAX) NULL
100 | )
101 |
102 | INSERT INTO @Results
103 | SELECT
104 | [MODULE_ID],
105 | [MODULE_CODE],
106 | [MODULE_TYPE],
107 | [DATA_OBJECT_SOURCE],
108 | [DATA_OBJECT_TARGET],
109 | [AREA_CODE],
110 | [FREQUENCY_CODE],
111 | [ACTIVE_INDICATOR],
112 | [MODULE_DESCRIPTION],
113 | [EXECUTABLE]
114 | FROM
115 | [omd].[MODULE]
116 | WHERE
117 | [MODULE_CODE] = @ModuleCode;
118 |
119 | IF EXISTS (SELECT 1 FROM @Results)
120 | BEGIN
121 | SET @SuccessIndicator = 'Y';
122 | SET @LogMessage = 'Module with Code ''' + @ModuleCode + ''' was found.'
123 | SET @MessageLog = [omd].[AddLogMessage]('INFO', DEFAULT, N'Module Found', @LogMessage, @MessageLog)
124 |
125 | END
126 | ELSE
127 | BEGIN
128 | SET @SuccessIndicator = 'N';
129 | SET @LogMessage = 'No Module with Code ''' + @ModuleCode + ''' was found.'
130 | SET @MessageLog = [omd].[AddLogMessage]('ERROR', DEFAULT, N'Error Message', @LogMessage, @MessageLog)
131 | END
132 |
133 | /*******************************************************************************
134 | * Return Resultset
135 | ******************************************************************************/
136 |
137 | SELECT *
138 | FROM @Results;
139 |
140 | /*******************************************************************************
141 | * EndOfProcedure Label
142 | ******************************************************************************/
143 |
144 | EndOfProcedure:
145 |
146 | SET @EndTimestamp = SYSUTCDATETIME();
147 | SET @EndTimestampString = FORMAT(@EndTimestamp, 'yyyy-MM-dd HH:mm:ss.fffffff');
148 | SET @LogMessage = @EndTimestampString;
149 | SET @MessageLog = [omd].[AddLogMessage](DEFAULT, DEFAULT, N'End Timestamp', @LogMessage, @MessageLog)
150 | SET @LogMessage = DATEDIFF(SECOND, @StartTimestamp, @EndTimestamp);
151 | SET @MessageLog = [omd].[AddLogMessage](DEFAULT, DEFAULT, N'Elapsed Time (s)', @LogMessage, @MessageLog)
152 |
153 | IF @Debug = 'Y'
154 | BEGIN
155 | EXEC [omd].[PrintMessageLog] @MessageLog;
156 | END
157 |
158 | END TRY
159 | BEGIN CATCH
160 | -- SP-wide error handler and logging
161 | SET @SuccessIndicator = 'N'
162 | SET @LogMessage = @SuccessIndicator;
163 | SET @MessageLog = [omd].[AddLogMessage](DEFAULT, DEFAULT, N'Parameter @SuccessIndicator', @LogMessage, @MessageLog)
164 |
165 | DECLARE @ErrorMessage NVARCHAR(4000);
166 | DECLARE @ErrorSeverity INT;
167 | DECLARE @ErrorState INT;
168 | DECLARE @ErrorProcedure NVARCHAR(128);
169 | DECLARE @ErrorNumber INT;
170 | DECLARE @ErrorLine INT;
171 |
172 | SELECT
173 | @ErrorMessage = COALESCE(ERROR_MESSAGE(), 'No Message' ),
174 | @ErrorSeverity = COALESCE(ERROR_SEVERITY(), -1 ),
175 | @ErrorState = COALESCE(ERROR_STATE(), -1 ),
176 | @ErrorProcedure = COALESCE(ERROR_PROCEDURE(), 'No Procedure' ),
177 | @ErrorLine = COALESCE(ERROR_LINE(), -1 ),
178 | @ErrorNumber = COALESCE(ERROR_NUMBER(), -1 );
179 |
180 | IF @Debug = 'Y'
181 | BEGIN
182 | PRINT 'Error in ''' + @SpName + ''''
183 | PRINT 'Error Message: ' + @ErrorMessage
184 | PRINT 'Error Severity: ' + CONVERT(NVARCHAR(10), @ErrorSeverity)
185 | PRINT 'Error State: ' + CONVERT(NVARCHAR(10), @ErrorState)
186 | PRINT 'Error Procedure: ' + @ErrorProcedure
187 | PRINT 'Error Line: ' + CONVERT(NVARCHAR(10), @ErrorLine)
188 | PRINT 'Error Number: ' + CONVERT(NVARCHAR(10), @ErrorNumber)
189 | PRINT 'SuccessIndicator: '+ @SuccessIndicator
190 |
191 | -- Spool message log
192 | EXEC [omd].[PrintMessageLog] @MessageLog;
193 |
194 | END
195 |
196 | SET @EventDetail = 'Error in ''' + COALESCE(@SpName,'N/A') + ''' from ''' + COALESCE(@ErrorProcedure,'N/A') + ''' at line ''' + CONVERT(NVARCHAR(10), COALESCE(@ErrorLine,'N/A')) + ''': '+ CHAR(10) + COALESCE(@ErrorMessage,'N/A');
197 | SET @EventReturnCode = ERROR_NUMBER();
198 |
199 | EXEC [omd].[InsertIntoEventLog]
200 | @EventDetail = @EventDetail,
201 | @EventReturnCode = @EventReturnCode;
202 |
203 | THROW
204 | END CATCH
205 |
--------------------------------------------------------------------------------
/Direct_Framework/Stored Procedures/omd.InsertIntoEventLog.sql:
--------------------------------------------------------------------------------
1 | /*******************************************************************************
2 | * [omd].[InsertIntoEventLog]
3 | *******************************************************************************
4 | *
5 | * https://github.com/data-solution-automation-engine/DIRECT
6 | *
7 | * DIRECT model v2.0
8 | *
9 | * Purpose:
10 | * Inserts an event log entry capturing failures or other noteworthy events.
11 | *
12 | * Input:
13 | * - Batch Instance Id (0 if not set)
14 | * - Module Instance Id (0 if not set)
15 | * - Event Details
16 | * - Event Datetime (defaults to SYSUTCDATETIME() if not set)
17 | * - Event Type Code (see omd.EVENT_TYPE table contents for options)
18 | * - Error Return Code
19 | * - Error Bitmap
20 | * - Debug flag Y/N (default to N)
21 | *
22 | * Outputs:
23 | * - Success Indicator (Y/N)
24 | * - Message Log
25 | *
26 | * Usage:
27 | *
28 | *******************************************************************************
29 |
30 | EXEC [omd].[InsertIntoEventLog]
31 | @ModuleInstanceId = <123>,
32 | @EventDetail = '',
33 | @EventTypeCode = '<2>'
34 |
35 | *******************************************************************************
36 | *
37 | ******************************************************************************/
38 |
39 | CREATE PROCEDURE [omd].[InsertIntoEventLog]
40 | (
41 | -- Mandatory parameters
42 | @ModuleInstanceId BIGINT = 0,
43 | @EventDetail NVARCHAR(4000),
44 | -- Optional parameters
45 | @BatchInstanceId BIGINT = 0,
46 | @EventTimestamp DATETIME2 = NULL,
47 | @EventTypeCode NVARCHAR(100) = '2',
48 | @EventReturnCode NVARCHAR(1000) = 'N/A',
49 | @ErrorBitmap NUMERIC(20,0) = 0,
50 | @Debug CHAR(1) = 'N',
51 | -- Output parameters
52 | @SuccessIndicator CHAR(1) = 'N' OUTPUT,
53 | @MessageLog NVARCHAR(MAX) = N'' OUTPUT
54 | )
55 | AS
56 | BEGIN TRY
57 | SET NOCOUNT ON;
58 |
59 | -- Default output logging setup
60 | DECLARE @SpName NVARCHAR(100) = N'[' + OBJECT_SCHEMA_NAME(@@PROCID) + '].[' + OBJECT_NAME(@@PROCID) + ']';
61 | DECLARE @DirectVersion NVARCHAR(10) = [omd_metadata].[GetFrameworkVersion]();
62 | DECLARE @StartTimestamp DATETIME = SYSUTCDATETIME();
63 | DECLARE @StartTimestampString NVARCHAR(20) = FORMAT(@StartTimestamp, 'yyyy-MM-dd HH:mm:ss.fffffff');
64 | DECLARE @EndTimestamp DATETIME = NULL;
65 | DECLARE @EndTimestampString NVARCHAR(20) = N'';
66 | DECLARE @LogMessage NVARCHAR(MAX);
67 |
68 | -- Log standard metadata
69 | SET @LogMessage = @SpName;
70 | SET @MessageLog = [omd].[AddLogMessage](DEFAULT, DEFAULT, N'Procedure', @LogMessage, @MessageLog)
71 | SET @LogMessage = @DirectVersion;
72 | SET @MessageLog = [omd].[AddLogMessage](DEFAULT, DEFAULT, N'Version',@LogMessage, @MessageLog)
73 | SET @LogMessage = @StartTimestampString;
74 | SET @MessageLog = [omd].[AddLogMessage](DEFAULT, DEFAULT, N'Start Timestamp', @LogMessage, @MessageLog)
75 |
76 | -- Log parameters
77 | SET @LogMessage = @ModuleInstanceId;
78 | SET @MessageLog = [omd].[AddLogMessage](DEFAULT, DEFAULT, N'Parameter @ModuleInstanceId', @LogMessage, @MessageLog)
79 | SET @LogMessage = @EventDetail;
80 | SET @MessageLog = [omd].[AddLogMessage](DEFAULT, DEFAULT, N'Parameter @EventDetail', @LogMessage, @MessageLog)
81 | SET @LogMessage = @BatchInstanceId
82 | SET @MessageLog = [omd].[AddLogMessage](DEFAULT, DEFAULT, N'Parameter @BatchInstanceId', @LogMessage, @MessageLog)
83 | SET @LogMessage = @EventTimestamp
84 | SET @MessageLog = [omd].[AddLogMessage](DEFAULT, DEFAULT, N'Parameter @EventTimestamp', @LogMessage, @MessageLog)
85 | SET @LogMessage = @EventTypeCode
86 | SET @MessageLog = [omd].[AddLogMessage](DEFAULT, DEFAULT, N'Parameter @EventTypeCode', @LogMessage, @MessageLog)
87 | SET @LogMessage = @EventReturnCode
88 | SET @MessageLog = [omd].[AddLogMessage](DEFAULT, DEFAULT, N'Parameter @EventReturnCode', @LogMessage, @MessageLog)
89 | SET @LogMessage = @ErrorBitmap
90 | SET @MessageLog = [omd].[AddLogMessage](DEFAULT, DEFAULT, N'Parameter @ErrorBitmap', @LogMessage, @MessageLog)
91 |
92 | -- Process variables
93 | SET @SuccessIndicator = 'N' -- Ensure the process starts as not successful, so that is updated accordingly when it is.
94 |
95 | /*******************************************************************************
96 | * Start of main process
97 | ******************************************************************************/
98 |
99 | SET @EventTimestamp = COALESCE(@EventTimestamp, SYSUTCDATETIME());
100 |
101 | SET @LogMessage = 'Inserting record in Event Log for Module Instance Id ''' + CONVERT(NVARCHAR(20), COALESCE(@ModuleInstanceId, 0)) + ''''
102 | SET @MessageLog = [omd].[AddLogMessage](DEFAULT, DEFAULT, N'Status Update', @LogMessage, @MessageLog)
103 | SET @LogMessage = 'Batch Instance Id ''' + CONVERT(NVARCHAR(20), COALESCE(@BatchInstanceId, 0)) + ''''
104 | SET @MessageLog = [omd].[AddLogMessage](DEFAULT, DEFAULT, N'Status Update', @LogMessage, @MessageLog)
105 | SET @LogMessage = 'Message: '+@EventDetail
106 | SET @MessageLog = [omd].[AddLogMessage](DEFAULT, DEFAULT, N'Status Update', @LogMessage, @MessageLog)
107 |
108 | INSERT INTO [omd].[EVENT_LOG]
109 | (
110 | [MODULE_INSTANCE_ID],
111 | [BATCH_INSTANCE_ID],
112 | [EVENT_TYPE_CODE],
113 | [EVENT_TIMESTAMP],
114 | [EVENT_RETURN_CODE],
115 | [EVENT_DETAIL],
116 | [ERROR_BITMAP]
117 | )
118 | VALUES
119 | (
120 | COALESCE(@ModuleInstanceId, 0),
121 | COALESCE(@BatchInstanceId, 0),
122 | @EventTypeCode,
123 | @EventTimestamp,
124 | @EventReturnCode,
125 | @EventDetail,
126 | @ErrorBitmap
127 | )
128 |
129 | -- End of procedure label
130 | EndOfProcedure:
131 |
132 | SET @SuccessIndicator = 'Y'
133 |
134 | SET @EndTimestamp = SYSUTCDATETIME();
135 | SET @EndTimestampString = FORMAT(@EndTimestamp, 'yyyy-MM-dd HH:mm:ss.fffffff');
136 | SET @LogMessage = @EndTimestampString;
137 | SET @MessageLog = [omd].[AddLogMessage](DEFAULT, DEFAULT, N'End Timestamp', @LogMessage, @MessageLog)
138 | SET @LogMessage = DATEDIFF(SECOND, @StartTimestamp, @EndTimestamp);
139 | SET @MessageLog = [omd].[AddLogMessage](DEFAULT, DEFAULT, N'Elapsed Time (s)', @LogMessage, @MessageLog)
140 | SET @LogMessage = @SuccessIndicator;
141 | SET @MessageLog = [omd].[AddLogMessage](DEFAULT, DEFAULT, N'Parameter @SuccessIndicator', @LogMessage, @MessageLog)
142 |
143 | IF @Debug = 'Y'
144 | BEGIN
145 | EXEC [omd].[PrintMessageLog] @MessageLog;
146 | END
147 |
148 | END TRY
149 | BEGIN CATCH
150 | -- SP-wide error handler and logging
151 | SET @SuccessIndicator = 'N'
152 | SET @LogMessage = @SuccessIndicator;
153 | SET @MessageLog = [omd].[AddLogMessage](DEFAULT, DEFAULT, N'Parameter @SuccessIndicator', @LogMessage, @MessageLog)
154 |
155 | DECLARE @ErrorMessage NVARCHAR(4000);
156 | DECLARE @ErrorSeverity INT;
157 | DECLARE @ErrorState INT;
158 | DECLARE @ErrorProcedure NVARCHAR(128);
159 | DECLARE @ErrorNumber INT;
160 | DECLARE @ErrorLine INT;
161 |
162 | SELECT
163 | @ErrorMessage = COALESCE(ERROR_MESSAGE(), 'No Message' ),
164 | @ErrorSeverity = COALESCE(ERROR_SEVERITY(), -1 ),
165 | @ErrorState = COALESCE(ERROR_STATE(), -1 ),
166 | @ErrorProcedure = COALESCE(ERROR_PROCEDURE(), 'No Procedure' ),
167 | @ErrorLine = COALESCE(ERROR_LINE(), -1 ),
168 | @ErrorNumber = COALESCE(ERROR_NUMBER(), -1 );
169 |
170 | IF @Debug = 'Y'
171 | BEGIN
172 | PRINT 'Error in ''' + @SpName + ''''
173 | PRINT 'Error Message: ' + @ErrorMessage
174 | PRINT 'Error Severity: ' + CONVERT(NVARCHAR(10), @ErrorSeverity)
175 | PRINT 'Error State: ' + CONVERT(NVARCHAR(10), @ErrorState)
176 | PRINT 'Error Procedure: ' + @ErrorProcedure
177 | PRINT 'Error Line: ' + CONVERT(NVARCHAR(10), @ErrorLine)
178 | PRINT 'Error Number: ' + CONVERT(NVARCHAR(10), @ErrorNumber)
179 | PRINT 'SuccessIndicator: '+ @SuccessIndicator
180 |
181 | -- Spool message log
182 | EXEC [omd].[PrintMessageLog] @MessageLog;
183 |
184 | END;
185 |
186 | THROW
187 | END CATCH
188 |
--------------------------------------------------------------------------------
/Direct_Framework/Stored Procedures/omd.PrintLog.sql:
--------------------------------------------------------------------------------
1 | /*******************************************************************************
2 | * [omd].[PrintMessageLog]
3 | *******************************************************************************
4 | *
5 | * https://github.com/data-solution-automation-engine/DIRECT
6 | *
7 | * DIRECT model v2.0
8 | *
9 | * Purpose:
10 | * Pretty Prints a message log
11 | *
12 | * Inputs:
13 | * - Message Log
14 | *
15 | * Output:
16 | * - Pretty Printed Log
17 | * (note: the output is displayed in the Messages tab/output.
18 | * It is not delivered to the client as a result set)
19 | *
20 | * Usage:
21 | *
22 | *******************************************************************************
23 |
24 | DECLARE @MessageLog NVARCHAR(MAX);
25 | SET @MessageLog =
26 | N'[{"severity":"INFO",' +
27 | N'"timestamp":"2001-12-26T12:23:18",' +
28 | N'"key":"Parameter Parsing",' +
29 | N'"message":"Starting special parameter parsing process"},'+
30 | N'{"severity":"WARNING",' +
31 | N'"timestamp":"2001-12-26T12:23:19",' +
32 | N'"key":"Value Parsing",' +
33 | N'"message":"The parsing of ''2319'' as event code failed"}]'
34 |
35 | EXEC [omd].[PrintMessageLog]
36 | @MessageLog = @MessageLog
37 |
38 | *******************************************************************************
39 | *
40 | ******************************************************************************/
41 |
42 | CREATE PROCEDURE [omd].[PrintMessageLog]
43 | (
44 | -- Mandatory Parameters
45 | @MessageLog NVARCHAR(MAX)
46 | )
47 | AS
48 | BEGIN
49 | SET NOCOUNT ON;
50 | SET ANSI_WARNINGS OFF;
51 |
52 | DECLARE @tempTable TABLE
53 | (
54 | [Id] INT IDENTITY(1,1),
55 | [Severity] NVARCHAR(100),
56 | [Timestamp] NVARCHAR(100),
57 | [Key] NVARCHAR(1000),
58 | [Message] NVARCHAR(MAX)
59 | )
60 |
61 | INSERT INTO @tempTable ([Severity], [Timestamp], [Key], [Message])
62 | SELECT [Severity], [Timestamp], [Key], [Message]
63 | FROM OPENJSON(@MessageLog)
64 | WITH (
65 | [Severity] NVARCHAR(100) '$.severity',
66 | [Timestamp] NVARCHAR(100) '$.timestamp',
67 | [Key] NVARCHAR(1000) '$.key',
68 | [Message] NVARCHAR(MAX) '$.message'
69 | )
70 |
71 | DECLARE
72 | @TableLine NVARCHAR(200) = REPLICATE('-', 170),
73 | @PrintSeverity NVARCHAR(100),
74 | @PrintTimestamp NVARCHAR(100),
75 | @PrintKey NVARCHAR(1000),
76 | @PrintMessage NVARCHAR(MAX),
77 |
78 | @index INT = 1,
79 | @count INT = (SELECT COUNT(1) FROM @tempTable);
80 |
81 | -- Table Header
82 | PRINT @TableLine;
83 | PRINT '| ' +
84 | LEFT('Severity' + SPACE(8), 8) + ' | ' +
85 | LEFT('Timestamp' + SPACE(19), 19) + ' | ' +
86 | LEFT('Key' + SPACE(30), 30) + ' | ' +
87 | LEFT('Message' + SPACE(100), 100) + ' |';
88 | PRINT @TableLine;
89 |
90 | WHILE @index <= @count
91 | BEGIN
92 | SELECT
93 | @PrintSeverity = [Severity],
94 | @PrintTimestamp = FORMAT(CAST([Timestamp] AS DATETIME2), 'yyyy-MM-dd HH:mm:ss'),
95 | @PrintKey = [Key],
96 | @PrintMessage = [Message]
97 | FROM @tempTable
98 | WHERE Id = @index;
99 |
100 | -- Formatted Table Contents
101 | PRINT '| ' +
102 | LEFT(ISNULL(@PrintSeverity, 'NULL') + SPACE(8), 8) + ' | ' +
103 | LEFT(ISNULL(@PrintTimestamp, 'NULL') + SPACE(19), 19) + ' | ' +
104 | LEFT(ISNULL(@PrintKey, 'NULL') + SPACE(30), 30) + ' | ' +
105 | LEFT(ISNULL(@PrintMessage, 'NULL') + SPACE(100), 100) + ' |';
106 |
107 | IF LEN(@PrintKey) > 30 OR LEN(@PrintMessage) > 100
108 | BEGIN
109 | -- Print Formatted Table Contents Line 2 for longer messages
110 | -- For even longer messages, review the contents of the log directly
111 | PRINT '| ' +
112 | SPACE(8) + ' | ' +
113 | SPACE(19) + ' | ' +
114 | LEFT(ISNULL(SUBSTRING(@PrintKey, 31, 30) , 'NULL') + SPACE(30), 30) + ' | ' +
115 | LEFT(ISNULL(SUBSTRING(@PrintMessage, 101, 100), 'NULL') + SPACE(100), 100) + ' |';
116 | END
117 |
118 | SET @index = @index + 1;
119 |
120 | END;
121 |
122 | -- Table Footer
123 | PRINT @TableLine;
124 |
125 | END
126 |
--------------------------------------------------------------------------------
/Direct_Framework/Tables/omd.BATCH.sql:
--------------------------------------------------------------------------------
1 | CREATE TABLE [omd].[BATCH] (
2 | [BATCH_ID] INT IDENTITY (1, 1) NOT NULL,
3 | [BATCH_CODE] NVARCHAR (1000) NOT NULL,
4 | [BATCH_TYPE] NVARCHAR (100) NULL,
5 | [FREQUENCY_CODE] NVARCHAR (100)
6 | CONSTRAINT [DF_OMD_BATCH_FREQUENCY_CODE]
7 | DEFAULT (N'On-demand') NOT NULL,
8 | [ACTIVE_INDICATOR] CHAR (1)
9 | CONSTRAINT [DF_OMD_BATCH_ACTIVE_INDICATOR]
10 | DEFAULT ('Y') NOT NULL,
11 | [BATCH_DESCRIPTION] NVARCHAR (4000) NULL,
12 |
13 | CONSTRAINT [PK_OMD_BATCH]
14 | PRIMARY KEY CLUSTERED ([BATCH_ID] ASC),
15 |
16 | CONSTRAINT [IX_OMD_BATCH]
17 | UNIQUE NONCLUSTERED ([BATCH_CODE] ASC)
18 | );
19 |
--------------------------------------------------------------------------------
/Direct_Framework/Tables/omd.BATCH_HIERARCHY.sql:
--------------------------------------------------------------------------------
1 | CREATE TABLE [omd].[BATCH_HIERARCHY] (
2 | [PARENT_BATCH_ID] INT NOT NULL,
3 | [BATCH_ID] INT NOT NULL,
4 | [SEQUENCE] INT
5 | CONSTRAINT [DF_OMD_BATCH_HIERARCHY_SEQUENCE]
6 | DEFAULT (0) NOT NULL,
7 | [ACTIVE_INDICATOR] CHAR (1)
8 | CONSTRAINT [DF_OMD_BATCH_HIERARCHY_ACTIVE_INDICATOR]
9 | DEFAULT ('Y') NOT NULL,
10 |
11 | CONSTRAINT [PK_OMD_BATCH_HIERARCHY]
12 | PRIMARY KEY CLUSTERED ([PARENT_BATCH_ID] ASC, [BATCH_ID] ASC),
13 |
14 | CONSTRAINT [FK_OMD_BATCH_HIERARCHY_OMD_BATCH]
15 | FOREIGN KEY ([BATCH_ID])
16 | REFERENCES [omd].[BATCH] ([BATCH_ID]),
17 |
18 | CONSTRAINT [FK_OMD_BATCH_HIERARCHY_OMD_BATCH_PARENT_BATCH]
19 | FOREIGN KEY ([PARENT_BATCH_ID])
20 | REFERENCES [omd].[BATCH] ([BATCH_ID]),
21 | );
22 |
--------------------------------------------------------------------------------
/Direct_Framework/Tables/omd.BATCH_INSTANCE.sql:
--------------------------------------------------------------------------------
1 | CREATE TABLE [omd].[BATCH_INSTANCE] (
2 | [BATCH_INSTANCE_ID] BIGINT IDENTITY (1, 1) NOT NULL,
3 | [BATCH_ID] INT NOT NULL,
4 | [PARENT_BATCH_INSTANCE_ID] BIGINT NOT NULL,
5 | [START_TIMESTAMP] DATETIME2 NOT NULL,
6 | [END_TIMESTAMP] DATETIME2 NULL,
7 | [INTERNAL_PROCESSING_CODE] NVARCHAR (100) NOT NULL,
8 | [NEXT_RUN_STATUS_CODE] NVARCHAR (100) NOT NULL,
9 | [EXECUTION_STATUS_CODE] NVARCHAR (100) NOT NULL,
10 | [EXECUTION_CONTEXT] NVARCHAR (4000) NULL,
11 |
12 | CONSTRAINT [PK_OMD_BATCH_INSTANCE]
13 | PRIMARY KEY CLUSTERED ([BATCH_INSTANCE_ID] ASC),
14 |
15 | CONSTRAINT [FK_OMD_BATCH_INSTANCE_OMD_BATCH]
16 | FOREIGN KEY ([BATCH_ID])
17 | REFERENCES [omd].[BATCH] ([BATCH_ID]),
18 |
19 | CONSTRAINT [FK_OMD_BATCH_INSTANCE_OMD_BATCH_INSTANCE]
20 | FOREIGN KEY ([PARENT_BATCH_INSTANCE_ID])
21 | REFERENCES [omd].[BATCH_INSTANCE] ([BATCH_INSTANCE_ID]),
22 |
23 | CONSTRAINT [FK_OMD_BATCH_INSTANCE_OMD_METADATA_EXECUTION_STATUS]
24 | FOREIGN KEY ([EXECUTION_STATUS_CODE])
25 | REFERENCES [omd_metadata].[EXECUTION_STATUS] ([EXECUTION_STATUS_CODE]),
26 |
27 | CONSTRAINT [FK_OMD_BATCH_INSTANCE_OMD_METADATA_NEXT_RUN_STATUS]
28 | FOREIGN KEY ([NEXT_RUN_STATUS_CODE])
29 | REFERENCES [omd_metadata].[NEXT_RUN_STATUS] ([NEXT_RUN_STATUS_CODE]),
30 |
31 | CONSTRAINT [FK_OMD_BATCH_INSTANCE_OMD_METADATA_INTERNAL_PROCESSING_STATUS]
32 | FOREIGN KEY ([INTERNAL_PROCESSING_CODE])
33 | REFERENCES [omd_metadata].[INTERNAL_PROCESSING_STATUS] ([INTERNAL_PROCESSING_STATUS_CODE])
34 | );
35 |
--------------------------------------------------------------------------------
/Direct_Framework/Tables/omd.BATCH_MODULE.sql:
--------------------------------------------------------------------------------
1 | CREATE TABLE [omd].[BATCH_MODULE] (
2 | [BATCH_ID] INT NOT NULL,
3 | [MODULE_ID] INT NOT NULL,
4 | [SEQUENCE] INT
5 | CONSTRAINT [DF_OMD_BATCH_MODULE_SEQUENCE]
6 | DEFAULT (0) NOT NULL,
7 | [ACTIVE_INDICATOR] CHAR (1)
8 | CONSTRAINT [DF_OMD_BATCH_MODULE_ACTIVE_INDICATOR]
9 | DEFAULT ('Y') NOT NULL,
10 |
11 | CONSTRAINT [PK_OMD_BATCH_MODULE]
12 | PRIMARY KEY CLUSTERED ([BATCH_ID] ASC, [MODULE_ID] ASC),
13 |
14 | CONSTRAINT [FK_OMD_BATCH_MODULE_OMD_BATCH]
15 | FOREIGN KEY ([BATCH_ID])
16 | REFERENCES [omd].[BATCH] ([BATCH_ID]),
17 |
18 | CONSTRAINT [FK_OMD_BATCH_MODULE_OMD_MODULE]
19 | FOREIGN KEY ([MODULE_ID])
20 | REFERENCES [omd].[MODULE] ([MODULE_ID])
21 | );
22 |
--------------------------------------------------------------------------------
/Direct_Framework/Tables/omd.BATCH_PARAMETER.sql:
--------------------------------------------------------------------------------
1 | CREATE TABLE [omd].[BATCH_PARAMETER] (
2 | [BATCH_ID] INT NOT NULL,
3 | [PARAMETER_ID] INT NOT NULL,
4 | [ACTIVE_INDICATOR] CHAR (1)
5 | CONSTRAINT [DF_OMD_BATCH_PARAMETER_ACTIVE_INDICATOR]
6 | DEFAULT ('Y') NOT NULL,
7 |
8 | CONSTRAINT [PK_OMD_BATCH_PARAMETER]
9 | PRIMARY KEY CLUSTERED ([BATCH_ID] ASC, [PARAMETER_ID] ASC),
10 |
11 | CONSTRAINT [FK_OMD_BATCH_PARAMETER_OMD_BATCH]
12 | FOREIGN KEY ([BATCH_ID])
13 | REFERENCES [omd].[BATCH] ([BATCH_ID]),
14 |
15 | CONSTRAINT [FK_OMD_BATCH_PARAMETER_OMD_PARAMETER]
16 | FOREIGN KEY ([PARAMETER_ID])
17 | REFERENCES [omd].[PARAMETER] ([PARAMETER_ID])
18 | );
19 |
--------------------------------------------------------------------------------
/Direct_Framework/Tables/omd.EVENT_LOG.sql:
--------------------------------------------------------------------------------
1 | CREATE TABLE [omd].[EVENT_LOG] (
2 | [EVENT_ID] BIGINT IDENTITY (1, 1) NOT NULL,
3 | [BATCH_INSTANCE_ID] BIGINT
4 | CONSTRAINT [DF_OMD_EVENT_LOG_BATCH_INSTANCE_ID]
5 | DEFAULT (0) NOT NULL,
6 | [MODULE_INSTANCE_ID] BIGINT
7 | CONSTRAINT [DF_OMD_EVENT_LOG_MODULE_INSTANCE_ID]
8 | DEFAULT (0) NOT NULL,
9 | [EVENT_TYPE_CODE] NVARCHAR (100) NOT NULL,
10 | [EVENT_TIMESTAMP] DATETIME2
11 | CONSTRAINT [DF_OMD_EVENT_LOG_EVENT_TIMESTAMP]
12 | DEFAULT (SYSUTCDATETIME()) NOT NULL,
13 | [EVENT_RETURN_CODE] NVARCHAR (100) NULL,
14 | [EVENT_DETAIL] NVARCHAR (4000) NOT NULL,
15 | [ERROR_BITMAP] NUMERIC (20) NULL,
16 |
17 | CONSTRAINT [PK_OMD_EVENT_LOG]
18 | PRIMARY KEY CLUSTERED ([EVENT_ID] ASC),
19 |
20 | CONSTRAINT [FK_OMD_EVENT_LOG_OMD_BATCH_INSTANCE]
21 | FOREIGN KEY ([BATCH_INSTANCE_ID])
22 | REFERENCES [omd].[BATCH_INSTANCE] ([BATCH_INSTANCE_ID]),
23 |
24 | CONSTRAINT [FK_OMD_EVENT_LOG_OMD_METADATA_EVENT_TYPE]
25 | FOREIGN KEY ([EVENT_TYPE_CODE])
26 | REFERENCES [omd_metadata].[EVENT_TYPE] ([EVENT_TYPE_CODE]),
27 |
28 | CONSTRAINT [FK_OMD_EVENT_LOG_OMD_MODULE_INSTANCE]
29 | FOREIGN KEY ([MODULE_INSTANCE_ID])
30 | REFERENCES [omd].[MODULE_INSTANCE] ([MODULE_INSTANCE_ID])
31 | );
32 |
--------------------------------------------------------------------------------
/Direct_Framework/Tables/omd.MODULE.sql:
--------------------------------------------------------------------------------
1 | CREATE TABLE [omd].[MODULE] (
2 | [MODULE_ID] INT IDENTITY (1, 1) NOT NULL,
3 | [MODULE_CODE] NVARCHAR (1000) NOT NULL,
4 | [MODULE_TYPE] NVARCHAR (100) NOT NULL,
5 | [DATA_OBJECT_SOURCE] NVARCHAR (1000) NULL,
6 | [DATA_OBJECT_TARGET] NVARCHAR (1000) NULL,
7 | [AREA_CODE] NVARCHAR (100) NOT NULL,
8 | [FREQUENCY_CODE] NVARCHAR (100)
9 | CONSTRAINT [DF_OMD_MODULE_FREQUENCY_CODE]
10 | DEFAULT (N'On-demand') NOT NULL,
11 | [ACTIVE_INDICATOR] CHAR (1)
12 | CONSTRAINT [DF_OMD_MODULE_ACTIVE_INDICATOR]
13 | DEFAULT ('Y') NOT NULL,
14 | [MODULE_DESCRIPTION] NVARCHAR (4000) NULL,
15 | [EXECUTABLE] NVARCHAR (MAX) NULL,
16 |
17 | CONSTRAINT [PK_OMD_MODULE]
18 | PRIMARY KEY CLUSTERED ([MODULE_ID] ASC),
19 |
20 | CONSTRAINT [IX_OMD_MODULE_MODULE_CODE]
21 | UNIQUE NONCLUSTERED ([MODULE_CODE] ASC),
22 |
23 | CONSTRAINT [FK_OMD_MODULE_OMD_METADATA_AREA]
24 | FOREIGN KEY ([AREA_CODE])
25 | REFERENCES [omd_metadata].[AREA] ([AREA_CODE]),
26 |
27 | CONSTRAINT [FK_OMD_MODULE_OMD_METADATA_FREQUENCY]
28 | FOREIGN KEY ([FREQUENCY_CODE])
29 | REFERENCES [omd_metadata].[FREQUENCY] ([FREQUENCY_CODE])
30 | );
31 |
--------------------------------------------------------------------------------
/Direct_Framework/Tables/omd.MODULE_INSTANCE.sql:
--------------------------------------------------------------------------------
1 | CREATE TABLE [omd].[MODULE_INSTANCE] (
2 | [MODULE_INSTANCE_ID] BIGINT IDENTITY (1, 1) NOT NULL,
3 | [MODULE_ID] INT NOT NULL,
4 | [BATCH_INSTANCE_ID] BIGINT NOT NULL,
5 | [START_TIMESTAMP] DATETIME2 NOT NULL,
6 | [END_TIMESTAMP] DATETIME2 NULL,
7 | [INTERNAL_PROCESSING_CODE] NVARCHAR (100) NOT NULL,
8 | [NEXT_RUN_STATUS_CODE] NVARCHAR (100) NOT NULL,
9 | [EXECUTION_STATUS_CODE] NVARCHAR (100) NOT NULL,
10 | [EXECUTION_CONTEXT] NVARCHAR (4000) NULL,
11 | [ROWS_INPUT] INT NULL,
12 | [ROWS_INSERTED] INT NULL,
13 | [ROWS_UPDATED] INT NULL,
14 | [ROWS_DELETED] INT NULL,
15 | [ROWS_DISCARDED] INT NULL,
16 | [ROWS_REJECTED] INT NULL,
17 | [EXECUTED_CODE_CHECKSUM] VARBINARY(64) NULL,
18 |
19 | CONSTRAINT [PK_MODULE_INSTANCE]
20 | PRIMARY KEY CLUSTERED ([MODULE_INSTANCE_ID] ASC),
21 |
22 | CONSTRAINT [FK_OMD_MODULE_INSTANCE_OMD_BATCH_INSTANCE]
23 | FOREIGN KEY ([BATCH_INSTANCE_ID])
24 | REFERENCES [omd].[BATCH_INSTANCE] ([BATCH_INSTANCE_ID]),
25 |
26 | CONSTRAINT [FK_OMD_MODULE_INSTANCE_OMD_METADATA_EXECUTION_STATUS_CODE]
27 | FOREIGN KEY ([EXECUTION_STATUS_CODE])
28 | REFERENCES [omd_metadata].[EXECUTION_STATUS] ([EXECUTION_STATUS_CODE]),
29 |
30 | CONSTRAINT [FK_OMD_MODULE_INSTANCE_OMD_MODULE]
31 | FOREIGN KEY ([MODULE_ID])
32 | REFERENCES [omd].[MODULE] ([MODULE_ID]),
33 |
34 | CONSTRAINT [FK_OMD_MODULE_INSTANCE_OMD_METADATA_NEXT_RUN_STATUS]
35 | FOREIGN KEY ([NEXT_RUN_STATUS_CODE])
36 | REFERENCES [omd_metadata].[NEXT_RUN_STATUS] ([NEXT_RUN_STATUS_CODE]),
37 |
38 | CONSTRAINT [FK_OMD_MODULE_INSTANCE_OMD_METADATA_PROCESSING_STATUS]
39 | FOREIGN KEY ([INTERNAL_PROCESSING_CODE])
40 | REFERENCES [omd_metadata].[INTERNAL_PROCESSING_STATUS] ([INTERNAL_PROCESSING_STATUS_CODE])
41 | );
42 |
--------------------------------------------------------------------------------
/Direct_Framework/Tables/omd.MODULE_INSTANCE_EXECUTED_CODE.sql:
--------------------------------------------------------------------------------
1 | CREATE TABLE [omd].[MODULE_INSTANCE_EXECUTED_CODE] (
2 | [CHECKSUM] VARBINARY(64) NOT NULL,
3 | [EXECUTED_CODE] NVARCHAR(MAX) NOT NULL,
4 |
5 | CONSTRAINT [PK_OMD_MODULE_INSTANCE_EXECUTED_CODE]
6 | PRIMARY KEY CLUSTERED ([CHECKSUM] ASC)
7 | );
8 |
--------------------------------------------------------------------------------
/Direct_Framework/Tables/omd.MODULE_PARAMETER.sql:
--------------------------------------------------------------------------------
1 | CREATE TABLE [omd].[MODULE_PARAMETER] (
2 | [MODULE_ID] INT NOT NULL,
3 | [PARAMETER_ID] INT NOT NULL,
4 | [ACTIVE_INDICATOR] CHAR (1)
5 | CONSTRAINT [DF_OMD_MODULE_PARAMETER_ACTIVE_INDICATOR]
6 | DEFAULT ('Y') NOT NULL,
7 |
8 | CONSTRAINT [PK_OMD_MODULE_PARAMETER]
9 | PRIMARY KEY CLUSTERED ([MODULE_ID] ASC, [PARAMETER_ID] ASC),
10 |
11 | CONSTRAINT [FK_OMD_MODULE_PARAMETER_OMD_MODULE]
12 | FOREIGN KEY ([MODULE_ID])
13 | REFERENCES [omd].[MODULE] ([MODULE_ID]),
14 |
15 | CONSTRAINT [FK_OMD_MODULE_PARAMETER_OMD_PARAMETER]
16 | FOREIGN KEY ([PARAMETER_ID])
17 | REFERENCES [omd].[PARAMETER] ([PARAMETER_ID])
18 | );
19 |
--------------------------------------------------------------------------------
/Direct_Framework/Tables/omd.PARAMETER.sql:
--------------------------------------------------------------------------------
1 | CREATE TABLE [omd].[PARAMETER] (
2 | [PARAMETER_ID] INT IDENTITY (1, 1) NOT NULL,
3 | [PARAMETER_KEY_CODE] NVARCHAR (1000) NOT NULL,
4 | [PARAMETER_VALUE_CODE] NVARCHAR (4000) NOT NULL,
5 | [ACTIVE_INDICATOR] CHAR (1)
6 | CONSTRAINT [DF_OMD_PARAMETER_ACTIVE_INDICATOR]
7 | DEFAULT ('Y') NOT NULL,
8 | [PARAMETER_DESCRIPTION] NVARCHAR (4000) NOT NULL,
9 |
10 | CONSTRAINT [PK_OMD_PARAMETER]
11 | PRIMARY KEY CLUSTERED ([PARAMETER_ID] ASC)
12 | );
13 |
--------------------------------------------------------------------------------
/Direct_Framework/Tables/omd.SOURCE_CONTROL.sql:
--------------------------------------------------------------------------------
1 | CREATE TABLE [omd].[SOURCE_CONTROL] (
2 | [MODULE_SOURCE_CONTROL_ID] BIGINT IDENTITY (1, 1) NOT NULL,
3 | [MODULE_ID] INT NOT NULL,
4 | [MODULE_INSTANCE_ID] BIGINT NOT NULL,
5 | [INSERT_TIMESTAMP] DATETIME2
6 | CONSTRAINT [DF_OMD_SOURCE_CONTROL_INSERT_TIMESTAMP]
7 | DEFAULT(SYSUTCDATETIME()) NULL,
8 | [START_VALUE] DATETIME2 NULL,
9 | [END_VALUE] DATETIME2 NULL,
10 |
11 | CONSTRAINT [PK_OMD_SOURCE_CONTROL]
12 | PRIMARY KEY CLUSTERED ([MODULE_SOURCE_CONTROL_ID] ASC),
13 |
14 | CONSTRAINT [FK_OMD_SOURCE_CONTROL_OMD_MODULE_INSTANCE]
15 | FOREIGN KEY ([MODULE_INSTANCE_ID])
16 | REFERENCES [omd].[MODULE_INSTANCE] ([MODULE_INSTANCE_ID]),
17 |
18 | CONSTRAINT [FK_OMD_SOURCE_CONTROL_OMD_MODULE]
19 | FOREIGN KEY ([MODULE_ID])
20 | REFERENCES [omd].[MODULE] ([MODULE_ID]),
21 | );
22 |
--------------------------------------------------------------------------------
/Direct_Framework/Tables/omd_metadata.AREA.sql:
--------------------------------------------------------------------------------
1 | CREATE TABLE [omd_metadata].[AREA] (
2 | [AREA_CODE] NVARCHAR (100) NOT NULL,
3 | [LAYER_CODE] NVARCHAR (100) NOT NULL,
4 | [AREA_DESCRIPTION] NVARCHAR (4000) NULL,
5 |
6 | CONSTRAINT [PK_OMD_METADATA_AREA]
7 | PRIMARY KEY CLUSTERED ([AREA_CODE] ASC),
8 |
9 | CONSTRAINT [FK_OMD_METADATA_AREA_OMD_METADATA_LAYER]
10 | FOREIGN KEY ([LAYER_CODE])
11 | REFERENCES [omd_metadata].[LAYER] ([LAYER_CODE])
12 | );
13 |
--------------------------------------------------------------------------------
/Direct_Framework/Tables/omd_metadata.EVENT_TYPE.sql:
--------------------------------------------------------------------------------
1 | CREATE TABLE [omd_metadata].[EVENT_TYPE] (
2 | [EVENT_TYPE_CODE] NVARCHAR (100) NOT NULL,
3 | [EVENT_TYPE_CODE_DESCRIPTION] NVARCHAR (4000) NULL,
4 |
5 | CONSTRAINT [PK_OMD_METADATA_EVENT_TYPE]
6 | PRIMARY KEY CLUSTERED ([EVENT_TYPE_CODE] ASC)
7 | );
8 |
--------------------------------------------------------------------------------
/Direct_Framework/Tables/omd_metadata.EXECUTION_STATUS.sql:
--------------------------------------------------------------------------------
1 | CREATE TABLE [omd_metadata].[EXECUTION_STATUS] (
2 | [EXECUTION_STATUS_CODE] NVARCHAR (100) NOT NULL,
3 | [EXECUTION_STATUS_DESCRIPTION] NVARCHAR (4000) NULL,
4 |
5 | CONSTRAINT [PK_OMD_METADATA_EXECUTION_STATUS]
6 | PRIMARY KEY CLUSTERED ([EXECUTION_STATUS_CODE] ASC)
7 | );
8 |
--------------------------------------------------------------------------------
/Direct_Framework/Tables/omd_metadata.FRAMEWORK_METADATA.sql:
--------------------------------------------------------------------------------
1 | CREATE TABLE [omd_metadata].[FRAMEWORK_METADATA] (
2 | [CODE] NVARCHAR (100) NOT NULL,
3 | [VALUE] NVARCHAR (4000) NOT NULL,
4 | [GROUP] NVARCHAR (100) NULL,
5 | [DESCRIPTION] NVARCHAR (4000) NULL,
6 | [ACTIVE_INDICATOR] CHAR (1)
7 | CONSTRAINT [DF_OMD_METADATA_FRAMEWORK_METADATA_ACTIVE_INDICATOR]
8 | DEFAULT ('Y') NULL,
9 |
10 | CONSTRAINT [PK_OMD_FRAMEWORK_METADATA]
11 | PRIMARY KEY ([CODE] ASC)
12 | );
13 |
--------------------------------------------------------------------------------
/Direct_Framework/Tables/omd_metadata.FREQUENCY.sql:
--------------------------------------------------------------------------------
1 | CREATE TABLE [omd_metadata].[FREQUENCY] (
2 | [FREQUENCY_CODE] NVARCHAR (100) NOT NULL,
3 | [FREQUENCY_DESCRIPTION] NVARCHAR (4000) NULL,
4 |
5 | CONSTRAINT [PK_OMD_METADATA_FREQUENCY]
6 | PRIMARY KEY CLUSTERED ([FREQUENCY_CODE] ASC)
7 | );
8 |
--------------------------------------------------------------------------------
/Direct_Framework/Tables/omd_metadata.INTERNAL_PROCESSING_STATUS.sql:
--------------------------------------------------------------------------------
1 | CREATE TABLE [omd_metadata].[INTERNAL_PROCESSING_STATUS] (
2 | [INTERNAL_PROCESSING_STATUS_CODE] NVARCHAR (100) NOT NULL,
3 | [INTERNAL_PROCESSING_STATUS_CODE_DESCRIPTION] NVARCHAR (4000) NULL,
4 |
5 | CONSTRAINT [PK_OMD_METADATA_INTERNAL_PROCESSING_STATUS]
6 | PRIMARY KEY CLUSTERED ([INTERNAL_PROCESSING_STATUS_CODE] ASC)
7 | );
8 |
--------------------------------------------------------------------------------
/Direct_Framework/Tables/omd_metadata.LAYER.sql:
--------------------------------------------------------------------------------
1 | CREATE TABLE [omd_metadata].[LAYER] (
2 | [LAYER_CODE] NVARCHAR (100) NOT NULL,
3 | [LAYER_DESCRIPTION] NVARCHAR (4000) NULL,
4 |
5 | CONSTRAINT [PK_OMD_METADATA_LAYER]
6 | PRIMARY KEY CLUSTERED ([LAYER_CODE] ASC)
7 | );
8 |
--------------------------------------------------------------------------------
/Direct_Framework/Tables/omd_metadata.NEXT_RUN_STATUS.sql:
--------------------------------------------------------------------------------
1 | CREATE TABLE [omd_metadata].[NEXT_RUN_STATUS] (
2 | [NEXT_RUN_STATUS_CODE] NVARCHAR (100) NOT NULL,
3 | [NEXT_RUN_DESCRIPTION] NVARCHAR (4000) NULL,
4 |
5 | CONSTRAINT [PK_OMD_METADATA_NEXT_RUN_STATUS]
6 | PRIMARY KEY CLUSTERED ([NEXT_RUN_STATUS_CODE] ASC)
7 | );
8 |
--------------------------------------------------------------------------------
/Direct_Framework/Views/omd_processing.vw_QUEUE_BATCH_PROCESSING.sql:
--------------------------------------------------------------------------------
1 | CREATE VIEW [omd_processing].[vw_QUEUE_BATCH_PROCESSING]
2 | AS
3 |
4 | SELECT
5 | batch.BATCH_ID,
6 | batch.BATCH_CODE,
7 | COALESCE(END_TIMESTAMP,'1900-01-01') AS END_TIMESTAMP,
8 | ROW_NUMBER() OVER(ORDER BY END_TIMESTAMP) QUEUE_ORDER
9 | FROM omd.BATCH batch
10 | LEFT OUTER JOIN omd.BATCH_INSTANCE main ON main.BATCH_ID=batch.BATCH_ID
11 | LEFT JOIN
12 | (
13 | SELECT batch.BATCH_ID, COALESCE(MAX(BATCH_INSTANCE_ID), 0) MOST_RECENT_EXECUTION_BATCH_ID
14 | FROM omd.BATCH batch
15 | LEFT JOIN omd.BATCH_INSTANCE batch_instance ON batch.BATCH_ID = batch_instance.BATCH_ID
16 | WHERE batch.BATCH_ID <> 0
17 | GROUP BY batch.BATCH_ID
18 | ) most_recent
19 | ON batch.BATCH_ID = most_recent.BATCH_ID AND COALESCE(main.BATCH_INSTANCE_ID, 0) = most_recent.MOST_RECENT_EXECUTION_BATCH_ID
20 | WHERE batch.BATCH_ID <> 0
21 | AND batch.ACTIVE_INDICATOR = 'Y'
22 | AND batch.FREQUENCY_CODE = 'On-demand'
23 | AND (MOST_RECENT_EXECUTION_BATCH_ID IS NOT NULL OR MOST_RECENT_EXECUTION_BATCH_ID = 0)
24 | AND COALESCE(EXECUTION_STATUS_CODE, 'Succeeded') <> 'Executing';
25 |
--------------------------------------------------------------------------------
/Direct_Framework/Views/omd_processing.vw_QUEUE_MODULE_PROCESSING.sql:
--------------------------------------------------------------------------------
1 | CREATE VIEW [omd_processing].[vw_QUEUE_MODULE_PROCESSING]
2 | AS
3 |
4 | SELECT
5 | MODULE_ID
6 | ,MODULE_CODE
7 | ,END_TIMESTAMP
8 | ,ROW_NUMBER() OVER( ORDER BY END_TIMESTAMP) QUEUE_ORDER
9 | FROM (
10 | SELECT
11 | MODULE.MODULE_ID,
12 | MODULE.MODULE_CODE,
13 | COALESCE(END_TIMESTAMP,'1900-01-01') AS END_TIMESTAMP,
14 | COALESCE(EXECUTION_STATUS_CODE,'Succeeded') AS EXECUTION_STATUS_CODE,
15 | ROW_NUMBER() OVER(PARTITION BY MODULE.DATA_OBJECT_TARGET ORDER BY CASE COALESCE(EXECUTION_STATUS_CODE,'Succeeded') WHEN 'Executing' THEN 1 ELSE 2 END, END_TIMESTAMP) BY_DATA_STORE
16 | FROM omd.MODULE MODULE
17 | LEFT JOIN omd.MODULE_INSTANCE main
18 | ON main.MODULE_ID=MODULE.MODULE_ID
19 | LEFT JOIN (
20 | SELECT MODULE.MODULE_ID, COALESCE(MAX(MODULE_INSTANCE_ID),0) MOST_RECENT_EXECUTION_MODULE_ID
21 | FROM omd.MODULE MODULE
22 | LEFT JOIN omd.MODULE_INSTANCE MODULE_instance
23 | ON MODULE.MODULE_ID=MODULE_instance.MODULE_ID
24 | WHERE MODULE.MODULE_ID<>0
25 | GROUP BY MODULE.MODULE_ID
26 | ) most_recent
27 | ON MODULE.MODULE_ID = most_recent.MODULE_ID AND COALESCE(main.MODULE_INSTANCE_ID,0) = most_recent.MOST_RECENT_EXECUTION_MODULE_ID
28 | WHERE MODULE.ACTIVE_INDICATOR = 'Y'
29 | AND MODULE.AREA_CODE = 'INT'
30 | AND MODULE.FREQUENCY_CODE = 'On-demand'
31 | AND MODULE.MODULE_ID <> 0
32 | AND (MOST_RECENT_EXECUTION_MODULE_ID IS NOT NULL OR MOST_RECENT_EXECUTION_MODULE_ID=0)
33 | ) as sq
34 | WHERE BY_DATA_STORE = 1
35 | AND EXECUTION_STATUS_CODE <> 'Executing'
36 |
--------------------------------------------------------------------------------
/Direct_Framework/Views/omd_reporting.vw_COMMON_ERRORS.sql:
--------------------------------------------------------------------------------
1 | CREATE VIEW [omd_reporting].[vw_COMMON_ERRORS]
2 | AS
3 |
4 | SELECT
5 | m.MODULE_CODE
6 | ,m.MODULE_DESCRIPTION
7 | ,CASE WHEN UPPER(error.ERROR_MSG) LIKE '%TEMPDB%' THEN 'TempDB'
8 | WHEN error.ERROR_MSG LIKE '%WinSCP%' THEN 'WinSCP'
9 | WHEN error.ERROR_MSG LIKE '%deadlocked%' THEN 'Dead Lock'
10 | WHEN error.ERROR_MSG LIKE '%duplicate key%' THEN 'Duplicate Key'
11 |
12 | ELSE REPLACE(error.ERROR_MSG,'
','')
13 | END AS ERROR_MSG
14 | ,count(*) AS COUNT
15 |
16 | from omd.MODULE m
17 | join (
18 | select mi.MODULE_ID
19 | ,mi.MODULE_INSTANCE_ID
20 | ,mi.BATCH_INSTANCE_ID
21 | ,(
22 | SELECT EVENT_DETAIL + ''
23 | from [omd].[EVENT_LOG] sub
24 | where sub.MODULE_INSTANCE_ID = mi.MODULE_INSTANCE_ID
25 | and sub.BATCH_INSTANCE_ID = mi.BATCH_INSTANCE_ID
26 | and sub.EVENT_TIMESTAMP > dateadd(MONTH, -1, SYSUTCDATETIME())
27 | for xml path ('') ) as ERROR_MSG
28 | from omd.MODULE_INSTANCE mi
29 | WHERE mi.START_TIMESTAMP> dateadd(MONTH, -1, SYSUTCDATETIME())
30 | group by mi.MODULE_ID,mi.MODULE_INSTANCE_ID, mi.BATCH_INSTANCE_ID
31 | ) error
32 | on error.MODULE_ID = m.MODULE_ID
33 | and rtrim(ERROR_MSG) <> ''
34 | group by m.MODULE_CODE, m.MODULE_DESCRIPTION, error.ERROR_MSG
35 | --order by 4 desc
36 |
--------------------------------------------------------------------------------
/Direct_Framework/Views/omd_reporting.vw_CUMULATIVE_LOAD_TIME.sql:
--------------------------------------------------------------------------------
1 | /*******************************************************************************
2 | * [omd_reporting].[vw_CUMULATIVE_LOAD_TIME]
3 | *******************************************************************************
4 | *
5 | * https://github.com/data-solution-automation-engine/DIRECT
6 | *
7 | * DIRECT Framework v2.0 reporting views
8 | *
9 | * Purpose:
10 | * List accumulated load times for all modules.
11 | * Handles if a table has been reloaded.
12 | *
13 | ******************************************************************************/
14 |
15 | CREATE VIEW [omd_reporting].[vw_CUMULATIVE_LOAD_TIME]
16 | AS
17 |
18 | WITH PRE_FORMATTING
19 | AS (
20 | SELECT
21 | m.MODULE_CODE,
22 | COUNT(*) AS INSTANCES_RUN,
23 | SUM(DATEDIFF(SECOND, mi.START_TIMESTAMP, COALESCE(mi.END_TIMESTAMP, SYSUTCDATETIME()))) AS DURATION_SEC,
24 | SUM(CAST(mi.ROWS_INSERTED AS BIGINT)) AS ROWS_TRANSFERRED
25 | FROM [omd].[MODULE] m
26 | INNER JOIN [omd].[MODULE_INSTANCE] mi ON m.[MODULE_ID] = mi.[MODULE_ID]
27 | INNER JOIN (
28 | SELECT
29 | mi.MODULE_ID,
30 | MAX(sc.MODULE_INSTANCE_ID) AS MODULE_INSTANCE_ID
31 | FROM [omd].[SOURCE_CONTROL] sc
32 | INNER JOIN [omd].[MODULE_INSTANCE] mi ON sc.[MODULE_INSTANCE_ID] = mi.[MODULE_INSTANCE_ID]
33 | WHERE sc.START_VALUE = '1900-01-01 00:00:00.0000000'
34 | GROUP BY mi.[MODULE_ID]
35 | ) last_reloaded
36 | ON last_reloaded.[MODULE_ID] = mi.[MODULE_ID]
37 | AND last_reloaded.[MODULE_INSTANCE_ID] <= mi.[MODULE_INSTANCE_ID]
38 | GROUP BY m.[MODULE_CODE]
39 | )
40 |
41 | SELECT
42 | [MODULE_CODE],
43 | [INSTANCES_RUN],
44 | [DURATION_SEC],
45 | ISNULL(CAST(NULLIF(DATEPART(DAY, DATEADD(SECOND, DURATION_SEC, 0)), 1) - 1 AS NVARCHAR(10)) +
46 | ' days ', '') +
47 | CONVERT(VARCHAR(30), DATEADD(SECOND, DURATION_SEC, 0), 108) AS [DURATION],
48 | ROWS_TRANSFERRED
49 | FROM PRE_FORMATTING;
50 |
--------------------------------------------------------------------------------
/Direct_Framework/Views/omd_reporting.vw_EXCEPTIONS_BATCH.sql:
--------------------------------------------------------------------------------
1 | CREATE VIEW omd_reporting.vw_EXCEPTIONS_BATCH AS
2 |
3 | SELECT
4 | batch.BATCH_CODE,
5 | main.EXECUTION_STATUS_CODE,
6 | main.BATCH_INSTANCE_ID AS MOST_RECENT_BATCH_INSTANCE_ID,
7 | main.START_TIMESTAMP,
8 | main.END_TIMESTAMP
9 | FROM omd.BATCH_INSTANCE main
10 | JOIN omd.BATCH batch ON main.BATCH_ID=batch.BATCH_ID
11 | JOIN
12 | (
13 | SELECT BATCH_ID, MAX(BATCH_INSTANCE_ID) as MAX_BATCH_INSTANCE_ID
14 | FROM omd.BATCH_INSTANCE
15 | WHERE BATCH_ID > 0
16 | GROUP BY BATCH_ID
17 | ) maxsub
18 | ON main.BATCH_ID = maxsub.BATCH_ID
19 | AND main.BATCH_INSTANCE_ID=maxsub.MAX_BATCH_INSTANCE_ID
20 | WHERE main.EXECUTION_STATUS_CODE <> 'Succeeded' AND batch.ACTIVE_INDICATOR = 'Y'
21 |
22 |
--------------------------------------------------------------------------------
/Direct_Framework/Views/omd_reporting.vw_EXCEPTIONS_DISABLED_PROCESSES.sql:
--------------------------------------------------------------------------------
1 | CREATE VIEW omd_reporting.vw_EXCEPTIONS_DISABLED_PROCESSES AS
2 | --Show which modules haven't run in the last 60 days
3 | SELECT
4 | MODULE_ID,
5 | MODULE_CODE,
6 | 'Module' AS CLASSIFICATION,
7 | FREQUENCY_CODE,
8 | MODULE_DESCRIPTION AS ADDITIONAL_INFORMATION
9 | FROM omd.MODULE WHERE ACTIVE_INDICATOR = 'N'
10 | UNION ALL
11 | SELECT
12 | BATCH_ID,
13 | BATCH_CODE,
14 | 'Batch' AS CLASSIFICATION,
15 | FREQUENCY_CODE,
16 | BATCH_DESCRIPTION AS ADDITIONAL_INFORMATION
17 | FROM omd.BATCH WHERE ACTIVE_INDICATOR = 'N'
18 | UNION ALL
19 | SELECT
20 | batchmod.MODULE_ID,
21 | module.MODULE_CODE,
22 | 'Module, disabled at Batch/Module level' AS CLASSIFICATION,
23 | 'Not applicable' AS FREQUENCY_CODE,
24 | 'Disabled within Batch ''' + batch.BATCH_CODE + ''' with Batch ID ' + CONVERT(NVARCHAR(10),batchmod.BATCH_ID )
25 | FROM omd.BATCH_MODULE batchmod
26 | JOIN omd.MODULE module ON batchmod.MODULE_ID=module.MODULE_ID
27 | JOIN omd.BATCH batch ON batchmod.BATCH_ID=batch.BATCH_ID
28 | WHERE batchmod.ACTIVE_INDICATOR = 'N'
29 |
--------------------------------------------------------------------------------
/Direct_Framework/Views/omd_reporting.vw_EXCEPTIONS_LONG_RUNNING_PROCESSES.sql:
--------------------------------------------------------------------------------
1 | CREATE VIEW [omd_reporting].[vw_EXCEPTIONS_LONG_RUNNING_PROCESSES]
2 |
3 | AS
4 |
5 | -- Module level
6 | SELECT
7 | module.MODULE_CODE,
8 | main.EXECUTION_STATUS_CODE,
9 | main.BATCH_INSTANCE_ID,
10 | CONVERT(NVARCHAR(20), main.MODULE_INSTANCE_ID) AS MODULE_INSTANCE_ID,
11 | CONVERT(NVARCHAR(10), main.MODULE_ID) AS MODULE_ID,
12 | main.START_TIMESTAMP,
13 | main.END_TIMESTAMP,
14 | DATEDIFF(HOUR, main.START_TIMESTAMP, COALESCE(END_TIMESTAMP, SYSUTCDATETIME())) AS HOURS_DIFFERENCE
15 | FROM omd.MODULE_INSTANCE main
16 | JOIN omd.MODULE module ON main.MODULE_ID = module.MODULE_ID
17 | WHERE main.EXECUTION_STATUS_CODE = 'Executing'
18 | AND DATEDIFF(HOUR, main.START_TIMESTAMP, COALESCE(END_TIMESTAMP, SYSUTCDATETIME())) >= 4
19 |
20 | UNION
21 |
22 | -- Batch level
23 | SELECT
24 | batch.BATCH_CODE,
25 | main.EXECUTION_STATUS_CODE,
26 | main.BATCH_INSTANCE_ID,
27 | 'N/A' AS MODULE_INSTANCE_ID,
28 | 'N/A' AS MODULE_ID,
29 | main.START_TIMESTAMP,
30 | main.END_TIMESTAMP,
31 | DATEDIFF(HOUR,main.START_TIMESTAMP, COALESCE(main.END_TIMESTAMP, SYSUTCDATETIME())) AS HOURS_DIFFERENCE
32 | FROM omd.BATCH_INSTANCE main
33 | INNER JOIN omd.BATCH batch ON main.BATCH_ID = batch.BATCH_ID
34 | WHERE main.EXECUTION_STATUS_CODE = 'Executing'
35 | AND DATEDIFF(HOUR, main.START_TIMESTAMP, COALESCE(END_TIMESTAMP, SYSUTCDATETIME())) >= 8
36 |
--------------------------------------------------------------------------------
/Direct_Framework/Views/omd_reporting.vw_EXCEPTIONS_MODULE.sql:
--------------------------------------------------------------------------------
1 | CREATE VIEW omd_reporting.vw_EXCEPTIONS_MODULE
2 |
3 | AS
4 |
5 | -- Exception check Module level
6 | SELECT
7 | module.MODULE_CODE,
8 | main.EXECUTION_STATUS_CODE,
9 | main.BATCH_INSTANCE_ID,
10 | batch.BATCH_CODE,
11 | main.MODULE_INSTANCE_ID AS MOST_RECENT_MODULE_INSTANCE_ID,
12 | main.MODULE_ID,
13 | main.START_TIMESTAMP,
14 | main.END_TIMESTAMP
15 | FROM omd.MODULE_INSTANCE main
16 | JOIN omd.MODULE module
17 | ON main.MODULE_ID=module.MODULE_ID
18 | JOIN (
19 | SELECT MODULE_ID, MAX(MODULE_INSTANCE_ID) as MAX_MODULE_INSTANCE_ID
20 | FROM omd.MODULE_INSTANCE
21 | WHERE MODULE_ID>0
22 | GROUP BY MODULE_ID
23 | ) maxsub
24 | ON main.MODULE_ID = maxsub.MODULE_ID
25 | AND main.MODULE_INSTANCE_ID = maxsub.MAX_MODULE_INSTANCE_ID
26 | JOIN omd.BATCH_INSTANCE
27 | ON main.BATCH_INSTANCE_ID = omd.BATCH_INSTANCE.BATCH_INSTANCE_ID
28 | JOIN omd.BATCH batch
29 | ON omd.BATCH_INSTANCE.BATCH_ID = batch.BATCH_ID
30 | WHERE main.EXECUTION_STATUS_CODE <> 'Succeeded'
31 | AND module.ACTIVE_INDICATOR = 'Y'
32 |
--------------------------------------------------------------------------------
/Direct_Framework/Views/omd_reporting.vw_EXCEPTIONS_NON_RUNNING_BATCHES.sql:
--------------------------------------------------------------------------------
1 | CREATE VIEW [omd_reporting].[vw_EXCEPTIONS_NON_RUNNING_BATCHES]
2 |
3 | AS
4 |
5 | SELECT
6 | BATCH.BATCH_CODE,
7 | BATCH.BATCH_ID,
8 | BATCH.BATCH_DESCRIPTION,
9 | main.BATCH_INSTANCE_ID AS MOST_RECENT_BATCH_INSTANCE_ID,
10 | main.START_TIMESTAMP,
11 | main.END_TIMESTAMP,
12 | main.EXECUTION_STATUS_CODE
13 | FROM omd.BATCH_INSTANCE main
14 | JOIN omd.BATCH BATCH ON main.BATCH_ID=BATCH.BATCH_ID
15 | JOIN
16 | (
17 | SELECT
18 | BATCH_ID,
19 | MAX(BATCH_INSTANCE_ID) as MAX_BATCH_INSTANCE_ID
20 | FROM omd.BATCH_INSTANCE
21 | WHERE BATCH_ID > 0
22 | GROUP BY BATCH_ID
23 | ) maxsub
24 | ON
25 | main.BATCH_ID = maxsub.BATCH_ID AND
26 | main.BATCH_INSTANCE_ID = maxsub.MAX_BATCH_INSTANCE_ID
27 | WHERE
28 | DATEDIFF(dd,START_TIMESTAMP, SYSUTCDATETIME()) >= 60 AND
29 | ACTIVE_INDICATOR = 'Y'
30 |
--------------------------------------------------------------------------------
/Direct_Framework/Views/omd_reporting.vw_EXCEPTIONS_NON_RUNNING_MODULES.sql:
--------------------------------------------------------------------------------
1 | CREATE VIEW [omd_reporting].[vw_EXCEPTIONS_NON_RUNNING_MODULES]
2 |
3 | AS
4 |
5 | SELECT
6 | module.MODULE_CODE,
7 | module.MODULE_ID,
8 | module.MODULE_DESCRIPTION,
9 | main.MODULE_INSTANCE_ID AS MOST_RECENT_MODULE_INSTANCE_ID,
10 | main.START_TIMESTAMP,
11 | main.END_TIMESTAMP,
12 | main.EXECUTION_STATUS_CODE
13 | FROM [omd].[MODULE_INSTANCE] main
14 | JOIN [omd].[MODULE] module ON main.MODULE_ID = module.MODULE_ID
15 | JOIN
16 | (
17 | SELECT MODULE_ID, MAX(MODULE_INSTANCE_ID) as MAX_MODULE_INSTANCE_ID
18 | FROM omd.MODULE_INSTANCE
19 | WHERE MODULE_ID > 0
20 | GROUP BY MODULE_ID
21 | ) maxsub
22 | ON
23 | main.MODULE_ID = maxsub.MODULE_ID
24 | AND
25 | main.MODULE_INSTANCE_ID = maxsub.MAX_MODULE_INSTANCE_ID
26 |
27 | WHERE
28 | DATEDIFF(dd, START_TIMESTAMP, SYSUTCDATETIME()) >= 60
29 | AND
30 | module.ACTIVE_INDICATOR = 'Y'
31 |
--------------------------------------------------------------------------------
/Direct_Framework/Views/omd_reporting.vw_EXCEPTIONS_TABLE_CONSISTENCY.sql:
--------------------------------------------------------------------------------
1 | CREATE VIEW [omd_reporting].[vw_EXCEPTIONS_TABLE_CONSISTENCY] AS
2 | WITH TableCheckCTE AS
3 | (
4 | SELECT
5 | a.TABLE_CATALOG,
6 | a.TABLE_SCHEMA,
7 | a.TABLE_NAME,
8 | b.COLUMN_NAME,
9 | b.ORDINAL_POSITION
10 | FROM INFORMATION_SCHEMA.TABLES a
11 | JOIN INFORMATION_SCHEMA.COLUMNS b ON a.TABLE_NAME = b.TABLE_NAME
12 | WHERE TABLE_TYPE = 'BASE TABLE' AND a.TABLE_SCHEMA <> 'omd'
13 | ), Attribute_Detection AS
14 | (
15 | SELECT
16 | TABLE_CATALOG,
17 | TABLE_NAME,
18 | TABLE_SCHEMA,
19 | COLUMN_NAME,
20 | CASE WHEN COLUMN_NAME = 'OMD_INSERT_MODULE_INSTANCE_ID' THEN 1 ELSE 0 END AS HAS_OMD_INSERT_MODULE_INSTANCE_ID,
21 | CASE WHEN COLUMN_NAME = 'OMD_INSERT_DATETIME' THEN 1 ELSE 0 END AS HAS_OMD_INSERT_DATETIME,
22 | CASE WHEN COLUMN_NAME = 'OMD_EVENT_DATETIME' THEN 1 ELSE 0 END AS HAS_OMD_EVENT_DATETIME,
23 | CASE WHEN COLUMN_NAME = 'OMD_RECORD_SOURCE' THEN 1 ELSE 0 END AS HAS_OMD_RECORD_SOURCE,
24 | CASE WHEN COLUMN_NAME = 'OMD_SOURCE_ROW_ID' THEN 1 ELSE 0 END AS HAS_OMD_SOURCE_ROW_ID,
25 | CASE WHEN COLUMN_NAME = 'OMD_CDC_OPERATION' THEN 1 ELSE 0 END AS HAS_OMD_CDC_OPERATION,
26 | CASE WHEN COLUMN_NAME = 'OMD_HASH_FULL_RECORD' THEN 1 ELSE 0 END AS HAS_OMD_HASH_FULL_RECORD,
27 | CASE WHEN COLUMN_NAME = 'OMD_CURRENT_RECORD_INDICATOR' THEN 1 ELSE 0 END AS HAS_OMD_CURRENT_RECORD_INDICATOR,
28 | CASE WHEN COLUMN_NAME = 'OMD_CHANGE_DATETIME' THEN 1 ELSE 0 END AS HAS_OMD_CHANGE_DATETIME,
29 | CASE WHEN COLUMN_NAME = 'OMD_CHANGE_KEY' THEN 1 ELSE 0 END AS HAS_OMD_CHANGE_KEY
30 | FROM TableCheckCTE
31 | ), SingleRowAttributeEvaluation AS
32 | (
33 | SELECT
34 | TABLE_CATALOG,
35 | TABLE_NAME,
36 | TABLE_SCHEMA,
37 | SUM(HAS_OMD_INSERT_MODULE_INSTANCE_ID) AS HAS_OMD_INSERT_MODULE_INSTANCE_ID,
38 | SUM(HAS_OMD_INSERT_DATETIME) AS HAS_OMD_INSERT_DATETIME,
39 | SUM(HAS_OMD_EVENT_DATETIME) AS HAS_OMD_EVENT_DATETIME,
40 | SUM(HAS_OMD_RECORD_SOURCE) AS HAS_OMD_RECORD_SOURCE,
41 | SUM(HAS_OMD_SOURCE_ROW_ID) AS HAS_OMD_SOURCE_ROW_ID,
42 | SUM(HAS_OMD_CDC_OPERATION) AS HAS_OMD_CDC_OPERATION,
43 | SUM(HAS_OMD_HASH_FULL_RECORD) AS HAS_OMD_HASH_FULL_RECORD,
44 | SUM(HAS_OMD_CURRENT_RECORD_INDICATOR) AS HAS_OMD_CURRENT_RECORD_INDICATOR,
45 | SUM(HAS_OMD_CHANGE_DATETIME) AS HAS_OMD_CHANGE_DATETIME,
46 | SUM(HAS_OMD_CHANGE_KEY) AS HAS_OMD_CHANGE_KEY
47 | FROM Attribute_Detection
48 | GROUP BY
49 | TABLE_CATALOG,
50 | TABLE_NAME,
51 | TABLE_SCHEMA
52 | ), ErrorEvaluation AS
53 | (
54 | SELECT
55 | TABLE_CATALOG,
56 | TABLE_NAME,
57 | TABLE_SCHEMA,
58 | CASE WHEN HAS_OMD_INSERT_MODULE_INSTANCE_ID = 0 THEN 'No change date/time attribute is defined.' ELSE '' END AS ERROR_OMD_INSERT_MODULE_INSTANCE_ID,
59 | CASE WHEN HAS_OMD_INSERT_DATETIME = 0 THEN 'No insert datetime attribute is defined.' ELSE '' END AS ERROR_OMD_INSERT_DATETIME,
60 | CASE WHEN HAS_OMD_EVENT_DATETIME = 0 THEN 'No event date/time attribute is defined.' ELSE '' END AS ERROR_OMD_EVENT_DATETIME,
61 | CASE WHEN HAS_OMD_RECORD_SOURCE = 0 THEN 'No record source attribute is defined.' ELSE '' END AS ERROR_OMD_RECORD_SOURCE,
62 | CASE WHEN HAS_OMD_SOURCE_ROW_ID = 0 THEN 'No source row ID attribute is defined.' ELSE '' END AS ERROR_OMD_SOURCE_ROW_ID,
63 | CASE WHEN HAS_OMD_CDC_OPERATION = 0 THEN 'No cdc operation attribute is defined.' ELSE '' END AS ERROR_OMD_CDC_OPERATION,
64 | CASE WHEN HAS_OMD_HASH_FULL_RECORD = 0 THEN 'No full row hash attribute is defined.' ELSE '' END AS ERROR_HASH_FULL_RECORD,
65 | CASE WHEN HAS_OMD_CURRENT_RECORD_INDICATOR = 0 THEN 'No current record indicator attribute is defined.' ELSE '' END AS ERROR_CURRENT_RECORD_INDICATOR,
66 | CASE WHEN HAS_OMD_CHANGE_DATETIME = 0 THEN 'No change date/time attribute is defined.' ELSE '' END AS ERROR_OMD_CHANGE_DATETIME,
67 | CASE WHEN HAS_OMD_CHANGE_KEY = 0 THEN 'No change key attribute is defined.' ELSE '' END AS ERROR_OMD_CHANGE_KEY
68 | FROM SingleRowAttributeEvaluation
69 | ), SingleErrorEvaluation AS
70 | (
71 | SELECT
72 | TABLE_CATALOG,
73 | TABLE_NAME,
74 | TABLE_SCHEMA,
75 | LTRIM(RTRIM(
76 | ERROR_OMD_INSERT_MODULE_INSTANCE_ID + ' ' +
77 | ERROR_OMD_INSERT_DATETIME + ' ' +
78 | ERROR_OMD_EVENT_DATETIME + ' ' +
79 | ERROR_OMD_RECORD_SOURCE + ' ' +
80 | ERROR_OMD_SOURCE_ROW_ID + ' ' +
81 | ERROR_OMD_CDC_OPERATION + ' ' +
82 | ERROR_HASH_FULL_RECORD + ' ' +
83 | ERROR_CURRENT_RECORD_INDICATOR + ' ' +
84 | ERROR_OMD_CHANGE_KEY + ' ' +
85 | ERROR_OMD_CHANGE_DATETIME + ' '
86 | )) AS ERROR_TOTAL
87 | FROM ErrorEvaluation
88 | )
89 | SELECT * FROM SingleErrorEvaluation
90 | WHERE ERROR_TOTAL <> ''
91 |
--------------------------------------------------------------------------------
/Direct_Framework/Views/omd_reporting.vw_EXECUTION_EVENT_LOG.sql:
--------------------------------------------------------------------------------
1 | CREATE VIEW [omd_reporting].[vw_EXECUTION_EVENT_LOG]
2 |
3 | AS
4 |
5 | SELECT
6 | EL.EVENT_ID
7 | , EL.BATCH_INSTANCE_ID
8 | , B.BATCH_CODE
9 | , EL.MODULE_INSTANCE_ID
10 | , M.MODULE_CODE
11 | , ET.EVENT_TYPE_CODE_DESCRIPTION
12 | , EL.EVENT_TIMESTAMP
13 | , EL.EVENT_RETURN_CODE
14 | , EL.EVENT_DETAIL
15 | FROM
16 | omd.EVENT_LOG EL
17 | INNER JOIN [omd_metadata].[EVENT_TYPE] ET ON EL.EVENT_TYPE_CODE = ET.EVENT_TYPE_CODE
18 | INNER JOIN [omd].[BATCH_INSTANCE] BI ON EL.BATCH_INSTANCE_ID = BI.BATCH_INSTANCE_ID
19 | INNER JOIN [omd].[BATCH] B ON BI.BATCH_ID = B.BATCH_ID
20 | INNER JOIN [omd].[MODULE_INSTANCE] MI ON EL.MODULE_INSTANCE_ID = MI.MODULE_INSTANCE_ID
21 | INNER JOIN [omd].[MODULE] M ON MI.MODULE_ID = M.MODULE_ID
22 | WHERE
23 | EVENT_ID <> 0
24 |
--------------------------------------------------------------------------------
/Direct_Framework/Views/omd_reporting.vw_EXECUTION_LOG_BATCH_INSTANCE.sql:
--------------------------------------------------------------------------------
1 | CREATE VIEW [omd_reporting].[vw_EXECUTION_LOG_BATCH_INSTANCE]
2 | AS
3 |
4 | SELECT
5 | BI.BATCH_INSTANCE_ID
6 | , B.BATCH_CODE
7 | , BI.EXECUTION_CONTEXT
8 | , BI.START_TIMESTAMP
9 | , BI.END_TIMESTAMP
10 | , DATEDIFF(second, BI.START_TIMESTAMP, BI.END_TIMESTAMP) AS EXECUTION_TIME
11 | --, CAST (CAST ((BI.END_TIMESTAMP - BI.START_TIMESTAMP) AS TIME) AS NVARCHAR (30)) AS EXECUTION_TIME
12 | , PIND.INTERNAL_PROCESSING_STATUS_CODE_DESCRIPTION
13 | , NR.NEXT_RUN_DESCRIPTION
14 | , BI.EXECUTION_STATUS_CODE
15 | , ES.EXECUTION_STATUS_DESCRIPTION
16 | FROM
17 | [omd].[BATCH_INSTANCE] BI
18 | INNER JOIN [omd].[BATCH] B ON BI.BATCH_ID = B.BATCH_ID
19 | INNER JOIN [omd_metadata].[INTERNAL_PROCESSING_STATUS] PIND ON BI.INTERNAL_PROCESSING_CODE = PIND.INTERNAL_PROCESSING_STATUS_CODE
20 | INNER JOIN [omd_metadata].[NEXT_RUN_STATUS] NR ON BI.NEXT_RUN_STATUS_CODE = NR.NEXT_RUN_STATUS_CODE
21 | INNER JOIN [omd_metadata].[EXECUTION_STATUS] ES ON BI.EXECUTION_STATUS_CODE = ES.EXECUTION_STATUS_CODE
22 | WHERE
23 | BATCH_INSTANCE_ID <> 0
24 |
--------------------------------------------------------------------------------
/Direct_Framework/Views/omd_reporting.vw_EXECUTION_LOG_MODULE_INSTANCE.sql:
--------------------------------------------------------------------------------
1 | CREATE VIEW [omd_reporting].[vw_EXECUTION_LOG_MODULE_INSTANCE]
2 | AS
3 |
4 | SELECT
5 | MI.MODULE_INSTANCE_ID
6 | , MI.EXECUTION_CONTEXT
7 | , MI.BATCH_INSTANCE_ID
8 | , M.MODULE_CODE
9 | , MI.START_TIMESTAMP
10 | , MI.END_TIMESTAMP
11 | , DATEDIFF(second, MI.START_TIMESTAMP, MI.END_TIMESTAMP) AS EXECUTION_TIME
12 | , PIND.INTERNAL_PROCESSING_STATUS_CODE_DESCRIPTION
13 | , NR.NEXT_RUN_DESCRIPTION
14 | , MI.EXECUTION_STATUS_CODE
15 | , ES.EXECUTION_STATUS_DESCRIPTION
16 | , MI.ROWS_INPUT
17 | , MI.ROWS_INSERTED
18 | , MI.ROWS_UPDATED
19 | , MI.ROWS_DELETED
20 | , MI.ROWS_DISCARDED
21 | , MI.ROWS_REJECTED
22 | FROM
23 | [omd].[MODULE_INSTANCE] MI
24 | INNER JOIN [omd].[MODULE] M ON MI.MODULE_ID = M.MODULE_ID
25 | INNER JOIN [omd_metadata].INTERNAL_PROCESSING_STATUS PIND ON MI.INTERNAL_PROCESSING_CODE = PIND.INTERNAL_PROCESSING_STATUS_CODE
26 | INNER JOIN [omd_metadata].NEXT_RUN_STATUS NR ON MI.INTERNAL_PROCESSING_CODE = NR.NEXT_RUN_STATUS_CODE
27 | INNER JOIN [omd_metadata].EXECUTION_STATUS ES ON MI.EXECUTION_STATUS_CODE = ES.EXECUTION_STATUS_CODE
28 | WHERE MODULE_INSTANCE_ID <> 0
29 |
--------------------------------------------------------------------------------
/Direct_Framework/Views/omd_reporting.vw_MODULE_FAILURES.sql:
--------------------------------------------------------------------------------
1 | CREATE VIEW [omd_reporting].[vw_MODULE_FAILURES] AS
2 |
3 | select --TOP 40
4 | m.MODULE_CODE
5 | ,m.MODULE_DESCRIPTION
6 | ,AVG(datediff(MINUTE,mi.START_TIMESTAMP,mi.END_TIMESTAMP)) as AVG_EXEC_MIN
7 | ,SUM(case when mi.EXECUTION_STATUS_CODE = 'F' then 1 else 0 end) as COUNT_ERRORS
8 | from omd.MODULE m
9 | JOIN omd.MODULE_INSTANCE mi
10 | ON m.MODULE_ID = mi.MODULE_ID
11 | WHERE mi.START_TIMESTAMP > dateadd(MONTH,-3,SYSUTCDATETIME())
12 | group by m.MODULE_CODE, m.MODULE_DESCRIPTION
13 | HAVING SUM(case when mi.EXECUTION_STATUS_CODE = 'F' then 1 else 0 end) >0
14 |
--------------------------------------------------------------------------------
/Documentation/Images/BatchEvaluation.png:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/data-solution-automation-engine/DIRECT/bf35ff2a3e3e5c2e4f98c42e0c9b51e4d7962ab8/Documentation/Images/BatchEvaluation.png
--------------------------------------------------------------------------------
/Documentation/Images/Components.png:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/data-solution-automation-engine/DIRECT/bf35ff2a3e3e5c2e4f98c42e0c9b51e4d7962ab8/Documentation/Images/Components.png
--------------------------------------------------------------------------------
/Documentation/Images/DIRECT_Framework.png:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/data-solution-automation-engine/DIRECT/bf35ff2a3e3e5c2e4f98c42e0c9b51e4d7962ab8/Documentation/Images/DIRECT_Framework.png
--------------------------------------------------------------------------------
/Documentation/Images/Execution.png:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/data-solution-automation-engine/DIRECT/bf35ff2a3e3e5c2e4f98c42e0c9b51e4d7962ab8/Documentation/Images/Execution.png
--------------------------------------------------------------------------------
/Documentation/Images/Instantiation.png:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/data-solution-automation-engine/DIRECT/bf35ff2a3e3e5c2e4f98c42e0c9b51e4d7962ab8/Documentation/Images/Instantiation.png
--------------------------------------------------------------------------------
/Documentation/Images/LogicalModel.png:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/data-solution-automation-engine/DIRECT/bf35ff2a3e3e5c2e4f98c42e0c9b51e4d7962ab8/Documentation/Images/LogicalModel.png
--------------------------------------------------------------------------------
/Documentation/Images/ModuleEvaluation.png:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/data-solution-automation-engine/DIRECT/bf35ff2a3e3e5c2e4f98c42e0c9b51e4d7962ab8/Documentation/Images/ModuleEvaluation.png
--------------------------------------------------------------------------------
/Documentation/Images/Orchestration.png:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/data-solution-automation-engine/DIRECT/bf35ff2a3e3e5c2e4f98c42e0c9b51e4d7962ab8/Documentation/Images/Orchestration.png
--------------------------------------------------------------------------------
/Documentation/Images/RunBatch.png:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/data-solution-automation-engine/DIRECT/bf35ff2a3e3e5c2e4f98c42e0c9b51e4d7962ab8/Documentation/Images/RunBatch.png
--------------------------------------------------------------------------------
/Documentation/Images/RunModule.png:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/data-solution-automation-engine/DIRECT/bf35ff2a3e3e5c2e4f98c42e0c9b51e4d7962ab8/Documentation/Images/RunModule.png
--------------------------------------------------------------------------------
/Documentation/Installation.md:
--------------------------------------------------------------------------------
1 | # Installing DIRECT
2 |
3 | The DIRECT framework can be deployed from the Visual Studio solution/project, using the publish function. Alternatively, the project can be compiled to a DACPAC and deployed via command-line tools such as sqlcmd.
4 |
5 | As part of the installation, post deployment scripts are run to provide the standard framework contents. Pre- and post DACPAC deployment placeholders are also available.
6 |
--------------------------------------------------------------------------------
/Documentation/MermaidChart/BatchEvaluation.mmd:
--------------------------------------------------------------------------------
1 | flowchart TD
2 | %% Nodes
3 |
4 | subgraph BatchEvaluation["Batch Evaluation"]
5 | Start("Start of the process"):::Main
6 | CheckMultiple("Check for multiple running Batch Instances")
7 | IsMultipleInstances{"Are multiple instances running?"}
8 | SetAbort("Update the Internal Processing Status Code to 'Abort'")
9 | IsActive{"Is the Batch enabled?"}
10 | SetCancel("Update the Internal Processing Status Code to 'Cancel'")
11 | IsRollback{"Is the rollback required?"}
12 | Rollback("Perform Rollback")
13 | End("End of the process"):::Main
14 | end
15 |
16 | %% Edges
17 | Start --> CheckMultiple --> IsMultipleInstances
18 | IsMultipleInstances -- Yes --> SetAbort
19 | IsMultipleInstances -- No --> IsActive
20 | IsActive -- No --> SetCancel
21 | IsActive -- Yes --> IsRollback
22 | IsRollback -- Yes --> Rollback
23 | Rollback ----> End
24 | IsRollback -- No --> End
25 |
26 | %% Styling
27 | classDef Main fill:#BBDEFB,stroke:#1976D2,stroke-width:2px
--------------------------------------------------------------------------------
/Documentation/MermaidChart/ModuleEvalation.mmd:
--------------------------------------------------------------------------------
1 | flowchart TD
2 | %% Nodes
3 |
4 | subgraph BatchEvaluation["Batch Evaluation"]
5 | Start("Start of the process"):::Main
6 | CheckMultiple("Check for multiple running Batch Instances")
7 | IsMultipleInstances{"Are multiple instances running?"}
8 | SetAbort("Update the Internal Processing Status Code to 'Abort'")
9 | IsActive{"Is the Batch enabled?"}
10 | SetCancel("Update the Internal Processing Status Code to 'Cancel'")
11 | IsRollback{"Is the rollback required?"}
12 | Rollback("Perform Rollback")
13 | End("End of the process"):::Main
14 | end
15 |
16 | %% Edges
17 | Start --> CheckMultiple --> IsMultipleInstances
18 | IsMultipleInstances -- Yes --> SetAbort
19 | IsMultipleInstances -- No --> IsActive
20 | IsActive -- No --> SetCancel
21 | IsActive -- Yes --> IsRollback
22 | IsRollback -- Yes --> Rollback
23 | Rollback ----> End
24 | IsRollback -- No --> End
25 |
26 | %% Styling
27 | classDef Main fill:#BBDEFB,stroke:#1976D2,stroke-width:2px
--------------------------------------------------------------------------------
/Documentation/MermaidChart/RunBatch.mmd:
--------------------------------------------------------------------------------
1 | flowchart TD
2 | %% Nodes
3 |
4 | subgraph BatchInstance["Batch Instance"]
5 | Start("Start of the process"):::Main
6 | CreateBatchInstance
7 | BatchEvaluation{"BatchEvaluation"}
8 | RunModule("Run all Modules associated with the Batch")
9 | RunBatch("Run all (child) Batches associated with the Batch")
10 | UpdateBatchInstance
11 | End("End of the process"):::Main
12 | end
13 |
14 | %% Edges
15 | Start --> CreateBatchInstance --> BatchEvaluation
16 | BatchEvaluation -- Internal Processing Status Code is not 'Abort' or 'Cancel' --> RunModule --> RunBatch
17 | BatchEvaluation -- Internal Processing Status Code is either 'Abort' or 'Cancel' --> End
18 | RunBatch --> UpdateBatchInstance
19 | UpdateBatchInstance --> End
20 |
21 | %% Styling
22 | classDef Main fill:#BBDEFB,stroke:#1976D2,stroke-width:2px
--------------------------------------------------------------------------------
/Documentation/MermaidChart/RunModule.mmd:
--------------------------------------------------------------------------------
1 | flowchart TD
2 | %% Nodes
3 |
4 | subgraph ModuleInstance["Module Instance"]
5 | Start("Start of the process"):::Main
6 | CreateModuleInstance
7 | ModuleEvaluation{"ModuleEvaluation"}
8 | RunModule("Execute Module logic")
9 | UpdateModuleInstance
10 | End("End of the process"):::Main
11 | end
12 |
13 | %% Edges
14 | Start --> CreateModuleInstance --> ModuleEvaluation
15 | ModuleEvaluation -- Internal Processing Status Code is not 'Abort' or 'Cancel' --> RunModule
16 | ModuleEvaluation -- Internal Processing Status Code is either 'Abort' or 'Cancel' --> End
17 | RunModule --> UpdateModuleInstance
18 | UpdateModuleInstance --> End
19 |
20 | %% Styling
21 | classDef Main fill:#BBDEFB,stroke:#1976D2,stroke-width:2px
--------------------------------------------------------------------------------
/Documentation/Model.md:
--------------------------------------------------------------------------------
1 | # Direct Framework Physical Model
2 |
3 | This section contains the DIRECT physical model in Mermaid Entity Relationship diagram format.
4 |
5 | In various platforms, including Github, the diagram will be rendered automatically. Otherwise, the contents below can also be rendered through mermaid [https://mermaid.js.org/](https://mermaid.js.org/) and [https://github.com/mermaid-js/mermaid](https://github.com/mermaid-js/mermaid), using any supported method, or pasted in an online editor such as [https://www.mermaidchart.com](https://www.mermaidchart.com).
6 |
7 | ```mermaid
8 | ---
9 | title: Direct Framework
10 | ---
11 |
12 | erDiagram
13 |
14 | %% All dates are SYSUTCDATETIME()
15 | %% Codes are NVARCHAR(100)
16 | %% Descriptions are NVARCHAR(4000)
17 |
18 | %% Processing objects
19 |
20 | BATCH {
21 | BATCH_ID INT PK
22 | BATCH_CODE NVARCHAR(1000) UK
23 | BATCH_TYPE NVARCHAR(100)
24 | FREQUENCY_CODE NVARCHAR(1000) FK
25 | ACTIVE_INDICATOR CHAR(1)
26 | BATCH_DESCRIPTION NVARCHAR(1000)
27 | }
28 |
29 | BATCH ||..o{ BATCH_INSTANCE : instantiates
30 | BATCH ||--o{ BATCH_HIERARCHY : is_parent
31 | BATCH ||--o{ BATCH_HIERARCHY : is_child
32 |
33 | BATCH_INSTANCE {
34 | BATCH_INSTANCE_ID BIGINT PK
35 | BATCH_ID INT FK
36 | PARENT_BATCH_INSTANCE_ID BIGINT
37 | START_TIMESTAMP DATETIME2
38 | END_TIMESTAMP DATETIME2
39 | INTERNAL_PROCESSING_CODE NVARCHAR(100) FK
40 | NEXT_RUN_STATUS_CODE NVARCHAR(100) FK
41 | EXECUTION_STATUS_CODE NVARCHAR(100) FK
42 | EXECUTION_CONTEXT NVARCHAR(4000)
43 | }
44 |
45 | BATCH_INSTANCE ||--|| BATCH_INSTANCE : is_parent_instance
46 |
47 | BATCH ||--o{ BATCH_HIERARCHY : is_child
48 |
49 | BATCH_HIERARCHY {
50 | PARENT_BATCH_ID INT PK
51 | BATCH_ID INT PK
52 | SEQUENCE INT
53 | ACTIVE_INDICATOR CHAR(1)
54 | }
55 |
56 | BATCH ||--o{ BATCH_MODULE : is_related_to
57 | MODULE ||--o{ BATCH_MODULE : is_related_to
58 |
59 | BATCH_MODULE {
60 | BATCH_ID INT PK
61 | MODULE_ID INT PK
62 | SEQUENCE INT
63 | ACTIVE_INDICATOR CHAR(1)
64 | }
65 |
66 | BATCH_PARAMETER {
67 | BATCH_ID INT PK
68 | PARAMETER_ID INT PK
69 | ACTIVE_INDICATOR CHAR(1)
70 | }
71 |
72 | BATCH_PARAMETER }o--|| BATCH : specifies
73 | BATCH_PARAMETER }o--|| PARAMETER : specifies
74 |
75 | MODULE {
76 | MODULE_ID INT PK
77 | MODULE_CODE NVARCHAR(1000) UK
78 | MODULE_TYPE NVARCHAR(100)
79 | DATA_OBJECT_SOURCE NVARCHAR(1000)
80 | DATA_OBJECT_TARGET NVARCHAR(1000)
81 | AREA_CODE NVARCHAR(100) FK
82 | FREQUENCY_CODE NVARCHAR(100) FK
83 | ACTIVE_INDICATOR CHAR(1)
84 | MODULE_DESCRIPTION NVARCHAR(4000)
85 | EXECUTABLE NVARCHAR(MAX)
86 | }
87 |
88 | MODULE_INSTANCE {
89 | MODULE_INSTANCE_ID BIGINT PK
90 | MODULE_ID INT FK
91 | BATCH_INSTANCE_ID BIGINT FK
92 | START_TIMESTAMP DATETIME2
93 | END_TIMESTAMP DATETIME2
94 | INTERNAL_PROCESSING_CODE NVARCHAR(100) FK
95 | NEXT_RUN_STATUS_CODE NVARCHAR(100) FK
96 | EXECUTION_STATUS_CODE NVARCHAR(100) FK
97 | EXECUTION_CONTEXT NVARCHAR(4000)
98 | ROWS_INPUT INT
99 | ROWS_INSERTED INT
100 | ROWS_UPDATED INT
101 | ROWS_DELETED INT
102 | ROWS_DISCARDED INT
103 | ROWS_REJECTED INT
104 | EXECUTED_CODE_CHECKSUM VARBINARY(64) FK
105 | }
106 |
107 | MODULE ||..o{ MODULE_INSTANCE : instantiates
108 |
109 | MODULE_INSTANCE_EXECUTED_CODE {
110 | CHECKSUM VARBINARY(64) PK
111 | EXECUTED_CODE NVARCHAR(MAX)
112 | }
113 |
114 | MODULE_INSTANCE_EXECUTED_CODE |o..o{ MODULE_INSTANCE : instantiates
115 |
116 | EVENT_LOG {
117 | EVENT_ID BIGINT PK
118 | BATCH_INSTANCE_ID BIGINT FK
119 | MODULE_INSTANCE_ID BIGINT FK
120 | EVENT_TYPE_CODE NVARCHAR(100) FK
121 | EVENT_TIMESTAMP DATETIME2
122 | EVENT_RETURN_CODE NVARCHAR(100)
123 | EVENT_DETAIL NVARCHAR(4000)
124 | ERROR_BITMAP NUMBER(20)
125 | }
126 |
127 | EVENT_LOG }o..o{ MODULE_INSTANCE : describes
128 | EVENT_LOG }o..o{ BATCH_INSTANCE : describes
129 |
130 | PARAMETER {
131 | PARAMETER_ID INT PK
132 | PARAMETER_DESCRIPTION NVARCHAR(4000)
133 | PARAMETER_KEY_CODE NVARCHAR(100)
134 | PARAMETER_VALUE_CODE NVARCHAR(100)
135 | ACTIVE_INDICATOR CHAR(1)
136 | }
137 |
138 | MODULE_PARAMETER {
139 | MODULE_ID INT PK
140 | PARAMETER_ID INT PK
141 | ACTIVE_INDICATOR CHAR(1)
142 | }
143 |
144 | MODULE_PARAMETER }o--|| MODULE : specifies
145 | MODULE_PARAMETER }o--|| PARAMETER : specifies
146 |
147 | SOURCE_CONTROL {
148 | MODULE_SOURCE_CONTROL_ID BIGINT PK
149 | MODULE_ID INT FK
150 | MODULE_INSTANCE_ID BIGINT FK
151 | INSERT_TIMESTAMP DATETIME2
152 | START_VALUE DATETIME2
153 | END_VALUE DATETIME2
154 | }
155 |
156 | SOURCE_CONTROL }o--|| MODULE : specifies
157 | SOURCE_CONTROL }o--|| MODULE_INSTANCE : specifies
158 |
159 |
160 | %% Reference tables
161 |
162 | AREA {
163 | AREA_CODE NVARCHAR(100) PK
164 | LAYER_CODE NVARCHAR(100) FK
165 | AREA_DESCRIPTION NVARCHAR(4000)
166 | }
167 |
168 | AREA ||..|{ MODULE : contains
169 |
170 | EVENT_TYPE {
171 | EVENT_TYPE_CODE NVARCHAR(100) PK
172 | EVENT_TYPE_CODE_DESCRIPTION NVARCHAR(4000)
173 | }
174 |
175 | EVENT_TYPE ||..|{ EVENT_LOG : states
176 |
177 | EXECUTION_STATUS {
178 | EXECUTION_STATUS_CODE NVARCHAR(100) PK
179 | EXECUTION_STATUS_CODE_DESCRIPTION NVARCHAR(4000)
180 | }
181 |
182 | EXECUTION_STATUS ||..|{ MODULE_INSTANCE : states
183 | EXECUTION_STATUS ||..|{ BATCH_INSTANCE : states
184 |
185 | FRAMEWORK_METADATA {
186 | CODE NVARCHAR(100)
187 | VALUE NVARCHAR(4000)
188 | GROUP NVARCHAR(100)
189 | DESCRIPTION NVARCHAR(4000)
190 | ACTIVE_INDICATOR CHAR(1)
191 | }
192 |
193 | FREQUENCY {
194 | FREQUENCY_CODE NVARCHAR(100) PK
195 | FREQUENCY_DESCRIPTION NVARCHAR(4000)
196 | }
197 |
198 | FREQUENCY ||..|{ MODULE : specifies
199 | FREQUENCY ||..|{ BATCH : specifies
200 |
201 | INTERNAL_PROCESSING_STATUS {
202 | INTERNAL_PROCESSING_STATUS_CODE NVARCHAR(100) PK
203 | INTERNAL_PROCESSING_STATUS_CODE_DESCRIPTION NVARCHAR(4000)
204 | }
205 |
206 | INTERNAL_PROCESSING_STATUS ||..|{ MODULE_INSTANCE : monitors
207 | INTERNAL_PROCESSING_STATUS ||..|{ BATCH_INSTANCE : monitors
208 |
209 | LAYER {
210 | LAYER_CODE NVARCHAR(100) PK
211 | LAYER_DESCRIPTION NVARCHAR(4000)
212 | }
213 |
214 | LAYER ||..|{ AREA : contains
215 |
216 | NEXT_RUN_STATUS {
217 | NEXT_RUN_STATUS_CODE NVARCHAR(100) PK
218 | NEXT_RUN_STATUS_CODE_DESCRIPTION NVARCHAR(4000)
219 | }
220 |
221 | NEXT_RUN_STATUS ||..|{ MODULE_INSTANCE : defines
222 | NEXT_RUN_STATUS ||..|{ BATCH_INSTANCE : defines
223 | ```
224 |
--------------------------------------------------------------------------------
/Documentation/PowerPoint/Images.pptx:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/data-solution-automation-engine/DIRECT/bf35ff2a3e3e5c2e4f98c42e0c9b51e4d7962ab8/Documentation/PowerPoint/Images.pptx
--------------------------------------------------------------------------------
/Example_Scripts/Controls/Batches-without-parents.sql:
--------------------------------------------------------------------------------
1 | /*
2 | Batches without parents.
3 | */
4 | SELECT *
5 | FROM
6 | (
7 | SELECT
8 | batch.*
9 | ,CASE WHEN isChildBatch.BATCH_ID IS NULL THEN 1 ELSE 0 END AS IS_MISSING_PARENT
10 | FROM omd.BATCH batch
11 | LEFT OUTER JOIN (SELECT DISTINCT BATCH_ID FROM omd.BATCH_HIERARCHY) isChildBatch
12 | ON batch.BATCH_ID = isChildBatch.BATCH_ID
13 | WHERE
14 | batch.BATCH_ID != 0
15 | AND batch.ACTIVE_INDICATOR = 'Y'
16 |
17 | ) sub
18 | WHERE IS_MISSING_PARENT = 1
--------------------------------------------------------------------------------
/Example_Scripts/Maintenance/DIRECT_Clear_BATCH_entries.sql:
--------------------------------------------------------------------------------
1 | DECLARE @ETL_PROCESS NVARCHAR(100);
2 | DECLARE @SQL_STATEMENT NVARCHAR(MAX);
3 |
4 | SET @ETL_PROCESS = ''
5 |
6 | PRINT 'Working on '+@ETL_PROCESS+CHAR(13);
7 | /* Event log Module errors*/
8 | SET @SQL_STATEMENT = 'DELETE FROM EVENT_LOG WHERE MODULE_INSTANCE_ID IN (SELECT MODULE_INSTANCE_ID FROM MODULE_INSTANCE WHERE BATCH_INSTANCE_ID IN (SELECT BATCH_INSTANCE_ID FROM BATCH_INSTANCE WHERE BATCH_ID = (SELECT BATCH_ID FROM BATCH WHERE BATCH_CODE ='''+@ETL_PROCESS+''')))';
9 | PRINT @SQL_STATEMENT;
10 | EXEC sp_executesql @SQL_STATEMENT
11 |
12 | /* Event log Batch errors*/
13 | SET @SQL_STATEMENT = 'DELETE FROM EVENT_LOG WHERE BATCH_INSTANCE_ID IN (SELECT BATCH_INSTANCE_ID FROM BATCH_INSTANCE WHERE BATCH_ID = (SELECT BATCH_ID FROM BATCH WHERE BATCH_CODE ='''+@ETL_PROCESS+'''))';
14 | PRINT @SQL_STATEMENT;
15 | EXEC sp_executesql @SQL_STATEMENT
16 |
17 | /* Source Control for some Modules */
18 | SET @SQL_STATEMENT = 'DELETE FROM SOURCE_CONTROL WHERE MODULE_INSTANCE_ID IN (SELECT MODULE_INSTANCE_ID FROM MODULE_INSTANCE WHERE BATCH_INSTANCE_ID IN (SELECT BATCH_INSTANCE_ID FROM BATCH_INSTANCE WHERE BATCH_ID = (SELECT BATCH_ID FROM BATCH WHERE BATCH_CODE='''+@ETL_PROCESS+''')))';
19 | PRINT @SQL_STATEMENT;
20 | EXEC sp_executesql @SQL_STATEMENT
21 |
22 | /* Module Instance */
23 | SET @SQL_STATEMENT = 'DELETE FROM MODULE_INSTANCE WHERE BATCH_INSTANCE_ID IN (SELECT BATCH_INSTANCE_ID FROM BATCH_INSTANCE WHERE BATCH_ID = (SELECT BATCH_ID FROM BATCH WHERE BATCH_CODE ='''+@ETL_PROCESS+'''))';
24 | PRINT @SQL_STATEMENT;
25 | EXEC sp_executesql @SQL_STATEMENT
26 |
27 | /* Batch Instance */
28 | SET @SQL_STATEMENT = 'DELETE FROM BATCH_INSTANCE WHERE BATCH_ID = (SELECT BATCH_ID FROM BATCH WHERE BATCH_CODE ='''+@ETL_PROCESS+''')';
29 | PRINT @SQL_STATEMENT;
30 | EXEC sp_executesql @SQL_STATEMENT
31 |
32 | /* Batch Module */
33 | SET @SQL_STATEMENT = 'DELETE FROM BATCH_MODULE WHERE BATCH_ID = (SELECT BATCH_ID FROM BATCH WHERE BATCH_CODE ='''+@ETL_PROCESS+''')';
34 | PRINT @SQL_STATEMENT;
35 | EXEC sp_executesql @SQL_STATEMENT
36 |
37 | /* Batch */
38 | SET @SQL_STATEMENT = 'DELETE FROM BATCH WHERE BATCH_CODE ='''+@ETL_PROCESS+'''';
39 | PRINT @SQL_STATEMENT;
40 | EXEC sp_executesql @SQL_STATEMENT
--------------------------------------------------------------------------------
/Example_Scripts/Maintenance/DIRECT_Clear_MODULE_entries.sql:
--------------------------------------------------------------------------------
1 | DECLARE @ETL_PROCESS NVARCHAR(100);
2 | DECLARE @SQL_STATEMENT NVARCHAR(MAX);
3 |
4 |
5 | SET @ETL_PROCESS = ''
6 |
7 | PRINT 'Working on '+@ETL_PROCESS+CHAR(13);
8 | /* Source Control */
9 | SET @SQL_STATEMENT = 'DELETE FROM SOURCE_CONTROL WHERE MODULE_INSTANCE_ID IN (SELECT MODULE_INSTANCE_ID FROM MODULE_INSTANCE WHERE MODULE_ID = (SELECT MODULE_ID FROM MODULE WHERE MODULE_CODE='''+@ETL_PROCESS+'''))'
10 | PRINT @SQL_STATEMENT;
11 | EXEC sp_executesql @SQL_STATEMENT
12 |
13 | /* Event log */
14 | SET @SQL_STATEMENT = 'DELETE FROM EVENT_LOG WHERE MODULE_INSTANCE_ID IN (SELECT MODULE_INSTANCE_ID FROM MODULE_INSTANCE WHERE MODULE_ID = (SELECT MODULE_ID FROM MODULE WHERE MODULE_CODE='''+@ETL_PROCESS+'''))'
15 | PRINT @SQL_STATEMENT;
16 | EXEC sp_executesql @SQL_STATEMENT
17 |
18 | /* Module Instance */
19 | SET @SQL_STATEMENT = 'DELETE FROM MODULE_INSTANCE WHERE MODULE_ID = (SELECT MODULE_ID FROM MODULE WHERE MODULE_CODE='''+@ETL_PROCESS+''')';
20 | PRINT @SQL_STATEMENT;
21 | EXEC sp_executesql @SQL_STATEMENT
22 |
23 | /* Batch Module */
24 | SET @SQL_STATEMENT = 'DELETE FROM BATCH_MODULE WHERE MODULE_ID = (SELECT MODULE_ID FROM MODULE WHERE MODULE_CODE='''+@ETL_PROCESS+''')';
25 | PRINT @SQL_STATEMENT;
26 | EXEC sp_executesql @SQL_STATEMENT
27 |
28 | /* Module Data Store*/
29 | SET @SQL_STATEMENT = 'DELETE FROM MODULE_DATA_STORE WHERE MODULE_ID = (SELECT MODULE_ID FROM MODULE WHERE MODULE_CODE='''+@ETL_PROCESS+''')';
30 | PRINT @SQL_STATEMENT;
31 | EXEC sp_executesql @SQL_STATEMENT
32 |
33 | /* Module */
34 | SET @SQL_STATEMENT = 'DELETE FROM MODULE WHERE MODULE_CODE='''+@ETL_PROCESS+'''';
35 | PRINT @SQL_STATEMENT;
36 | EXEC sp_executesql @SQL_STATEMENT
37 |
38 | /* Batch Instance */
39 | SET @SQL_STATEMENT = 'DELETE FROM BATCH_INSTANCE WHERE BATCH_ID = (SELECT BATCH_ID FROM BATCH WHERE BATCH_CODE ='''+@ETL_PROCESS+''')';
40 | PRINT @SQL_STATEMENT;
41 | EXEC sp_executesql @SQL_STATEMENT
42 |
43 | /* Batch */
44 | SET @SQL_STATEMENT = 'DELETE FROM BATCH WHERE BATCH_CODE ='''+@ETL_PROCESS+'''';
45 | PRINT @SQL_STATEMENT;
46 | EXEC sp_executesql @SQL_STATEMENT
--------------------------------------------------------------------------------
/Example_Scripts/Maintenance/DIRECT_Non_Execution_Exception_Check.sql:
--------------------------------------------------------------------------------
1 | --Show which modules haven't run in the last 3 days
2 | SELECT
3 | module.MODULE_CODE,
4 | module.MODULE_ID,
5 | main.MODULE_INSTANCE_ID AS MOST_RECENT_MODULE_INSTANCE_ID,
6 | main.START_DATETIME,
7 | main.END_DATETIME,
8 | main.EXECUTION_STATUS_CODE
9 | FROM MODULE_INSTANCE main
10 | JOIN MODULE module ON main.MODULE_ID=module.MODULE_ID
11 | JOIN
12 | (
13 | SELECT MODULE_ID, MAX(MODULE_INSTANCE_ID) as MAX_MODULE_INSTANCE_ID
14 | FROM MODULE_INSTANCE
15 | WHERE MODULE_ID>0
16 | GROUP BY MODULE_ID
17 | ) maxsub
18 | ON main.MODULE_ID=maxsub.MODULE_ID
19 | AND main.MODULE_INSTANCE_ID=maxsub.MAX_MODULE_INSTANCE_ID
20 | WHERE DATEDIFF(dd,START_DATETIME, GETDATE())>=3
21 | AND INACTIVE_INDICATOR='N'
--------------------------------------------------------------------------------
/Example_Scripts/Maintenance/DIRECT_Recent_Executions.sql:
--------------------------------------------------------------------------------
1 | SELECT
2 | MODULE_CODE,
3 | modinst.EXECUTION_STATUS_CODE,
4 | modinst.MODULE_INSTANCE_ID,
5 | modinst.START_DATETIME,
6 | modinst.END_DATETIME, module.MODULE_ID
7 | FROM MODULE_INSTANCE modinst
8 | JOIN MODULE module ON modinst.MODULE_ID=module.MODULE_ID
9 | ORDER BY modinst.MODULE_INSTANCE_ID DESC
--------------------------------------------------------------------------------
/Example_Scripts/Maintenance/DIRECT_Runtime_Exception_Check.sql:
--------------------------------------------------------------------------------
1 | USE
2 |
3 | -- Exception check Batch level
4 | SELECT
5 | batch.BATCH_CODE,
6 | main.BATCH_INSTANCE_ID AS MOST_RECENT_BATCH_INSTANCE_ID,
7 | main.START_DATETIME,
8 | main.END_DATETIME,
9 | main.EXECUTION_STATUS_CODE
10 | FROM BATCH_INSTANCE main
11 | JOIN BATCH batch ON main.BATCH_ID=batch.BATCH_ID
12 | JOIN
13 | (
14 | SELECT BATCH_ID, MAX(BATCH_INSTANCE_ID) as MAX_BATCH_INSTANCE_ID
15 | FROM BATCH_INSTANCE
16 | WHERE BATCH_ID>0
17 | GROUP BY BATCH_ID
18 | ) maxsub
19 | ON main.BATCH_ID=maxsub.BATCH_ID
20 | AND main.BATCH_INSTANCE_ID=maxsub.MAX_BATCH_INSTANCE_ID
21 | WHERE main.EXECUTION_STATUS_CODE<>'S' AND batch.INACTIVE_INDICATOR='N'
22 | ORDER BY 3 DESC
23 |
24 | -- Exception check Module level
25 | SELECT
26 | module.MODULE_CODE,
27 | main.BATCH_INSTANCE_ID,
28 | main.MODULE_INSTANCE_ID AS MOST_RECENT_MODULE_INSTANCE_ID,
29 | main.START_DATETIME,
30 | main.END_DATETIME,
31 | main.EXECUTION_STATUS_CODE
32 | FROM MODULE_INSTANCE main
33 | JOIN MODULE module ON main.MODULE_ID=module.MODULE_ID
34 | JOIN
35 | (
36 | SELECT MODULE_ID, MAX(MODULE_INSTANCE_ID) as MAX_MODULE_INSTANCE_ID
37 | FROM MODULE_INSTANCE
38 | WHERE MODULE_ID>0
39 | GROUP BY MODULE_ID
40 | ) maxsub
41 | ON main.MODULE_ID=maxsub.MODULE_ID
42 | AND main.MODULE_INSTANCE_ID=maxsub.MAX_MODULE_INSTANCE_ID
43 | WHERE main.EXECUTION_STATUS_CODE<>'S' AND module.INACTIVE_INDICATOR='N'
44 | ORDER BY 3 DESC
--------------------------------------------------------------------------------
/Example_Scripts/Maintenance/Generic_Table_Row_Count.sql:
--------------------------------------------------------------------------------
1 | select
2 | t.name [Table],
3 | MAX(FORMAT(p.rows, '#,###')) AS [Rows],
4 | FORMAT(SUM(round(8 * a.data_pages/1024.0,2)),'#,###') [Data (MB)],
5 | FORMAT(SUM(round(8 * a.used_pages/1024.0,2)),'#,###') [Used (MB)],
6 | FORMAT(SUM(round(8 * a.total_pages/1024.0,2)),'#,###') [Total (MB)]
7 | from
8 | sys.tables t
9 | inner join sys.partitions p
10 | on t.object_id = p.object_id
11 | inner join sys.allocation_units a on p.partition_id = a.container_id
12 | group by t.name
13 | order by
14 | CAST(FORMAT(SUM(round(8 * a.total_pages/1024.0,2)),'####') AS INT)
15 | DESC
16 |
--------------------------------------------------------------------------------
/Example_Scripts/README.md:
--------------------------------------------------------------------------------
1 | # DIRECT - useful SQl scripts
2 |
3 | A collection of scripts that may be of use when working with DIRECT.
4 |
--------------------------------------------------------------------------------
/Example_Scripts/Samples/module-wrapper-example.sql:
--------------------------------------------------------------------------------
1 | /*
2 | This example combines the registration, and possible reset, for a Module in DIRECT with the execution of specific code to be executed.
3 | */
4 |
5 | /*
6 | Parameters
7 | */
8 |
9 | DECLARE @Reset CHAR(1) = 'N';
10 | DECLARE @ModuleCode VARCHAR(255) = 'DataLogisticsExample';
11 | DECLARE @ModuleDescription VARCHAR(4000) = 'Data logistics Example';
12 | DECLARE @ModuleType VARCHAR(255) = 'SQL';
13 | DECLARE @ModuleSourceDataObject VARCHAR(255) = 'N/A';
14 | DECLARE @ModuleTargetDataObject VARCHAR(255) = 'N/A';
15 | DECLARE @ModuleAreaCode VARCHAR(255) = 'INT';
16 | DECLARE @ModuleFrequency VARCHAR(255) = 'Continuous';
17 | DECLARE @ModuleInactiveIndicator VARCHAR(255) = 'N';
18 |
19 | DECLARE @Module_Id INT;
20 | SELECT @Module_Id = module_id FROM [900_Direct_Framework].[omd].module WHERE module_code = @ModuleCode;
21 |
22 | /*
23 | Module Registration block.
24 | This is often a separate, independent step.
25 | */
26 |
27 | INSERT INTO [900_Direct_Framework].[omd].MODULE (MODULE_CODE, MODULE_DESCRIPTION, MODULE_TYPE, DATA_OBJECT_SOURCE, DATA_OBJECT_TARGET, AREA_CODE, FREQUENCY_CODE, INACTIVE_INDICATOR)
28 | SELECT *
29 | FROM
30 | (
31 | VALUES (@ModuleCode, @ModuleDescription, @ModuleType, @ModuleSourceDataObject, @ModuleTargetDataObject,@ModuleAreaCode, @ModuleFrequency, @ModuleInactiveIndicator)
32 | ) AS refData( MODULE_CODE, MODULE_DESCRIPTION, MODULE_TYPE, DATA_OBJECT_SOURCE, DATA_OBJECT_TARGET, AREA_CODE, FREQUENCY_CODE, INACTIVE_INDICATOR)
33 | WHERE NOT EXISTS
34 | (
35 | SELECT NULL
36 | FROM [900_Direct_Framework].[omd].MODULE module
37 | WHERE module.MODULE_CODE = refData.MODULE_CODE
38 | );
39 |
40 | /*
41 | Reset block, for debugging and testing purposes.
42 | */
43 |
44 | IF @Reset = 'Y'
45 | BEGIN TRY
46 | BEGIN
47 | DELETE FROM [900_Direct_Framework].[omd].event_log WHERE MODULE_INSTANCE_ID IN (SELECT MODULE_INSTANCE_ID FROM [900_Direct_Framework].[omd].module_instance WHERE MODULE_ID=@Module_id)
48 | DELETE FROM [900_Direct_Framework].[omd].source_control WHERE MODULE_INSTANCE_ID IN (SELECT MODULE_INSTANCE_ID FROM [900_Direct_Framework].[omd].module_instance WHERE MODULE_ID=@Module_id)
49 | DELETE FROM [900_Direct_Framework].[omd].module_instance WHERE MODULE_ID=@Module_id
50 | DELETE FROM [900_Direct_Framework].[omd].batch_module where module_id = @Module_id
51 | END
52 | END TRY
53 |
54 | BEGIN CATCH
55 | THROW
56 | END CATCH
57 |
58 | /*
59 | Start a new Module Instance.
60 | */
61 |
62 | BEGIN
63 |
64 | EXEC [omd].[RunModule]
65 | @ModuleCode = @ModuleCode,
66 | @Debug = 'Y',
67 | @Query = 'SELECT GETDATE()'
68 |
69 | END
70 | GO
--------------------------------------------------------------------------------
/README.md:
--------------------------------------------------------------------------------
1 | # DIRECT
2 |
3 | The Data Integration Run-time Execution Control Tool (DIRECT) is a framework for defining, orchestrating, and logging of data logistics processes and workflows so that a full audit trail is created.
4 |
5 | The framework provides mechanism to administer the individual processes or workflows, and track their runtime execution.
6 |
7 | This repository contains the following:
8 |
9 | * [Data Model](https://github.com/data-solution-automation-engine/DIRECT/blob/main/Documentation/Model.md)
10 | * Tables and scripts (DDL and DML)
11 | * Examples and support scripts
12 | * [Documentation](https://github.com/data-solution-automation-engine/DIRECT/blob/main/Documentation/Documentation.md)
13 | * Testing script to validate any framework changes
14 |
15 | ## Learn more
16 |
17 | * GitHub information: [https://github.com/data-solution-automation-engine](https://github.com/data-solution-automation-engine)
18 |
--------------------------------------------------------------------------------
/Reference_Databases/Reference_Databases.sqlproj:
--------------------------------------------------------------------------------
1 |
2 |
3 |
4 |
5 | Reference_Databases
6 | Microsoft.Data.Tools.Schema.Sql.SqlAzureV12DatabaseSchemaProvider
7 | 1033, CI
8 | {00000000-0000-0000-0000-000000000000}
9 |
10 |
11 |
12 | 160.2.2
13 | True
14 | master
15 |
16 |
17 |
--------------------------------------------------------------------------------
/Reference_Databases/readme.md:
--------------------------------------------------------------------------------
1 | # Reference Databases and Dacpacs
2 |
3 | Reference databases are maintained through a SQL SDK database project.
4 |
5 | ## Information on .sqlproj as Microsoft.Build.Sql Sdk project
6 |
7 | More information
8 |
9 | * [https://github.com/microsoft/DacFx](https://github.com/microsoft/DacFx)
10 | * [https://learn.microsoft.com/en-us/dotnet/core/project-sdk/overview](https://learn.microsoft.com/en-us/dotnet/core/project-sdk/overview)
11 | The SDK documentation has not been updated with the SQL SDK information, and might never be. This project is solely used to gain access to the dacpacs in a convenient way to make it easier to manage the project locally without manually configuring references.
12 | * ADS/VS Code Extension: `ms-mssql.sql-database-projects-vscode` allows opening the project in Code. It currently isn't supported by Visual Studio.
13 | * More information on SQL Database Projects: [https://learn.microsoft.com/en-us/azure-data-studio/extensions/sql-database-project-extension](https://learn.microsoft.com/en-us/azure-data-studio/extensions/sql-database-project-extension)
14 | * Launch announcement: [https://techcommunity.microsoft.com/t5/azure-sql-blog/microsoft-build-sql-the-next-frontier-of-sql-projects/ba-p/3290628](https://techcommunity.microsoft.com/t5/azure-sql-blog/microsoft-build-sql-the-next-frontier-of-sql-projects/ba-p/3290628)
15 | * Nuget for Master Dacpac [https://www.nuget.org/packages/Microsoft.SqlServer.Dacpacs.Master](https://www.nuget.org/packages/Microsoft.SqlServer.Dacpacs.Master)
16 | * Nuget for Msdb Dacpac [https://www.nuget.org/packages/Microsoft.SqlServer.Dacpacs.Msdb](https://www.nuget.org/packages/Microsoft.SqlServer.Dacpacs.Msdb)
17 |
18 | This allows it to pull the required reference Dacpac files from nuget without having to have SQL Server installed, or having a local reference to the system databases that will be in a different location and a different version for different developers.
19 |
20 | This project format also allows building the project using dotnet, removing a dependency on other, less readily available toolings, which can be helpful when building in containers, or through pipelines with limited tool support.
21 |
22 | Version and references in the project are currently Azure SQL database, which is only using the master reference.
23 |
24 | Add/remove references as needed, and set the version to the expected target. The below example uses version 150 instead (SQL Server 2019)
25 |
26 | ## Creating a project
27 |
28 | sequence of events for creating this:
29 |
30 | 1. `dotnet tool update -g microsoft.sqlpackage`
31 | 1. `dotnet new install Microsoft.Build.Sql.Templates`
32 | 1. `dotnet new sqlproj -n "Reference_Databases"`
33 | 1. `dotnet add package Microsoft.SqlServer.Dacpacs.Master --version 150.1.1`
34 | 1. `dotnet add package Microsoft.SqlServer.Dacpacs.Msdb --version 150.0.0`
35 |
36 | ## Restoring nugets
37 |
38 | * `dotnet restore`
39 |
40 | a manual restore can be done if needed. Building should perform the restore if needed.
41 |
42 | ## building target
43 |
44 | * `dotnet build`
45 |
46 | building will add the `master.dacpac` and `msdb.dacpac` files to the `bin/Debug` folder, ready for referencing from the main database project.
47 |
48 | To stop the need for restoring before opening the main database project, the reference Dacpac files are checked in as part of the repository.
49 |
--------------------------------------------------------------------------------