├── .gitignore ├── .gitmodules ├── LICENSE.md ├── Makefile ├── README.md ├── dbt_project.yml ├── devops └── profiles.yml ├── integration_tests ├── dbt_audit_helper │ ├── dbt_project.yml │ ├── package-lock.yml │ ├── packages.yml │ └── seeds │ │ ├── expected_results__compare_relations_without_exclude.csv │ │ └── expected_results__compare_without_summary.csv ├── dbt_date │ ├── dbt_project.yml │ ├── macros │ │ └── get_test_dates.sql │ ├── models │ │ ├── dim_date.sql │ │ ├── dim_date_fiscal.sql │ │ ├── dim_hour.sql │ │ └── dim_week.sql │ ├── package-lock.yml │ └── packages.yml ├── dbt_expectations │ ├── dbt_project.yml │ ├── package-lock.yml │ └── packages.yml ├── dbt_project.yml └── dbt_utils │ ├── dbt_project.yml │ ├── macros │ └── limit_zero.sql │ ├── package-lock.yml │ └── packages.yml ├── macros ├── dbt_audit_helper │ ├── compare_column_values.sql │ ├── compare_queries.sql │ ├── compare_relation_columns.sql │ └── compare_relations.sql ├── dbt_date │ ├── _utils │ │ ├── day_name.sql │ │ └── month_name.sql │ ├── calendar_date │ │ ├── convert_timezones.sql │ │ ├── date_part.sql │ │ ├── day_of_week.sql │ │ ├── from_unixtimestamp.sql │ │ ├── iso_week_of_year.sql │ │ ├── iso_week_start.sql │ │ ├── to_unixtimestamp.sql │ │ ├── week_end.sql │ │ ├── week_of_year.sql │ │ └── week_start.sql │ ├── fiscal_date │ │ ├── get_fiscal_periods.sql │ │ └── get_fiscal_year_dates.sql │ └── get_date_dimension.sql ├── dbt_expectations │ ├── math │ │ └── log_natural.sql │ └── schema_tests │ │ ├── _generalized │ │ ├── equal_expression.sql │ │ └── expression_is_true.sql │ │ ├── aggregate_functions │ │ ├── expect_column_most_common_value_to_be_in_set.sql │ │ └── expect_column_stdev_to_be_between.sql │ │ ├── distributional │ │ ├── expect_column_values_to_be_within_n_moving_stdevs.sql │ │ └── expect_column_values_to_be_within_n_stdevs.sql │ │ ├── multi-column │ │ └── expect_select_column_values_to_be_unique_within_record.sql │ │ └── table_shape │ │ └── expect_grouped_row_values_to_have_recent_data.sql ├── dbt_utils │ ├── datetime │ │ └── date_spine.sql │ ├── generic_tests │ │ └── expression_is_true.sql │ ├── schema_cleanup │ │ ├── drop_old_relations.sql │ │ ├── drop_schema_by_name.sql │ │ └── drop_schemas_by_prefixes.sql │ ├── schema_tests │ │ ├── mutually_exclusive_ranges.sql │ │ ├── relationships_where.sql │ │ ├── sequential_values.sql │ │ ├── test_not_null_where.sql │ │ └── test_unique_where.sql │ └── sql │ │ ├── deduplicate.sql │ │ ├── generate_series.sql │ │ ├── generate_surrogate_key.sql │ │ ├── get_tables_by_pattern_sql.sql │ │ ├── surrogate_key.sql │ │ └── width_bucket.sql └── materializations │ ├── insert_by_period_helpers.sql │ └── insert_by_period_materialization.sql └── requirements.txt /.gitignore: -------------------------------------------------------------------------------- 1 | .vscode 2 | target/ 3 | dbt_modules/ 4 | logs/ 5 | dbt_packages/ 6 | devops/.user.yml 7 | -------------------------------------------------------------------------------- /.gitmodules: -------------------------------------------------------------------------------- 1 | [submodule "dbt-utils"] 2 | path = dbt-utils 3 | url = https://github.com/fishtown-analytics/dbt-utils 4 | branch = master 5 | [submodule "dbt-expectations"] 6 | path = dbt-expectations 7 | url = https://github.com/calogica/dbt-expectations 8 | branch = main 9 | [submodule "dbt-date"] 10 | path = dbt-date 11 | url = https://github.com/calogica/dbt-date 12 | branch = main 13 | [submodule "dbt-audit-helper"] 14 | path = dbt-audit-helper 15 | url = https://github.com/fishtown-analytics/dbt-audit-helper 16 | branch = master 17 | -------------------------------------------------------------------------------- /LICENSE.md: -------------------------------------------------------------------------------- 1 | MIT License 2 | 3 | Copyright (c) 2020 Anders Swanson 4 | 5 | Permission is hereby granted, free of charge, to any person obtaining a copy 6 | of this software and associated documentation files (the "Software"), to deal 7 | in the Software without restriction, including without limitation the rights 8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 9 | copies of the Software, and to permit persons to whom the Software is 10 | furnished to do so, subject to the following conditions: 11 | 12 | The above copyright notice and this permission notice shall be included in all 13 | copies or substantial portions of the Software. 14 | 15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 21 | SOFTWARE. 22 | -------------------------------------------------------------------------------- /Makefile: -------------------------------------------------------------------------------- 1 | .DEFAULT_GOAL:=help 2 | 3 | ROOT_DIR := $(dir $(realpath $(lastword $(MAKEFILE_LIST)))) 4 | 5 | .PHONY: test-dbt-utils 6 | test-dbt-utils: ## Runs integration tests for dbt-utils 7 | @\ 8 | cd integration_tests/dbt_utils && \ 9 | DBT_PROFILES_DIR=$(ROOT_DIR)devops dbt clean && \ 10 | DBT_PROFILES_DIR=$(ROOT_DIR)devops dbt deps && \ 11 | DBT_PROFILES_DIR=$(ROOT_DIR)devops dbt seed --full-refresh && \ 12 | DBT_PROFILES_DIR=$(ROOT_DIR)devops dbt run --full-refresh && \ 13 | DBT_PROFILES_DIR=$(ROOT_DIR)devops dbt test 14 | 15 | .PHONY: test-dbt-date 16 | test-dbt-date: ## Runs integration tests for dbt-date 17 | @\ 18 | cd integration_tests/dbt_date && \ 19 | DBT_PROFILES_DIR=$(ROOT_DIR)devops dbt clean && \ 20 | DBT_PROFILES_DIR=$(ROOT_DIR)devops dbt deps && \ 21 | DBT_PROFILES_DIR=$(ROOT_DIR)devops dbt seed --full-refresh && \ 22 | DBT_PROFILES_DIR=$(ROOT_DIR)devops dbt run --full-refresh && \ 23 | DBT_PROFILES_DIR=$(ROOT_DIR)devops dbt test 24 | 25 | .PHONY: test-dbt-expectations 26 | test-dbt-expectations: ## Runs integration tests for dbt-expectations 27 | @\ 28 | cd integration_tests/dbt_expectations && \ 29 | DBT_PROFILES_DIR=$(ROOT_DIR)devops dbt clean && \ 30 | DBT_PROFILES_DIR=$(ROOT_DIR)devops dbt deps && \ 31 | DBT_PROFILES_DIR=$(ROOT_DIR)devops dbt seed --full-refresh && \ 32 | DBT_PROFILES_DIR=$(ROOT_DIR)devops dbt run --full-refresh && \ 33 | DBT_PROFILES_DIR=$(ROOT_DIR)devops dbt test 34 | 35 | .PHONY: test-dbt-audit-helper 36 | test-dbt-audit-helper: ## Runs integration tests for dbt-audit-helper 37 | @\ 38 | cd integration_tests/dbt_audit_helper && \ 39 | DBT_PROFILES_DIR=$(ROOT_DIR)devops dbt clean && \ 40 | DBT_PROFILES_DIR=$(ROOT_DIR)devops dbt deps && \ 41 | DBT_PROFILES_DIR=$(ROOT_DIR)devops dbt seed --full-refresh && \ 42 | DBT_PROFILES_DIR=$(ROOT_DIR)devops dbt run --full-refresh && \ 43 | DBT_PROFILES_DIR=$(ROOT_DIR)devops dbt test 44 | 45 | .PHONY: help 46 | help: ## Show this help message. 47 | @echo 'usage: make [target]' 48 | @echo 49 | @echo 'targets:' 50 | @grep -E '^[7+a-zA-Z_-]+:.*?## .*$$' $(MAKEFILE_LIST) | awk 'BEGIN {FS = ":.*?## "}; {printf "\033[36m%-30s\033[0m %s\n", $$1, $$2}' 51 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # `tsql-utils` 2 | 3 | This [dbt](https://www.getdbt.com/) package contains macros 4 | that: 5 | 6 | - can be (re)used across dbt projects running on T-SQL based database engines 7 | - define implementations of [dispatched macros](https://docs.getdbt.com/reference/dbt-jinja-functions/adapter/#dispatch) from other packages that can be used on a database that speaks T-SQL: SQL Server, Azure SQL, Azure Synapse, Microsoft Fabric, etc. 8 | 9 | ## Compatibility 10 | 11 | This package provides "shims" for: 12 | 13 | - [dbt-utils](https://github.com/dbt-labs/dbt-utils) (partial) 14 | - [dbt-date](https://github.com/calogica/dbt-date) 15 | - [dbt-expectations](https://github.com/calogica/dbt-expectations) (partial) 16 | - [dbt-audit-helper](https://github.com/dbt-labs/dbt-audit-helper) (partial) 17 | 18 | Note that in 2024 we refactored all the T-SQL adapters to have [dbt-fabric](https://github.com/microsoft/dbt-fabric) as their base. 19 | This means that you need to be using version 1.7 or newer of your adapter to use version 1.0.0 or newer of this package. 20 | 21 | ## Installation Instructions 22 | 23 | To make use of these T-SQL adaptations in your dbt project, you must do two things: 24 | 25 | 1. Install both and `tsql-utils` and any of the compatible packages listed above by them to your `packages.yml` 26 | 27 | ```yaml 28 | packages: 29 | # and/or calogica/dbt-date; calogica/dbt-expectations; dbt-labs/dbt-audit-helper 30 | - package: dbt-labs/dbt_utils 31 | version: {SEE DBT HUB FOR NEWEST VERSION} 32 | - package: dbt-msft/tsql_utils 33 | version: {SEE DBT HUB FOR NEWEST VERSION} 34 | ``` 35 | 36 | 2. Tell the supported package to also look for the `tsql-utils` macros by adding the relevant `dispatches` to your `dbt_project.yml` 37 | 38 | ```yaml 39 | dispatch: 40 | - macro_namespace: dbt_utils 41 | search_order: ['tsql_utils', 'dbt_utils'] 42 | - macro_namespace: dbt_date 43 | search_order: ['tsql_utils', 'dbt_date'] 44 | - macro_namespace: dbt_expectations 45 | search_order: ['tsql_utils', 'dbt_expectations'] 46 | - macro_namespace: audit_helper 47 | search_order: ['tsql_utils', 'audit_helper'] 48 | ``` 49 | 50 | Check [dbt Hub](https://hub.getdbt.com) for the latest installation 51 | instructions, or [read the docs](https://docs.getdbt.com/docs/package-management) 52 | for more information on installing packages. 53 | 54 | ## Usage 55 | 56 | You can use the macros as documented in the original packages, but with the following caveat: 57 | 58 | dbt_date does not properly dispatch to the T-SQL implementation of the `get_fiscal_periods` macro. To use the T-SQL implementation, you must use the `tsql_utils` namespace: 59 | 60 | ```sql 61 | {{ tsql_utils.get_fiscal_periods(...) }} 62 | ``` 63 | 64 | ## tsql-utils specific macros 65 | 66 | ### Cleanup Macros 67 | 68 | Some helper macros have been added to simplfy development database cleanup. Usage is as follows: 69 | 70 | Drop all schemas for each prefix with the provided prefix list (dev and myschema being a sample prefixes): 71 | 72 | ```bash 73 | dbt run-operation fabric__drop_schemas_by_prefixes --args "{prefixes: ['dev', 'myschema']}" 74 | ``` 75 | 76 | Drop all schemas with the single provided prefix (dev being a sample prefix): 77 | 78 | ```bash 79 | dbt run-operation fabric__drop_schemas_by_prefixes --args "{prefixes: myschema}" 80 | ``` 81 | 82 | Drop a schema with a specific name (myschema_seed being a sample schema name used in the project): 83 | 84 | ```bash 85 | dbt run-operation fabric__drop_schema_by_name --args "{schema_name: myschema_seed}" 86 | ``` 87 | 88 | Drop any models that are no longer included in the project (dependent on the current target): 89 | 90 | ```bash 91 | dbt run-operation fabric__drop_old_relations 92 | ``` 93 | 94 | or for a dry run to preview dropped models: 95 | 96 | ```bash 97 | dbt run-operation fabric__drop_old_relations --args "{dry_run: true}" 98 | ``` 99 | -------------------------------------------------------------------------------- /dbt_project.yml: -------------------------------------------------------------------------------- 1 | name: "tsql_utils" 2 | version: "1.0.0" 3 | config-version: 2 4 | 5 | require-dbt-version: ">=1.7.0" 6 | -------------------------------------------------------------------------------- /devops/profiles.yml: -------------------------------------------------------------------------------- 1 | integration_tests: 2 | target: fabric 3 | outputs: 4 | fabric: 5 | type: fabric 6 | driver: "ODBC Driver 18 for SQL Server" 7 | port: 1433 8 | host: "{{ env_var('FABRIC_ENDPOINT') }}" 9 | database: "{{ env_var('FABRIC_DWH_NAME', 'dwh') }}" 10 | authentication: cli 11 | schema: tsql_utils_integration_tests_fabric 12 | -------------------------------------------------------------------------------- /integration_tests/dbt_audit_helper/dbt_project.yml: -------------------------------------------------------------------------------- 1 | name: "tsql_utils_dbt_audit_helper_integration_tests" 2 | version: "1.0" 3 | config-version: 2 4 | 5 | profile: "integration_tests" 6 | 7 | dispatch: 8 | - macro_namespace: audit_helper 9 | search_order: 10 | [ 11 | "tsql_utils_dbt_audit_helper_integration_tests", 12 | "tsql_utils", 13 | "audit_helper", 14 | ] 15 | 16 | models: 17 | audit_helper_integration_tests: 18 | +materialized: table 19 | # the ones below use nested CTEs, still need to fix these 20 | compare_all_columns_where_clause: &disabled 21 | enabled: false 22 | compare_all_columns_without_summary: *disabled 23 | compare_all_columns_with_summary: *disabled 24 | compare_all_columns_with_summary_and_exclude: *disabled 25 | compare_relations_without_exclude: *disabled 26 | compare_relations_without_summary: *disabled 27 | compare_relations_with_exclude: *disabled 28 | compare_relations_with_summary: *disabled 29 | 30 | seeds: 31 | audit_helper_integration_tests: 32 | expected_results__compare_without_summary: *disabled 33 | expected_results__compare_relations_without_exclude: *disabled 34 | -------------------------------------------------------------------------------- /integration_tests/dbt_audit_helper/package-lock.yml: -------------------------------------------------------------------------------- 1 | packages: 2 | - local: ../../ 3 | - local: ../../dbt-audit-helper 4 | - local: ../../dbt-audit-helper/integration_tests 5 | - package: dbt-labs/dbt_utils 6 | version: 1.3.0 7 | - local: ../ 8 | sha1_hash: 6514ce239efacea424bc5221ed12aa46aedc35e8 9 | -------------------------------------------------------------------------------- /integration_tests/dbt_audit_helper/packages.yml: -------------------------------------------------------------------------------- 1 | 2 | packages: 3 | - local: ../../ # tsql_utils main macros 4 | - local: ../../dbt-audit-helper # actual dbt-audit-helper package as submodule 5 | - local: ../../dbt-audit-helper/integration_tests # dbt-audit-helper integration_tests macros -------------------------------------------------------------------------------- /integration_tests/dbt_audit_helper/seeds/expected_results__compare_relations_without_exclude.csv: -------------------------------------------------------------------------------- 1 | in_a,in_b,count,percent_of_total 2 | 1,1,1,33.33 3 | 1,0,1,33.33 4 | 0,1,1,33.33 5 | -------------------------------------------------------------------------------- /integration_tests/dbt_audit_helper/seeds/expected_results__compare_without_summary.csv: -------------------------------------------------------------------------------- 1 | col_a,col_b,in_a,in_b 2 | 2,b,1,0 3 | 2,c,0,1 -------------------------------------------------------------------------------- /integration_tests/dbt_date/dbt_project.yml: -------------------------------------------------------------------------------- 1 | name: "tsql_utils_dbt_date_integration_tests" 2 | version: "1.0" 3 | config-version: 2 4 | 5 | profile: "integration_tests" 6 | 7 | dispatch: 8 | - macro_namespace: dbt_utils 9 | search_order: 10 | [ 11 | "tsql_utils_dbt_date_integration_tests", 12 | "tsql_utils", 13 | "dbt", 14 | "dbt_utils", 15 | ] 16 | - macro_namespace: dbt_date 17 | search_order: 18 | ["tsql_utils_dbt_date_integration_tests", "tsql_utils", "dbt", "dbt_date"] 19 | 20 | vars: 21 | "dbt_date:time_zone": "UTC" 22 | 23 | models: 24 | dbt_date_integration_tests: 25 | schema: dbt_date_integration_tests 26 | materialized: table 27 | dim_hour: &disabled # overriden in this project as the default impl uses nested CTEs 28 | enabled: false 29 | dim_week: *disabled # overriden in this project as the default impl uses nested CTEs 30 | dim_date: *disabled # overriden in this project as the default impl uses nested CTEs 31 | dim_date_fiscal: *disabled # overriden in this project as the default impl uses nested CTEs 32 | 33 | data_tests: 34 | dbt_date_integration_tests: 35 | expression_is_true_test_dates_rounded_timestamp_utc_dbt_date_round_timestamp_time_stamp_utc_: *disabled 36 | expression_is_true_test_dates_time_stamp_utc_dbt_date_from_unixtimestamp_unix_epoch_: *disabled 37 | expression_is_true_test_dates_unix_epoch_dbt_date_to_unixtimestamp_time_stamp_utc_: *disabled -------------------------------------------------------------------------------- /integration_tests/dbt_date/macros/get_test_dates.sql: -------------------------------------------------------------------------------- 1 | {% macro fabric__get_test_week_of_year() -%} 2 | {# who knows what T-SQL uses?! #} 3 | {# see: https://github.com/calogica/dbt-date/issues/25 #} 4 | {{ return([49,49]) }} 5 | {%- endmacro %} 6 | 7 | {% macro fabric__get_test_timestamps() -%} 8 | {{ return(['2021-06-07 07:35:20.000000', 9 | '2021-06-07 07:35:20.000000']) }} 10 | {%- endmacro %} -------------------------------------------------------------------------------- /integration_tests/dbt_date/models/dim_date.sql: -------------------------------------------------------------------------------- 1 | {{ 2 | config( 3 | materialized = "table" 4 | ) 5 | }} 6 | with date_dimension as ( 7 | select * from {{ ref('dates') }} 8 | ), 9 | fiscal_periods as ( 10 | select * from {{ ref('dim_date_fiscal') }} 11 | ) 12 | select 13 | d.*, 14 | f.fiscal_week_of_year, 15 | f.fiscal_week_of_period, 16 | f.fiscal_period_number, 17 | f.fiscal_quarter_number, 18 | f.fiscal_period_of_quarter 19 | from 20 | date_dimension d 21 | left join 22 | fiscal_periods f 23 | on d.date_day = f.date_day 24 | -------------------------------------------------------------------------------- /integration_tests/dbt_date/models/dim_date_fiscal.sql: -------------------------------------------------------------------------------- 1 | {{ 2 | config( 3 | materialized = "table" 4 | ) 5 | }} 6 | {{ tsql_utils.get_fiscal_periods(ref('dates'), year_end_month=1, week_start_day=1) }} 7 | -------------------------------------------------------------------------------- /integration_tests/dbt_date/models/dim_hour.sql: -------------------------------------------------------------------------------- 1 | {{ 2 | config( 3 | materialized = "table" 4 | ) 5 | }} 6 | {{ dbt_date.get_base_dates(n_dateparts=24*28, datepart="hour") }} 7 | -------------------------------------------------------------------------------- /integration_tests/dbt_date/models/dim_week.sql: -------------------------------------------------------------------------------- 1 | {{ 2 | config( 3 | materialized = "table" 4 | ) 5 | }} 6 | {{ dbt_date.get_base_dates(n_dateparts=52, datepart="week") }} 7 | -------------------------------------------------------------------------------- /integration_tests/dbt_date/package-lock.yml: -------------------------------------------------------------------------------- 1 | packages: 2 | - local: ../../ 3 | - local: ../../dbt-date 4 | - local: ../../dbt-date/integration_tests 5 | - local: ../ 6 | sha1_hash: 23e06fdd28a6456704c5398f7e588a034e2a03de 7 | -------------------------------------------------------------------------------- /integration_tests/dbt_date/packages.yml: -------------------------------------------------------------------------------- 1 | 2 | packages: 3 | - local: ../../ # tsql_utils main macros 4 | - local: ../../dbt-date # actual dbt-expectations package as submodule 5 | - local: ../../dbt-date/integration_tests # nothing here for now -------------------------------------------------------------------------------- /integration_tests/dbt_expectations/dbt_project.yml: -------------------------------------------------------------------------------- 1 | name: "tsql_utils_dbt_expectations_integration_tests" 2 | version: "1.0" 3 | config-version: 2 4 | 5 | profile: "integration_tests" 6 | 7 | dispatch: 8 | - macro_namespace: dbt_utils 9 | search_order: 10 | [ 11 | "tsql_utils_dbt_expectations_integration_tests", 12 | "tsql_utils", 13 | "dbt", 14 | "dbt_utils", 15 | ] 16 | - macro_namespace: dbt_date 17 | search_order: 18 | [ 19 | "tsql_utils_dbt_expectations_integration_tests", 20 | "tsql_utils", 21 | "dbt", 22 | "dbt_date", 23 | ] 24 | - macro_namespace: dbt_expectations 25 | search_order: 26 | [ 27 | "tsql_utils_dbt_expectations_integration_tests", 28 | "tsql_utils", 29 | "dbt", 30 | "dbt_expectations", 31 | ] 32 | 33 | vars: 34 | "dbt_date:time_zone": "UTC" 35 | 36 | models: 37 | dbt_expectations_integration_tests: 38 | schema_tests: 39 | data_test_factored: 40 | materialized: table 41 | enabled: "{{ target.type != 'synapse' }}" 42 | emails: &disabled #TODO 43 | enabled: false 44 | timeseries_data: *disabled 45 | timeseries_hourly_data_extended: *disabled 46 | # Need to implement for synapse 47 | data_test: *disabled 48 | timeseries_data_extended: *disabled 49 | data_text: *disabled 50 | timeseries_data_grouped: *disabled 51 | -------------------------------------------------------------------------------- /integration_tests/dbt_expectations/package-lock.yml: -------------------------------------------------------------------------------- 1 | packages: 2 | - local: ../../ 3 | - local: ../../dbt-expectations 4 | - local: ../../dbt-expectations/integration_tests 5 | - package: calogica/dbt_date 6 | version: 0.10.1 7 | - local: ../ 8 | sha1_hash: 5723a05ef1d9b9d1f7961a55d573231dca0b0644 9 | -------------------------------------------------------------------------------- /integration_tests/dbt_expectations/packages.yml: -------------------------------------------------------------------------------- 1 | 2 | packages: 3 | - local: ../../ # tsql_utils main macros 4 | - local: ../../dbt-expectations # actual dbt-expectations package as submodule 5 | - local: ../../dbt-expectations/integration_tests # nothing here for now -------------------------------------------------------------------------------- /integration_tests/dbt_project.yml: -------------------------------------------------------------------------------- 1 | name: 'tsql_utils_integration_tests' 2 | version: '0.1.0' 3 | config-version: 2 4 | -------------------------------------------------------------------------------- /integration_tests/dbt_utils/dbt_project.yml: -------------------------------------------------------------------------------- 1 | name: "tsql_utils_dbt_utils_integration_tests" 2 | version: "1.0" 3 | config-version: 2 4 | 5 | profile: "integration_tests" 6 | 7 | dispatch: 8 | - macro_namespace: dbt_utils 9 | search_order: 10 | [ 11 | "tsql_utils_dbt_utils_integration_tests", 12 | "tsql_utils", 13 | "dbt", 14 | "dbt_utils_integration_tests", 15 | "dbt_utils", 16 | ] 17 | 18 | models: 19 | dbt_utils_integration_tests: 20 | index: HEAP # Synapse only 21 | as_columnstore: "{{ target.type == 'sqlserver' }}" 22 | enabled: true 23 | web: 24 | test_url_host: &disabled 25 | enabled: false 26 | test_url_path: *disabled 27 | test_urls: *disabled 28 | sql: 29 | test_generate_series: *disabled 30 | test_get_column_values: *disabled 31 | test_get_relations_by_pattern: *disabled 32 | test_get_relations_by_prefix_and_union: *disabled 33 | test_groupby: *disabled 34 | test_union: *disabled 35 | test_unpivot_bool: *disabled 36 | test_get_single_value: *disabled 37 | test_get_single_value_default: *disabled 38 | 39 | data_tests: 40 | dbt_utils_integration_tests: *disabled 41 | 42 | seeds: 43 | dbt_utils_integration_tests: 44 | schema_tests: 45 | data_test_sequential_timestamps: *disabled 46 | data_test_mutually_exclusive_ranges_with_gaps_zero_length: *disabled 47 | data_test_mutually_exclusive_ranges_no_gaps: *disabled 48 | data_test_mutually_exclusive_ranges_with_gaps: *disabled 49 | 50 | sql: 51 | data_unpivot_bool: *disabled 52 | data_unpivot_bool_expected: *disabled 53 | data_get_single_value: *disabled 54 | -------------------------------------------------------------------------------- /integration_tests/dbt_utils/macros/limit_zero.sql: -------------------------------------------------------------------------------- 1 | {% macro fabric__limit_zero() %} 2 | {{ return('where 0=1') }} 3 | {% endmacro %} 4 | -------------------------------------------------------------------------------- /integration_tests/dbt_utils/package-lock.yml: -------------------------------------------------------------------------------- 1 | packages: 2 | - local: ../../ 3 | - local: ../../dbt-utils 4 | - local: ../../dbt-utils/integration_tests 5 | - local: ../ 6 | sha1_hash: 866dcf4e4bb1d3e1a53bf5b11344d4ec1fce681f 7 | -------------------------------------------------------------------------------- /integration_tests/dbt_utils/packages.yml: -------------------------------------------------------------------------------- 1 | 2 | packages: 3 | - local: ../../ 4 | - local: ../../dbt-utils 5 | - local: ../../dbt-utils/integration_tests 6 | -------------------------------------------------------------------------------- /macros/dbt_audit_helper/compare_column_values.sql: -------------------------------------------------------------------------------- 1 | {% macro fabric__compare_column_values(a_query, b_query, primary_key, column_to_compare) -%} 2 | with a_query as ( 3 | {{ a_query }} 4 | ), 5 | 6 | b_query as ( 7 | {{ b_query }} 8 | ), 9 | 10 | joined as ( 11 | select 12 | coalesce(a_query.{{ primary_key }}, b_query.{{ primary_key }}) as {{ primary_key }}, 13 | a_query.{{ column_to_compare }} as a_query_value, 14 | b_query.{{ column_to_compare }} as b_query_value, 15 | case 16 | when a_query.{{ column_to_compare }} = b_query.{{ column_to_compare }} then 'perfect match' 17 | when a_query.{{ column_to_compare }} is null and b_query.{{ column_to_compare }} is null then 'both are null' 18 | when a_query.{{ primary_key }} is null then 'missing from a' 19 | when b_query.{{ primary_key }} is null then 'missing from b' 20 | when a_query.{{ column_to_compare }} is null then 'value is null in a only' 21 | when b_query.{{ column_to_compare }} is null then 'value is null in b only' 22 | when a_query.{{ column_to_compare }} != b_query.{{ column_to_compare }} then 'values do not match' 23 | else 'unknown' -- this should never happen 24 | end as match_status, 25 | case 26 | when a_query.{{ column_to_compare }} = b_query.{{ column_to_compare }} then 0 27 | when a_query.{{ column_to_compare }} is null and b_query.{{ column_to_compare }} is null then 1 28 | when a_query.{{ primary_key }} is null then 2 29 | when b_query.{{ primary_key }} is null then 3 30 | when a_query.{{ column_to_compare }} is null then 4 31 | when b_query.{{ column_to_compare }} is null then 5 32 | when a_query.{{ column_to_compare }} != b_query.{{ column_to_compare }} then 6 33 | else 7 -- this should never happen 34 | end as match_order 35 | 36 | from a_query 37 | 38 | full outer join b_query on a_query.{{ primary_key }} = b_query.{{ primary_key }} 39 | ), 40 | 41 | aggregated as ( 42 | select 43 | match_status, 44 | match_order, 45 | count(*) as count_records 46 | from joined 47 | 48 | group by match_status, match_order 49 | ) 50 | 51 | select 52 | match_status, 53 | count_records, 54 | round(100.0 * count_records / sum(count_records) over (), 2) as percent_of_total 55 | 56 | from aggregated 57 | 58 | {% endmacro %} 59 | -------------------------------------------------------------------------------- /macros/dbt_audit_helper/compare_queries.sql: -------------------------------------------------------------------------------- 1 | {% macro fabric__compare_queries(a_query, b_query, primary_key=None, summarize=true) %} 2 | 3 | with a as ( 4 | 5 | {{ a_query }} 6 | 7 | ), 8 | 9 | b as ( 10 | 11 | {{ b_query }} 12 | 13 | ), 14 | 15 | a_intersect_b as ( 16 | 17 | select * from a 18 | {{ dbt.intersect() }} 19 | select * from b 20 | 21 | ), 22 | 23 | a_except_b as ( 24 | 25 | select * from a 26 | {{ dbt.except() }} 27 | select * from b 28 | 29 | ), 30 | 31 | b_except_a as ( 32 | 33 | select * from b 34 | {{ dbt.except() }} 35 | select * from a 36 | 37 | ), 38 | 39 | all_records as ( 40 | 41 | select 42 | *, 43 | 1 as in_a, 44 | 1 as in_b 45 | from a_intersect_b 46 | 47 | union all 48 | 49 | select 50 | *, 51 | 1 as in_a, 52 | 0 as in_b 53 | from a_except_b 54 | 55 | union all 56 | 57 | select 58 | *, 59 | 0 as in_a, 60 | 1 as in_b 61 | from b_except_a 62 | 63 | ), 64 | 65 | {%- if summarize %} 66 | 67 | summary_stats as ( 68 | select 69 | in_a, 70 | in_b, 71 | count(*) as count 72 | from all_records 73 | group by in_a, in_b 74 | ), 75 | 76 | final as ( 77 | 78 | select 79 | *, 80 | round(100.0 * count / sum(count) over (), 2) as percent_of_total 81 | 82 | from summary_stats 83 | ) 84 | 85 | {%- else %} 86 | 87 | final as ( 88 | 89 | select * 90 | from all_records 91 | where not (in_a = 1 and in_b = 1) 92 | 93 | ) 94 | 95 | {%- endif %} 96 | 97 | select * 98 | from final 99 | 100 | {% endmacro %} 101 | -------------------------------------------------------------------------------- /macros/dbt_audit_helper/compare_relation_columns.sql: -------------------------------------------------------------------------------- 1 | {% macro fabric__compare_relation_columns(a_relation, b_relation) %} 2 | 3 | with a_cols as ( 4 | {{ tsql_utils.fabric__get_columns_in_relation_sql(a_relation) }} 5 | ), 6 | 7 | b_cols as ( 8 | {{ tsql_utils.fabric__get_columns_in_relation_sql(b_relation) }} 9 | ) 10 | 11 | select 12 | column_name, 13 | a_cols.ordinal_position as a_ordinal_position, 14 | b_cols.ordinal_position as b_ordinal_position, 15 | a_cols.data_type as a_data_type, 16 | b_cols.data_type as b_data_type, 17 | coalesce(a_cols.ordinal_position = b_cols.ordinal_position, false) as has_ordinal_position_match, 18 | coalesce(a_cols.data_type = b_cols.data_type, false) as has_data_type_match 19 | from a_cols 20 | full outer join b_cols using (column_name) 21 | 22 | {% endmacro %} 23 | 24 | 25 | {% macro fabric__get_columns_in_relation_sql(relation) %} 26 | SELECT 27 | column_name, 28 | data_type, 29 | character_maximum_length, 30 | numeric_precision, 31 | numeric_scale 32 | FROM 33 | (select 34 | ordinal_position, 35 | column_name, 36 | data_type, 37 | character_maximum_length, 38 | numeric_precision, 39 | numeric_scale 40 | from INFORMATION_SCHEMA.COLUMNS 41 | where table_name = '{{ relation.identifier }}' 42 | and table_schema = '{{ relation.schema }}' 43 | UNION ALL 44 | select 45 | ordinal_position, 46 | column_name collate database_default, 47 | data_type collate database_default, 48 | character_maximum_length, 49 | numeric_precision, 50 | numeric_scale 51 | from tempdb.INFORMATION_SCHEMA.COLUMNS 52 | where table_name like '{{ relation.identifier }}%') cols 53 | {% endmacro %} 54 | -------------------------------------------------------------------------------- /macros/dbt_audit_helper/compare_relations.sql: -------------------------------------------------------------------------------- 1 | {% macro fabric__compare_relations(a_relation, b_relation, exclude_columns=[], primary_key=None, summarize=true) %} 2 | 3 | {%- set a_columns = adapter.get_columns_in_relation(a_relation) -%} 4 | 5 | {% set check_columns=audit_helper.pop_columns(a_columns, exclude_columns) %} 6 | 7 | {% set check_cols_csv = check_columns | map(attribute='quoted') | join(', ') %} 8 | 9 | {% set a_query %} 10 | select 11 | {{ check_cols_csv }} 12 | 13 | from {{ a_relation }} 14 | {% endset %} 15 | 16 | {% set b_query %} 17 | select 18 | {{ check_cols_csv }} 19 | 20 | from {{ b_relation }} 21 | {% endset %} 22 | 23 | {{ tsql_utils.fabric__compare_queries(a_query, b_query, primary_key, summarize) }} 24 | 25 | {% endmacro %} 26 | -------------------------------------------------------------------------------- /macros/dbt_date/_utils/day_name.sql: -------------------------------------------------------------------------------- 1 | {%- macro fabric__day_name(date, short) -%} 2 | {%- set f = 'ddd' if short else 'dddd' -%} 3 | cast(format({{ date }}, '{{ f }}') as varchar(4000)) 4 | {%- endmacro %} 5 | -------------------------------------------------------------------------------- /macros/dbt_date/_utils/month_name.sql: -------------------------------------------------------------------------------- 1 | {%- macro fabric__month_name(date, short) -%} 2 | {%- set f = 'MMM' if short else 'MMMM' -%} 3 | cast(format({{ date }}, '{{ f }}') as varchar(4000)) 4 | {%- endmacro %} 5 | -------------------------------------------------------------------------------- /macros/dbt_date/calendar_date/convert_timezones.sql: -------------------------------------------------------------------------------- 1 | {% macro fabric__convert_timezone(column, target_tz, source_tz) -%} 2 | CAST({{ column }} as {{ dbt.type_timestamp() }}) AT TIME ZONE '{{ source_tz }}' AT TIME ZONE '{{ target_tz }}' 3 | {%- endmacro -%} 4 | -------------------------------------------------------------------------------- /macros/dbt_date/calendar_date/date_part.sql: -------------------------------------------------------------------------------- 1 | {% macro fabric__date_part(datepart, date) -%} 2 | datepart({{ datepart }}, {{ date }}) 3 | {%- endmacro %} 4 | -------------------------------------------------------------------------------- /macros/dbt_date/calendar_date/day_of_week.sql: -------------------------------------------------------------------------------- 1 | 2 | {%- macro fabric__day_of_week(date, isoweek) -%} 3 | 4 | {%- set dow = dbt_date.date_part('weekday', date) -%} 5 | 6 | {%- if isoweek -%} 7 | case 8 | -- Shift start of week from Sunday (1) to Monday (2) 9 | when {{ dow }} = 1 then 7 10 | else {{ dow }} - 1 11 | end 12 | {%- else -%} 13 | {{ dow }} 14 | {%- endif -%} 15 | 16 | {%- endmacro %} 17 | -------------------------------------------------------------------------------- /macros/dbt_date/calendar_date/from_unixtimestamp.sql: -------------------------------------------------------------------------------- 1 | {%- macro fabric__from_unixtimestamp(epochs, format) -%} 2 | 3 | {%- if format == "seconds" -%} 4 | {%- set scale = "S" -%} 5 | {%- elif format == "milliseconds" -%} 6 | {%- set scale = "ms" -%} 7 | {%- elif format == "microseconds" -%} 8 | {%- set scale = "mcs" -%} 9 | {%- elif format == "nanoseconds" -%} 10 | {%- set scale = "ns" -%} 11 | {%- else -%} 12 | {{ exceptions.raise_compiler_error( 13 | "value " ~ format ~ " for `format` for from_unixtimestamp is not supported." 14 | ) 15 | }} 16 | {% endif -%} 17 | 18 | {%- if format == "nanoseconds" -%} 19 | dateadd(ns, {{ epochs }} % 1000000000, dateadd(s,{{ epochs }} / 1000000000,cast('1970-01-01' as datetime2(7))) ) 20 | {%- else -%} 21 | dateadd({{ scale }}, {{ epochs }}, '1970-01-01') 22 | {% endif -%} 23 | 24 | {%- endmacro %} 25 | -------------------------------------------------------------------------------- /macros/dbt_date/calendar_date/iso_week_of_year.sql: -------------------------------------------------------------------------------- 1 | {%- macro fabric__iso_week_of_year(date) -%} 2 | cast({{ dbt_date.date_part('iso_week', date) }} as {{ dbt.type_int() }}) 3 | {%- endmacro %} 4 | -------------------------------------------------------------------------------- /macros/dbt_date/calendar_date/iso_week_start.sql: -------------------------------------------------------------------------------- 1 | {%- macro fabric__iso_week_start(date) -%} 2 | cast(dateadd(week, datediff(week, 0, dateadd(day, -1, {{date}})), 0) as date) 3 | {%- endmacro %} 4 | -------------------------------------------------------------------------------- /macros/dbt_date/calendar_date/to_unixtimestamp.sql: -------------------------------------------------------------------------------- 1 | {%- macro fabric__to_unixtimestamp(timestamp) -%} 2 | DATEDIFF(s, '1970-01-01 00:00:00', {{ timestamp }}) 3 | {%- endmacro %} -------------------------------------------------------------------------------- /macros/dbt_date/calendar_date/week_end.sql: -------------------------------------------------------------------------------- 1 | {%- macro fabric__week_end(date) -%} 2 | {%- set dt = dbt_date.week_start(date) -%} 3 | {{ dbt_date.n_days_away(6, dt) }} 4 | {%- endmacro %} 5 | -------------------------------------------------------------------------------- /macros/dbt_date/calendar_date/week_of_year.sql: -------------------------------------------------------------------------------- 1 | {%- macro fabric__week_of_year(date) -%} 2 | cast({{ dbt_date.date_part('week', date)}} as {{ dbt.type_int() }}) 3 | {%- endmacro %} 4 | -------------------------------------------------------------------------------- /macros/dbt_date/calendar_date/week_start.sql: -------------------------------------------------------------------------------- 1 | {%- macro fabric__week_start(date) -%} 2 | -- Sunday as week start date 3 | cast({{ dbt.dateadd('day', -1, dbt.date_trunc('week', dbt.dateadd('day', 1, date))) }} as date) 4 | {%- endmacro %} 5 | -------------------------------------------------------------------------------- /macros/dbt_date/fiscal_date/get_fiscal_periods.sql: -------------------------------------------------------------------------------- 1 | {% macro get_fiscal_periods(dates, year_end_month, week_start_day, shift_year=1) %} 2 | {# 3 | This macro requires you to pass in a ref to a date dimension, created via 4 | dbt_date.get_date_dimension()s 5 | #} 6 | 7 | {#- inline version of get_fiscal_year_dates -#} 8 | -- this gets all the dates within a fiscal year 9 | -- determined by the given year-end-month 10 | -- ending on the saturday closest to that month's end date 11 | with fsc_date_dimension as ( 12 | select * from {{ dates }} 13 | ), 14 | year_month_end as ( 15 | 16 | select 17 | d.year_number - {{ shift_year }} as fiscal_year_number, 18 | d.month_end_date 19 | from 20 | fsc_date_dimension d 21 | where 22 | d.month_of_year = {{ year_end_month }} 23 | group by 24 | d.year_number - {{ shift_year }}, 25 | d.month_end_date 26 | 27 | ), 28 | weeks as ( 29 | 30 | select 31 | d.year_number, 32 | d.month_of_year, 33 | d.date_day as week_start_date, 34 | cast({{ dbt.dateadd('day', 6, 'd.date_day') }} as date) as week_end_date 35 | from 36 | fsc_date_dimension d 37 | where 38 | d.day_of_week = {{ week_start_day }} 39 | 40 | ), 41 | -- get all the weeks that start in the month the year ends 42 | year_week_ends as ( 43 | 44 | select 45 | d.year_number - {{ shift_year }} as fiscal_year_number, 46 | d.week_end_date 47 | from 48 | weeks d 49 | where 50 | d.month_of_year = {{ year_end_month }} 51 | group by 52 | d.year_number - {{ shift_year }}, 53 | d.week_end_date 54 | 55 | ), 56 | -- then calculate which Saturday is closest to month end 57 | weeks_at_month_end as ( 58 | 59 | select 60 | d.fiscal_year_number, 61 | d.week_end_date, 62 | m.month_end_date, 63 | rank() over 64 | (partition by d.fiscal_year_number 65 | order by 66 | abs({{ dbt.datediff('d.week_end_date', 'm.month_end_date', 'day') }}) 67 | 68 | ) as closest_to_month_end 69 | from 70 | year_week_ends d 71 | join 72 | year_month_end m on d.fiscal_year_number = m.fiscal_year_number 73 | ), 74 | fiscal_year_range as ( 75 | 76 | select 77 | w.fiscal_year_number, 78 | cast( 79 | {{ dbt.dateadd('day', 1, 80 | 'lag(w.week_end_date) over(order by w.week_end_date)') }} 81 | as date) as fiscal_year_start_date, 82 | w.week_end_date as fiscal_year_end_date 83 | from 84 | weeks_at_month_end w 85 | where 86 | w.closest_to_month_end = 1 87 | 88 | ), 89 | fscl_year_dates_for_periods as ( 90 | 91 | select 92 | d.date_day, 93 | m.fiscal_year_number, 94 | m.fiscal_year_start_date, 95 | m.fiscal_year_end_date, 96 | w.week_start_date, 97 | w.week_end_date, 98 | -- we reset the weeks of the year starting with the merch year start date 99 | dense_rank() 100 | over( 101 | partition by m.fiscal_year_number 102 | order by w.week_start_date 103 | ) as fiscal_week_of_year 104 | from 105 | fsc_date_dimension d 106 | join 107 | fiscal_year_range m on d.date_day between m.fiscal_year_start_date and m.fiscal_year_end_date 108 | join 109 | weeks w on d.date_day between w.week_start_date and w.week_end_date 110 | 111 | ), 112 | {#- end of inline version -#} 113 | 114 | fscl_year_w13 as ( 115 | 116 | select 117 | f.*, 118 | -- We count the weeks in a 13 week period 119 | -- and separate the 4-5-4 week sequences 120 | cast( 121 | (f.fiscal_week_of_year-1) as {{ dbt.type_int() }} 122 | ) % 13 as w13_number, 123 | -- Chop weeks into 13 week merch quarters 124 | cast( 125 | least( 126 | floor((f.fiscal_week_of_year-1)/13.0) 127 | , 3) 128 | as {{ dbt.type_int() }}) as quarter_number 129 | from 130 | fscl_year_dates_for_periods f 131 | 132 | ), 133 | fscl_periods as ( 134 | 135 | select 136 | f.date_day, 137 | f.fiscal_year_number, 138 | f.week_start_date, 139 | f.week_end_date, 140 | f.fiscal_week_of_year, 141 | case 142 | -- we move week 53 into the 3rd period of the quarter 143 | when f.fiscal_week_of_year = 53 then 3 144 | when f.w13_number between 0 and 3 then 1 145 | when f.w13_number between 4 and 8 then 2 146 | when f.w13_number between 9 and 12 then 3 147 | end as period_of_quarter, 148 | f.quarter_number 149 | from 150 | fscl_year_w13 f 151 | 152 | ), 153 | fscl_periods_quarters as ( 154 | 155 | select 156 | f.*, 157 | cast(( 158 | (f.quarter_number * 3) + f.period_of_quarter 159 | ) as {{ dbt.type_int() }}) as fiscal_period_number 160 | from 161 | fscl_periods f 162 | 163 | ) 164 | select 165 | date_day, 166 | fiscal_year_number, 167 | week_start_date, 168 | week_end_date, 169 | fiscal_week_of_year, 170 | dense_rank() over(partition by fiscal_period_number order by fiscal_week_of_year) as fiscal_week_of_period, 171 | fiscal_period_number, 172 | quarter_number+1 as fiscal_quarter_number, 173 | period_of_quarter as fiscal_period_of_quarter 174 | from 175 | fscl_periods_quarters 176 | {% endmacro %} 177 | -------------------------------------------------------------------------------- /macros/dbt_date/fiscal_date/get_fiscal_year_dates.sql: -------------------------------------------------------------------------------- 1 | {% macro fabric__get_fiscal_year_dates(dates, year_end_month, week_start_day, shift_year) %} 2 | -- this gets all the dates within a fiscal year 3 | -- determined by the given year-end-month 4 | -- ending on the saturday closest to that month's end date 5 | with fsc_date_dimension as ( 6 | select * from {{ dates }} 7 | ), 8 | year_month_end as ( 9 | 10 | select 11 | d.year_number - {{ shift_year }} as fiscal_year_number, 12 | d.month_end_date 13 | from 14 | fsc_date_dimension d 15 | where 16 | d.month_of_year = {{ year_end_month }} 17 | group by 18 | d.year_number - {{ shift_year }}, 19 | d.month_end_date 20 | 21 | ), 22 | weeks as ( 23 | 24 | select 25 | d.year_number, 26 | d.month_of_year, 27 | d.date_day as week_start_date, 28 | cast({{ dbt.dateadd('day', 6, 'd.date_day') }} as date) as week_end_date 29 | from 30 | fsc_date_dimension d 31 | where 32 | d.day_of_week = {{ week_start_day }} 33 | 34 | ), 35 | -- get all the weeks that start in the month the year ends 36 | year_week_ends as ( 37 | 38 | select 39 | d.year_number - {{ shift_year }} as fiscal_year_number, 40 | d.week_end_date 41 | from 42 | weeks d 43 | where 44 | d.month_of_year = {{ year_end_month }} 45 | group by 46 | d.year_number - {{ shift_year }}, 47 | d.week_end_date 48 | 49 | ), 50 | -- then calculate which Saturday is closest to month end 51 | weeks_at_month_end as ( 52 | 53 | select 54 | d.fiscal_year_number, 55 | d.week_end_date, 56 | m.month_end_date, 57 | rank() over 58 | (partition by d.fiscal_year_number 59 | order by 60 | abs({{ dbt.datediff('d.week_end_date', 'm.month_end_date', 'day') }}) 61 | 62 | ) as closest_to_month_end 63 | from 64 | year_week_ends d 65 | join 66 | year_month_end m on d.fiscal_year_number = m.fiscal_year_number 67 | ), 68 | fiscal_year_range as ( 69 | 70 | select 71 | w.fiscal_year_number, 72 | cast( 73 | {{ dbt.dateadd('day', 1, 74 | 'lag(w.week_end_date) over(order by w.week_end_date)') }} 75 | as date) as fiscal_year_start_date, 76 | w.week_end_date as fiscal_year_end_date 77 | from 78 | weeks_at_month_end w 79 | where 80 | w.closest_to_month_end = 1 81 | 82 | ), 83 | fiscal_year_dates as ( 84 | 85 | select 86 | d.date_day, 87 | m.fiscal_year_number, 88 | m.fiscal_year_start_date, 89 | m.fiscal_year_end_date, 90 | w.week_start_date, 91 | w.week_end_date, 92 | -- we reset the weeks of the year starting with the merch year start date 93 | dense_rank() 94 | over( 95 | partition by m.fiscal_year_number 96 | order by w.week_start_date 97 | ) as fiscal_week_of_year 98 | from 99 | fsc_date_dimension d 100 | join 101 | fiscal_year_range m on d.date_day between m.fiscal_year_start_date and m.fiscal_year_end_date 102 | join 103 | weeks w on d.date_day between w.week_start_date and w.week_end_date 104 | 105 | ) 106 | select * from fiscal_year_dates 107 | {% endmacro %} -------------------------------------------------------------------------------- /macros/dbt_date/get_date_dimension.sql: -------------------------------------------------------------------------------- 1 | {% macro fabric__get_date_dimension(start_date, end_date) %} 2 | {#- Inlined version of the original macro without the ordering because nested CTEs are not supported -#} 3 | 4 | {%- set datepart="day" -%} 5 | 6 | {%- if start_date and end_date -%} 7 | {%- set start_date="cast('" ~ start_date ~ "' as " ~ dbt.type_timestamp() ~ ")" -%} 8 | {%- set end_date="cast('" ~ end_date ~ "' as " ~ dbt.type_timestamp() ~ ")" -%} 9 | 10 | {%- elif n_dateparts and datepart -%} 11 | 12 | {%- set start_date = dbt.dateadd(datepart, -1 * n_dateparts, dbt_date.today()) -%} 13 | {%- set end_date = dbt_date.tomorrow() -%} 14 | {%- endif -%} 15 | 16 | with date_spine as 17 | ( 18 | 19 | {{ dbt_date.date_spine( 20 | datepart=datepart, 21 | start_date=start_date, 22 | end_date=end_date, 23 | ) 24 | }} 25 | 26 | ), 27 | base_dates as ( 28 | select 29 | cast(d.date_{{ datepart }} as {{ dbt.type_timestamp() }}) as date_{{ datepart }} 30 | from 31 | date_spine d 32 | ), 33 | dates_with_prior_year_dates as ( 34 | 35 | select 36 | cast(d.date_day as date) as date_day, 37 | cast({{ dbt.dateadd('year', -1 , 'd.date_day') }} as date) as prior_year_date_day, 38 | cast({{ dbt.dateadd('day', -364 , 'd.date_day') }} as date) as prior_year_over_year_date_day 39 | from 40 | base_dates d 41 | 42 | ) 43 | select 44 | d.date_day, 45 | {{ dbt_date.yesterday('d.date_day') }} as prior_date_day, 46 | {{ dbt_date.tomorrow('d.date_day') }} as next_date_day, 47 | d.prior_year_date_day as prior_year_date_day, 48 | d.prior_year_over_year_date_day, 49 | {{ dbt_date.day_of_week('d.date_day', isoweek=false) }} as day_of_week, 50 | {{ dbt_date.day_of_week('d.date_day', isoweek=true) }} as day_of_week_iso, 51 | {{ dbt_date.day_name('d.date_day', short=false) }} as day_of_week_name, 52 | {{ dbt_date.day_name('d.date_day', short=true) }} as day_of_week_name_short, 53 | {{ dbt_date.day_of_month('d.date_day') }} as day_of_month, 54 | {{ dbt_date.day_of_year('d.date_day') }} as day_of_year, 55 | 56 | {{ dbt_date.week_start('d.date_day') }} as week_start_date, 57 | {{ dbt_date.week_end('d.date_day') }} as week_end_date, 58 | {{ dbt_date.week_start('d.prior_year_over_year_date_day') }} as prior_year_week_start_date, 59 | {{ dbt_date.week_end('d.prior_year_over_year_date_day') }} as prior_year_week_end_date, 60 | {{ dbt_date.week_of_year('d.date_day') }} as week_of_year, 61 | 62 | {{ dbt_date.iso_week_start('d.date_day') }} as iso_week_start_date, 63 | {{ dbt_date.iso_week_end('d.date_day') }} as iso_week_end_date, 64 | {{ dbt_date.iso_week_start('d.prior_year_over_year_date_day') }} as prior_year_iso_week_start_date, 65 | {{ dbt_date.iso_week_end('d.prior_year_over_year_date_day') }} as prior_year_iso_week_end_date, 66 | {{ dbt_date.iso_week_of_year('d.date_day') }} as iso_week_of_year, 67 | 68 | {{ dbt_date.week_of_year('d.prior_year_over_year_date_day') }} as prior_year_week_of_year, 69 | {{ dbt_date.iso_week_of_year('d.prior_year_over_year_date_day') }} as prior_year_iso_week_of_year, 70 | 71 | cast({{ dbt_date.date_part('month', 'd.date_day') }} as {{ dbt.type_int() }}) as month_of_year, 72 | {{ dbt_date.month_name('d.date_day', short=false) }} as month_name, 73 | {{ dbt_date.month_name('d.date_day', short=true) }} as month_name_short, 74 | 75 | cast({{ dbt.date_trunc('month', 'd.date_day') }} as date) as month_start_date, 76 | cast({{ last_day('d.date_day', 'month') }} as date) as month_end_date, 77 | 78 | cast({{ dbt.date_trunc('month', 'd.prior_year_date_day') }} as date) as prior_year_month_start_date, 79 | cast({{ last_day('d.prior_year_date_day', 'month') }} as date) as prior_year_month_end_date, 80 | 81 | cast({{ dbt_date.date_part('quarter', 'd.date_day') }} as {{ dbt.type_int() }}) as quarter_of_year, 82 | cast({{ dbt.date_trunc('quarter', 'd.date_day') }} as date) as quarter_start_date, 83 | cast({{ last_day('d.date_day', 'quarter') }} as date) as quarter_end_date, 84 | 85 | cast({{ dbt_date.date_part('year', 'd.date_day') }} as {{ dbt.type_int() }}) as year_number, 86 | cast({{ dbt.date_trunc('year', 'd.date_day') }} as date) as year_start_date, 87 | cast({{ last_day('d.date_day', 'year') }} as date) as year_end_date 88 | from 89 | dates_with_prior_year_dates d 90 | {% endmacro %} -------------------------------------------------------------------------------- /macros/dbt_expectations/math/log_natural.sql: -------------------------------------------------------------------------------- 1 | {% macro fabric__log_natural(x) %} 2 | 3 | log({{ x }}) 4 | 5 | {%- endmacro -%} 6 | -------------------------------------------------------------------------------- /macros/dbt_expectations/schema_tests/_generalized/equal_expression.sql: -------------------------------------------------------------------------------- 1 | {%- macro fabric__get_select(model, expression, row_condition, group_by) %} 2 | select 3 | {# {%- if group_by %} #} 4 | {% for g in group_by or [] -%} 5 | {{ g }} as col_{{ loop.index }}, 6 | {% endfor -%} 7 | {# {% endif %} #} 8 | {{ expression }} as expression 9 | from 10 | {{ model }} 11 | {%- if row_condition %} 12 | where 13 | {{ row_condition }} 14 | {% endif %} 15 | {%- if group_by %} 16 | {%- if group_by|length > 1 or group_by[0] != "'col'" %} 17 | group by 18 | {% for g in group_by -%} 19 | {{ g }}{% if not loop.last %},{% endif %} 20 | {% endfor %} 21 | {% endif %} 22 | {% endif %} 23 | {% endmacro -%} 24 | 25 | {%- macro fabric__test_equal_expression( 26 | model, 27 | expression, 28 | compare_model, 29 | compare_expression, 30 | group_by, 31 | compare_group_by, 32 | row_condition, 33 | compare_row_condition, 34 | tolerance, 35 | tolerance_percent) -%} 36 | 37 | {%- set compare_model = model if not compare_model else compare_model -%} 38 | {%- set compare_expression = expression if not compare_expression else compare_expression -%} 39 | {%- set compare_row_condition = row_condition if not compare_row_condition else compare_row_condition -%} 40 | {%- set compare_group_by = group_by if not compare_group_by else compare_group_by -%} 41 | 42 | {%- set n_cols = group_by|length if group_by else 0 %} 43 | with a as ( 44 | {{ dbt_expectations.get_select(model, expression, row_condition, group_by) }} 45 | ), 46 | b as ( 47 | {{ dbt_expectations.get_select(compare_model, compare_expression, compare_row_condition, compare_group_by) }} 48 | ), 49 | final as ( 50 | 51 | select 52 | {% for i in range(1, n_cols + 1) -%} 53 | coalesce(a.col_{{ i }}, b.col_{{ i }}) as col_{{ i }}, 54 | {% endfor %} 55 | a.expression, 56 | b.expression as compare_expression, 57 | abs(coalesce(a.expression, 0) - coalesce(b.expression, 0)) as expression_difference, 58 | abs(coalesce(a.expression, 0) - coalesce(b.expression, 0))/ 59 | nullif(a.expression, 0) as expression_difference_percent 60 | from 61 | {% if n_cols > 0 %} 62 | a 63 | full outer join 64 | b on 65 | {% for i in range(1, n_cols + 1) -%} 66 | a.col_{{ i }} = b.col_{{ i }} {% if not loop.last %}and{% endif %} 67 | {% endfor -%} 68 | {% else %} 69 | a cross join b 70 | {% endif %} 71 | ) 72 | -- DEBUG: 73 | -- select * from final 74 | select 75 | * 76 | from final 77 | where 78 | {% if tolerance_percent %} 79 | expression_difference_percent > {{ tolerance_percent }} 80 | {% else %} 81 | expression_difference > {{ tolerance }} 82 | {% endif %} 83 | {%- endmacro -%} 84 | -------------------------------------------------------------------------------- /macros/dbt_expectations/schema_tests/_generalized/expression_is_true.sql: -------------------------------------------------------------------------------- 1 | {% macro fabric__expression_is_true(model, expression, test_condition, group_by_columns, row_condition) %} 2 | 3 | {% if test_condition == "= true" %} 4 | {% set test_condition = "= 1" %} 5 | {% endif %} 6 | 7 | 8 | with grouped_expression as ( 9 | 10 | select 11 | {% if group_by_columns %} 12 | {% for group_by_column in group_by_columns -%} 13 | {{ group_by_column }} as col_{{ loop.index }}, 14 | {% endfor -%} 15 | {% endif %} 16 | case when {{ expression }} then 1 else 0 end as expression 17 | from {{ model }} 18 | {%- if row_condition %} 19 | where 20 | {{ row_condition }} 21 | {% endif %} 22 | {% if group_by_columns %} 23 | group by 24 | {% for group_by_column in group_by_columns -%} 25 | {{ group_by_column }}{% if not loop.last %},{% endif %} 26 | {% endfor %} 27 | {% endif %} 28 | 29 | ), 30 | validation_errors as ( 31 | 32 | select 33 | * 34 | from 35 | grouped_expression 36 | where 37 | not(expression {{ test_condition }}) 38 | 39 | ) 40 | 41 | select * 42 | from validation_errors 43 | 44 | {% endmacro %} 45 | -------------------------------------------------------------------------------- /macros/dbt_expectations/schema_tests/aggregate_functions/expect_column_most_common_value_to_be_in_set.sql: -------------------------------------------------------------------------------- 1 | {% macro fabric__test_expect_column_most_common_value_to_be_in_set(model, column_name, 2 | value_set, 3 | top_n, 4 | quote_values=False, 5 | data_type="decimal", 6 | row_condition=None 7 | ) -%} 8 | 9 | with value_counts as ( 10 | 11 | select 12 | {% if quote_values -%} 13 | {{ column_name }} 14 | {%- else -%} 15 | cast({{ column_name }} as {{ data_type }}) 16 | {%- endif %} as value_field, 17 | count(*) as value_count 18 | 19 | from {{ model }} 20 | {% if row_condition %} 21 | where {{ row_condition }} 22 | {% endif %} 23 | 24 | group by {% if quote_values -%} 25 | {{ column_name }} 26 | {%- else -%} 27 | cast({{ column_name }} as {{ data_type }}) 28 | {%- endif %} 29 | 30 | ), 31 | value_counts_ranked as ( 32 | 33 | select 34 | *, 35 | row_number() over(order by value_count desc) as value_count_rank 36 | from 37 | value_counts 38 | 39 | ), 40 | value_count_top_n as ( 41 | 42 | select 43 | value_field 44 | from 45 | value_counts_ranked 46 | where 47 | value_count_rank = {{ top_n }} 48 | 49 | ), 50 | set_values as ( 51 | 52 | {% for value in value_set -%} 53 | select 54 | {% if quote_values -%} 55 | '{{ value }}' 56 | {%- else -%} 57 | cast({{ value }} as {{ data_type }}) 58 | {%- endif %} as value_field 59 | {% if not loop.last %}union all{% endif %} 60 | {% endfor %} 61 | 62 | ), 63 | unique_set_values as ( 64 | 65 | select distinct value_field 66 | from 67 | set_values 68 | 69 | ), 70 | validation_errors as ( 71 | -- values from the model that are not in the set 72 | select 73 | value_field 74 | from 75 | value_count_top_n 76 | where 77 | value_field not in (select value_field from unique_set_values) 78 | 79 | ) 80 | 81 | select * 82 | from validation_errors 83 | 84 | {% endmacro %} 85 | -------------------------------------------------------------------------------- /macros/dbt_expectations/schema_tests/aggregate_functions/expect_column_stdev_to_be_between.sql: -------------------------------------------------------------------------------- 1 | {% macro fabric__test_expect_column_stdev_to_be_between(model, column_name, 2 | min_value, 3 | max_value, 4 | group_by, 5 | row_condition=None, 6 | strictly=False 7 | ) -%} 8 | {% set expression %} 9 | stdev({{ column_name }}) 10 | {% endset %} 11 | {{ dbt_expectations.expression_between(model, 12 | expression=expression, 13 | min_value=min_value, 14 | max_value=max_value, 15 | group_by_columns=group_by, 16 | row_condition=row_condition, 17 | strictly=strictly 18 | ) }} 19 | {% endmacro %} 20 | -------------------------------------------------------------------------------- /macros/dbt_expectations/schema_tests/distributional/expect_column_values_to_be_within_n_moving_stdevs.sql: -------------------------------------------------------------------------------- 1 | {%- macro _get_metric_expression(metric_column, take_logs) -%} 2 | 3 | {%- if take_logs %} 4 | {%- set expr = "nullif(" ~ metric_column ~ ", 0)" -%} 5 | coalesce({{ dbt_expectations.log_natural(expr) }}, 0) 6 | {%- else -%} 7 | coalesce({{ metric_column }}, 0) 8 | {%- endif %} 9 | 10 | {%- endmacro -%} 11 | 12 | 13 | {% macro fabric__test_expect_column_values_to_be_within_n_moving_stdevs(model, 14 | column_name, 15 | date_column_name, 16 | group_by, 17 | period, 18 | lookback_periods, 19 | trend_periods, 20 | test_periods, 21 | sigma_threshold, 22 | sigma_threshold_upper, 23 | sigma_threshold_lower, 24 | take_diffs, 25 | take_logs 26 | ) %} 27 | 28 | {%- set sigma_threshold_upper = sigma_threshold_upper if sigma_threshold_upper else sigma_threshold -%} 29 | {%- set sigma_threshold_lower = sigma_threshold_lower if sigma_threshold_lower else -1 * sigma_threshold -%} 30 | {%- set partition_by = "partition by " ~ (group_by | join(",")) if group_by -%} 31 | {%- set group_by_length = (group_by | length ) if group_by else 0 -%} 32 | 33 | {# TODO: adapt to new group_by arg #} 34 | 35 | with grouped_metric_values as ( 36 | 37 | select 38 | {{ dbt.date_trunc(period, date_column_name) }} as metric_period, 39 | {{ group_by | join(",") ~ "," if group_by }} 40 | sum({{ column_name }}) as agg_metric_value 41 | from 42 | {{ model }} 43 | group by 44 | {{ dbt.date_trunc(period, date_column_name) }} 45 | {% if group_by %} 46 | , {{ group_by | join(",") }} 47 | {% endif %} 48 | 49 | ), 50 | 51 | grouped_metric_values_with_priors as ( 52 | 53 | select 54 | *, 55 | lag(agg_metric_value, {{ lookback_periods }}) over({{ partition_by }} order by metric_period) as prior_agg_metric_value 56 | from 57 | grouped_metric_values d 58 | 59 | ), 60 | 61 | {%- if take_diffs %} 62 | 63 | metric_values as ( 64 | 65 | select 66 | *, 67 | {{ dbt_expectations._get_metric_expression("agg_metric_value", take_logs) }} 68 | - 69 | {{ dbt_expectations._get_metric_expression("prior_agg_metric_value", take_logs) }} 70 | as metric_test_value 71 | from 72 | grouped_metric_values_with_priors d 73 | ), 74 | 75 | {%- else %} 76 | 77 | metric_values as ( 78 | select 79 | *, 80 | {{ dbt_expectations._get_metric_expression("agg_metric_value", take_logs) }} 81 | from 82 | grouped_metric_values 83 | ), 84 | {%- endif %} 85 | 86 | metric_moving_calcs as ( 87 | 88 | select 89 | *, 90 | avg(metric_test_value) 91 | over({{ partition_by }} order by metric_period rows 92 | between {{ trend_periods }} preceding and 1 preceding) as metric_test_rolling_average, 93 | stdev(metric_test_value) 94 | over({{ partition_by }} order by metric_period rows 95 | between {{ trend_periods }} preceding and 1 preceding) as metric_test_rolling_stddev 96 | from 97 | metric_values 98 | 99 | ), 100 | metric_sigma as ( 101 | 102 | select 103 | *, 104 | (metric_test_value - metric_test_rolling_average) as metric_test_delta, 105 | (metric_test_value - metric_test_rolling_average)/nullif(metric_test_rolling_stddev, 0) as metric_test_sigma 106 | from 107 | metric_moving_calcs 108 | 109 | ) 110 | select 111 | count(*) as count 112 | from 113 | metric_sigma 114 | where 115 | 116 | metric_period >= cast( 117 | {{ dbt.dateadd(period, -test_periods, dbt.date_trunc(period, dbt_date.now())) }} 118 | as {{ dbt.type_timestamp() }}) 119 | and 120 | metric_period < {{ dbt.date_trunc(period, dbt_date.now()) }} 121 | and 122 | 123 | not ( 124 | metric_test_sigma >= {{ sigma_threshold_lower }} and 125 | metric_test_sigma <= {{ sigma_threshold_upper }} 126 | ) 127 | {%- endmacro -%} 128 | 129 | -------------------------------------------------------------------------------- /macros/dbt_expectations/schema_tests/distributional/expect_column_values_to_be_within_n_stdevs.sql: -------------------------------------------------------------------------------- 1 | 2 | {% macro fabric__test_expect_column_values_to_be_within_n_stdevs(model, 3 | column_name, 4 | group_by, 5 | sigma_threshold 6 | ) %} 7 | with metric_values as ( 8 | 9 | {% if group_by -%} 10 | select 11 | {{ group_by }} as metric_date, 12 | sum({{ column_name }}) as {{ column_name }} 13 | from 14 | {{ model }} 15 | group by 16 | {{ group_by }} 17 | {%- else -%} 18 | select 19 | {{ column_name }} as {{ column_name }} 20 | from 21 | {{ model }} 22 | {%- endif %} 23 | 24 | ), 25 | metric_values_with_statistics as ( 26 | 27 | select 28 | *, 29 | avg({{ column_name }}) over() as {{ column_name }}_average, 30 | stdev({{ column_name }}) over() as {{ column_name }}_stddev 31 | from 32 | metric_values 33 | 34 | ), 35 | metric_values_z_scores as ( 36 | 37 | select 38 | *, 39 | ({{ column_name }} - {{ column_name }}_average)/{{ column_name }}_stddev as {{ column_name }}_sigma 40 | from 41 | metric_values_with_statistics 42 | 43 | ) 44 | select 45 | count(*) as error_count 46 | from 47 | metric_values_z_scores 48 | where 49 | abs({{ column_name }}_sigma) > {{ sigma_threshold }} 50 | {%- endmacro %} 51 | -------------------------------------------------------------------------------- /macros/dbt_expectations/schema_tests/multi-column/expect_select_column_values_to_be_unique_within_record.sql: -------------------------------------------------------------------------------- 1 | {% macro fabric__test_expect_select_column_values_to_be_unique_within_record(model, 2 | column_list, 3 | quote_columns, 4 | ignore_row_if, 5 | row_condition 6 | ) %} 7 | 8 | {% if not quote_columns %} 9 | {%- set columns=column_list %} 10 | {% elif quote_columns %} 11 | {%- set columns=[] %} 12 | {% for column in column_list -%} 13 | {% set columns = columns.append( adapter.quote(column) ) %} 14 | {%- endfor %} 15 | {% else %} 16 | {{ exceptions.raise_compiler_error( 17 | "`quote_columns` argument for unique_combination_of_columns test must be one of [True, False] Got: '" ~ quote_columns ~"'.'" 18 | ) }} 19 | {% endif %} 20 | 21 | with column_values as ( 22 | 23 | select 24 | row_number() over(order by (SELECT 'does order really matter here?')) as row_index, 25 | {% for column in columns -%} 26 | {{ column }}{% if not loop.last %},{% endif %} 27 | {%- endfor %} 28 | from {{ model }} 29 | where 1=1 30 | {% if row_condition %} 31 | and {{ row_condition }} 32 | {% endif %} 33 | {% if ignore_row_if == "all_values_are_missing" %} 34 | and 35 | ( 36 | {% for column in columns -%} 37 | {{ column }} is not null{% if not loop.last %} and {% endif %} 38 | {%- endfor %} 39 | ) 40 | {% elif ignore_row_if == "any_value_is_missing" %} 41 | and 42 | ( 43 | {% for column in columns -%} 44 | {{ column }} is not null{% if not loop.last %} or {% endif %} 45 | {%- endfor %} 46 | ) 47 | {% endif %} 48 | 49 | ), 50 | unpivot_columns as ( 51 | 52 | {% for column in columns %} 53 | select row_index, '{{ column }}' as column_name, {{ column }} as column_value from column_values 54 | {% if not loop.last %}union all{% endif %} 55 | {% endfor %} 56 | ), 57 | validation_errors as ( 58 | 59 | select 60 | row_index, 61 | count(distinct column_value) as column_values 62 | from unpivot_columns 63 | group by row_index 64 | having count(distinct column_value) < {{ columns | length }} 65 | 66 | ) 67 | select * 68 | from validation_errors 69 | {% endmacro %} 70 | -------------------------------------------------------------------------------- /macros/dbt_expectations/schema_tests/table_shape/expect_grouped_row_values_to_have_recent_data.sql: -------------------------------------------------------------------------------- 1 | {% macro fabric__test_expect_grouped_row_values_to_have_recent_data(model, group_by, timestamp_column, datepart, interval, row_condition=None) %} 2 | with latest_grouped_timestamps as ( 3 | 4 | select 5 | {%- for g in group_by %} 6 | {{ g }}, 7 | {%- endfor %} 8 | max(1) as join_key, 9 | max({{ timestamp_column }}) as latest_timestamp_column 10 | from 11 | {{ model }} 12 | where 13 | -- to exclude erroneous future dates 14 | cast({{ timestamp_column }} as {{ type_timestamp() }}) <= {{ dbt_date.now() }} 15 | {% if row_condition %} 16 | and {{ row_condition }} 17 | {% endif %} 18 | group by 19 | {%- for g in group_by %} 20 | {{g}}{%- if not loop.last %}, {%- endif %} 21 | {%- endfor %} 22 | 23 | ), 24 | total_row_counts as ( 25 | 26 | select 27 | max(1) as join_key, 28 | count(*) as row_count 29 | from 30 | latest_grouped_timestamps 31 | 32 | ), 33 | outdated_grouped_timestamps as ( 34 | 35 | select * 36 | from 37 | latest_grouped_timestamps 38 | where 39 | -- are the max timestamps per group older than the specified cutoff? 40 | latest_timestamp_column < 41 | cast( 42 | {{ dateadd(datepart, interval * -1, dbt_date.now()) }} 43 | as {{ type_timestamp() }} 44 | ) 45 | 46 | ), 47 | validation_errors as ( 48 | 49 | select 50 | r.row_count, 51 | t.* 52 | from 53 | total_row_counts r 54 | left join 55 | outdated_grouped_timestamps t 56 | on r.join_key = t.join_key 57 | where 58 | -- fail if either no rows were returned due to row_condition, 59 | -- or the recency test returned failed rows 60 | r.row_count = 0 61 | or 62 | t.join_key is not null 63 | 64 | ) 65 | select * from validation_errors 66 | {% endmacro %} 67 | -------------------------------------------------------------------------------- /macros/dbt_utils/datetime/date_spine.sql: -------------------------------------------------------------------------------- 1 | {% macro fabric__date_spine_sql(datepart, start_date, end_date) %} 2 | 3 | 4 | with 5 | 6 | l0 as ( 7 | 8 | select c 9 | from (select 1 union all select 1) as d(c) 10 | 11 | ), 12 | l1 as ( 13 | 14 | select 15 | 1 as c 16 | from l0 as a 17 | cross join l0 as b 18 | 19 | ), 20 | 21 | l2 as ( 22 | 23 | select 1 as c 24 | from l1 as a 25 | cross join l1 as b 26 | ), 27 | 28 | l3 as ( 29 | 30 | select 1 as c 31 | from l2 as a 32 | cross join l2 as b 33 | ), 34 | 35 | l4 as ( 36 | 37 | select 1 as c 38 | from l3 as a 39 | cross join l3 as b 40 | ), 41 | 42 | l5 as ( 43 | 44 | select 1 as c 45 | from l4 as a 46 | cross join l4 as b 47 | ), 48 | 49 | nums as ( 50 | 51 | select row_number() over (order by (select null)) as rownum 52 | from l5 53 | ), 54 | 55 | rawdata as ( 56 | 57 | select top ({{dbt.datediff(start_date, end_date, datepart)}}) rownum -1 as n 58 | from nums 59 | order by rownum 60 | ), 61 | 62 | all_periods as ( 63 | 64 | select ( 65 | {{ 66 | dbt.dateadd( 67 | datepart, 68 | 'n', 69 | start_date 70 | ) 71 | }} 72 | ) as date_{{datepart}} 73 | from rawdata 74 | ), 75 | 76 | filtered as ( 77 | 78 | select * 79 | from all_periods 80 | where date_{{datepart}} <= {{ end_date }} 81 | 82 | ) 83 | 84 | select * from filtered 85 | 86 | {% endmacro %} 87 | 88 | 89 | {% macro fabric__date_spine(datepart, start_date, end_date) -%} 90 | 91 | {% set date_spine_query %} 92 | 93 | {{tsql_utils.fabric__date_spine_sql(datepart, start_date, end_date)}} order by 1 94 | 95 | {% endset %} 96 | 97 | 98 | {% set results = run_query(date_spine_query) %} 99 | 100 | {% if execute %} 101 | 102 | {% set results_list = results.columns[0].values() %} 103 | 104 | {% else %} 105 | 106 | {% set results_list = [] %} 107 | 108 | {% endif %} 109 | 110 | {%- for date_field in results_list %} 111 | select '{{ date_field }}' as date_{{datepart}} {{ 'union all ' if not loop.last else '' }} 112 | {% endfor -%} 113 | 114 | {% endmacro %} 115 | -------------------------------------------------------------------------------- /macros/dbt_utils/generic_tests/expression_is_true.sql: -------------------------------------------------------------------------------- 1 | {% macro fabric__test_expression_is_true(model, expression, column_name) %} 2 | 3 | {% set column_list = '*' if should_store_failures() else "1 as col" %} 4 | 5 | select 6 | {{ column_list }} 7 | from {{ model }} 8 | {% if column_name is none %} 9 | where not({{ expression }}) 10 | {%- else %} 11 | where not({{ column_name }} {{ expression }}) 12 | {%- endif %} 13 | 14 | {% endmacro %} 15 | -------------------------------------------------------------------------------- /macros/dbt_utils/schema_cleanup/drop_old_relations.sql: -------------------------------------------------------------------------------- 1 | -- Tidyed up version of Jacob Matson's contribution in the dbt-sqlserver slack channel https://app.slack.com/client/T0VLPD22H/CMRMDDQ9W/thread/CMRMDDQ9W-1625096967.079800 2 | 3 | {% macro fabric__drop_old_relations(dry_run='false') %} 4 | {% if execute %} 5 | {% set current_models = [] %} 6 | {% for node in graph.nodes.values()|selectattr("resource_type", "in", ["model", "seed", "snapshot"])%} 7 | {% do current_models.append(node.name) %} 8 | {% endfor %} 9 | {% endif %} 10 | {% set cleanup_query %} 11 | with models_to_drop as ( 12 | select 13 | case 14 | when table_type = 'BASE TABLE' then 'TABLE' 15 | when table_type = 'VIEW' then 'VIEW' 16 | end as relation_type, 17 | CASE 18 | WHEN table_type = 'VIEW' THEN concat_ws('.', table_schema, table_name) 19 | ELSE concat_ws('.', table_catalog, table_schema, table_name) 20 | END as relation_name 21 | from 22 | [{{ target.database }}].information_schema.tables -- Escape DB name 23 | where 24 | table_schema like '{{ target.schema }}%' 25 | and table_name not in ( 26 | {%- for model in current_models -%} 27 | '{{ model.upper() }}' 28 | {%- if not loop.last -%} 29 | , 30 | {% endif %} 31 | {%- endfor -%}) 32 | ) 33 | select 34 | CONCAT( 'drop ' , relation_type , ' ' , relation_name , ';' ) as drop_commands 35 | from 36 | models_to_drop 37 | where 38 | -- intentionally exclude unhandled table_types, including 'external table` 39 | CONCAT( 'drop ' , relation_type , ' ' , relation_name , ';' ) is not null 40 | {% endset %} 41 | 42 | {% do log(cleanup_query, info=True) %} 43 | {% set drop_commands = run_query(cleanup_query).columns[0].values() %} 44 | 45 | {% do log('dry_run: ' + dry_run|string, info=True) %} 46 | 47 | {% if drop_commands %} 48 | {% for drop_command in drop_commands %} 49 | {% do log(drop_command, info=True) %} 50 | {% if dry_run == 'false' %} 51 | {% do run_query(drop_command) %} 52 | {% endif %} 53 | {% endfor %} 54 | {% else %} 55 | {% do log('No relations to clean.', info=True) %} 56 | {% endif %} 57 | {%- endmacro -%} -------------------------------------------------------------------------------- /macros/dbt_utils/schema_cleanup/drop_schema_by_name.sql: -------------------------------------------------------------------------------- 1 | {% macro fabric__drop_schema_by_name(schema_name) %} 2 | {% set relation = api.Relation.create(database=target.database, schema=schema_name) %} 3 | {% do drop_schema(relation) %} 4 | {% endmacro %} -------------------------------------------------------------------------------- /macros/dbt_utils/schema_cleanup/drop_schemas_by_prefixes.sql: -------------------------------------------------------------------------------- 1 | {% macro fabric__drop_schemas_by_prefixes(prefixes) %} 2 | {# Ensure input is a list to iterate later #} 3 | {% set prefix_list = [prefixes] if prefixes is string else prefixes %} 4 | 5 | {% for prefix in prefix_list %} 6 | {# Fetch all schemas that use the current prefix #} 7 | {% do log('Fetching schemas for ' + prefix + '...', info=True) %} 8 | {% set schemas_table %} 9 | select name 10 | from sys.schemas 11 | where name LIKE '{{prefix}}%' 12 | {% endset %} 13 | {% set schema_names = run_query(schemas_table).columns[0].values() %} 14 | 15 | {# Test if results are empty #} 16 | {% if schema_names is none or schema_names|length == 0 %} 17 | {% do log('None found.', info=True) %} 18 | {% else %} 19 | {# Drop each found schema #} 20 | {% for schema_name in schema_names %} 21 | {% do log('Dropping schema ' + schema_name, info=True) %} 22 | {% do fabric__drop_schema_by_name(schema_name) %} 23 | {% endfor %} 24 | {% endif %} 25 | {% endfor %} 26 | 27 | {% endmacro %} -------------------------------------------------------------------------------- /macros/dbt_utils/schema_tests/mutually_exclusive_ranges.sql: -------------------------------------------------------------------------------- 1 | {% macro fabric__test_mutually_exclusive_ranges(model, lower_bound_column, upper_bound_column, partition_by=None, gaps='allowed', zero_length_range_allowed=False) %} 2 | 3 | {% if gaps == 'not_allowed' %} 4 | {% set allow_gaps_operator='=' %} 5 | {% set allow_gaps_operator_in_words='equal_to' %} 6 | {% elif gaps == 'allowed' %} 7 | {% set allow_gaps_operator='<=' %} 8 | {% set allow_gaps_operator_in_words='less_than_or_equal_to' %} 9 | {% elif gaps == 'required' %} 10 | {% set allow_gaps_operator='<' %} 11 | {% set allow_gaps_operator_in_words='less_than' %} 12 | {% else %} 13 | {{ exceptions.raise_compiler_error( 14 | "`gaps` argument for mutually_exclusive_ranges test must be one of ['not_allowed', 'allowed', 'required'] Got: '" ~ gaps ~"'.'" 15 | ) }} 16 | {% endif %} 17 | {% if not zero_length_range_allowed %} 18 | {% set allow_zero_length_operator='<' %} 19 | {% set allow_zero_length_operator_in_words='less_than' %} 20 | {% elif zero_length_range_allowed %} 21 | {% set allow_zero_length_operator='<=' %} 22 | {% set allow_zero_length_operator_in_words='less_than_or_equal_to' %} 23 | {% else %} 24 | {{ exceptions.raise_compiler_error( 25 | "`zero_length_range_allowed` argument for mutually_exclusive_ranges test must be one of [true, false] Got: '" ~ zero_length_range_allowed ~"'.'" 26 | ) }} 27 | {% endif %} 28 | 29 | {% set partition_clause="partition by " ~ partition_by if partition_by else '' %} 30 | 31 | with window_functions as ( 32 | 33 | select 34 | {% if partition_by %} 35 | {{ partition_by }}, 36 | {% endif %} 37 | {{ lower_bound_column }} as lower_bound, 38 | {{ upper_bound_column }} as upper_bound, 39 | 40 | lead({{ lower_bound_column }}) over ( 41 | {{ partition_clause }} 42 | order by {{ lower_bound_column }} 43 | ) as next_lower_bound, 44 | 45 | case when 46 | row_number() over ( 47 | {{ partition_clause }} 48 | order by {{ lower_bound_column }} desc 49 | ) = 1 50 | then 1 else 0 end as is_last_record 51 | from {{ model }} 52 | 53 | ), 54 | 55 | calc as ( 56 | -- We want to return records where one of our assumptions fails, so we'll use 57 | -- the `not` function with `and` statements so we can write our assumptions nore cleanly 58 | select 59 | *, 60 | 61 | --TODO turn thesse into null ifs or case whens... 62 | 63 | -- For each record: lower_bound should be < upper_bound. 64 | -- Coalesce it to return an error on the null case (implicit assumption 65 | -- these columns are not_null) 66 | coalesce( 67 | lower_bound {{ allow_zero_length_operator }} upper_bound, 68 | false 69 | ) as lower_bound_{{ allow_zero_length_operator_in_words }}_upper_bound, 70 | 71 | -- For each record: upper_bound {{ allow_gaps_operator }} the next lower_bound. 72 | -- Coalesce it to handle null cases for the last record. 73 | coalesce( 74 | upper_bound {{ allow_gaps_operator }} next_lower_bound, 75 | is_last_record, 76 | false 77 | ) as upper_bound_{{ allow_gaps_operator_in_words }}_next_lower_bound 78 | 79 | from window_functions 80 | 81 | ), 82 | 83 | validation_errors as ( 84 | 85 | select 86 | * 87 | from calc 88 | 89 | where not( 90 | -- THE FOLLOWING SHOULD BE TRUE -- 91 | lower_bound_{{ allow_zero_length_operator_in_words }}_upper_bound 92 | and upper_bound_{{ allow_gaps_operator_in_words }}_next_lower_bound 93 | ) 94 | ) 95 | 96 | select * 97 | from validation_errors 98 | {% endmacro %} 99 | -------------------------------------------------------------------------------- /macros/dbt_utils/schema_tests/relationships_where.sql: -------------------------------------------------------------------------------- 1 | {% macro fabric__test_relationships_where(model, column_name, to, field, from_condition, to_condition) %} 2 | 3 | {# override dbt-utils' integration tests args default see: #} 4 | {# https://github.com/fishtown-analytics/dbt-utils/blob/bbba960726667abc66b42624f0d36bbb62c37593/integration_tests/models/schema_tests/schema.yml#L67-L75 #} 5 | {# TSQL has non-ANSI not-equal sign #} 6 | {% if from_condition == 'id <> 4' %} 7 | {% set where = 'id != 4' %} 8 | {% endif %} 9 | 10 | {{ return(dbt_utils.default__test_relationships_where(model, column_name, to, field, from_condition, to_condition)) }} 11 | 12 | {% endmacro %} 13 | -------------------------------------------------------------------------------- /macros/dbt_utils/schema_tests/sequential_values.sql: -------------------------------------------------------------------------------- 1 | {% macro fabric__test_sequential_values(model, column_name, interval=1, datepart=None, group_by_columns = []) %} 2 | 3 | {% if group_by_columns|length() > 0 %} 4 | {% set select_gb_cols = group_by_columns|join(',') + ', ' %} 5 | {% set partition_gb_cols = 'partition by ' + group_by_columns|join(',') %} 6 | {% endif %} 7 | 8 | with windowed as ( 9 | 10 | select 11 | {{ select_gb_cols }} 12 | {{ column_name }}, 13 | lag({{ column_name }}) over ( 14 | {{partition_gb_cols}} 15 | order by {{ column_name }} 16 | ) as {{ previous_column_name }} 17 | from {{ model }} required_alias_for_tsql 18 | ), 19 | 20 | validation_errors as ( 21 | select 22 | * 23 | from windowed 24 | {% if datepart %} 25 | where not(cast({{ column_name }} as {{ dbt.type_timestamp() }})= cast({{ dbt.dateadd(datepart, interval, previous_column_name) }} as {{ dbt.type_timestamp() }})) 26 | {% else %} 27 | where not({{ column_name }} = {{ previous_column_name }} + {{ interval }}) 28 | {% endif %} 29 | ) 30 | 31 | select * 32 | from validation_errors 33 | 34 | {% endmacro %} 35 | -------------------------------------------------------------------------------- /macros/dbt_utils/schema_tests/test_not_null_where.sql: -------------------------------------------------------------------------------- 1 | {% macro fabric__test_not_null_where(model, column_name) %} 2 | 3 | {% set where = kwargs.get('where', kwargs.get('arg')) %} 4 | {# override dbt-utils' integration tests args default see: #} 5 | {# https://github.com/fishtown-analytics/dbt-utils/blob/bbba960726667abc66b42624f0d36bbb62c37593/integration_tests/models/schema_tests/schema.yml#L53-L65 #} 6 | {# TSQL has no bool type #} 7 | {% if where == '_deleted = false' %} 8 | {% set where = '_deleted = 0' %} 9 | {% endif %} 10 | 11 | {{ return(dbt_utils.default__test_not_null_where(model, column_name, **kwargs)) }} 12 | 13 | {% endmacro %} 14 | -------------------------------------------------------------------------------- /macros/dbt_utils/schema_tests/test_unique_where.sql: -------------------------------------------------------------------------------- 1 | {% macro fabric__test_unique_where(model, column_name) %} 2 | {% set where = kwargs.get('where', kwargs.get('arg')) %} 3 | {# override dbt-utils' integration tests args default see: #} 4 | {# https://github.com/fishtown-analytics/dbt-utils/blob/bbba960726667abc66b42624f0d36bbb62c37593/integration_tests/models/schema_tests/schema.yml#L53-L65 #} 5 | {# TSQL has no bool type #} 6 | {% if where == '_deleted = false' %} 7 | {% set where = '_deleted = 0' %} 8 | {% endif %} 9 | 10 | {{ return(dbt_utils.default__test_unique_where(model, column_name=column_name)) }} 11 | 12 | {% endmacro %} 13 | -------------------------------------------------------------------------------- /macros/dbt_utils/sql/deduplicate.sql: -------------------------------------------------------------------------------- 1 | {# 2 | -- This seems to be the best way to do the deduplication in TSQL without introducing 3 | -- a new column for the row number. 4 | #} 5 | {%- macro fabric__deduplicate(relation, partition_by, order_by) -%} 6 | 7 | select top 1 with ties 8 | * 9 | from {{ relation }} 10 | order by row_number() over ( 11 | partition by {{ partition_by }} 12 | order by {{ order_by }} 13 | ) 14 | 15 | {%- endmacro -%} 16 | -------------------------------------------------------------------------------- /macros/dbt_utils/sql/generate_series.sql: -------------------------------------------------------------------------------- 1 | {% macro fabric__generate_series(upper_bound) %} 2 | 3 | {% set n = dbt_utils.get_powers_of_two(upper_bound) %} 4 | 5 | with p as ( 6 | select 0 as generated_number union all select 1 7 | ), unioned as ( 8 | 9 | select 10 | 11 | {% for i in range(n) %} 12 | p{{i}}.generated_number * power(2, {{i}}) 13 | {% if not loop.last %} + {% endif %} 14 | {% endfor %} 15 | + 1 16 | as generated_number 17 | 18 | from 19 | 20 | {% for i in range(n) %} 21 | p as p{{i}} 22 | {% if not loop.last %} cross join {% endif %} 23 | {% endfor %} 24 | 25 | ) 26 | 27 | select * 28 | from unioned 29 | where generated_number <= {{upper_bound}} 30 | {# in TSQL you can't have an order by in a view statement! #} 31 | {# order by generated_number #} 32 | 33 | {% endmacro %} 34 | -------------------------------------------------------------------------------- /macros/dbt_utils/sql/generate_surrogate_key.sql: -------------------------------------------------------------------------------- 1 | {%- macro fabric__generate_surrogate_key(field_list) -%} 2 | 3 | {%- if var('surrogate_key_treat_nulls_as_empty_strings', False) -%} 4 | {%- set default_null_value = "" -%} 5 | {%- else -%} 6 | {%- set default_null_value = '_dbt_utils_surrogate_key_null_' -%} 7 | {%- endif -%} 8 | 9 | {%- set fields = [] -%} 10 | 11 | {%- for field in field_list -%} 12 | 13 | {%- do fields.append( 14 | "coalesce(cast(" ~ field ~ " as " ~ dbt.type_string() ~ "), '" ~ default_null_value ~"')" 15 | ) -%} 16 | 17 | {%- if not loop.last %} 18 | {%- do fields.append("'-'") -%} 19 | {%- endif -%} 20 | 21 | {%- endfor -%} 22 | 23 | {%- if fields|length > 1 %} 24 | {{ dbt.hash(dbt.concat(fields)) }} 25 | {%- else -%} 26 | {{ dbt.hash(fields[0]) }} 27 | {%- endif -%} 28 | 29 | {%- endmacro -%} 30 | -------------------------------------------------------------------------------- /macros/dbt_utils/sql/get_tables_by_pattern_sql.sql: -------------------------------------------------------------------------------- 1 | {% macro fabric__get_tables_by_pattern_sql(schema_pattern, table_pattern, exclude='', database=target.database) %} 2 | 3 | SELECT DISTINCT 4 | table_schema AS "table_schema", 5 | table_name AS "table_name", 6 | {{ dbt_utils.get_table_types_sql() }} 7 | FROM [{{database}}].information_schema.tables -- Escape DB name 8 | WHERE table_schema LIKE '{{ schema_pattern }}' 9 | AND table_name LIKE '{{ table_pattern }}' 10 | AND table_name NOT LIKE '{{ exclude }}' 11 | 12 | {% endmacro %} 13 | -------------------------------------------------------------------------------- /macros/dbt_utils/sql/surrogate_key.sql: -------------------------------------------------------------------------------- 1 | {# 2 | Generates a surrogate key hash like dbt_utils.surrogate_key(), but 3 | provides additional, T-SQL specific parameters and config. 4 | 5 | Example usage: 6 | ```sql 7 | select 8 | {{ tsql_utils.surrogate_key(["id"]) }} as test_key 9 | from src_test 10 | ``` 11 | 12 | Args: 13 | field_list (list): A list of columns or values that should be used to 14 | generate the surrogate key. 15 | 16 | col_type (str): The column type field values will be casted to before 17 | hashing. Useful for when the underlying columns are 18 | nvarchar, for example. 19 | 20 | use_binary_hash (bool): By default the hash is converted to a varchar 21 | string that uses 32 bytes of data. Setting 22 | this parameter to True will keep the key as 23 | varbinary that only uses 16 bytes of data. 24 | 25 | This will reduce space in the database and can 26 | potentially increase join performance, but the 27 | column has to be converted into varchar before 28 | it can be used in Power BI for relationships. 29 | 30 | Returns: 31 | str: SQL code that generates a hashed surrogate key. 32 | 33 | DBT Project Variables: 34 | You can also adjust default settings through variables in your 35 | dbt_project.yml: 36 | 37 | ```yml 38 | vars: 39 | dbt_utils_dispatch_list: ['tsql_utils'] 40 | tsql_utils_surrogate_key_col_type: 'nvarchar(1234)' 41 | tsql_utils_surrogate_key_use_binary_hash: True 42 | ``` 43 | #} 44 | 45 | 46 | {%- macro surrogate_key(field_list, col_type=None, use_binary_hash=None) -%} 47 | 48 | {%- if col_type == None -%} 49 | {%- set col_type = var( 50 | "tsql_utils_surrogate_key_col_type", 51 | "varchar(8000)" 52 | ) -%} 53 | {%- endif -%} 54 | 55 | {%- if use_binary_hash == None -%} 56 | {%- set use_binary_hash = var( 57 | "tsql_utils_surrogate_key_use_binary_hash", 58 | False 59 | ) -%} 60 | {%- endif -%} 61 | 62 | {%- if field_list is string -%} 63 | {%- set field_list = [field_list] -%} 64 | {%- endif -%} 65 | 66 | {%- set fields = [] -%} 67 | 68 | {%- for field in field_list -%} 69 | 70 | {%- set _ = fields.append( 71 | "coalesce(cast(" ~ field ~ " as " ~ col_type ~ "), '')" 72 | ) -%} 73 | 74 | {%- if not loop.last %} 75 | {%- set _ = fields.append("'-'") -%} 76 | {%- endif -%} 77 | 78 | {%- endfor -%} 79 | 80 | {%- if use_binary_hash == True -%} 81 | {%- set key = "hashbytes('md5', " ~ dbt.concat(fields) ~ ")" -%} 82 | {%- else -%} 83 | {%- set key = dbt.hash(dbt.concat(fields)) -%} 84 | {%- endif -%} 85 | 86 | {{ key }} 87 | 88 | {%- endmacro -%} 89 | 90 | {# 91 | Converts a value from a binary surrogate key hash into varchar. 92 | 93 | This is useful if you are using `use_binary_hash=True` for your surrogate keys. Binary columns cannot be used for relationships in Power BI. 94 | 95 | This macro allows you to convert them to varchar inside your report views 96 | before importing them into Power BI to allow relationships on your 97 | surrogate key columns. 98 | 99 | Args: 100 | col (str): The column or value that should be converted from binary 101 | hash to varchar hash. 102 | 103 | Returns: 104 | str: SQL code that converts a varbinary has to varchar. 105 | 106 | #} 107 | {%- macro cast_hash_to_str(col) -%} 108 | convert(varchar(32), {{ col }}, 2) 109 | {%- endmacro -%} 110 | -------------------------------------------------------------------------------- /macros/dbt_utils/sql/width_bucket.sql: -------------------------------------------------------------------------------- 1 | {% macro fabric__width_bucket(expr, min_value, max_value, num_buckets) -%} 2 | 3 | {% set bin_size -%} 4 | (( {{ max_value }} - {{ min_value }} ) / {{ num_buckets }} ) 5 | {%- endset %} 6 | ( 7 | -- to break ties when the amount is exactly at the bucket edge 8 | case 9 | when 10 | {{ dbt.safe_cast(expr, dbt.type_numeric() ) }} % 11 | {{ dbt.safe_cast(bin_size, dbt.type_numeric() ) }} 12 | = 0 13 | then 1 14 | else 0 15 | end 16 | ) + 17 | -- Anything over max_value goes the N+1 bucket 18 | {%- set ceil_val -%} 19 | CEILING(({{ expr }} - {{ min_value }})/{{ bin_size }}) 20 | {%- endset %} 21 | (case when {{ ceil_val }} > ({{ num_buckets }} + 1) 22 | then {{ num_buckets }} + 1 23 | else {{ ceil_val }} 24 | end) 25 | 26 | {%- endmacro %} 27 | -------------------------------------------------------------------------------- /macros/materializations/insert_by_period_helpers.sql: -------------------------------------------------------------------------------- 1 | {% macro get_start_stop_dates(timestamp_field, date_source_models) %} 2 | 3 | {% if config.get('start_date', default=none) is not none %} 4 | 5 | {%- set start_date = config.get('start_date') -%} 6 | {%- set stop_date = config.get('stop_date', default=none) -%} 7 | 8 | {% do return({'start_date': start_date,'stop_date': stop_date}) %} 9 | 10 | {% elif date_source_models is not none %} 11 | 12 | {% if date_source_models is string %} 13 | {% set date_source_models = [date_source_models] %} 14 | {% endif %} 15 | {% set query_sql %} 16 | WITH stage AS ( 17 | {% for source_model in date_source_models %} 18 | SELECT {{ timestamp_field }} FROM {{ ref(source_model) }} 19 | {% if not loop.last %} UNION ALL {% endif %} 20 | {% endfor %}) 21 | 22 | SELECT MIN({{ timestamp_field }}) AS MIN, MAX({{ timestamp_field }}) AS MAX 23 | FROM stage 24 | {% endset %} 25 | 26 | {% set min_max_dict = dbt_utils.get_query_results_as_dict(query_sql) %} 27 | 28 | {% set start_date = min_max_dict['MIN'][0] | string %} 29 | {% set stop_date = min_max_dict['MAX'][0] | string %} 30 | {% set min_max_dates = {"start_date": start_date, "stop_date": stop_date} %} 31 | 32 | {% do return(min_max_dates) %} 33 | 34 | {% else %} 35 | {%- if execute -%} 36 | {{ exceptions.raise_compiler_error("Invalid 'insert_by_period' configuration. Must provide 'start_date' and 'stop_date' and/or 'date_source_models' options.") }} 37 | {%- endif -%} 38 | {% endif %} 39 | 40 | {% endmacro %} 41 | 42 | {% macro check_placeholder(model_sql, placeholder='__PERIOD_FILTER__') %} 43 | 44 | {%- if model_sql.find(placeholder) == -1 -%} 45 | {%- set error_message -%} 46 | Model '{{ model.unique_id }}' does not include the required string '__PERIOD_FILTER__' in its sql 47 | {%- endset -%} 48 | {{ exceptions.raise_compiler_error(error_message) }} 49 | {%- endif -%} 50 | 51 | {% endmacro %} 52 | 53 | {%- macro replace_placeholder_with_period_filter(core_sql, timestamp_field, start_timestamp, stop_timestamp, offset, period) -%} 54 | 55 | {%- set period_filter -%} 56 | 57 | (CAST({{ timestamp_field }} AS DATE) >= DATEADD({{period}}, {{offset}}, CAST('{{ start_timestamp }}' AS DATE)) AND 58 | CAST({{ timestamp_field }} AS DATE) < DATEADD({{period}}, {{offset}} + 1, CAST('{{ start_timestamp }}' AS DATE))) AND 59 | (CAST({{ timestamp_field }} AS DATE) >= CAST('{{start_timestamp}}' AS DATE)) 60 | {%- endset -%} 61 | 62 | {%- set filtered_sql = core_sql | replace("__PERIOD_FILTER__", period_filter) -%} 63 | 64 | {% do return(filtered_sql) %} 65 | 66 | 67 | {%- endmacro %} 68 | 69 | {% macro get_period_boundaries(target_schema, target_table, timestamp_field, start_date, stop_date, period) -%} 70 | 71 | {% set period_boundary_sql -%} 72 | with data as ( 73 | select 74 | coalesce(max({{ timestamp_field }}), '{{ start_date }}') as start_timestamp, 75 | coalesce({{ dbt.dateadd('millisecond', 86399999, "nullif('" ~ stop_date | lower ~ "','none')") }}, 76 | {{ dbt_utils.current_timestamp() }} ) as stop_timestamp 77 | from {{ target_schema }}.{{ target_table }} 78 | ) 79 | select 80 | start_timestamp, 81 | stop_timestamp, 82 | {{ dbt.datediff('start_timestamp', 83 | 'stop_timestamp', 84 | period) }} + 1 as num_periods 85 | from data 86 | {%- endset %} 87 | 88 | {% set period_boundaries_dict = dbt_utils.get_query_results_as_dict(period_boundary_sql) %} 89 | 90 | {% set period_boundaries = {'start_timestamp': period_boundaries_dict['start_timestamp'][0] | string, 91 | 'stop_timestamp': period_boundaries_dict['stop_timestamp'][0] | string, 92 | 'num_periods': period_boundaries_dict['num_periods'][0] | int} %} 93 | 94 | {% do return(period_boundaries) %} 95 | {%- endmacro %} 96 | 97 | {%- macro get_period_of_load(period, offset, start_timestamp) -%} 98 | 99 | {% set period_of_load_sql -%} 100 | SELECT DATEADD({{ period }}, {{ offset }}, CAST('{{start_timestamp}}' AS DATE)) AS period_of_load 101 | {%- endset %} 102 | 103 | {% set period_of_load_dict = dbt_utils.get_query_results_as_dict(period_of_load_sql) %} 104 | 105 | {% set period_of_load = period_of_load_dict['period_of_load'][0] | string %} 106 | 107 | {% do return(period_of_load) %} 108 | {%- endmacro -%} 109 | 110 | {%- macro get_period_filter_sql(target_cols_csv, base_sql, timestamp_field, period, start_timestamp, stop_timestamp, offset) -%} 111 | 112 | {%- set filtered_sql = {'sql': base_sql} -%} 113 | 114 | {%- do filtered_sql.update({'sql': tsql_utils.replace_placeholder_with_period_filter(filtered_sql.sql, 115 | timestamp_field, 116 | start_timestamp, 117 | stop_timestamp, 118 | offset, period)}) -%} 119 | {{ filtered_sql.sql }} 120 | 121 | {%- endmacro %} 122 | -------------------------------------------------------------------------------- /macros/materializations/insert_by_period_materialization.sql: -------------------------------------------------------------------------------- 1 | 2 | {% materialization insert_by_period, adapter = 'fabric' -%} 3 | 4 | {%- set full_refresh_mode = flags.FULL_REFRESH -%} 5 | 6 | {%- set target_relation = this -%} 7 | {%- set existing_relation = load_relation(this) -%} 8 | {%- set tmp_relation = make_temp_relation(this) -%} 9 | 10 | {%- set target_relation = api.Relation.create( 11 | database = target_relation.database, 12 | schema = target_relation.schema, 13 | identifier = target_relation.identifier, 14 | type = 'table' 15 | ) -%} 16 | 17 | 18 | 19 | {%- set timestamp_field = config.require('timestamp_field') -%} 20 | {%- set date_source_models = config.get('date_source_models', default=none) -%} 21 | {%- set unique_key = config.get('unique_key', default=none) -%} 22 | 23 | {%- set start_stop_dates = tsql_utils.get_start_stop_dates(timestamp_field, date_source_models) | as_native -%} 24 | 25 | {%- set period = config.get('period', default='day') -%} 26 | 27 | {%- set to_drop = [] -%} 28 | 29 | {%- do tsql_utils.check_placeholder(sql) -%} 30 | 31 | {{ run_hooks(pre_hooks, inside_transaction=False) }} 32 | 33 | -- `BEGIN` happens here: 34 | {{ run_hooks(pre_hooks, inside_transaction=True) }} 35 | 36 | {% if existing_relation is none %} 37 | 38 | {% set filtered_sql = tsql_utils.replace_placeholder_with_period_filter(sql, timestamp_field, 39 | start_stop_dates.start_date, 40 | start_stop_dates.stop_date, 41 | 0, period) %} 42 | {% set build_sql = create_table_as(False, target_relation, filtered_sql) %} 43 | 44 | {% do to_drop.append(tmp_relation) %} 45 | 46 | {% elif existing_relation.is_view or full_refresh_mode %} 47 | {#-- Make sure the backup doesn't exist so we don't encounter issues with the rename below #} 48 | {% set backup_identifier = existing_relation.identifier ~ "__dbt_backup" %} 49 | {% set backup_relation = existing_relation.incorporate(path={"identifier": backup_identifier}) %} 50 | 51 | {% do adapter.drop_relation(backup_relation) %} 52 | {% do adapter.rename_relation(target_relation, backup_relation) %} 53 | 54 | {% set filtered_sql = tsql_utils.replace_placeholder_with_period_filter(sql, timestamp_field, 55 | start_stop_dates.start_date, 56 | start_stop_dates.stop_date, 57 | 0, period) %} 58 | {% set build_sql = create_table_as(False, target_relation, filtered_sql) %} 59 | 60 | {% do to_drop.append(tmp_relation) %} 61 | {% do to_drop.append(backup_relation) %} 62 | {% else %} 63 | 64 | {% set period_boundaries = tsql_utils.get_period_boundaries(schema, 65 | target_relation.name, 66 | timestamp_field, 67 | start_stop_dates.start_date, 68 | start_stop_dates.stop_date, 69 | period) %} 70 | 71 | {% set target_columns = adapter.get_columns_in_relation(target_relation) %} 72 | {%- set target_cols_csv = target_columns | map(attribute='quoted') | join(', ') -%} 73 | {%- set loop_vars = {'sum_rows_inserted': 0} -%} 74 | 75 | {% for i in range(1, period_boundaries.num_periods) -%} 76 | 77 | {%- set iteration_number = i + 1 -%} 78 | {%- set period_of_load = tsql_utils.get_period_of_load(period, i, period_boundaries.start_timestamp) -%} 79 | 80 | {{ dbt_utils.log_info("Running for {} {} of {} ({}) [{}]".format(period, iteration_number, period_boundaries.num_periods, period_of_load, model.unique_id)) }} 81 | 82 | {%- set tmp_identifier = target_relation.identifier ~ '__dbt_incremental_period' ~ i ~ '_tmp' -%} 83 | {%- set tmp_relation = api.Relation.create( 84 | identifier=tmp_identifier, 85 | database = target_relation.database, 86 | schema = target_relation.schema, 87 | type='table') -%} 88 | 89 | 90 | {% set tmp_table_sql = tsql_utils.get_period_filter_sql(target_cols_csv, sql, timestamp_field, period, 91 | period_boundaries.start_timestamp, 92 | period_boundaries.stop_timestamp, i) %} 93 | 94 | {% call statement() -%} 95 | {{ create_table_as(True, tmp_relation, tmp_table_sql) }} 96 | {%- endcall %} 97 | 98 | {{ adapter.expand_target_column_types(from_relation=tmp_relation, 99 | to_relation=target_relation) }} 100 | 101 | {%- set insert_query_name = 'main-' ~ i -%} 102 | {% call statement(insert_query_name, fetch_result=True) -%} 103 | 104 | {%- if unique_key is not none -%} 105 | delete 106 | from {{ target_relation }} 107 | where ({{ unique_key }}) in ( 108 | select ({{ unique_key }}) 109 | from {{ tmp_relation }} 110 | ); 111 | {%- endif %} 112 | 113 | insert into {{ target_relation }} ({{ target_cols_csv }}) 114 | ( 115 | select {{ target_cols_csv }} 116 | from {{ tmp_relation.include(schema=True) }} 117 | ); 118 | {%- endcall %} 119 | 120 | {% set result = load_result(insert_query_name) %} 121 | 122 | {% if 'response' in result.keys() %} {# added in v0.19.0 #} 123 | {% set rows_inserted = result['response']['rows_affected'] %} 124 | {% else %} {# older versions #} 125 | {% set rows_inserted = result['status'].split(" ")[2] | int %} 126 | {% endif %} 127 | 128 | {%- set sum_rows_inserted = loop_vars['sum_rows_inserted'] + rows_inserted -%} 129 | {%- do loop_vars.update({'sum_rows_inserted': sum_rows_inserted}) %} 130 | 131 | {{ dbt_utils.log_info("Ran for {} {} of {} ({}); {} records inserted [{}]".format(period, iteration_number, 132 | period_boundaries.num_periods, 133 | period_of_load, rows_inserted, 134 | model.unique_id)) }} 135 | 136 | {% do to_drop.append(tmp_relation) %} 137 | {% do adapter.commit() %} 138 | 139 | {% endfor %} 140 | 141 | {% call noop_statement('main', "INSERT {}".format(loop_vars['sum_rows_inserted']) ) -%} 142 | {{ tmp_table_sql }} 143 | {%- endcall %} 144 | 145 | {% endif %} 146 | 147 | {% if build_sql is defined %} 148 | {% call statement("main", fetch_result=True) %} 149 | {{ build_sql }} 150 | {% endcall %} 151 | 152 | {% set result = load_result('main') %} 153 | 154 | {% if 'response' in result.keys() %} {# added in v0.19.0 #} 155 | {% set rows_inserted = result['response']['rows_affected'] %} 156 | {% else %} {# older versions #} 157 | {% set rows_inserted = result['status'].split(" ")[2] | int %} 158 | {% endif %} 159 | 160 | {% call noop_statement('main', "BASE LOAD {}".format(rows_inserted)) -%} 161 | {{ build_sql }} 162 | {%- endcall %} 163 | 164 | {% do adapter.commit() %} 165 | {% endif %} 166 | 167 | {{ run_hooks(post_hooks, inside_transaction=True) }} 168 | 169 | {% for rel in to_drop %} 170 | {% if rel.type is not none %} 171 | {% do adapter.drop_relation(rel) %} 172 | {% endif %} 173 | {% endfor %} 174 | 175 | {{ run_hooks(post_hooks, inside_transaction=False) }} 176 | 177 | {{ return({'relations': [target_relation]}) }} 178 | 179 | {%- endmaterialization %} -------------------------------------------------------------------------------- /requirements.txt: -------------------------------------------------------------------------------- 1 | dbt-fabric==1.8.7 2 | dbt-core==1.8.6 --------------------------------------------------------------------------------