From f2c4329f5f3ec6ae7b338d7dcbbac5069c5da2b3 Mon Sep 17 00:00:00 2001 From: Dan Flippo Date: Mon, 31 Jul 2023 11:55:12 -0400 Subject: [PATCH 1/4] Added always_create_constraint config option --- integration_tests/models/schema.yml | 10 ++++++++++ macros/create_constraints.sql | 12 ++++++------ 2 files changed, 16 insertions(+), 6 deletions(-) diff --git a/integration_tests/models/schema.yml b/integration_tests/models/schema.yml index ac642bd..12df991 100644 --- a/integration_tests/models/schema.yml +++ b/integration_tests/models/schema.yml @@ -147,14 +147,24 @@ models: - name: o_orderkey_seq description: "duplicate seq column to test UK" tests: + # This constraint should be skipped because it has failures - dbt_constraints.primary_key: column_name: o_orderkey config: severity: warn + # This constraint should be still generated because always_create_constraint=true + - dbt_constraints.unique_key: + column_name: o_orderkey + config: + warn_if: ">= 5000" + error_if: ">= 10000" + always_create_constraint: true + # This constraint should be still generated because always_create_constraint=true - dbt_constraints.unique_key: column_name: o_orderkey_seq config: severity: warn + always_create_constraint: true - name: fact_order_line_missing_orders description: "Test that we do not create FK on failed tests" diff --git a/macros/create_constraints.sql b/macros/create_constraints.sql index 7b7e9dd..faf6299 100644 --- a/macros/create_constraints.sql +++ b/macros/create_constraints.sql @@ -168,14 +168,14 @@ {#- Loop through the results and find all tests that passed and match the constraint_types -#} {#- Issue #2: added condition that the where config must be empty -#} {%- for res in results - if res.status == "pass" - and res.node.config.materialized == "test" + if res.node.config.materialized == "test" + and res.status in ("pass", "warn") and res.node.test_metadata and res.node.test_metadata.name is in( constraint_types ) - and res.failures == 0 - and res.node.config.error_if == '!= 0' - and res.node.config.warn_if == '!= 0' - and res.node.config.where is none -%} + and ( res.failures == 0 or + res.node.config.get("always_create_constraint", false) ) + and ( res.node.config.where is none or + res.node.config.get("always_create_constraint", false) ) -%} {%- set test_model = res.node -%} {%- set test_parameters = test_model.test_metadata.kwargs -%} From 52f8773a749f8900fbdd653d6bc08931321a9859 Mon Sep 17 00:00:00 2001 From: Dan Flippo Date: Mon, 31 Jul 2023 12:18:20 -0400 Subject: [PATCH 2/4] Initially comment out feature --- integration_tests/models/schema.yml | 8 ++++---- 1 file changed, 4 insertions(+), 4 deletions(-) diff --git a/integration_tests/models/schema.yml b/integration_tests/models/schema.yml index 12df991..8e498a2 100644 --- a/integration_tests/models/schema.yml +++ b/integration_tests/models/schema.yml @@ -152,19 +152,19 @@ models: column_name: o_orderkey config: severity: warn - # This constraint should be still generated because always_create_constraint=true + # This constraint can be generated if you uncomment always_create_constraint=true - dbt_constraints.unique_key: column_name: o_orderkey config: warn_if: ">= 5000" error_if: ">= 10000" - always_create_constraint: true - # This constraint should be still generated because always_create_constraint=true + # always_create_constraint: true + # This constraint can be generated if you uncomment always_create_constraint=true - dbt_constraints.unique_key: column_name: o_orderkey_seq config: severity: warn - always_create_constraint: true + # always_create_constraint: true - name: fact_order_line_missing_orders description: "Test that we do not create FK on failed tests" From 52c1f276bfd0240f101c29e33dfb8da7aa61d70f Mon Sep 17 00:00:00 2001 From: Dan Flippo Date: Mon, 31 Jul 2023 12:42:32 -0400 Subject: [PATCH 3/4] Updated docs for always_create_constraint --- README.md | 47 +++++++++++++++++++++++++++++++++++++++++++---- 1 file changed, 43 insertions(+), 4 deletions(-) diff --git a/README.md b/README.md index ddf4aec..fd24392 100644 --- a/README.md +++ b/README.md @@ -1,6 +1,6 @@ # dbt Constraints Package -This package generates database constraints based on the tests in a dbt project. It is currently compatible with Snowflake, PostgreSQL, and Oracle only. +This package generates database constraints based on the tests in a dbt project. It is currently compatible with Snowflake, PostgreSQL, Oracle, Redshift, and Vertica only. ## Why data engineers should add referential integrity constraints @@ -117,13 +117,13 @@ packages: Generally, if you don't meet a requirement, tests are still executed but the constraint is skipped rather than producing an error. -- All models involved in a constraint must be materialized as table, incremental, or snapshot. +- All models involved in a constraint must be materialized as table, incremental, snapshot, or seed. - If source constraints are enabled, the source must be a table. You must also have the `OWNERSHIP` table privilege to add a constraint. For foreign keys you also need the `REFERENCES` privilege on the parent table with the primary or unique key. The package will identify when you lack these privileges on Snowflake and PostgreSQL. Oracle does not provide an easy way to look up your effective privileges so it has an exception handler and will display Oracle's error messages. - All columns on constraints must be individual column names, not expressions. You can reference columns on a model that come from an expression. -- Constraints are not created for failed tests +- Constraints are not created for failed tests. See how to get around this using severity and `config: always_create_constraint: true` in the next section. - `primary_key`, `unique_key`, and `foreign_key` tests are considered first and duplicate constraints are skipped. One exception is that you will get an error if you add two different `primary_key` tests to the same model. @@ -133,7 +133,46 @@ Generally, if you don't meet a requirement, tests are still executed but the con - The `foreign_key` test will ignore any rows with a null column, even if only one of two columns in a compound key is null. If you also want to ensure FK columns are not null, you should add standard `not_null` tests to your model which will add not null constraints to the table. -- Referential constraints must apply to all the rows in a table so any tests with a `config: where:` property will be skipped when creating constraints. +- Referential constraints must apply to all the rows in a table so any tests with a `config: where:` property will be skipped when creating constraints. See how to disable this rule using `config: always_create_constraint: true` in the next section. + + +## Advanced: `config: always_create_constraint: true` property +There is an advanced option to force a constraint to be generated when there is a `config: where:` property or if the constraint has a threshold. The `config: always_create_constraint: true` property will override those exclusions. When this setting is in effect, you can create constraints even when you have excluded some records or have a number of failures below a threshold. If your test has a status of 'failed', it will still be skipped. Please see [dbt's documentation on how to set a threshold for failures](https://docs.getdbt.com/reference/resource-configs/severity). + +__Caveat Emptor:__ +* You will get an error if you try to force constraints to be generated that are enforced by your database. On Snowflake that is only a not_null constraint but on databases like Oracle, all the generated constraints are enforced. +* This feature could cause unexpected query results on Snowflake due to [join elimination](https://docs.snowflake.com/en/user-guide/join-elimination). + +This is an example using the feature: +```yml + - name: dim_duplicate_orders + description: "Test that we do not try to create PK/UK on failed tests" + columns: + - name: o_orderkey + description: "The primary key for this table" + - name: o_orderkey_seq + description: "duplicate seq column to test UK" + tests: + # This constraint should be skipped because it has failures + - dbt_constraints.primary_key: + column_name: o_orderkey + config: + severity: warn + # This constraint should be still generated because always_create_constraint=true + - dbt_constraints.unique_key: + column_name: o_orderkey + config: + warn_if: ">= 5000" + error_if: ">= 10000" + always_create_constraint: true + # This constraint should be still generated because always_create_constraint=true + - dbt_constraints.unique_key: + column_name: o_orderkey_seq + config: + severity: warn + always_create_constraint: true +``` + ## Primary Maintainers From 156d923df21013c5bbc5310c770090d4f53ccc34 Mon Sep 17 00:00:00 2001 From: Dan Flippo Date: Mon, 31 Jul 2023 13:27:13 -0400 Subject: [PATCH 4/4] Added differences from model contracts --- README.md | 4 ++++ 1 file changed, 4 insertions(+) diff --git a/README.md b/README.md index fd24392..ec73eb7 100644 --- a/README.md +++ b/README.md @@ -2,6 +2,10 @@ This package generates database constraints based on the tests in a dbt project. It is currently compatible with Snowflake, PostgreSQL, Oracle, Redshift, and Vertica only. +## How the dbt Constraints Package differs from dbt's Model Contracts feature + +This package focuses on automatically generating constraints base on the tests already in a user's dbt project. In most cases, merely adding the dbt Constraints package is all that is needed to generate constraints. dbt's recent [model contracts feature](https://docs.getdbt.com/docs/collaborate/govern/model-contracts) allows users to explicitly document constraints for models in yml. This package and the core feature are 100% compatible with one another and the dbt Constraints package will skip generating constraints already created by a model constract. However, the dbt Constraints package will also generate constraints for any tests that are not documented as model contracts. As decribed in the next section dbt Constraints is also designed to provide join elimination on Snowflake. + ## Why data engineers should add referential integrity constraints The primary reason to add constraints to your database tables is that many tools including [DBeaver](https://dbeaver.io) and [Oracle SQL Developer Data Modeler](https://community.snowflake.com/s/article/How-To-Customizing-Oracle-SQL-Developer-Data-Modeler-SDDM-to-Support-Snowflake-Variant) can correctly reverse-engineer data model diagrams if there are primary keys, unique keys, and foreign keys on tables. Most BI tools will also add joins automatically between tables when you import tables that have foreign keys. This can both save time and avoid mistakes.