Skip to content

Commit

Permalink
feat(unpivot): add quote identifier parameter to unpivot macro
Browse files Browse the repository at this point in the history
fixes #216
  • Loading branch information
error418 committed May 15, 2023
1 parent 965726e commit 605dcaa
Show file tree
Hide file tree
Showing 8 changed files with 64 additions and 9 deletions.
3 changes: 2 additions & 1 deletion CHANGELOG.md
Original file line number Diff line number Diff line change
Expand Up @@ -10,11 +10,12 @@

# Unreleased
## New features
- XXX ([#XXX](https://github.com/dbt-labs/dbt-utils/issues/XXX), [#XXX](https://github.com/dbt-labs/dbt-utils/pull/XXX))
- Added `quote_identifiers` parameter to `unpivot` macro to handle case sensitive columns. This parameter defaults to `False`.
## Fixes
## Quality of life
## Under the hood
## Contributors:
- [@error418] (https://github.com/error418) (#216)

# dbt utils v1.1.0
## What's Changed
Expand Down
1 change: 1 addition & 0 deletions README.md
Original file line number Diff line number Diff line change
Expand Up @@ -1210,6 +1210,7 @@ Boolean values are replaced with the strings 'true'|'false'
- `remove`: A list of columns to remove from the resulting table.
- `field_name`: column name in the resulting table for field
- `value_name`: column name in the resulting table for value
- `quote_identifiers` (optional, default=`False`): will encase selected columns and aliases in double quotes (`"field_name" as "field_name"`).

### width_bucket ([source](macros/cross_db_utils/width_bucket.sql))

Expand Down
4 changes: 4 additions & 0 deletions integration_tests/data/sql/data_unpivot_quote.csv
Original file line number Diff line number Diff line change
@@ -0,0 +1,4 @@
customer_id,created_at,sTaTuS,SEGMENT,name
123,2017-01-01,active,tier 1,name 1
234,2017-02-01,active,tier 3,name 3
567,2017-03-01,churned,tier 2,name 2
7 changes: 7 additions & 0 deletions integration_tests/data/sql/data_unpivot_quote_expected.csv
Original file line number Diff line number Diff line change
@@ -0,0 +1,7 @@
customer_id,created_at,prop,val
123,"2017-01-01","SEGMENT","tier 1"
123,"2017-01-01","sTaTuS","active"
234,"2017-02-01","SEGMENT","tier 3"
234,"2017-02-01","sTaTuS","active"
567,"2017-03-01","sTaTuS","churned"
567,"2017-03-01","SEGMENT","tier 2"
9 changes: 9 additions & 0 deletions integration_tests/dbt_project.yml
Original file line number Diff line number Diff line change
Expand Up @@ -48,6 +48,15 @@ seeds:
num_buckets: integer
min_value: float
max_value: float

data_unpivot_quote:
+quote_columns: true
+pre-hook: SET enable_case_sensitive_identifier TO true
+post-hook: RESET enable_case_sensitive_identifier
data_unpivot_quote_expected:
+quote_columns: true
+pre-hook: SET enable_case_sensitive_identifier TO true
+post-hook: RESET enable_case_sensitive_identifier

schema_tests:
data_test_sequential_timestamps:
Expand Down
5 changes: 5 additions & 0 deletions integration_tests/models/sql/schema.yml
Original file line number Diff line number Diff line change
Expand Up @@ -158,6 +158,11 @@ models:
- dbt_utils.equality:
compare_model: ref('data_unpivot_bool_expected')

- name: test_unpivot_quote
tests:
- dbt_utils.equality:
compare_model: ref('data_unpivot_quote_expected')

- name: test_star
tests:
- dbt_utils.equality:
Expand Down
27 changes: 27 additions & 0 deletions integration_tests/models/sql/test_unpivot_quote.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,27 @@
{% if target.name == 'redshift' %}
{{
config(
pre_hook="SET enable_case_sensitive_identifier TO true",
post_hook="RESET enable_case_sensitive_identifier"
)
}}
{% endif %}


select
{{ adapter.quote("customer_id") }},
{{ adapter.quote("created_at") }},
{{ adapter.quote("prop") }},
{{ adapter.quote("val") }}

from (
{{ dbt_utils.unpivot(
relation=ref('data_unpivot_quote'),
cast_to=type_string(),
exclude=['customer_id', 'created_at'],
remove=['name'],
field_name='prop',
value_name='val',
quote_identifiers=True,
) }}
) as sbq
17 changes: 9 additions & 8 deletions macros/sql/unpivot.sql
Original file line number Diff line number Diff line change
Expand Up @@ -12,11 +12,11 @@ Arguments:
value_name: Destination table column name for the pivoted values
#}

{% macro unpivot(relation=none, cast_to='varchar', exclude=none, remove=none, field_name='field_name', value_name='value') -%}
{{ return(adapter.dispatch('unpivot', 'dbt_utils')(relation, cast_to, exclude, remove, field_name, value_name)) }}
{% macro unpivot(relation=none, cast_to='varchar', exclude=none, remove=none, field_name='field_name', value_name='value', quote_identifiers=False) -%}
{{ return(adapter.dispatch('unpivot', 'dbt_utils')(relation, cast_to, exclude, remove, field_name, value_name, quote_identifiers)) }}
{% endmacro %}

{% macro default__unpivot(relation=none, cast_to='varchar', exclude=none, remove=none, field_name='field_name', value_name='value') -%}
{% macro default__unpivot(relation=none, cast_to='varchar', exclude=none, remove=none, field_name='field_name', value_name='value', quote_identifiers=False) -%}

{% if not relation %}
{{ exceptions.raise_compiler_error("Error: argument `relation` is required for `unpivot` macro.") }}
Expand All @@ -43,18 +43,19 @@ Arguments:


{%- for col in include_cols -%}
{%- set current_col_name = adapter.quote(col.column) if quote_identifiers else col.column -%}
select
{%- for exclude_col in exclude %}
{{ exclude_col }},
{{ adapter.quote(exclude_col) if quote_identifiers else exclude_col }},
{%- endfor %}

cast('{{ col.column }}' as {{ dbt.type_string() }}) as {{ field_name }},
cast('{{ col.column }}' as {{ dbt.type_string() }}) as {{ adapter.quote(field_name) if quote_identifiers else field_name }},
cast( {% if col.data_type == 'boolean' %}
{{ dbt.cast_bool_to_text(col.column) }}
{{ dbt.cast_bool_to_text(current_col_name) }}
{% else %}
{{ col.column }}
{{ current_col_name }}
{% endif %}
as {{ cast_to }}) as {{ value_name }}
as {{ cast_to }}) as {{ adapter.quote(value_name) if quote_identifiers else value_name }}

from {{ relation }}

Expand Down

0 comments on commit 605dcaa

Please sign in to comment.