├── .github ├── release-drafter.yml └── workflows │ └── release.yml ├── README.md ├── dbt_project.yml ├── models ├── marts │ ├── dim_elementary_models.sql │ ├── dim_elementary_models.yml │ ├── dim_elementary_sources.sql │ ├── dim_elementary_sources.yml │ ├── dim_elementary_tests.sql │ ├── dim_elementary_tests.yml │ ├── fact_elementary_invocations.sql │ ├── fact_elementary_invocations.yml │ ├── fact_elementary_model_run_results.sql │ ├── fact_elementary_model_run_results.yml │ ├── fact_elementary_source_freshness.sql │ ├── fact_elementary_source_freshness.yml │ ├── fact_elementary_test_result_rows.sql │ ├── fact_elementary_test_result_rows.yml │ ├── fact_elementary_test_run_results.sql │ └── fact_elementary_test_run_results.yml └── staging │ ├── dbt_elementary_utils_day.sql │ ├── sources.yml │ ├── stg_elementary_dbt_invocations.sql │ ├── stg_elementary_dbt_models.sql │ ├── stg_elementary_dbt_run_results.sql │ ├── stg_elementary_dbt_source_freshness_results.sql │ ├── stg_elementary_dbt_sources.sql │ ├── stg_elementary_dbt_tests.sql │ ├── stg_elementary_elementary_test_results.sql │ └── stg_elementary_test_result_rows.sql └── packages.yml /.github/release-drafter.yml: -------------------------------------------------------------------------------- 1 | template: | 2 | ## What's Changed 3 | $CHANGES 4 | 5 | **Full Changelog**: https://github.com/$OWNER/$REPOSITORY/compare/$PREVIOUS_TAG...v$RESOLVED_VERSION -------------------------------------------------------------------------------- /.github/workflows/release.yml: -------------------------------------------------------------------------------- 1 | name: Release Drafter and Publisher 2 | 3 | on: 4 | pull_request: 5 | types: [closed] 6 | 7 | permissions: 8 | contents: read 9 | 10 | jobs: 11 | new_release: 12 | if: github.event.pull_request.merged == true 13 | permissions: 14 | # write permission is required to create a github release 15 | contents: write 16 | # write permission is required for autolabeler 17 | # otherwise, read permission is required at least 18 | pull-requests: write 19 | runs-on: ubuntu-latest 20 | 21 | steps: 22 | - name: Checkout code 23 | uses: actions/checkout@v2 24 | with: 25 | fetch-depth: 0 26 | 27 | - name: Get branch name 28 | id: getbranch 29 | run: echo ::set-output name=BRANCH::${GITHUB_HEAD_REF} 30 | 31 | # ${{ github.ref }} was not giving v* as tag name, but refs/tags/v* instead, so I had to abbreviate it 32 | - name: Get latest abbreviated tag 33 | id: gettag 34 | run: echo ::set-output name=TAG::$(git describe --tags $(git rev-list --tags --max-count=1)) # get the latest tag across all branches and put it in the output TAG 35 | 36 | - name: Calculate next version 37 | id: nextversion 38 | run: | 39 | BRANCH_NAME="${{ steps.getbranch.outputs.BRANCH }}" 40 | CURRENT_VERSION="${{ steps.gettag.outputs.TAG }}" 41 | CURRENT_VERSION="${CURRENT_VERSION#v}" # Remove the 'v' from the start of the version 42 | IFS='.' read -ra VERSION_PARTS <<< "$CURRENT_VERSION" 43 | if [[ $BRANCH_NAME =~ ^release/ ]]; then 44 | VERSION_PARTS[0]=$((VERSION_PARTS[0] + 1)) 45 | VERSION_PARTS[1]=0 46 | VERSION_PARTS[2]=0 47 | elif [[ $BRANCH_NAME =~ ^feature/ ]]; then 48 | VERSION_PARTS[1]=$((VERSION_PARTS[1] + 1)) 49 | VERSION_PARTS[2]=0 50 | elif [[ $BRANCH_NAME =~ ^patch/ ]]; then 51 | VERSION_PARTS[2]=$((VERSION_PARTS[2] + 1)) 52 | fi 53 | NEXT_VERSION="v${VERSION_PARTS[0]}.${VERSION_PARTS[1]}.${VERSION_PARTS[2]}" 54 | echo ::set-output name=NEXT_VERSION::"$NEXT_VERSION" 55 | 56 | - name: Create and publish new tag 57 | run: | 58 | git tag ${{ steps.nextversion.outputs.NEXT_VERSION }} 59 | git push origin ${{ steps.nextversion.outputs.NEXT_VERSION }} 60 | 61 | - uses: release-drafter/release-drafter@v5 62 | with: 63 | commitish: main 64 | name: "elementary-dbt-monitoring ${{ steps.nextversion.outputs.NEXT_VERSION }}" 65 | tag: ${{ steps.nextversion.outputs.NEXT_VERSION }} 66 | publish: True 67 | env: 68 | GITHUB_TOKEN: ${{ secrets.GITHUB_TOKEN }} -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # dbt Monitoring 2 | ## This repository is in experimental stage. It is NOT ready for production yet. 3 | ### Changes are being made! 4 | 5 | This package allows you to easily monitor the quality, dependency, volume, schema and how up-to-date the data is your dbt, providing helpful info to improve your data pipeline. 6 | 7 | 8 | # :running: Quickstart 9 | 10 | New to dbt packages? Read more about them [here](https://docs.getdbt.com/docs/building-a-dbt-project/package-management/). 11 | 12 | ## Before creating a branch 13 | 14 | Pay attention, it is very important to know if your modification to this repository is a release (breaking changes), a feature (functionalities) or a patch(to fix bugs). 15 | With that information, create your branch name like this: 16 | 17 | * ```release/``` 18 | * ```feature/ ``` 19 | * ```patch/``` 20 | 21 | ## Requirements 22 | dbt version 23 | * ```dbt version >= 1.0.0``` 24 | 25 | dbt_utils package. Read more about them [here](https://hub.getdbt.com/dbt-labs/dbt_utils/latest/). 26 | * ```dbt-labs/dbt_utils version: >=0.9.0 and <1.2.0``` 27 | 28 | elementary package. Read more about them [here](https://docs.elementary-data.com/quickstart-cli). 29 | * ``` elementary-data/elementary version: 0.7.1 ``` 30 | 31 | # Installation elementary package and create first tables to dbt monitoring modelling 32 | 33 | ## Installation elementary package 34 | 35 | 1. Include this package in your `packages.yml` file. 36 | ```yaml 37 | packages: 38 | - package: elementary-data/elementary 39 | version: 0.7.1 40 | ``` 41 | 42 | 2. Run `dbt deps` to install the package. 43 | 44 | ## Configuring models elementary package 45 | 46 | 1. The package's models can be configured in your `dbt_project.yml` by specifying the package under `models`. 47 | 48 | ``` 49 | models: 50 | elementary: 51 | +schema: 'elementary' 52 | ``` 53 | 54 | 2. Run `dbt run -m elementary` to build the package inside your dbt project. 55 | 56 | "This command will create tables that at first will be empty, but will be fed with the results of these executions of each “dbt run”, “dbt test” and “dbt build” within the project." 57 | 58 | ## Installation elementary CLI 59 | 60 | Reports can be generated by the elementary package by installing the monitoring module via the CLI. To install it in your project folder, just install elementary according to the used platform: 61 | 62 | ``` 63 | pip install 'elementary-data[snowflake]' 64 | pip install 'elementary-data[bigquery]' 65 | pip install 'elementary-data[redshift]' 66 | pip install 'elementary-data[databricks]' 67 | ``` 68 | 69 | In order to connect, Elementary needs a connection profile in a file named profiles.yml. This profile will be used by the CLI, to connect to the DWH and find the dbt package tables. 70 | 71 | The easiest way to generate the profile is to run the following command within the dbt project where you deployed the elementary dbt package: 72 | 73 | ``` 74 | dbt run-operation elementary.generate_elementary_cli_profile 75 | ``` 76 | 77 | Copy the output, fill in the missing fields and add the profile to your profiles.yml. 78 | 79 | ``` 80 | Profile name: elementary 81 | Schema name: The schema of elementary models, default is _elementary 82 | ``` 83 | 84 | # Installation elementary-dbt-monitoring package and Configuring models 85 | 86 | ## Installation elementary-dbt-monitoring package 87 | 88 | 1. Include this package in your `packages.yml` file and specify the version you want to be installed 89 | ```yaml 90 | packages: 91 | - git: https://github.com/techindicium/elementary-dbt-monitoring # insert git SSH URL 92 | ## revision: v0.1.0 (example, if specific version is needed) 93 | ``` 94 | 95 | 2. Run `dbt deps` to install the package. 96 | 97 | ## Configuring models package 98 | 99 | The package's models can be configured in your `dbt_project.yml` by specifying the package under `models` and the start date of the dbt monitoring data. 100 | 101 | ``` 102 | models: 103 | elementary_dbt_monitoring: 104 | staging: 105 | materialized: ephemeral 106 | marts: 107 | materialized: table 108 | ``` 109 | ... 110 | 111 | ``` 112 | vars: 113 | elementary_dbt_monitoring: 114 | dbt_monitoring_start_date: cast('2022-08-01' as date) 115 | ``` 116 | 117 | To ensure the package runs correctly, you must declare an environment variable named `ELEMENTARY_SOURCE_SCHEMA`. This variable allows dbt to locate the source tables that feed all the models. The schema you define here must match the schema where the tables are being created by Elementary. 118 | 119 | By setting this as an environment variable, you gain flexibility to adjust the schema as environments change, such as when switching between development, QA, or production environments. This setup ensures that dbt can always find the correct source tables, regardless of which environment you're working in. 120 | 121 | Imagine that the Elementary package is creating the tables in the `elementary` schema, **as we recommended above**. You need to set the environment variable ELEMENTARY_SOURCE_SCHEMA to elementary so that dbt knows where to find the source tables for the models. 122 | 123 | For Bash CLI, you can use this: 124 | 125 | `export ELEMENTARY_SOURCE_SCHEMA="elementary"` 126 | 127 | Or to CMD (Windows): 128 | 129 | `set ELEMENTARY_SOURCE_SCHEMA=elementary` 130 | 131 | ## Deduplication of staging models 132 | 133 | We identify an issue involving duplication of IDs in some models. These staging models feed into dimension models, and the duplicates were causing inconsistencies in the data pipeline. 134 | 135 | The duplication of IDs in the staging models was propagating to both dimension and fact models, leading to potential inaccuracies in downstream processes. These duplications can negatively impact various use cases of this package, such as data analysis, reporting, and dashboards in data visualization tools, resulting in misleading insights. 136 | 137 | So, in the last update of this package, we've added a step to deduplicate this models. The deduplication is based on the ID and the generated_at timestamp. The following SQL criterion was applied: 138 | 139 | ```sql 140 | 141 | qualify row_number() over ( 142 | partition by model_id -- source_id or test_id 143 | order by generated_at desc 144 | ) = 1 145 | 146 | ``` 147 | 148 | ## Recommendations 149 | 150 | We strongly recommend that you use this package separatly from the production jobs. This is a way to prevent package-related issues from affecting your production jobs. 151 | 152 | It has been observed that one possible issue with the package is related to its installation with the `dbt deps` command. 153 | 154 | A possible solution to this problem is just installing the package when the job that runs this package would be trigged. This ensures that although you've separeted the package from production jobs, the dbt deps command that will install all packages of your project don't beak anything in production. 155 | 156 | A possible way to do this is remain the packages.yml without the installation of the elementary_dbt_monitoring in your dbt project and have another yaml file in your dbt project folder, like `package_monitoring.yml`. So, the original yaml can be like this: 157 | 158 | ```yml 159 | packages: 160 | - package: dbt-labs/codegen 161 | version: 0.12.1 162 | - package: dbt-labs/dbt_utils 163 | version: 1.1.1 164 | ## Docs: https://docs.elementary-data.com 165 | - package: elementary-data/elementary 166 | version: 0.14.1 167 | - package: calogica/dbt_expectations 168 | version: 0.10.4 169 | 170 | ``` 171 | 172 | The monitoring package yaml can be like this: 173 | 174 | ```yml 175 | # Elementary dbt Monitoring 176 | - git: https://github.com/techindicium/elementary-dbt-monitoring 177 | revision: v2.1.0 178 | ``` 179 | 180 | And in your monitoring job you can run the following bash command before the `dbt deps`: 181 | 182 | ```bash 183 | cat packages_monitoring.yml >> packages.yml 184 | ``` 185 | 186 | ## New releases 187 | 188 | Want a new release (major/minor/patch) ? 189 | 1. Push your modifications to main 190 | 2. Push the tag you want, example: "git tag v1.0.1" 191 | 3. git push origin tag v1.0.1 or git push --tags (warning: It pushes all tags you have) 192 | -------------------------------------------------------------------------------- /dbt_project.yml: -------------------------------------------------------------------------------- 1 | name: 'elementary_dbt_monitoring' 2 | version: '0.1.0' 3 | 4 | require-dbt-version: [">=1.0.0", "<2.0.0"] 5 | 6 | config-version: 2 7 | 8 | target-path: "target" 9 | clean-targets: ["target", "dbt_modules", "dbt_packages"] 10 | macro-paths: ["macros"] 11 | log-path: "logs" 12 | -------------------------------------------------------------------------------- /models/marts/dim_elementary_models.sql: -------------------------------------------------------------------------------- 1 | with 2 | stg_models as ( 3 | select distinct 4 | model_id 5 | , materialization 6 | , model_tags 7 | , project_database_name 8 | , schema_name 9 | , model_depends_on_nodes 10 | , model_description 11 | , model_name 12 | , table_type_mod 13 | , dbt_model_path 14 | , model_generated_at 15 | from {{ ref('stg_elementary_dbt_models') }} 16 | ) 17 | , stg_models_with_sk as ( 18 | select distinct 19 | {{ dbt_utils.generate_surrogate_key(['model_id']) }} as model_sk 20 | , * 21 | from stg_models 22 | ) 23 | select * 24 | from stg_models_with_sk -------------------------------------------------------------------------------- /models/marts/dim_elementary_models.yml: -------------------------------------------------------------------------------- 1 | version: 2 2 | 3 | models: 4 | - name: dim_elementary_models 5 | description: "Dimension table consisting of models." 6 | columns: 7 | - name: 'model_sk' 8 | description: "Surrogate Key. Created from: model_id." 9 | tests: 10 | - unique 11 | - not_null 12 | 13 | - name: 'model_id' 14 | description: "Column with the table primary key." 15 | tests: 16 | - unique 17 | - not_null 18 | 19 | - name: 'project_database_name' 20 | description: "Column with the project's database name." 21 | 22 | - name: 'schema_name' 23 | description: "Column with the schema name." 24 | 25 | - name: 'materialization' 26 | description: "Column with the model's materialization type." 27 | 28 | - name: 'model_depends_on_nodes' 29 | description: "Column with the model's dependencies." 30 | 31 | - name: 'model_description' 32 | description: "Column with the model's description." 33 | 34 | - name: 'model_tags' 35 | description: "Column with the model's tag." 36 | 37 | - name: 'model_name' 38 | description: "Column with the model's name." 39 | 40 | - name: 'table_type_mod' 41 | description: "Column with the type of table to which the model belongs, modified to include elementary models." 42 | 43 | - name: 'dbt_model_path' 44 | description: "Column with the current directory path of the model." 45 | 46 | - name: 'model_generated_at' 47 | description: "Column with the timestamp of when the model was generated." 48 | -------------------------------------------------------------------------------- /models/marts/dim_elementary_sources.sql: -------------------------------------------------------------------------------- 1 | with 2 | stg_sources as ( 3 | select distinct 4 | source_id 5 | , source_name 6 | , table_name 7 | , project_database_name 8 | , schema_name 9 | , relation_name 10 | , source_tags 11 | , package_name 12 | , dbt_source_path 13 | , source_description 14 | , source_table_description 15 | , source_generated_at 16 | from {{ ref('stg_elementary_dbt_sources') }} 17 | ) 18 | , stg_sources_with_sk as ( 19 | select 20 | {{ dbt_utils.generate_surrogate_key(['source_id']) }} as source_sk 21 | , * 22 | from stg_sources 23 | ) 24 | select * 25 | from stg_sources_with_sk -------------------------------------------------------------------------------- /models/marts/dim_elementary_sources.yml: -------------------------------------------------------------------------------- 1 | version: 2 2 | 3 | models: 4 | - name: dim_elementary_sources 5 | description: "Dimension table with the project sources data." 6 | columns: 7 | - name: 'source_sk' 8 | description: "Surrogate key. Created from: source_id." 9 | tests: 10 | - unique 11 | - not_null 12 | 13 | - name: 'source_id' 14 | description: "Column with the table primary key." 15 | tests: 16 | - unique 17 | - not_null 18 | 19 | - name: 'source_name' 20 | description: "Column with the source name." 21 | 22 | - name: 'table_name' 23 | description: "Column with the table name." 24 | 25 | - name: 'project_database_name' 26 | description: "Column with the project's database name." 27 | 28 | - name: 'schema_name' 29 | description: "Column with the schema name." 30 | 31 | - name: 'relation_name' 32 | description: "Column with the concatenation of project_database_name.schema_name.table_name." 33 | 34 | - name: 'source_tags' 35 | description: "Column with the source tags." 36 | 37 | - name: 'package_name' 38 | description: "Column with the dbt project name." 39 | 40 | - name: 'dbt_source_path' 41 | description: "Column with the path within the dbt project." 42 | 43 | - name: 'source_description' 44 | description: "Column with the source description." 45 | 46 | - name: 'source_table_description' 47 | description: "Column with the source table description." 48 | 49 | - name: 'source_generated_at' 50 | description: "Column with the timestamp of when the source was generated." -------------------------------------------------------------------------------- /models/marts/dim_elementary_tests.sql: -------------------------------------------------------------------------------- 1 | with 2 | stg_tests as ( 3 | select distinct 4 | test_id 5 | , project_database_name 6 | , schema_name 7 | , test_name 8 | , test_short_name 9 | , test_type_mod 10 | , test_column_name 11 | , test_severity 12 | , test_tags 13 | , test_depends_on_macros 14 | , test_depends_on_nodes 15 | , parent_model_unique_id 16 | , test_description 17 | , package_name 18 | , test_type 19 | , dbt_test_path 20 | , test_generated_at 21 | from {{ ref('stg_elementary_dbt_tests') }} 22 | ) 23 | , stg_models as ( 24 | select distinct 25 | model_id 26 | , model_name 27 | from {{ ref('stg_elementary_dbt_models') }} 28 | ) 29 | , joined_tests_models as ( 30 | select 31 | stg_tests.test_id 32 | , stg_tests.project_database_name 33 | , stg_tests.schema_name 34 | , stg_models.model_name 35 | , stg_tests.test_name 36 | , stg_tests.test_short_name 37 | , stg_tests.test_type_mod 38 | , stg_tests.test_column_name 39 | , stg_tests.test_severity 40 | , stg_tests.test_tags 41 | , stg_tests.test_depends_on_macros 42 | , stg_tests.test_depends_on_nodes 43 | , stg_tests.parent_model_unique_id 44 | , stg_tests.test_description 45 | , stg_tests.package_name 46 | , stg_tests.test_type 47 | , stg_tests.dbt_test_path 48 | , stg_tests.test_generated_at 49 | from stg_tests 50 | left join stg_models on stg_tests.parent_model_unique_id = stg_models.model_id 51 | ) 52 | , stg_tests_with_sk as ( 53 | select distinct 54 | {{ dbt_utils.generate_surrogate_key(['test_id']) }} as test_sk 55 | , * 56 | from joined_tests_models 57 | ) 58 | select * 59 | from stg_tests_with_sk -------------------------------------------------------------------------------- /models/marts/dim_elementary_tests.yml: -------------------------------------------------------------------------------- 1 | version: 2 2 | 3 | models: 4 | - name: dim_elementary_tests 5 | description: "Dimension table consisting of tests. The 'tests' include the native tests implemented on the projects." 6 | columns: 7 | - name: 'test_sk' 8 | description: "Surrogate key created from: test_id." 9 | tests: 10 | - unique 11 | - not_null 12 | 13 | - name: 'test_id' 14 | description: "Table natural key." 15 | tests: 16 | - unique 17 | - not_null 18 | 19 | - name: 'project_database_name' 20 | description: "Column with the project's database name." 21 | 22 | - name: 'schema_name' 23 | description: "Column with the schema name." 24 | 25 | - name: 'model_name' 26 | description: "Column with the model name." 27 | 28 | - name: 'test_name' 29 | description: "Column with the test full name, which is a concatenation of 'test_short_name'.'test_column_name'." 30 | 31 | - name: 'test_short_name' 32 | description: "Column with the specific test name." 33 | 34 | - name: 'test_type_mod' 35 | description: "Column with the specific test name modified to include data tests." 36 | 37 | - name: 'test_column_name' 38 | description: "Column with the test column name." 39 | 40 | - name: 'test_severity' 41 | description: "Column with the severity configured for the test." 42 | 43 | - name: 'test_tags' 44 | description: "Column with the tags configured in the test." 45 | 46 | - name: 'test_depends_on_macros' 47 | description: "Column with the test macro dependencies." 48 | 49 | - name: 'test_depends_on_nodes' 50 | description: "Column with the test model dependencies." 51 | 52 | - name: 'parent_model_unique_id' 53 | description: "Column with the model id that was tested." 54 | 55 | - name: 'test_description' 56 | description: "Column with the test description." 57 | 58 | - name: 'package_name' 59 | description: "Column with the dbt project name." 60 | 61 | - name: 'test_type' 62 | description: "Column with the test types." 63 | 64 | - name: 'dbt_test_path' 65 | description: "Column with the test path." 66 | 67 | - name: 'test_generated_at' 68 | description: "Column with the timestamp of when the test was generated." -------------------------------------------------------------------------------- /models/marts/fact_elementary_invocations.sql: -------------------------------------------------------------------------------- 1 | with 2 | util_days as ( 3 | select cast(date_day as date) as date_day 4 | from {{ ref('dbt_elementary_utils_day') }} 5 | ) 6 | , stg_invocations as ( 7 | select distinct 8 | invocation_id 9 | , job_id 10 | , job_name 11 | , job_run_id 12 | , invocation_started_at 13 | , invocation_completed_at 14 | , invocation_date 15 | , dbt_invocation_command 16 | , is_full_refresh 17 | , invocation_vars 18 | , vars 19 | , target_name 20 | , target_database 21 | , target_schema 22 | , target_profile_name 23 | , threads 24 | , models_ran 25 | , project_id 26 | , project_name 27 | from {{ ref('stg_elementary_dbt_invocations') }} 28 | ) 29 | , joined_with_sk as ( 30 | select distinct 31 | {{ dbt_utils.generate_surrogate_key(['invocation_id']) }} as invocation_sk 32 | , invocation_id 33 | , job_id 34 | , job_name 35 | , job_run_id 36 | , invocation_started_at 37 | , invocation_completed_at 38 | , util_days.date_day as invocation_date 39 | , dbt_invocation_command 40 | , is_full_refresh 41 | , invocation_vars 42 | , vars 43 | , target_name 44 | , target_database 45 | , target_schema 46 | , target_profile_name 47 | , threads 48 | , models_ran 49 | , project_id 50 | , project_name 51 | from stg_invocations 52 | left join util_days on stg_invocations.invocation_date = util_days.date_day 53 | ) 54 | select * 55 | from joined_with_sk -------------------------------------------------------------------------------- /models/marts/fact_elementary_invocations.yml: -------------------------------------------------------------------------------- 1 | version: 2 2 | 3 | models: 4 | - name: fact_elementary_invocations 5 | description: "Dimension table with dbt invocations (run, test, and build)." 6 | columns: 7 | - name: 'invocation_sk' 8 | description: "Surrogate key. Composed of: invocation_id." 9 | tests: 10 | - unique 11 | - not_null 12 | 13 | - name: 'invocation_id' 14 | description: "Table natural key." 15 | tests: 16 | - unique 17 | 18 | - name: 'job_id' 19 | description: "Column with the job identification." 20 | 21 | - name: 'job_name' 22 | description: "Column with the job name." 23 | 24 | - name: 'job_run_id' 25 | description: "Column with the job execution identification." 26 | 27 | - name: 'invocation_started_at' 28 | description: "Column with the invocation start timestamp." 29 | 30 | - name: 'invocation_completed_at' 31 | description: "Column with the invocation end timestamp." 32 | 33 | - name: 'invocation_date' 34 | description: "Column with the invocation date." 35 | tests: 36 | - relationships: 37 | to: ref('dbt_elementary_utils_day') 38 | field: date_day 39 | 40 | - name: 'dbt_invocation_command' 41 | description: "Column with the dbt command used in the invocation." 42 | 43 | - name: 'is_full_refresh' 44 | description: "Column indicating if it is a full refresh." 45 | 46 | - name: 'invocation_vars' 47 | description: "Column with the variables configured in the invocation." 48 | 49 | - name: 'vars' 50 | description: "Column with the global variables configured in dbt_project." 51 | 52 | - name: 'target_name' 53 | description: "Column with the target name." 54 | 55 | - name: 'target_database' 56 | description: "Column with the target database name." 57 | 58 | - name: 'target_schema' 59 | description: "Column with the target schema name." 60 | 61 | - name: 'target_profile_name' 62 | description: "Column with the target profile name." 63 | 64 | - name: 'threads' 65 | description: "Column with the number of processor subsystems used." 66 | 67 | - name: 'models_ran' 68 | description: "Column with the model executed in dbt run, dbt test, or dbt build." 69 | 70 | - name: 'project_id' 71 | description: "Column with the project identification." 72 | 73 | - name: 'project_name' 74 | description: "Column with the project name." -------------------------------------------------------------------------------- /models/marts/fact_elementary_model_run_results.sql: -------------------------------------------------------------------------------- 1 | with 2 | util_days as ( 3 | select cast(date_day as date) as date_day 4 | from {{ ref('dbt_elementary_utils_day') }} 5 | ) 6 | , models as ( 7 | select distinct 8 | model_sk 9 | , model_id 10 | from {{ ref('dim_elementary_models') }} 11 | ) 12 | , invocations as ( 13 | select distinct 14 | invocation_sk 15 | , invocation_id 16 | from {{ ref('fact_elementary_invocations') }} 17 | ) 18 | , run_results as ( 19 | select 20 | model_execution_id 21 | , run_result_id 22 | , invocation_id 23 | , invocation_generated_at 24 | , invocation_status 25 | , resource_type 26 | , execution_time 27 | , run_date 28 | , run_started_at 29 | , run_completed_at 30 | , compile_started_at 31 | , compile_completed_at 32 | , rows_affected 33 | , query_id 34 | , is_full_refresh 35 | , failures 36 | from {{ ref('stg_elementary_dbt_run_results') }} 37 | ) 38 | , model_run_results_joined_with_sk as ( 39 | select distinct 40 | {{ dbt_utils.generate_surrogate_key(['run_results.model_execution_id', 'run_results.run_result_id', 'models.model_sk']) }} as model_run_result_sk 41 | , run_results.model_execution_id 42 | , models.model_sk as model_fk 43 | , invocations.invocation_sk as invocation_fk 44 | , run_results.run_result_id 45 | , util_days.date_day as run_date 46 | , run_results.invocation_generated_at 47 | , run_results.invocation_status 48 | , run_results.resource_type 49 | , run_results.execution_time 50 | , run_results.failures 51 | , run_results.run_started_at 52 | , run_results.run_completed_at 53 | , run_results.compile_started_at 54 | , run_results.compile_completed_at 55 | , run_results.rows_affected 56 | , run_results.query_id 57 | , run_results.is_full_refresh 58 | , row_number() over ( 59 | partition by run_results.run_result_id 60 | order by run_results.invocation_generated_at desc 61 | ) as model_invocation_reverse_index 62 | from run_results 63 | right join models on run_results.run_result_id = models.model_id 64 | left join util_days on run_results.run_date = util_days.date_day 65 | left join invocations on run_results.invocation_id = invocations.invocation_id 66 | ) 67 | select * 68 | from model_run_results_joined_with_sk -------------------------------------------------------------------------------- /models/marts/fact_elementary_model_run_results.yml: -------------------------------------------------------------------------------- 1 | version: 2 2 | 3 | models: 4 | - name: fact_elementary_model_run_results 5 | description: "Fact table about models execution run results. Provides information about models run status, execution time, failures, and other relevant information." 6 | columns: 7 | - name: 'model_run_result_sk' 8 | description: "Surrogate key. Composed of: model_execution_id, run_result_id, model_sk." 9 | tests: 10 | - unique 11 | - not_null 12 | 13 | - name: 'model_fk' 14 | description: "Foreign key. Composed of: model_sk." 15 | tests: 16 | - relationships: 17 | to: ref('dim_elementary_models') 18 | field: model_sk 19 | 20 | - name: 'invocation_fk' 21 | description: "Foreign key. Composed of: invocation_sk." 22 | tests: 23 | - relationships: 24 | to: ref('fact_elementary_invocations') 25 | field: invocation_sk 26 | 27 | - name: 'run_date' 28 | description: "Column with the date the model was executed." 29 | tests: 30 | - relationships: 31 | to: ref('dbt_elementary_utils_day') 32 | field: date_day 33 | 34 | - name: 'invocation_status' 35 | description: "Column with the invocation status." 36 | 37 | - name: 'resource_type' 38 | description: "Column with the resource type." 39 | 40 | - name: 'execution_time' 41 | description: "Column with the execution time of the models." 42 | 43 | - name: 'failures' 44 | description: "Column with the number of failures in the execution of the models." 45 | 46 | - name: 'run_started_at' 47 | description: "Column with the timestamp of the start of the model execution." 48 | 49 | - name: 'run_completed_at' 50 | description: "Column with the timestamp of the end of the model execution." 51 | 52 | - name: 'compile_started_at' 53 | description: "Column with the timestamp of the start of the model compilation." 54 | 55 | - name: 'compile_completed_at' 56 | description: "Column with the timestamp of the end of the model compilation." 57 | 58 | - name: 'rows_affected' 59 | description: "Column with the number of rows affected in the models." 60 | 61 | - name: 'query_id' 62 | description: "Query ID in the data warehouse, if returned by the adapter (currently only supported in Snowflake, is null for any other adapter)." 63 | 64 | - name: 'is_full_refresh' 65 | description: "Column that indicates if there was a full refresh in the model execution." 66 | 67 | - name: 'model_invocation_reverse_index' 68 | description: "Column with the cardinality of the specific model execution." -------------------------------------------------------------------------------- /models/marts/fact_elementary_source_freshness.sql: -------------------------------------------------------------------------------- 1 | with 2 | util_days as ( 3 | select cast(date_day as date) as date_day 4 | from {{ ref('dbt_elementary_utils_day') }} 5 | ) 6 | , sources as ( 7 | select * 8 | from {{ ref('dim_elementary_sources') }} 9 | ) 10 | , invocations as ( 11 | select 12 | invocation_sk 13 | , invocation_id 14 | from {{ ref('fact_elementary_invocations') }} 15 | ) 16 | , source_freshness as ( 17 | select 18 | source_freshness_execution_id 19 | , source_freshness_id 20 | , invocation_id 21 | , source_max_loaded_at 22 | , source_snapshotted_at 23 | , source_freshness_generated_at 24 | , source_generate_date 25 | , source_max_loaded_at_seconds 26 | , source_status 27 | , source_error 28 | , source_compile_started_at 29 | , source_compile_completed_at 30 | , source_execute_started_at 31 | , source_execute_completed_at 32 | from {{ ref('stg_elementary_dbt_source_freshness_results') }} 33 | ) 34 | , source_freshness_joined_with_sk as ( 35 | select 36 | {{ dbt_utils.generate_surrogate_key(['source_freshness.source_freshness_execution_id']) }} as source_freshness_sk 37 | , sources.source_sk as source_fk 38 | , invocations.invocation_sk as invocation_fk 39 | , util_days.date_day as source_generate_date 40 | , source_freshness.source_snapshotted_at 41 | , source_freshness.source_freshness_generated_at 42 | , source_freshness.source_max_loaded_at_seconds 43 | , source_freshness.source_status 44 | , source_freshness.source_error 45 | , source_freshness.source_compile_started_at 46 | , source_freshness.source_compile_completed_at 47 | , source_freshness.source_execute_started_at 48 | , source_freshness.source_execute_completed_at 49 | from source_freshness 50 | left join sources on source_freshness.source_freshness_id = sources.source_id 51 | left join invocations on source_freshness.invocation_id = invocations.invocation_id 52 | left join util_days on source_freshness.source_generate_date = util_days.date_day 53 | ) 54 | select * 55 | from source_freshness_joined_with_sk -------------------------------------------------------------------------------- /models/marts/fact_elementary_source_freshness.yml: -------------------------------------------------------------------------------- 1 | version: 2 2 | 3 | models: 4 | - name: fact_elementary_source_freshness 5 | description: "Source Freshness fact table. Provides information about the updates of data sources for elementary models." 6 | columns: 7 | - name: 'source_freshness_sk' 8 | description: "Surrogate key. Created from: source_freshness_execution_id." 9 | tests: 10 | - unique 11 | - not_null 12 | 13 | - name: 'source_fk' 14 | description: "Foreign key. Composed of: source_sk." 15 | tests: 16 | - relationships: 17 | to: ref('dim_elementary_sources') 18 | field: source_sk 19 | 20 | - name: 'invocation_fk' 21 | description: "Foreign key. Composed of: invocation_sk." 22 | tests: 23 | - relationships: 24 | to: ref('fact_elementary_invocations') 25 | field: invocation_sk 26 | 27 | - name: 'source_snapshotted_at' 28 | description: "Column with the timestamp when the source was snapshotted." 29 | 30 | - name: 'source_freshness_generated_at' 31 | description: "Column with timestamp when the source freshness information was generated." 32 | 33 | - name: 'source_generate_date' 34 | description: "Column with the source creation date of the information in the dbt_source_freshness_results table." 35 | tests: 36 | - relationships: 37 | to: ref('dbt_elementary_utils_day') 38 | field: date_day 39 | 40 | - name: 'source_max_loaded_at_seconds' 41 | description: "Column with the time required to load the source data." 42 | 43 | - name: 'source_status' 44 | description: "Column with the source status." 45 | 46 | - name: 'source_error' 47 | description: "Column indicating source errors." 48 | 49 | - name: 'source_compile_started_at' 50 | description: "Column with the timestamp of when the source compilation started." 51 | 52 | - name: 'source_compile_completed_at' 53 | description: "Column with the timestamp of when the source compilation ended." 54 | 55 | - name: 'source_execute_started_at' 56 | description: "Column with the timestamp of when the source execution started." 57 | 58 | - name: 'source_execute_completed_at' 59 | description: "Column with the timestamp of when the source execution ended." -------------------------------------------------------------------------------- /models/marts/fact_elementary_test_result_rows.sql: -------------------------------------------------------------------------------- 1 | with 2 | util_days as ( 3 | select cast(date_day as date) as date_day 4 | from {{ ref('dbt_elementary_utils_day') }} 5 | ) 6 | , invocations as ( 7 | select distinct 8 | invocation_sk 9 | , invocation_id 10 | from {{ ref('fact_elementary_invocations') }} 11 | ) 12 | , dim_tests as ( 13 | select distinct 14 | test_sk 15 | , test_id 16 | from {{ ref('dim_elementary_tests') }} 17 | ) 18 | , run_results as ( 19 | select 20 | model_execution_id 21 | , run_result_id 22 | , invocation_id 23 | , invocation_generated_at 24 | , invocation_status 25 | , resource_type 26 | , execution_time 27 | , run_date 28 | , run_started_at 29 | , run_completed_at 30 | , compile_started_at 31 | , compile_completed_at 32 | , rows_affected 33 | , is_full_refresh 34 | , failures 35 | from {{ ref('stg_elementary_dbt_run_results') }} 36 | ) 37 | , elementary_test_results as ( 38 | select 39 | elementary_test_results_id 40 | , test_id 41 | , invocation_id 42 | , test_detected_date 43 | , test_type 44 | , test_status 45 | , test_failures 46 | from {{ ref('stg_elementary_elementary_test_results') }} 47 | ) 48 | , tests_result_row as ( 49 | select 50 | elementary_test_results_id 51 | , test_result_row 52 | , test_detected_date 53 | , row_number () over ( 54 | partition by elementary_test_results_id 55 | order by test_detected_at 56 | ) as rn 57 | from {{ ref('stg_elementary_test_result_rows') }} 58 | ) 59 | , fact_test_results as ( 60 | select 61 | elementary_test_results.elementary_test_results_id 62 | , elementary_test_results.test_id 63 | , run_results.run_result_id 64 | , elementary_test_results.invocation_id as invocation_id 65 | , elementary_test_results.test_detected_date 66 | , elementary_test_results.test_type 67 | , run_results.model_execution_id 68 | , run_results.run_date 69 | from run_results 70 | left join elementary_test_results on run_results.run_result_id = elementary_test_results.test_id 71 | where test_type is not null 72 | ) 73 | , join_with_dim as ( 74 | select 75 | {{ dbt_utils.generate_surrogate_key([ 76 | 'fact_test_results.model_execution_id' 77 | , 'fact_test_results.elementary_test_results_id' 78 | , 'dim_tests.test_sk' 79 | , 'invocations.invocation_sk' 80 | , 'tests_result_row.test_result_row' 81 | ]) }} as test_run_result_row_sk 82 | , dim_tests.test_sk as test_fk 83 | , invocations.invocation_sk as invocation_fk 84 | , fact_test_results.elementary_test_results_id 85 | , fact_test_results.model_execution_id 86 | , util_days.date_day as test_detected_date 87 | , tests_result_row.test_result_row 88 | from fact_test_results 89 | left join dim_tests on fact_test_results.test_id = dim_tests.test_id 90 | left join invocations on fact_test_results.invocation_id = invocations.invocation_id 91 | left join util_days on fact_test_results.test_detected_date = util_days.date_day 92 | left join tests_result_row on fact_test_results.elementary_test_results_id = tests_result_row.elementary_test_results_id 93 | where (tests_result_row.test_result_row is not null 94 | and rn = 1) 95 | ) 96 | select * 97 | from join_with_dim 98 | -------------------------------------------------------------------------------- /models/marts/fact_elementary_test_result_rows.yml: -------------------------------------------------------------------------------- 1 | version: 2 2 | 3 | models: 4 | - name: fact_elementary_test_result_rows 5 | description: "Fact table of test result IDs and their count." 6 | columns: 7 | - name: 'test_run_result_row_sk' 8 | description: "Surrogate key. Composed of: 'fact_test_results.model_execution_id', 'fact_test_results.elementary_test_results_id', 'dim_tests.test_sk', 'invocations.invocation_sk', and 'tests_result_row.test_result_row'." 9 | tests: 10 | - unique 11 | - not_null 12 | 13 | - name: 'test_fk' 14 | description: "Foreign key. Composed of: test_sk." 15 | tests: 16 | - relationships: 17 | to: ref('dim_elementary_tests') 18 | field: test_sk 19 | 20 | - name: 'invocation_fk' 21 | description: "Foreign key. Composed of: invocation_sk." 22 | tests: 23 | - relationships: 24 | to: ref('fact_elementary_invocations') 25 | field: invocation_sk 26 | 27 | - name: 'elementary_test_results_id' 28 | description: "Column with the ID of the test result." 29 | 30 | - name: 'model_execution_id' 31 | description: "Column with the ID of the model test execution." 32 | 33 | - name: 'test_result_row' 34 | description: "Column that identifies the number of tests executed." -------------------------------------------------------------------------------- /models/marts/fact_elementary_test_run_results.sql: -------------------------------------------------------------------------------- 1 | with 2 | util_days as ( 3 | select cast(date_day as date) as date_day 4 | from {{ ref('dbt_elementary_utils_day') }} 5 | ) 6 | , invocations as ( 7 | select distinct 8 | invocation_sk 9 | , invocation_id 10 | from {{ ref('fact_elementary_invocations') }} 11 | ) 12 | , dim_tests as ( 13 | select distinct 14 | test_sk 15 | , test_id 16 | from {{ ref('dim_elementary_tests') }} 17 | ) 18 | , run_results as ( 19 | select 20 | model_execution_id 21 | , run_result_id 22 | , invocation_id 23 | , invocation_generated_at 24 | , invocation_status 25 | , resource_type 26 | , execution_time 27 | , run_date 28 | , run_started_at 29 | , run_completed_at 30 | , compile_started_at 31 | , compile_completed_at 32 | , rows_affected 33 | , is_full_refresh 34 | , failures 35 | from {{ ref('stg_elementary_dbt_run_results') }} 36 | ) 37 | , elementary_test_results as ( 38 | select 39 | elementary_test_results_id 40 | , test_id 41 | , invocation_id 42 | , test_detected_date 43 | , test_type 44 | , test_status 45 | , test_failures 46 | from {{ ref('stg_elementary_elementary_test_results') }} 47 | ) 48 | , fact_test_results as ( 49 | select 50 | elementary_test_results.elementary_test_results_id 51 | , elementary_test_results.test_id 52 | , run_results.run_result_id 53 | , elementary_test_results.invocation_id as invocation_id 54 | , elementary_test_results.test_detected_date 55 | , elementary_test_results.test_type 56 | , elementary_test_results.test_status 57 | , elementary_test_results.test_failures 58 | , run_results.model_execution_id 59 | , run_results.invocation_generated_at 60 | , run_results.invocation_status 61 | , run_results.resource_type 62 | , run_results.execution_time 63 | , run_results.run_date 64 | , run_results.run_started_at 65 | , run_results.run_completed_at 66 | , run_results.compile_started_at 67 | , run_results.compile_completed_at 68 | , run_results.rows_affected 69 | , run_results.is_full_refresh 70 | , run_results.failures 71 | from run_results 72 | left join elementary_test_results 73 | on run_results.invocation_id = elementary_test_results.invocation_id 74 | and run_results.run_result_id = elementary_test_results.test_id 75 | where elementary_test_results.test_type is not null 76 | ) 77 | , join_with_dim as ( 78 | select 79 | {{ dbt_utils.generate_surrogate_key([ 80 | 'fact_test_results.model_execution_id' 81 | , 'fact_test_results.elementary_test_results_id' 82 | , 'dim_tests.test_sk' 83 | , 'invocations.invocation_sk' 84 | ]) }} as test_run_result_sk 85 | , fact_test_results.elementary_test_results_id 86 | , fact_test_results.model_execution_id 87 | , dim_tests.test_sk as test_fk 88 | , invocations.invocation_sk as invocation_fk 89 | , util_days.date_day as test_detected_date 90 | , fact_test_results.test_type 91 | , fact_test_results.test_status 92 | , fact_test_results.run_started_at 93 | , fact_test_results.run_completed_at 94 | , fact_test_results.execution_time 95 | , fact_test_results.test_failures 96 | from fact_test_results 97 | left join dim_tests on fact_test_results.test_id = dim_tests.test_id 98 | left join invocations on fact_test_results.invocation_id = invocations.invocation_id 99 | left join util_days on fact_test_results.test_detected_date = util_days.date_day 100 | ) 101 | select * 102 | from join_with_dim -------------------------------------------------------------------------------- /models/marts/fact_elementary_test_run_results.yml: -------------------------------------------------------------------------------- 1 | version: 2 2 | 3 | models: 4 | - name: fact_elementary_test_run_results 5 | description: "Fact table for models test run results. Provides information about the status and number of test failures based on time and test type." 6 | columns: 7 | - name: 'test_run_result_sk' 8 | description: "Surrogate key. Composed of: fact_test_results.model_execution_id, fact_test_results.elementary_test_results_id, 'dim_tests.test_sk, and invocations.invocation_sk" 9 | tests: 10 | - unique 11 | - not_null 12 | 13 | - name: 'test_fk' 14 | description: "Foreign key. Composed of: test_sk." 15 | tests: 16 | - relationships: 17 | to: ref('dim_elementary_tests') 18 | field: test_sk 19 | 20 | - name: 'invocation_fk' 21 | description: "Foreign key. Composed of: invocation_sk." 22 | tests: 23 | - relationships: 24 | to: ref('fact_elementary_invocations') 25 | field: invocation_sk 26 | 27 | - name: 'elementary_test_results_id' 28 | description: "Column with the ID of the test result." 29 | 30 | - name: 'model_execution_id' 31 | description: "Column with the ID of the model test execution." 32 | 33 | - name: 'test_detected_date' 34 | description: "Column with the timestamp of test detection." 35 | tests: 36 | - relationships: 37 | to: ref('dbt_elementary_utils_day') 38 | field: date_day 39 | 40 | - name: 'test_type' 41 | description: "Column that segments the type of test: native or within elementary." 42 | 43 | - name: 'test_status' 44 | description: "Column with the status of the test performed." 45 | 46 | - name: 'run_started_at' 47 | description: "Column with the timestamp of test execution start." 48 | 49 | - name: 'run_completed_at' 50 | description: "Column with the timestamp of test execution end." 51 | 52 | - name: 'execution_time' 53 | description: "Column with the execution time taken to run the tests." 54 | 55 | - name: 'test_failures' 56 | description: "Column that counts the failures in test execution." -------------------------------------------------------------------------------- /models/staging/dbt_elementary_utils_day.sql: -------------------------------------------------------------------------------- 1 | {% set my_query %} 2 | select cast({{dbt.current_timestamp()}} as date) 3 | {% endset %} 4 | 5 | {% if execute %} 6 | {% set today = run_query(my_query).columns[0].values()[0] %} 7 | {% set tomorrow = dbt.dateadd("day", 1, "'" ~ today ~ "'") %} 8 | {% set start_date = var('elementary_dbt_monitoring')['dbt_monitoring_start_date'] %} 9 | {% else %} 10 | {% set tomorrow = ' ' %} 11 | {% set start_date = ' ' %} 12 | {% endif %} 13 | 14 | {{ dbt_utils.date_spine( 15 | datepart="day", 16 | start_date=start_date, 17 | end_date=tomorrow 18 | ) 19 | }} -------------------------------------------------------------------------------- /models/staging/sources.yml: -------------------------------------------------------------------------------- 1 | version: 2 2 | 3 | sources: 4 | - name: raw_dbt_monitoring 5 | description: "Raw data extracted from the models generated by the elementary package." 6 | schema: "{{ var('elementary_source_schema') }}" 7 | freshness: 8 | warn_after: {count: 1, period: day} 9 | error_after: {count: 2, period: day} 10 | loaded_at_field: cast(ind_extraction_date as timestamp) 11 | 12 | tables: 13 | - name: "elementary_test_results" 14 | description: "Incremental model that brings the results of each dbt test. Each row is the result of a specific test and can be native dbt tests, package tests, and elementary tests." 15 | columns: 16 | - name: id 17 | description: "Table unique identifier." 18 | tests: 19 | - unique 20 | - not_null 21 | 22 | - name: "dbt_sources" 23 | description: "Table with metadata about the sources configured in the project and in the project packages, containing the properties of these sources." 24 | columns: 25 | - name: unique_id 26 | description: "Table unique identifier." 27 | tests: 28 | - unique 29 | - not_null 30 | 31 | - name: "dbt_models" 32 | description: "Table that brings information about all models belonging to the project." 33 | columns: 34 | - name: unique_id 35 | description: "Table unique identifier." 36 | tests: 37 | - unique 38 | - not_null 39 | 40 | - name: "dbt_run_results" 41 | description: "Incremental model that shows the results of each dbt run and dbt test for each project model." 42 | columns: 43 | - name: model_execution_id 44 | description: "Table unique identifier." 45 | tests: 46 | - unique 47 | - not_null 48 | 49 | - name: "dbt_invocations" 50 | description: "Table that brings information about each job (dbt run, dbt test, and dbt build)." 51 | columns: 52 | - name: invocation_id 53 | description: "Table unique identifier." 54 | tests: 55 | - unique 56 | - not_null 57 | 58 | - name: "dbt_source_freshness_results" 59 | description: "Model that brings information about each update/change in the sources." 60 | columns: 61 | - name: unique_id 62 | description: "Table unique identifier." 63 | tests: 64 | - unique 65 | - not_null 66 | - name: source_freshness_execution_id 67 | description: "Model execution identifier, which is also unique." 68 | tests: 69 | - unique 70 | - not_null 71 | 72 | - name: "dbt_tests" 73 | description: "Table that brings information about each test." 74 | columns: 75 | - name: unique_id 76 | description: "Table unique identifier." 77 | tests: 78 | - unique 79 | - not_null 80 | 81 | - name: dbt_utils_day 82 | description: "Table that contains data of the dates created from the dbt_utils macro." 83 | 84 | - name: "test_result_rows" 85 | description: "Table with ID of the test results and the test count." -------------------------------------------------------------------------------- /models/staging/stg_elementary_dbt_invocations.sql: -------------------------------------------------------------------------------- 1 | with 2 | renamed as ( 3 | select distinct 4 | invocation_id 5 | , job_id 6 | , job_name 7 | , job_run_id 8 | , cast(run_started_at as timestamp) as run_started_at 9 | , cast(run_completed_at as timestamp) as run_completed_at 10 | , cast(generated_at as timestamp) as generated_at 11 | , case 12 | when command = 'test' then 'dbt test' 13 | when command = 'run' then 'dbt run' 14 | when command = 'build' then 'dbt build' 15 | end as dbt_invocation_command 16 | , dbt_version 17 | , elementary_version 18 | , full_refresh as is_full_refresh 19 | , invocation_vars 20 | , vars 21 | , target_name 22 | , target_database 23 | , target_schema 24 | , target_profile_name 25 | , threads 26 | , selected as models_ran 27 | , yaml_selector 28 | , project_id 29 | , project_name 30 | from {{ source('raw_dbt_monitoring', 'dbt_invocations') }} 31 | ) 32 | 33 | , dbt_dateadd as ( 34 | select distinct 35 | invocation_id 36 | , job_id 37 | , job_name 38 | , job_run_id 39 | , run_started_at as invocation_started_at 40 | , run_completed_at as invocation_completed_at 41 | , cast(run_started_at as date) as invocation_date 42 | , generated_at as invocation_generated_at 43 | , dbt_invocation_command 44 | , dbt_version 45 | , elementary_version 46 | , is_full_refresh 47 | , invocation_vars 48 | , vars 49 | , target_name 50 | , target_database 51 | , target_schema 52 | , target_profile_name 53 | , threads 54 | , models_ran 55 | , yaml_selector 56 | , project_id 57 | , project_name 58 | from renamed 59 | ) 60 | 61 | select * 62 | from dbt_dateadd -------------------------------------------------------------------------------- /models/staging/stg_elementary_dbt_models.sql: -------------------------------------------------------------------------------- 1 | with 2 | renamed as ( 3 | select 4 | unique_id as model_id 5 | , checksum 6 | , materialization 7 | , tags as model_tags 8 | , database_name as project_database_name 9 | , schema_name 10 | , depends_on_macros as model_depends_on_macros 11 | , depends_on_nodes as model_depends_on_nodes 12 | , description as model_description 13 | , path as dbt_model_path 14 | , name as model_name 15 | , case 16 | when name like '%fact_%' then 'Fact' 17 | when name like '%dim_%' then 'Dim' 18 | when name like '%stg_%' then 'Stg' 19 | when name like '%agg_%' then 'Agg' 20 | when name like '%bridge_%' then 'Bridge' 21 | when path like '%edr/%' then 'Elementary' 22 | else 'Other' 23 | end as table_type_mod 24 | , package_name 25 | , original_path 26 | , cast(generated_at as timestamp) as generated_at 27 | , metadata_hash 28 | from {{ source('raw_dbt_monitoring', 'dbt_models') }} 29 | qualify row_number() over( 30 | partition by model_id 31 | order by generated_at desc 32 | ) = 1 33 | ) 34 | 35 | , dbt_dateadd as ( 36 | select 37 | model_id 38 | , checksum 39 | , materialization 40 | , model_tags 41 | , project_database_name 42 | , schema_name 43 | , model_depends_on_macros 44 | , model_depends_on_nodes 45 | , model_description 46 | , dbt_model_path 47 | , model_name 48 | , table_type_mod 49 | , package_name 50 | , original_path 51 | , generated_at as model_generated_at 52 | , metadata_hash 53 | from renamed 54 | ) 55 | 56 | select * 57 | from dbt_dateadd -------------------------------------------------------------------------------- /models/staging/stg_elementary_dbt_run_results.sql: -------------------------------------------------------------------------------- 1 | with 2 | renamed as ( 3 | select 4 | model_execution_id 5 | , unique_id as run_result_id 6 | , invocation_id 7 | , cast(generated_at as timestamp) as generated_at 8 | , name as run_result_name 9 | , message as sql_statement 10 | , status as invocation_status 11 | , resource_type 12 | , execution_time 13 | , cast(execute_started_at as timestamp) as execute_started_at 14 | , cast(execute_completed_at as timestamp) as execute_completed_at 15 | , cast(compile_started_at as timestamp) as compile_started_at 16 | , cast(compile_completed_at as timestamp) as compile_completed_at 17 | , coalesce(rows_affected, 0) as rows_affected 18 | , query_id 19 | , full_refresh as is_full_refresh 20 | , compiled_code 21 | , coalesce(cast(failures as integer), 0) as failures 22 | , thread_id 23 | from {{ source('raw_dbt_monitoring', 'dbt_run_results') }} 24 | ) 25 | 26 | , dbt_dateadd as ( 27 | select 28 | model_execution_id 29 | , run_result_id 30 | , invocation_id 31 | , generated_at as invocation_generated_at 32 | , run_result_name 33 | , sql_statement 34 | , invocation_status 35 | , resource_type 36 | , execution_time 37 | , cast(generated_at as date) as run_date 38 | , execute_started_at as run_started_at 39 | , execute_completed_at as run_completed_at 40 | , compile_started_at as compile_started_at 41 | , compile_completed_at as compile_completed_at 42 | , rows_affected 43 | , query_id 44 | , is_full_refresh 45 | , compiled_code 46 | , failures 47 | , thread_id 48 | from renamed 49 | ) 50 | 51 | select * 52 | from dbt_dateadd -------------------------------------------------------------------------------- /models/staging/stg_elementary_dbt_source_freshness_results.sql: -------------------------------------------------------------------------------- 1 | with 2 | renamed as ( 3 | select 4 | source_freshness_execution_id 5 | , unique_id as source_freshness_id 6 | , cast(max_loaded_at as timestamp) as max_loaded_at 7 | , cast(snapshotted_at as timestamp) as snapshotted_at 8 | , cast(generated_at as timestamp) as generated_at 9 | , cast(generated_at as date) as source_generate_date 10 | , max_loaded_at_time_ago_in_s as source_max_loaded_at_seconds 11 | , status as source_status 12 | , upper(error) as source_error 13 | , cast(compile_started_at as timestamp) as compile_started_at 14 | , cast(compile_completed_at as timestamp) as compile_completed_at 15 | , cast(execute_started_at as timestamp) as execute_started_at 16 | , cast(execute_completed_at as timestamp) as execute_completed_at 17 | , invocation_id 18 | from {{ source('raw_dbt_monitoring', 'dbt_source_freshness_results') }} 19 | ) 20 | 21 | , dbt_dateadd as ( 22 | select 23 | source_freshness_execution_id 24 | , source_freshness_id 25 | , max_loaded_at as source_max_loaded_at 26 | , snapshotted_at as source_snapshotted_at 27 | , generated_at as source_freshness_generated_at 28 | , source_generate_date 29 | , source_max_loaded_at_seconds 30 | , source_status 31 | , source_error 32 | , compile_started_at as source_compile_started_at 33 | , compile_completed_at as source_compile_completed_at 34 | , execute_started_at as source_execute_started_at 35 | , execute_completed_at as source_execute_completed_at 36 | , invocation_id 37 | from renamed 38 | ) 39 | 40 | select * 41 | from dbt_dateadd -------------------------------------------------------------------------------- /models/staging/stg_elementary_dbt_sources.sql: -------------------------------------------------------------------------------- 1 | with 2 | renamed as ( 3 | select 4 | unique_id as source_id 5 | , database_name as project_database_name 6 | , schema_name 7 | , source_name 8 | , name as table_name 9 | , loaded_at_field 10 | , freshness_warn_after 11 | , freshness_error_after 12 | , relation_name 13 | , tags as source_tags 14 | , package_name 15 | , path as dbt_source_path 16 | , source_description 17 | , description as source_table_description 18 | , cast(generated_at as timestamp) generated_at 19 | , metadata_hash 20 | from {{ source('raw_dbt_monitoring', 'dbt_sources') }} 21 | qualify row_number() over( 22 | partition by source_id 23 | order by generated_at desc 24 | ) = 1 25 | ) 26 | 27 | , dbt_dateadd as ( 28 | select 29 | source_id 30 | , project_database_name 31 | , schema_name 32 | , source_name 33 | , table_name 34 | , loaded_at_field 35 | , freshness_warn_after 36 | , freshness_error_after 37 | , relation_name 38 | , source_tags 39 | , package_name 40 | , dbt_source_path 41 | , source_description 42 | , source_table_description 43 | , generated_at as source_generated_at 44 | , metadata_hash 45 | from renamed 46 | ) 47 | 48 | select * 49 | from dbt_dateadd -------------------------------------------------------------------------------- /models/staging/stg_elementary_dbt_tests.sql: -------------------------------------------------------------------------------- 1 | with 2 | source as ( 3 | select 4 | unique_id as test_id 5 | , database_name as project_database_name 6 | , schema_name 7 | , name as test_name 8 | , type as test_type 9 | , short_name as test_short_name 10 | , case 11 | when type = 'singular' then 'singular' 12 | when type = 'generic' and short_name = 'not_null' then 'not_null' 13 | when type = 'generic' and short_name = 'unique' then 'unique' 14 | when type = 'generic' and short_name = 'relationships' then 'relationships' 15 | when type = 'generic' and short_name = 'accepted_values' then 'accepted_values' 16 | else 'other' 17 | end as test_type_mod 18 | , alias 19 | , test_column_name 20 | , upper(severity) as test_severity 21 | , warn_if as test_warn_if 22 | , error_if as test_error_if 23 | , test_params as test_parameters 24 | , tags as test_tags 25 | , model_tags 26 | , meta as test_metadata 27 | , depends_on_macros as test_depends_on_macros 28 | , depends_on_nodes as test_depends_on_nodes 29 | , parent_model_unique_id 30 | , description as test_description 31 | , package_name 32 | , original_path 33 | , path as dbt_test_path 34 | , cast(generated_at as timestamp) as test_generated_at 35 | , metadata_hash 36 | from {{ source('raw_dbt_monitoring', 'dbt_tests') }} 37 | qualify row_number() over( 38 | partition by test_id 39 | order by test_generated_at desc 40 | ) = 1 41 | ) 42 | 43 | select * 44 | from source -------------------------------------------------------------------------------- /models/staging/stg_elementary_elementary_test_results.sql: -------------------------------------------------------------------------------- 1 | with 2 | renamed as ( 3 | select 4 | id as elementary_test_results_id 5 | , cast(data_issue_id as date) as data_issue_id 6 | , test_execution_id 7 | , test_unique_id as test_id 8 | , model_unique_id as model_id 9 | , invocation_id 10 | , detected_at as test_detected_at 11 | , cast(detected_at as date) as test_detected_date 12 | , database_name as project_database_name 13 | , schema_name 14 | , table_name 15 | , column_name 16 | , test_type 17 | , test_sub_type 18 | , test_results_description 19 | , tags as invocation_tags 20 | , test_results_query 21 | , test_name 22 | , test_params as test_parameters 23 | , upper(severity) as severity 24 | , status as test_status 25 | , cast(failures as integer) as test_failures 26 | , test_short_name 27 | , test_alias 28 | , result_rows 29 | from {{ source('raw_dbt_monitoring', 'elementary_test_results') }} 30 | ) 31 | 32 | select * 33 | from renamed -------------------------------------------------------------------------------- /models/staging/stg_elementary_test_result_rows.sql: -------------------------------------------------------------------------------- 1 | with 2 | renamed as ( 3 | select 4 | elementary_test_results_id 5 | , result_row as test_result_row 6 | , detected_at as test_detected_at 7 | , cast(detected_at as date) as test_detected_date 8 | from {{ source('raw_dbt_monitoring', 'test_result_rows') }} 9 | ) 10 | 11 | select * 12 | from renamed 13 | -------------------------------------------------------------------------------- /packages.yml: -------------------------------------------------------------------------------- 1 | packages: 2 | - package: dbt-labs/dbt_utils 3 | version: [">=0.9.0", "<1.2.0"] --------------------------------------------------------------------------------