├── .gitignore ├── README.md ├── analyses └── .gitkeep ├── data └── .gitkeep ├── dbt_project.yml ├── macros └── .gitkeep ├── models └── sources │ └── snowflake │ ├── base │ ├── bse_snowflake_access_history.sql │ └── bse_snowflake_access_history.yml │ ├── snowflake_sources.yml │ └── staging │ ├── stg_snowflake_queries.sql │ ├── stg_snowflake_queries.yml │ ├── stg_snowflake_query_table_columns.sql │ ├── stg_snowflake_query_table_columns.yml │ ├── stg_snowflake_query_tables.sql │ ├── stg_snowflake_query_tables.yml │ ├── stg_snowflake_table_columns.sql │ ├── stg_snowflake_table_columns.yml │ ├── stg_snowflake_tables.sql │ └── stg_snowflake_tables.yml ├── snapshots └── .gitkeep └── tests ├── .gitkeep └── generic ├── not_null_recently.sql ├── unique_not_null_recently.sql └── unique_recently.sql /.gitignore: -------------------------------------------------------------------------------- 1 | 2 | target/ 3 | dbt_packages/ 4 | logs/ 5 | .DS_Store 6 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | ## Snowflake Usage Data 2 | 3 | This repo provides a handful of models operating over Snowflake's [Query History](https://docs.snowflake.com/en/sql-reference/functions/query_history.html), [Access History](https://docs.snowflake.com/en/sql-reference/account-usage/access_history.html) views (available to Enterprise accounts). These views provide detailed query-granular usage data about your Snowflake instance. 4 | 5 | The `query_history` view provides query timing and context details, while `access_history` provides JSON blobs of each query's accessed `tables` (or views)* and the specific columns referenced from those tables. The set of queries includes DDL and DML commands; there are over 30 `query_type` values. 6 | 7 | This partial dbt repo produces a staging layer of models at and around the query grain, derived from the schema `snowflake.account_usage`. 8 | 9 | * `stg_snowflake_queries` 10 | * `stg_snowflake_query_tables` 11 | * `stg_snowflake_query_table_columns` 12 | * `stg_snowflake_tables` (includes views) 13 | * `stg_snowflake_table_columns` 14 | 15 | ## Setup Steps 16 | 17 | 1. Copy-paste the contents of `/models/sources/snowflake/*` into a similar directory in your own Snowflake-based dbt project. Also grab the three generic tests from `/tests/generic/*.sql`. 18 | 2. In each model, uncomment and complete `database` and `schema` name filter lists (or delete them). The query dataset can be large, and some of the databases and schemas in your Snowflake instance may not be of-interest. 19 | 3. In `stg_snowflake_queries` fill-in the definition of `is_tooling_user`, or substitute your own means of filtering out noisy automated queries, like those run by Data Observability or Cataloging tools. 20 | 21 | ## Column-level Lineage 22 | 23 | In theory, these models can be used to derive column-level lineage within a dbt project. By filtering to DDL/DML commands issued by dbt users toward production schemas and further unpacking the `access_history.objects_modified` array, one could determine the tables and columns relevant to building each model. 24 | 25 | However, the accessed column arrays are a reflection of query text rather than interpretted references. This means that any `select * from my_table` will be tracked as actually referencing all column.s The popular "import-style CTEs" will interfere with this insight. 26 | 27 | [Here's a post in dbt Slack on the issue.](https://getdbt.slack.com/archives/C2JRRQDTL/p1658242587243599) 28 | 29 | ## Notes, Disclaimers, Considerations 30 | 31 | This code has been minimally run/tested. 32 | 33 | The `access_history` view can contain a small number of duplicate rows. These are tolerated, as de-duping can be prohibitively expensive during a full-refresh. 34 | 35 | The `query_history` and access_history` have a truncated lookback of 365 days. If data beyond that range seems valuable, it may be worth maintaining an incremental base model with full refresh disabled and a simple selection of the native columns. 36 | 37 | Querying the `information_schema` for tables and columns provides "real-time" results within a database, but it can be slow. The `snowflake.account_usage` schema has a latency of up to 90 minutes, but tends to be more performant, and includes results across databases. 38 | 39 | #### Footnotes 40 | \* In all cases, usage of the word "tables" includes views. 41 | -------------------------------------------------------------------------------- /analyses/.gitkeep: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/jaysobel/dbt-snowflake-queries/6c9e983c611a691becb6109e750b1a355a974f70/analyses/.gitkeep -------------------------------------------------------------------------------- /data/.gitkeep: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/jaysobel/dbt-snowflake-queries/6c9e983c611a691becb6109e750b1a355a974f70/data/.gitkeep -------------------------------------------------------------------------------- /dbt_project.yml: -------------------------------------------------------------------------------- 1 | 2 | # Name your project! Project names should contain only lowercase characters 3 | # and underscores. A good package name should reflect your organization's 4 | # name or the intended use of these models 5 | name: "dbt_snowflake_queries" 6 | version: "1.0.0" 7 | config-version: 2 8 | 9 | # This setting configures which "profile" dbt uses for this project. 10 | profile: "default" 11 | 12 | # These configurations specify where dbt should look for different types of files. 13 | # The `model-paths` config, for example, states that models in this project can be 14 | # found in the "models/" directory. You probably won't need to change these! 15 | model-paths: ["models"] 16 | analysis-paths: ["analyses"] 17 | test-paths: ["tests"] 18 | seed-paths: ["seeds"] 19 | macro-paths: ["macros"] 20 | snapshot-paths: ["snapshots"] 21 | 22 | target-path: "target" # directory which will store compiled SQL files 23 | clean-targets: # directories to be removed by `dbt clean` 24 | - "target" 25 | - "dbt_packages" 26 | -------------------------------------------------------------------------------- /macros/.gitkeep: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/jaysobel/dbt-snowflake-queries/6c9e983c611a691becb6109e750b1a355a974f70/macros/.gitkeep -------------------------------------------------------------------------------- /models/sources/snowflake/base/bse_snowflake_access_history.sql: -------------------------------------------------------------------------------- 1 | 2 | {{ 3 | config( 4 | materialized = 'incremental' 5 | , unique_key = 'query_id' 6 | ) 7 | }} 8 | 9 | with access_history as ( 10 | 11 | select * from {{ source('snowflake_internal', 'access_history') }} 12 | 13 | ) 14 | 15 | -- Small scale duplication is possible, and may be expensive to de-dupe 16 | , renamed_recasted as ( 17 | 18 | select 19 | query_id::text as query_id 20 | , query_start_time::timestamp_ntz as start_at_utc 21 | , user_name::text as user_name 22 | , direct_objects_accessed::array as direct_objects_accessed 23 | , base_objects_accessed::array as base_objects_accessed 24 | , objects_modified::array as objects_modified 25 | 26 | from access_history 27 | 28 | where true 29 | 30 | {% if is_incremental() %} 31 | and start_at_utc > (select dateadd('day', -1, max(t.start_at_utc)) from {{ this }} t) 32 | {% endif %} 33 | 34 | {% if target.name == 'dev' or target.name == 'ci' %} 35 | and start_at_utc >= dateadd('day', -28, current_timestamp) 36 | {% endif %} 37 | 38 | ) 39 | 40 | select * from renamed_recasted 41 | -------------------------------------------------------------------------------- /models/sources/snowflake/base/bse_snowflake_access_history.yml: -------------------------------------------------------------------------------- 1 | version: 2 2 | 3 | models: 4 | - name: bse_snowflake_access_history 5 | description: | 6 | Snowflake documentation [here](https://docs.snowflake.com/en/user-guide/access-history.html#querying-the-access-history-view) 7 | columns: 8 | - name: query_id 9 | description: | 10 | Primary key identifier for a Snowflake query. 11 | tests: 12 | - unique_not_null_recently: 13 | time_column: start_at_utc 14 | lookback_days: 7 15 | config: 16 | warn_if: ">100" 17 | 18 | - name: start_at_utc 19 | description: | 20 | When the query started in UTC time. 21 | 22 | - name: user_name 23 | description: | 24 | The name of the Snowflake user who started the query 25 | 26 | - name: direct_objects_accessed 27 | description: | 28 | A JSON array of objects each either representing a table or view with a further array of columns accessed (either 29 | directly or with a wildcard). 30 | 31 | - name: base_objects_accessed 32 | description: | 33 | Similar to direct_objects_accessed but with treating views as pass-throughs. 34 | 35 | - name: objects_modified 36 | description: | 37 | Similar to direct_objects_accessed, but representing modified tables or views for DDL or DML queries. 38 | -------------------------------------------------------------------------------- /models/sources/snowflake/snowflake_sources.yml: -------------------------------------------------------------------------------- 1 | version: 2 2 | 3 | sources: 4 | - name: snowflake_internal 5 | database: snowflake 6 | schema: account_usage 7 | 8 | tables: 9 | - name: access_history 10 | description: "https://docs.snowflake.com/en/user-guide/access-history.html" 11 | 12 | - name: query_history 13 | description: "https://docs.snowflake.com/en/sql-reference/account-usage/query_history.html" 14 | 15 | - name: tables 16 | description: "https://docs.snowflake.com/en/sql-reference/account-usage/tables.html" 17 | 18 | - name: columns 19 | description: https://docs.snowflake.com/en/sql-reference/account-usage/columns.html 20 | -------------------------------------------------------------------------------- /models/sources/snowflake/staging/stg_snowflake_queries.sql: -------------------------------------------------------------------------------- 1 | 2 | {{ 3 | config( 4 | materialized = 'incremental' 5 | , unique_key = 'query_id' 6 | ) 7 | }} 8 | 9 | with queries as ( 10 | 11 | select * from {{ source('snowflake_internal', 'query_history') }} 12 | 13 | ) 14 | 15 | , renamed_recasted as ( 16 | 17 | select 18 | query_id 19 | , lower(query_text) as query_text 20 | -- database_ and schema_ are nullable, and the relationship to query is complex. 21 | -- , database_id 22 | -- , lower(database_name) as database_name 23 | -- , schema_id 24 | -- , lower(schema_name) as schema_name 25 | , lower(query_type) as query_type 26 | , session_id 27 | , lower(user_name) as user_name 28 | -- queries by tooling user accounts are a popular filter for 'usage' analyses, ex; DBT_USER 29 | , user_name in ('') as is_tooling_user 30 | , lower(role_name) as role_name 31 | , warehouse_id 32 | , lower(warehouse_name) as warehouse_name 33 | , lower(warehouse_size) as warehouse_size 34 | , lower(warehouse_type) as warehouse_type 35 | , cluster_number 36 | , query_tag 37 | , lower(execution_status) as execution_status 38 | , error_code 39 | , error_message 40 | , start_time as start_at_utc 41 | , end_time as end_at_utc 42 | , total_elapsed_time / 1000 as duration_seconds 43 | , compilation_time / 1000 as compilation_seconds 44 | , execution_time / 1000 as execution_seconds 45 | , queued_provisioning_time / 1000 as queued_provisioning_seconds 46 | , queued_repair_time / 1000 as queued_repair_seconds 47 | , queued_overload_time / 1000 as queued_overload_seconds 48 | , transaction_blocked_time / 1000 as transaction_blocked_seconds 49 | -- many niche fields are excluded 50 | 51 | from queries 52 | 53 | where true 54 | 55 | -- and database_name in ('') -- Databases of interest, uppercase, ex: PROD 56 | 57 | {% if is_incremental() %} 58 | and start_at_utc > (select dateadd('day', -1, max(t.start_at_utc)) from {{ this }} t) 59 | {% endif %} 60 | 61 | ) 62 | 63 | select * from renamed_recasted 64 | -------------------------------------------------------------------------------- /models/sources/snowflake/staging/stg_snowflake_queries.yml: -------------------------------------------------------------------------------- 1 | version: 2 2 | 3 | models: 4 | - name: stg_snowflake_queries 5 | description: | 6 | Snowflake query history. Reference provided by Snowflake. 7 | https://docs.snowflake.com/en/sql-reference/account-usage/query_history.html 8 | columns: 9 | - name: query_id 10 | description: | 11 | Primary key identifier for a Snowflake query. 12 | tests: 13 | - unique_not_null_recently: 14 | time_column: start_at_utc 15 | lookback_days: 7 16 | 17 | - name: query_type 18 | description: | 19 | The type of query, like 'select'. There are a wide variety (30+) of query types. 20 | -------------------------------------------------------------------------------- /models/sources/snowflake/staging/stg_snowflake_query_table_columns.sql: -------------------------------------------------------------------------------- 1 | 2 | {{ 3 | config( 4 | materialized = 'incremental' 5 | , unique_key = 'query_table_id' 6 | ) 7 | }} 8 | 9 | with snowflake_access_history as ( 10 | 11 | select * from {{ ref('bse_snowflake_access_history') }} 12 | 13 | ) 14 | 15 | , renamed_recasted as ( 16 | 17 | -- a query can reference the same table and-or columns multiple times 18 | select distinct 19 | queries.query_id 20 | , queries.start_at_utc 21 | , lower(queries.user_name) as user_name 22 | , lower(split_part(tables.value:objectName::text, '.', 1)) as database_name 23 | , lower(split_part(tables.value:objectName::text, '.', 2)) as schema_name 24 | , lower(split_part(tables.value:objectName::text, '.', 3)) as table_name 25 | , lower(table_columns.value:columnName) as column_name 26 | 27 | from snowflake_access_history as queries 28 | , lateral flatten(queries.direct_objects_accessed) as tables 29 | , lateral flatten(tables.value:columns) as table_columns 30 | 31 | where true 32 | -- and database_name in ('') -- Databases of interest, uppercase, ex: PROD 33 | 34 | {% if is_incremental() %} 35 | and queries.start_at_utc > (select dateadd('day', -1, max(t.start_at_utc)) from {{ this }} t) 36 | {% endif %} 37 | 38 | ) 39 | 40 | , keyed as ( 41 | 42 | select 43 | * 44 | , md5( 45 | concat( 46 | query_id 47 | , '-', database_name 48 | , '.', schema_name 49 | , '.', table_name 50 | , '.', column_name 51 | ) 52 | ) as query_table_column_key 53 | , md5( 54 | concat( 55 | query_id 56 | , '-', database_name 57 | , '.', schema_name 58 | , '.', table_name 59 | ) 60 | ) as query_table_key 61 | , concat( 62 | database_name 63 | , '.', schema_name 64 | , '.', table_name 65 | , '.', column_name 66 | ) as table_column_key 67 | , concat( 68 | database_name 69 | , '.', schema_name 70 | , '.', table_name 71 | ) as table_key 72 | 73 | from renamed_recasted 74 | 75 | ) 76 | 77 | select * from keyed 78 | -------------------------------------------------------------------------------- /models/sources/snowflake/staging/stg_snowflake_query_table_columns.yml: -------------------------------------------------------------------------------- 1 | version: 2 2 | 3 | models: 4 | - name: stg_snowflake_query_table_columns 5 | description: | 6 | Snowflake queries' uniquely accessed table and view columns. A row of this table represents a reference 7 | to a table or view's column by a Snowflake query. Further explained by Snowflake's documentation. 8 | It is necessary to re-flatten the direct_objects_accessed blob because the usage of distinct in 9 | stg_snowflake_query_tables may have destroyed different sets of columns across query-table duplicates. 10 | https://docs.snowflake.com/en/sql-reference/account-usage/access_history.html#label-acctuse-view-access-history-columns 11 | columns: 12 | - name: query_table_column_key 13 | description: | 14 | Unique surrogate key combining the query_id and unique accessed table or view's database.schema.table.column reference. 15 | tests: 16 | - unique_not_null_recently: 17 | time_column: start_at_utc 18 | lookback_days: 7 19 | 20 | - name: query_table_key 21 | description: | 22 | Foreign key combining the query_id and unique accessed table or view's database.schema.table. 23 | tests: 24 | - not_null_recently: 25 | time_column: start_at_utc 26 | lookback_days: 7 27 | 28 | - name: query_id 29 | description: | 30 | Foreign key identifier of a Snowflake query. 31 | tests: 32 | - not_null_recently: 33 | time_column: start_at_utc 34 | lookback_days: 7 35 | 36 | - name: table_key 37 | description: | 38 | Foreign key identifier of a table or view's database.schema.table. 39 | tests: 40 | - not_null_recently: 41 | time_column: start_at_utc 42 | lookback_days: 7 43 | 44 | - name: table_column_key 45 | description: | 46 | Foreign key identifier of a table or view's database.schema.table.column reference. 47 | tests: 48 | - not_null_recently: 49 | time_column: start_at_utc 50 | lookback_days: 7 51 | -------------------------------------------------------------------------------- /models/sources/snowflake/staging/stg_snowflake_query_tables.sql: -------------------------------------------------------------------------------- 1 | 2 | {{ 3 | config( 4 | materialized = 'incremental' 5 | , unique_key = 'query_table_id' 6 | ) 7 | }} 8 | 9 | with snowflake_access_history as ( 10 | 11 | select * from {{ ref('bse_snowflake_access_history') }} 12 | 13 | ) 14 | 15 | , renamed_recasted as ( 16 | 17 | -- a query can reference the same object multiple times 18 | select distinct 19 | snowflake_access_history.query_id 20 | , snowflake_access_history.start_at_utc 21 | , lower(snowflake_access_history.user_name) as user_name 22 | , lower(split_part(objects_accessed.value:objectName::text, '.', 1)) as database_name 23 | , lower(split_part(objects_accessed.value:objectName::text, '.', 2)) as schema_name 24 | , lower(split_part(objects_accessed.value:objectName::text, '.', 3)) as table_name 25 | , objects_accessed.value:columns as columns_array 26 | 27 | from snowflake_access_history 28 | , lateral flatten(snowflake_access_history.direct_objects_accessed) as objects_accessed 29 | 30 | where true 31 | 32 | -- and database_name in ('') -- Databases of interest, uppercase, ex: PROD 33 | 34 | {% if is_incremental() %} 35 | and snowflake_access_history.start_at_utc > (select dateadd('day', -1, max(t.start_at_utc)) from {{ this }} t) 36 | {% endif %} 37 | 38 | ) 39 | 40 | , keyed as ( 41 | 42 | select 43 | * 44 | , md5( 45 | concat( 46 | query_id 47 | , '-', database_name 48 | , '.', schema_name 49 | , '.', table_name 50 | ) 51 | ) as query_table_key 52 | , concat( 53 | database_name 54 | , '.', schema_name 55 | , '.', table_name 56 | ) as table_key 57 | 58 | from renamed_recasted 59 | 60 | ) 61 | 62 | select * from keyed 63 | -------------------------------------------------------------------------------- /models/sources/snowflake/staging/stg_snowflake_query_tables.yml: -------------------------------------------------------------------------------- 1 | version: 2 2 | 3 | models: 4 | - name: stg_snowflake_query_tables 5 | description: | 6 | Snowflake queries' uniquely accessed objects (tables and views). A row of this table represents a reference 7 | to a table or view by a Snowflake query. Further explained by Snowflake's documentation. 8 | https://docs.snowflake.com/en/sql-reference/account-usage/access_history.html#label-acctuse-view-access-history-columns 9 | columns: 10 | - name: query_table_key 11 | description: | 12 | Unique surrogate key identifying the query_id and unique accessed table or view's database.schema.table reference. 13 | tests: 14 | - unique_not_null_recently: 15 | time_column: start_at_utc 16 | lookback_days: 7 17 | 18 | - name: query_id 19 | description: | 20 | Foreign key identifier of a the Snowflake query. 21 | tests: 22 | - not_null_recently: 23 | time_column: start_at_utc 24 | lookback_days: 7 25 | 26 | - name: table_key 27 | description: | 28 | Foreign key identifier of a table or view's database.schema.table reference. 29 | tests: 30 | - not_null_recently: 31 | time_column: start_at_utc 32 | lookback_days: 7 33 | -------------------------------------------------------------------------------- /models/sources/snowflake/staging/stg_snowflake_table_columns.sql: -------------------------------------------------------------------------------- 1 | 2 | {{ 3 | config( 4 | materialized = 'table' 5 | ) 6 | }} 7 | 8 | with columns as ( 9 | 10 | select * from {{ source('snowflake_internal', 'columns') }} 11 | 12 | ) 13 | 14 | , renamed_recasted as ( 15 | 16 | select 17 | lower(column_name) as column_name 18 | , lower(table_name) as table_name 19 | , lower(table_schema) as schema_name 20 | , lower(table_catalog) as database_name 21 | , ordinal_position 22 | , column_default 23 | , lower(data_type) as data_type 24 | 25 | from columns 26 | 27 | where true 28 | -- and table_catalog in ('') -- Databases of interest, uppercase, ex: PROD 29 | -- and table_schema in ('') -- Schemas of interest (within databases above, uppercase) 30 | and deleted is null -- exclude deleted columns (deleted is a timestamp field) 31 | 32 | ) 33 | 34 | , keyed as ( 35 | 36 | select 37 | * 38 | , concat( 39 | database_name 40 | , '.', schema_name 41 | , '.', table_name 42 | , '.', column_name 43 | ) as table_column_key 44 | , concat( 45 | database_name 46 | , '.', schema_name 47 | , '.', table_name 48 | ) as table_key 49 | 50 | from renamed_recasted 51 | 52 | ) 53 | 54 | select * from keyed 55 | -------------------------------------------------------------------------------- /models/sources/snowflake/staging/stg_snowflake_table_columns.yml: -------------------------------------------------------------------------------- 1 | version: 2 2 | 3 | models: 4 | - name: stg_snowflake_table_columns 5 | description: > 6 | Materialization of Snowflake's information_schema.columns. Actually accessed via 7 | the account_usage views which carry up to 90 minutes of latency. 8 | columns: 9 | - name: table_column_key 10 | description: Unique surrogate key identifying the database.schema.table.column reference. 11 | tests: 12 | - unique_not_null_recently: 13 | time_column: start_at_utc 14 | lookback_days: 7 15 | 16 | - name: table_key 17 | description: Foreign key identifying a table or view's database.schema.table reference. 18 | tests: 19 | - not_null_recently: 20 | time_column: start_at_utc 21 | lookback_days: 7 22 | -------------------------------------------------------------------------------- /models/sources/snowflake/staging/stg_snowflake_tables.sql: -------------------------------------------------------------------------------- 1 | 2 | {{ 3 | config( 4 | materialized = 'table' 5 | ) 6 | }} 7 | 8 | with tables as ( 9 | 10 | select * from {{ source('snowflake_internal', 'tables') }} 11 | 12 | ) 13 | 14 | , renamed_recasted as ( 15 | 16 | select 17 | lower(table_name) as table_name 18 | , lower(table_schema) as schema_name 19 | , lower(table_catalog) as database_name 20 | , lower(table_catalog) as table_catalog 21 | , lower(table_owner) as table_owner 22 | , case 23 | when table_type = 'BASE TABLE' then 'table' 24 | else lower(table_type) -- ex: view 25 | end as table_type 26 | , created as created_at_utc 27 | , last_altered as last_altered_at_utc 28 | , clustering_key 29 | , row_count 30 | , bytes 31 | , round(bytes / 1000000, 2) as megabytes 32 | , is_transient = 'YES' as is_transient 33 | , auto_clustering_on = 'YES' as is_auto_clustering_on 34 | 35 | from tables 36 | 37 | where true 38 | -- and table_catalog in ('') -- Databases of interest, uppercase, ex: PROD 39 | -- and table_schema in ('') -- Schemas of interest (across above databases, uppercase) 40 | and deleted is null -- exclude deleted tables/views (deleted is a timestamp field) 41 | 42 | ) 43 | 44 | , keyed as ( 45 | 46 | select 47 | * 48 | , concat( 49 | database_name 50 | , '.', schema_name 51 | , '.', table_name 52 | ) as table_key 53 | 54 | from renamed_recasted 55 | 56 | ) 57 | 58 | select * from keyed 59 | -------------------------------------------------------------------------------- /models/sources/snowflake/staging/stg_snowflake_tables.yml: -------------------------------------------------------------------------------- 1 | version: 2 2 | 3 | models: 4 | - name: stg_snowflake_tables 5 | description: > 6 | Materialization of Snowflake's information_schema.tables (includes tables and views). 7 | Actually accessed via the account_usage views which carry up to 90 minutes of latency. 8 | columns: 9 | - name: table_key 10 | description: Unique surrogate key identifying the database.schema.table reference 11 | tests: 12 | - unique_not_null_recently: 13 | time_column: start_at_utc 14 | lookback_days: 7 15 | -------------------------------------------------------------------------------- /snapshots/.gitkeep: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/jaysobel/dbt-snowflake-queries/6c9e983c611a691becb6109e750b1a355a974f70/snapshots/.gitkeep -------------------------------------------------------------------------------- /tests/.gitkeep: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/jaysobel/dbt-snowflake-queries/6c9e983c611a691becb6109e750b1a355a974f70/tests/.gitkeep -------------------------------------------------------------------------------- /tests/generic/not_null_recently.sql: -------------------------------------------------------------------------------- 1 | {% test not_null_recently(model, column_name, time_column, lookback_days=14) %} 2 | 3 | select {{ column_name }} 4 | from {{ model }} 5 | where {{ column_name }} is null 6 | and ( 7 | {{ time_column }} >= dateadd('day', -{{ lookback_days }}, current_timestamp) 8 | -- in case test is applied to time column itself 9 | or {{ time_column }} is null 10 | ) 11 | 12 | {% endtest %} -------------------------------------------------------------------------------- /tests/generic/unique_not_null_recently.sql: -------------------------------------------------------------------------------- 1 | {% test unique_not_null_recently(model, column_name, time_column, lookback_days=14) %} 2 | 3 | select 4 | {{ column_name }} as unique_not_null_column 5 | , count({{ column_name }}) as count_values 6 | from {{ model }} 7 | where {{ time_column }} >= dateadd('day', -{{ lookback_days }}, current_timestamp) 8 | group by 1 9 | having count({{ column_name }}) <> 1 10 | 11 | {% endtest %} 12 | -------------------------------------------------------------------------------- /tests/generic/unique_recently.sql: -------------------------------------------------------------------------------- 1 | {% test unique_recently(model, column_name, time_column, lookback_days=14) %} 2 | 3 | select 4 | {{ column_name }} 5 | , count(*) as count_rows 6 | from {{ model }} 7 | where {{ time_column }} >= dateadd('day', -{{ lookback_days }}, current_timestamp) 8 | group by 1 9 | having count(*) >= 2 10 | 11 | {% endtest %} --------------------------------------------------------------------------------