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

add macro to get columns #516

Merged
merged 13 commits into from
Mar 28, 2022
46 changes: 43 additions & 3 deletions README.md
Original file line number Diff line number Diff line change
Expand Up @@ -30,6 +30,7 @@ For compatibility details between versions of dbt-core and dbt-utils, [see this

- [Introspective macros](#introspective-macros):
- [get_column_values](#get_column_values-source)
- [get_filtered_columns_in_relation](#get_filtered_columns_in_relation-source)
- [get_relations_by_pattern](#get_relations_by_pattern-source)
- [get_relations_by_prefix](#get_relations_by_prefix-source)
- [get_query_results_as_dict](#get_query_results_as_dict-source)
Expand Down Expand Up @@ -544,7 +545,7 @@ These macros run a query and return the results of the query as objects. They ar
#### get_column_values ([source](macros/sql/get_column_values.sql))
This macro returns the unique values for a column in a given [relation](https://docs.getdbt.com/docs/writing-code-in-dbt/class-reference/#relation) as an array.

Arguments:
**Args:**
- `table` (required): a [Relation](https://docs.getdbt.com/reference/dbt-classes#relation) (a `ref` or `source`) that contains the list of columns you wish to select from
- `column` (required): The name of the column you wish to find the column values of
- `order_by` (optional, default=`'count(*) desc'`): How the results should be ordered. The default is to order by `count(*) desc`, i.e. decreasing frequency. Setting this as `'my_column'` will sort alphabetically, while `'min(created_at)'` will sort by when thevalue was first observed.
Expand Down Expand Up @@ -585,6 +586,28 @@ Arguments:
...
```

#### get_filtered_columns_in_relation ([source](macros/sql/get_filtered_columns_in_relation.sql))
This macro returns an iterable Jinja list of columns for a given [relation](https://docs.getdbt.com/docs/writing-code-in-dbt/class-reference/#relation), (i.e. not from a CTE)
- optionally exclude columns
- the input values are not case-sensitive (input uppercase or lowercase and it will work!)
> Note: The native [`adapter.get_columns_in_relation` macro](https://docs.getdbt.com/reference/dbt-jinja-functions/adapter#get_columns_in_relation) allows you
to pull column names in a non-filtered fashion, also bringing along with it other (potentially unwanted) information, such as dtype, char_size, numeric_precision, etc.

**Args:**
- `from` (required): a [Relation](https://docs.getdbt.com/reference/dbt-classes#relation) (a `ref` or `source`) that contains the list of columns you wish to select from
- `except` (optional, default=`[]`): The name of the columns you wish to exclude. (case-insensitive)

**Usage:**
```sql
-- Returns a list of the columns from a relation, so you can then iterate in a for loop
{% set column_names = dbt_utils.get_filtered_columns_in_relation(from=ref('your_model'), except=["field_1", "field_2"]) %}
...
{% for column_name in column_names %}
max({{ column_name }}) ... as max_'{{ column_name }}',
{% endfor %}
...
```

#### get_relations_by_pattern ([source](macros/sql/get_relations_by_pattern.sql))
Returns a list of [Relations](https://docs.getdbt.com/docs/writing-code-in-dbt/class-reference/#relation)
that match a given schema- or table-name pattern.
Expand Down Expand Up @@ -748,9 +771,19 @@ group by 1,2,3
```

#### star ([source](macros/sql/star.sql))
This macro generates a comma-separated list of all fields that exist in the `from` relation, excluding any fields listed in the `except` argument. The construction is identical to `select * from {{ref('my_model')}}`, replacing star (`*`) with the star macro. This macro also has an optional `relation_alias` argument that will prefix all generated fields with an alias (`relation_alias`.`field_name`).
This macro generates a comma-separated list of all fields that exist in the `from` relation, excluding any fields
listed in the `except` argument. The construction is identical to `select * from {{ref('my_model')}}`, replacing star (`*`) with
the star macro.
This macro also has an optional `relation_alias` argument that will prefix all generated fields with an alias (`relation_alias`.`field_name`).
The macro also has optional `prefix` and `suffix` arguments. When one or both are provided, they will be concatenated onto each field's alias
in the output (`prefix` ~ `field_name` ~ `suffix`). NB: This prevents the output from being used in any context other than a select statement.

The macro also has optional `prefix` and `suffix` arguments. When one or both are provided, they will be concatenated onto each field's alias in the output (`prefix` ~ `field_name` ~ `suffix`). NB: This prevents the output from being used in any context other than a select statement.
**Args:**
- `from` (required): a [Relation](https://docs.getdbt.com/reference/dbt-classes#relation) (a `ref` or `source`) that contains the list of columns you wish to select from
- `except` (optional, default=`[]`): The name of the columns you wish to exclude. (case-insensitive)
- `relation_alias` (optional, default=`''`): will prefix all generated fields with an alias (`relation_alias`.`field_name`).
- `prefix` (optional, default=`''`): will prefix the output `field_name` (`field_name as prefix_field_name`).
- `suffix` (optional, default=`''`): will suffix the output `field_name` (`field_name as field_name_suffix`).
patkearns10 marked this conversation as resolved.
Show resolved Hide resolved

**Usage:**
```sql
Expand All @@ -767,6 +800,13 @@ from {{ ref('my_model') }}

```

```sql
select
{{ dbt_utils.star(from=ref('my_model'), except=["exclude_field_1", "exclude_field_2"], prefix="max_") }}
from {{ ref('my_model') }}

```

#### union_relations ([source](macros/sql/union.sql))

This macro unions together an array of [Relations](https://docs.getdbt.com/docs/writing-code-in-dbt/class-reference/#relation),
Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,4 @@
field_1,field_2,field_3
a,b,c
d,e,f
g,h,i
Original file line number Diff line number Diff line change
@@ -0,0 +1,2 @@
field_2,field_3
h,i
32 changes: 32 additions & 0 deletions integration_tests/macros/assert_equal_values.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,32 @@
{% macro assert_equal_values(actual_object, expected_object) %}
{% if not execute %}

{# pass #}

{% elif actual_object != expected_object %}

{% set msg %}
Expected did not match actual

-----------
Actual:
-----------
--->{{ actual_object }}<---

-----------
Expected:
-----------
--->{{ expected_object }}<---
patkearns10 marked this conversation as resolved.
Show resolved Hide resolved

{% endset %}

{{ log(msg, info=True) }}

select 'fail'

{% else %}

select 'ok' {{ limit_zero() }}

{% endif %}
{% endmacro %}
10 changes: 10 additions & 0 deletions integration_tests/models/sql/schema.yml
Original file line number Diff line number Diff line change
Expand Up @@ -50,6 +50,11 @@ models:
values:
- '5'

- name: test_get_filtered_columns_in_relation
tests:
- dbt_utils.equality:
compare_model: ref('data_filtered_columns_in_relation_expected')

- name: test_get_relations_by_prefix_and_union
columns:
- name: event
Expand Down Expand Up @@ -121,6 +126,11 @@ models:
- dbt_utils.equality:
compare_model: ref('data_star_aggregate_expected')

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

- name: test_surrogate_key
tests:
- assert_equal:
Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,16 @@
{% set exclude_field = 'field_1' %}
{% set column_names = dbt_utils.get_filtered_columns_in_relation(from= ref('data_filtered_columns_in_relation'), except=[exclude_field]) %}

with data as (

select

{% for column_name in column_names %}
max({{ column_name }}) as {{ column_name }} {% if not loop.last %},{% endif %}
{% endfor %}

from {{ ref('data_filtered_columns_in_relation') }}

)

select * from data
13 changes: 13 additions & 0 deletions integration_tests/models/sql/test_star_uppercase.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,13 @@
{% set exclude_field = 'FIELD_3' %}


with data as (

select
{{ dbt_utils.star(from=ref('data_star'), except=[exclude_field]) }}

from {{ ref('data_star') }}

)

select * from data
25 changes: 25 additions & 0 deletions macros/sql/get_filtered_columns_in_relation.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,25 @@
{% macro get_filtered_columns_in_relation(from, except=[]) -%}
{{ return(adapter.dispatch('get_filtered_columns_in_relation', 'dbt_utils')(from, except)) }}
{% endmacro %}

{% macro default__get_filtered_columns_in_relation(from, except=[]) -%}
{%- do dbt_utils._is_relation(from, 'get_filtered_columns_in_relation') -%}
{%- do dbt_utils._is_ephemeral(from, 'get_filtered_columns_in_relation') -%}

{# -- Prevent querying of db in parsing mode. This works because this macro does not create any new refs. #}
{%- if not execute -%}
{{ return('') }}
{% endif %}

{%- set include_cols = [] %}
{%- set cols = adapter.get_columns_in_relation(from) -%}
{%- set except = except | map("lower") | list %}
{%- for col in cols -%}
{%- if col.column|lower not in except -%}
{% do include_cols.append(col.column) %}
{%- endif %}
{%- endfor %}

{{ return(include_cols) }}

{%- endmacro %}
15 changes: 2 additions & 13 deletions macros/sql/star.sql
Original file line number Diff line number Diff line change
Expand Up @@ -11,20 +11,9 @@
{{ return('') }}
{% endif %}

{%- set include_cols = [] %}
{%- set cols = adapter.get_columns_in_relation(from) -%}
{%- set except = except | map("lower") | list %}
{%- for col in cols -%}
{%- for col in dbt_utils.get_filtered_columns_in_relation(from, except) %}

{%- if col.column|lower not in except -%}
{% do include_cols.append(col.column) %}

{%- endif %}
{%- endfor %}

{%- for col in include_cols %}

{%- if relation_alias %}{{ relation_alias }}.{% else %}{%- endif -%}{{ adapter.quote(col)|trim }} {%- if prefix!='' or suffix!='' -%} as {{ adapter.quote(prefix ~ col ~ suffix)|trim }} {%- endif -%}
{%- if relation_alias %}{{ relation_alias }}.{% else %}{%- endif -%}{{ adapter.quote(col)|trim }} {%- if prefix!='' or suffix!='' %} as {{ adapter.quote(prefix ~ col ~ suffix)|trim }} {%- endif -%}
{%- if not loop.last %},{{ '\n ' }}{% endif %}

{%- endfor -%}
Expand Down