diff --git a/README.md b/README.md index f599e213..7918dc49 100644 --- a/README.md +++ b/README.md @@ -212,6 +212,25 @@ models: ``` +#### relationships_where ([source](macros/schema_tests/relationships_where.sql)) +This test validates the referential integrity between two tables (same as the core relationships schema test) with an added predicate to filter out some rows from the test. This is useful to exclude records such as test entities, rows created in the last X minutes/hours to account for temporary gaps due to ETL limitations, etc. + +Usage: +```yaml +version: 2 + +models: + - name: model_name + columns: + - name: id + tests: + - dbt_utils.relationships_where: + to: ref('other_model_name') + field: client_id + from_condition: id <> '4ca448b8-24bf-4b88-96c6-b1609499c38b' + +``` + --- ### SQL helpers #### get_column_values ([source](macros/sql/get_column_values.sql)) diff --git a/integration_tests/data/schema_tests/data_test_relationships_where_table_1.csv b/integration_tests/data/schema_tests/data_test_relationships_where_table_1.csv new file mode 100644 index 00000000..7a8faf79 --- /dev/null +++ b/integration_tests/data/schema_tests/data_test_relationships_where_table_1.csv @@ -0,0 +1,4 @@ +id +1 +2 +3 diff --git a/integration_tests/data/schema_tests/data_test_relationships_where_table_2.csv b/integration_tests/data/schema_tests/data_test_relationships_where_table_2.csv new file mode 100644 index 00000000..60907911 --- /dev/null +++ b/integration_tests/data/schema_tests/data_test_relationships_where_table_2.csv @@ -0,0 +1,4 @@ +id +1 +2 +4 diff --git a/integration_tests/models/schema_tests/schema.yml b/integration_tests/models/schema_tests/schema.yml index 8e4b974a..44e168d3 100644 --- a/integration_tests/models/schema_tests/schema.yml +++ b/integration_tests/models/schema_tests/schema.yml @@ -6,13 +6,13 @@ models: - name: field tests: - dbt_utils.not_constant - + - name: data_test_at_least_one columns: - name: field tests: - dbt_utils.at_least_one - + - name: data_test_expression_is_true tests: - dbt_utils.expression_is_true: @@ -32,11 +32,21 @@ models: tests: - dbt_utils.equal_rowcount: compare_model: ref('test_equal_rowcount') - + - name: data_people columns: - name: is_active tests: - dbt_utils.cardinality_equality: field: is_active - to: ref('data_people') \ No newline at end of file + to: ref('data_people') + + - name: data_test_relationships_where_table_2 + columns: + - name: id + tests: + - dbt_utils.relationships_where: + from: id + to: ref('data_test_relationships_where_table_1') + field: id + from_condition: id <> 4 diff --git a/macros/schema_tests/relationships_where.sql b/macros/schema_tests/relationships_where.sql new file mode 100644 index 00000000..08954b90 --- /dev/null +++ b/macros/schema_tests/relationships_where.sql @@ -0,0 +1,48 @@ +{% macro test_relationships_where(model, to, field) %} + +{% set column_name = kwargs.get('column_name', kwargs.get('from')) %} +{% set from_condition = kwargs.get('from_condition', "true") %} +{% set to_condition = kwargs.get('to_condition', "true") %} + +with left_table as ( + + select + {{column_name}} as id + + from {{model}} + + where {{column_name}} is not null + and {{from_condition}} + +), + +right_table as ( + + select + {{field}} as id + + from {{to}} + + where {{field}} is not null + and {{to_condition}} + +), + +exceptions as ( + + select + left_table.id, + right_table.id as right_id + + from left_table + + left join right_table + on left_table.id = right_table.id + + where right_table.id is null + +) + +select count(*) from exceptions + +{% endmacro %}