Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

New test: accepted_range #276

Merged
merged 5 commits into from
Sep 15, 2020
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
39 changes: 39 additions & 0 deletions README.md
Original file line number Diff line number Diff line change
Expand Up @@ -418,6 +418,45 @@ An optional `quote_columns` parameter (`default=false`) can also be used if a co
quote_columns: true
```


#### accepted_range ([source](macros/schema_tests/accepted_range.sql))
This test checks that a column's values fall inside an expected range. Any combination of `min_value` and `max_value` is allowed, and the range can be inclusive or exclusive. Provide a `where` argument to filter to specific records only.

In addition to comparisons to a scalar value, you can also compare to another column's values. Any data type that supports the `>` or `<` operators can be compared, so you could also run tests like checking that all order dates are in the past.

Usage:
```yaml
version: 2

models:
- name: model_name
columns:
- name: user_id
tests:
- dbt_utils.accepted_range:
min_value: 0
inclusive: false

- name: account_created_at
tests:
- dbt_utils.accepted_range:
max_value: "getdate()"
#inclusive is true by default

- name: num_returned_orders
tests:
- dbt_utils.accepted_range:
min_value: 0
max_value: "num_orders"

- name: num_web_sessions
tests:
- dbt_utils.accepted_range:
min_value: 0
inclusive: false
where: "num_orders > 0"
```

---
### SQL helpers
#### get_query_results_as_dict ([source](macros/sql/get_query_results_as_dict.sql))
Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,3 @@
id
-1
11
19 changes: 19 additions & 0 deletions integration_tests/models/schema_tests/schema.yml
Original file line number Diff line number Diff line change
Expand Up @@ -101,3 +101,22 @@ models:
combination_of_columns:
- month
- product

- name: data_test_accepted_range
columns:
- name: id
tests:
- dbt_utils.accepted_range:
min_value: -1
max_value: 11
inclusive: true

- dbt_utils.accepted_range:
min_value: -2
max_value: 11.1
inclusive: false

- dbt_utils.accepted_range:
min_value: 0
inclusive: true
where: "id <> -1"
32 changes: 32 additions & 0 deletions macros/schema_tests/accepted_range.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,32 @@
{% macro test_accepted_range(model, min_value = none, max_value = none, inclusive = true, where = "true") %}

{%- set column_name = kwargs.get('column_name', kwargs.get('field')) -%}

with meet_condition as(
select {{ column_name }}
from {{ model }}
where {{ where }}
),

validation_errors as (
select *
from meet_condition
where
-- never true, defaults to an empty result set. Exists to ensure any combo of the `or` clauses below succeeds
1 = 2

{%- if min_value is not none %}
-- records with a value >= min_value are permitted. The `not` flips this to find records that don't meet the rule.
or not {{ column_name }} > {{- "=" if inclusive }} {{ min_value }}
{%- endif %}

{%- if max_value is not none %}
-- records with a value <= max_value are permitted. The `not` flips this to find records that don't meet the rule.
or not {{ column_name }} < {{- "=" if inclusive }} {{ max_value }}
{%- endif %}
)

select count(*)
from validation_errors

{% endmacro %}