Skip to content

Add "unpivot" macro #72

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

Merged
merged 12 commits into from
Jul 20, 2018
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
34 changes: 34 additions & 0 deletions README.md
Original file line number Diff line number Diff line change
Expand Up @@ -257,6 +257,40 @@ Arguments:
- then_value: Value to use if comparison succeeds, default is 1
- else_value: Value to use if comparison fails, default is 0

#### unpivot ([source](macros/sql/unpivot.sql))
This macro "un-pivots" a table from wide format to long format. Functionality is similar to pandas [melt](http://pandas.pydata.org/pandas-docs/stable/generated/pandas.melt.html) function.

Usage:
```
{{ dbt_utils.unpivot(table=ref('table_name'), cast_to='datatype', exclude=[<list of columns to exclude from unpivot>]) }}
```

Example:

Input: orders

| date | size | color | status |
|------------|------|-------|------------|
| 2017-01-01 | S | red | complete |
| 2017-03-01 | S | red | processing |

{{ dbt_utils.unpivot(ref('orders'), cast_to='varchar', exclude=['date','status']) }}

Output:

| date | status | field_name | value |
|------------|------------|------------|-------|
| 2017-01-01 | complete | size | S |
| 2017-01-01 | complete | color | red |
| 2017-03-01 | processing | size | S |
| 2017-03-01 | processing | color | red |

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.

---
### Web
#### get_url_parameter ([source](macros/web/get_url_parameter.sql))
Expand Down
2 changes: 1 addition & 1 deletion dbt_project.yml
Original file line number Diff line number Diff line change
Expand Up @@ -4,4 +4,4 @@ version: '0.1.0'
target-path: "target"
clean-targets: ["target", "dbt_modules"]
macro-paths: ["macros"]
log-path: "logs"
log-path: "logs"
4 changes: 4 additions & 0 deletions integration_tests/data/sql/data_unpivot.csv
Original file line number Diff line number Diff line change
@@ -0,0 +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
7 changes: 7 additions & 0 deletions integration_tests/data/sql/data_unpivot_expected.csv
Original file line number Diff line number Diff line change
@@ -0,0 +1,7 @@
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
5 changes: 5 additions & 0 deletions integration_tests/models/sql/schema.yml
Original file line number Diff line number Diff line change
Expand Up @@ -41,6 +41,11 @@ test_pivot:
dbt_utils.equality:
- ref('data_pivot_expected')

test_unpivot:
constraints:
dbt_utils.equality:
- ref('data_unpivot_expected')


test_star:
constraints:
Expand Down
1 change: 1 addition & 0 deletions integration_tests/models/sql/test_unpivot.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1 @@
{{ dbt_utils.unpivot(table=ref('data_unpivot'), cast_to='varchar', exclude=['customer_id','created_at']) }}
43 changes: 43 additions & 0 deletions macros/sql/unpivot.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,43 @@
{#
Pivot values from columns to rows.

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

Arguments:
table: Table name, 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.
#}

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

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

{%- set table_columns = {} %}

{%- set _ = table_columns.update({table: []}) %}

{%- if table.name -%}
{%- set schema, table_name = table.schema, table.name -%}
{%- else -%}
{%- set schema, table_name = (table | string).split(".") -%}
{%- endif -%}

{%- set cols = adapter.get_columns_in_table(schema, table_name) %}

{%- for col in cols -%}

{%- if col.column not in exclude -%}
select
{%- for exclude_col in exclude %}
{{ exclude_col }},
{%- endfor %}
cast('{{ col.column }}' as varchar) as field_name,
{{ dbt_utils.safe_cast(field=col.column, type=cast_to) }} as value
from {{ table }}
{% if not loop.last -%}
union all
{% endif -%}
{%- endif -%}
{%- endfor -%}
{%- endmacro %}