Skip to content

Commit

Permalink
Test neighborhood codes in iasworld.pardat.nbhd (#103)
Browse files Browse the repository at this point in the history
* Add column_is_subset_of_external_column dbt generic test and use it to test pardat.nbhd

* Limit pardat_nbhd_matches_spatial_town_nbhd results to filter out years and dummy codes

* Don't cast taxyr to int in pardat nbhd test filter condition

Co-authored-by: Dan Snow <31494343+dfsnow@users.noreply.github.com>

---------

Co-authored-by: Dan Snow <31494343+dfsnow@users.noreply.github.com>
  • Loading branch information
jeancochrane and dfsnow authored Aug 31, 2023
1 parent 8e7a22f commit 96d2f62
Show file tree
Hide file tree
Showing 2 changed files with 41 additions and 0 deletions.
13 changes: 13 additions & 0 deletions dbt/models/iasworld/schema.yml
Original file line number Diff line number Diff line change
Expand Up @@ -143,6 +143,19 @@ sources:
combination_of_columns:
- parid
- taxyr
- column_is_subset_of_external_column:
name: pardat_nbhd_matches_spatial_town_nbhd
column: nbhd
external_model: spatial.neighborhood
external_column: town_nbhd
additional_select_columns:
- parid
- taxyr
config:
# Codes ending in 999 are dummy codes used for some purpose,
# although we do not yet know what it is
where: (taxyr between '2010' and '2021') and (nbhd not like '%999')
error_if: ">1992"
- name: permit
freshness:
filter: date_format(date_parse(permdt, '%Y-%m-%d %H:%i:%s.0'), '%Y') >= date_format(current_date - interval '1' year, '%Y')
Expand Down
28 changes: 28 additions & 0 deletions dbt/tests/generic/test_column_is_subset_of_external_column.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,28 @@
-- Test that a given column is a subset of a column in an external relation.
--
-- Returns rows where `column` has no matches in the external relation, with
-- additional return columns drawn from the base relation as specified by
-- `additional_select_columns`.
{% test column_is_subset_of_external_column(
model,
column,
external_model,
external_column,
additional_select_columns=[]
) %}

{%- set additional_select_columns_csv = additional_select_columns | join(", ") %}
{%- set columns_csv = additional_select_columns_csv ~ ", " ~ column %}

with
distinct_external_values as (
select distinct ({{ external_column }}) as external_column
from {{ external_model }}
)
select {{ columns_csv }}
from {{ model }}
left join
distinct_external_values dist_ext on {{ column }} = dist_ext.external_column
where dist_ext.external_column is null

{% endtest %}

0 comments on commit 96d2f62

Please sign in to comment.