Skip to content

Commit

Permalink
Adds 3 parameters to unpivot: remove, field_name, value_name
Browse files Browse the repository at this point in the history
  • Loading branch information
remigabillet committed Jun 19, 2019
1 parent b383a44 commit 178900e
Show file tree
Hide file tree
Showing 8 changed files with 103 additions and 46 deletions.
7 changes: 5 additions & 2 deletions README.md
Original file line number Diff line number Diff line change
Expand Up @@ -337,7 +337,7 @@ This macro "un-pivots" a table from wide format to long format. Functionality is

Usage:
```
{{ dbt_utils.unpivot(table=ref('table_name'), cast_to='datatype', exclude=[<list of columns to exclude from unpivot>]) }}
{{ dbt_utils.unpivot(table=ref('table_name'), cast_to='datatype', exclude=[<list of columns to exclude from unpivot>], remove=[<list of columns to remove>], field_name=<column name for field>, value_name=<column name for value>) }}
```

Example:
Expand All @@ -364,7 +364,10 @@ Arguments:

- table: Table name, required
- cast_to: The data type to cast the unpivoted values to, default is varchar
- exclude: A list of columns to exclude from the unpivot.
- exclude: A list of columns to exclude from the unpivot operation but keep in the resulting table.
- 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

---
### Web
Expand Down
8 changes: 4 additions & 4 deletions integration_tests/data/sql/data_unpivot.csv
Original file line number Diff line number Diff line change
@@ -1,4 +1,4 @@
customer_id,created_at,status,segment
123,2017-01-01,active,tier 1
234,2017-02-01,active,tier 3
567,2017-03-01,churned,tier 2
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
17 changes: 10 additions & 7 deletions integration_tests/data/sql/data_unpivot_expected.csv
Original file line number Diff line number Diff line change
@@ -1,7 +1,10 @@
customer_id,created_at,field_name,value
123,2017-01-01,status,active
123,2017-01-01,segment,tier 1
234,2017-02-01,status,active
234,2017-02-01,segment,tier 3
567,2017-03-01,status,churned
567,2017-03-01,segment,tier 2
customer_id,created_at,prop,val
123,"2017-01-01","segment","tier 1"
123,"2017-01-01","status","active"
123,"2017-01-01","name","name 1"
234,"2017-02-01","segment","tier 3"
234,"2017-02-01","status","active"
234,"2017-02-01","name","name 3"
567,"2017-03-01","status","churned"
567,"2017-03-01","name","name 2"
567,"2017-03-01","segment","tier 2"
10 changes: 10 additions & 0 deletions integration_tests/data/sql/data_unpivot_original_api_expected.csv
Original file line number Diff line number Diff line change
@@ -0,0 +1,10 @@
customer_id,created_at,field_name,value
123,2017-01-01,status,active
123,2017-01-01,segment,tier 1
234,2017-02-01,status,active
234,2017-02-01,segment,tier 3
567,2017-03-01,status,churned
567,2017-03-01,segment,tier 2
123,2017-01-01,name,name 1
234,2017-02-01,name,name 3
567,2017-03-01,name,name 2
37 changes: 21 additions & 16 deletions integration_tests/models/sql/schema.yml
Original file line number Diff line number Diff line change
Expand Up @@ -5,51 +5,51 @@ models:
tests:
- dbt_utils.equality:
arg: ref('data_generate_series')

- name: test_get_column_values
columns:
- name: count_a
tests:
- accepted_values:
values:
- '1'

- name: count_b
tests:
- accepted_values:
values:
- '1'

- name: count_c
tests:
- accepted_values:
values:
- '1'

- name: count_d
tests:
- accepted_values:
values:
- '1'

- name: count_e
tests:
- accepted_values:
values:
- '1'

- name: count_f
tests:
- accepted_values:
values:
- '1'

- name: count_g
tests:
- accepted_values:
values:
- '5'

- name: test_get_tables_by_prefix_and_union
columns:
- name: event
Expand All @@ -60,42 +60,47 @@ models:
- dbt_utils.at_least_one
- not_null
- unique

- name: test_nullcheck_table
columns:
- name: field_1
tests:
- not_empty_string

- name: field_2
tests:
- not_empty_string

- name: field_3
tests:
- not_empty_string

- name: test_pivot
tests:
- dbt_utils.equality:
compare_model: ref('data_pivot_expected')


- name: test_unpivot_original_api
tests:
- dbt_utils.equality:
compare_model: ref('data_unpivot_original_api_expected')

- name: test_unpivot
tests:
- dbt_utils.equality:
compare_model: ref('data_unpivot_expected')

- name: test_star
tests:
- dbt_utils.equality:
compare_model: ref('data_star_expected')

- name: test_surrogate_key
tests:
- assert_equal:
actual: actual
expected: expected

- name: test_union
tests:
- dbt_utils.equality:
Expand Down
14 changes: 5 additions & 9 deletions integration_tests/models/sql/test_unpivot.sql
Original file line number Diff line number Diff line change
Expand Up @@ -11,19 +11,15 @@
{% set exclude = ['customer_id', 'created_at'] %}
{% endif %}

select
customer_id,
created_at,
case
when '{{ target.name }}' = 'snowflake' then lower(field_name)
else field_name
end as field_name,
value
select *

from (
{{ dbt_utils.unpivot(
table=ref('data_unpivot'),
cast_to=dbt_utils.type_string(),
exclude=exclude
exclude=exclude,
remove='name',
field_name='prop',
value_name='val'
) }}
) as sbq
32 changes: 32 additions & 0 deletions integration_tests/models/sql/test_unpivot_original_api.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,32 @@

-- unpivot() was enhanced with 3 new parameters
-- This test targets the original API.

-- snowflake messes with these tests pretty badly since the
-- output of the macro considers the casing of the source
-- table columns. Using some hacks here to get this to work,
-- but we should consider lowercasing the unpivot macro output
-- at some point in the future for consistency

{% if target.name == 'snowflake' %}
{% set exclude = ['CUSTOMER_ID', 'CREATED_AT'] %}
{% else %}
{% set exclude = ['customer_id', 'created_at'] %}
{% endif %}

select
customer_id,
created_at,
case
when '{{ target.name }}' = 'snowflake' then lower(FIELD_NAME)
else field_name
end as field_name,
value

from (
{{ dbt_utils.unpivot(
table=ref('data_unpivot'),
cast_to=dbt_utils.type_string(),
exclude=exclude
) }}
) as sbq
24 changes: 16 additions & 8 deletions macros/sql/unpivot.sql
Original file line number Diff line number Diff line change
@@ -1,17 +1,21 @@
{#
Pivot values from columns to rows.
Pivot values from columns to rows. Similar to pandas DataFrame melt() function.

Example Usage: {{ dbt_utils.unpivot(table=ref('users'), cast_to='integer', exclude=['id','created_at']) }}
Example Usage: {{ unpivot(table=ref('users'), cast_to='integer', exclude=['id','created_at']) }}

Arguments:
table: Relation object, required.
cast_to: The datatype to cast all unpivoted columns to. Default is varchar.
exclude: A list of columns to exclude from the unpivot operation. Default is none.
exclude: A list of columns to keep but exclude from the unpivot operation. Default is none.
remove: A list of columns to remove from the resulting table. Default is none.
field_name: Destination table column name for the source table column names.
value_name: Destination table column name for the pivoted values
#}

{% macro unpivot(table, cast_to='varchar', exclude=none) -%}
{% macro unpivot(table, cast_to='varchar', exclude=none, remove=none, field_name='field_name', value_name='value') -%}

{%- set exclude = exclude if exclude is not none else [] %}
{%- set remove = remove if remove is not none else [] %}

{%- set include_cols = [] %}

Expand All @@ -23,22 +27,26 @@ Arguments:
{%- set cols = adapter.get_columns_in_relation(table) %}

{%- for col in cols -%}
{%- if col.column.lower() not in exclude|map('lower') -%}
{%- if col.column.lower() not in remove|map('lower') and col.column.lower() not in exclude|map('lower') -%}
{% set _ = include_cols.append(col) %}
{%- endif %}
{%- endfor %}

{%- for col in include_cols -%}

{%- for col in include_cols -%}
select
{%- for exclude_col in exclude %}
{{ exclude_col }},
{%- endfor %}
cast('{{ col.column }}' as {{ dbt_utils.type_string() }}) as field_name,
cast({{ col.column }} as {{ cast_to }}) as value

cast('{{ col.column }}' as {{ dbt_utils.type_string() }}) as {{ field_name }},
cast({{ col.column }} as {{ cast_to }}) as {{ value_name }}

from {{ table }}

{% if not loop.last -%}
union all
{% endif -%}
{%- endfor -%}

{%- endmacro %}

0 comments on commit 178900e

Please sign in to comment.