diff --git a/CHANGELOG.md b/CHANGELOG.md index bfb78dab..ec79de28 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -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 diff --git a/README.md b/README.md index 09b76c93..9ffe841b 100644 --- a/README.md +++ b/README.md @@ -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)) diff --git a/integration_tests/data/sql/data_unpivot_quote.csv b/integration_tests/data/sql/data_unpivot_quote.csv new file mode 100644 index 00000000..958e05f3 --- /dev/null +++ b/integration_tests/data/sql/data_unpivot_quote.csv @@ -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 diff --git a/integration_tests/data/sql/data_unpivot_quote_expected.csv b/integration_tests/data/sql/data_unpivot_quote_expected.csv new file mode 100644 index 00000000..a370a32c --- /dev/null +++ b/integration_tests/data/sql/data_unpivot_quote_expected.csv @@ -0,0 +1,7 @@ +customer_id,created_at,prop,Value +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" diff --git a/integration_tests/dbt_project.yml b/integration_tests/dbt_project.yml index a9531e78..27ad0ee7 100644 --- a/integration_tests/dbt_project.yml +++ b/integration_tests/dbt_project.yml @@ -48,6 +48,11 @@ seeds: num_buckets: integer min_value: float max_value: float + + data_unpivot_quote: + +quote_columns: true + data_unpivot_quote_expected: + +quote_columns: true schema_tests: data_test_sequential_timestamps: diff --git a/integration_tests/models/sql/schema.yml b/integration_tests/models/sql/schema.yml index e79e782f..57ab7edb 100644 --- a/integration_tests/models/sql/schema.yml +++ b/integration_tests/models/sql/schema.yml @@ -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: diff --git a/integration_tests/models/sql/test_unpivot_quote.sql b/integration_tests/models/sql/test_unpivot_quote.sql new file mode 100644 index 00000000..89069649 --- /dev/null +++ b/integration_tests/models/sql/test_unpivot_quote.sql @@ -0,0 +1,21 @@ + +select + customer_id, + created_at, + case + when '{{ target.name }}' = 'snowflake' then lower(prop) + else prop + end as prop, + "Value" + +from ( + {{ dbt_utils.unpivot( + relation=ref('data_unpivot_quote'), + cast_to=type_string(), + exclude=exclude, + remove=['name'], + field_name='prop', + value_name='Value', + quote_identifiers=True, + ) }} +) as sbq diff --git a/macros/sql/unpivot.sql b/macros/sql/unpivot.sql index 371b314b..c82b45e0 100644 --- a/macros/sql/unpivot.sql +++ b/macros/sql/unpivot.sql @@ -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.") }} @@ -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 }}