-
Notifications
You must be signed in to change notification settings - Fork 504
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Added new macros array_append and array_construct and integration tes…
…ts (#595) * Added new macros array_append and create_array and integration tests * updated casting to use type_string * joined list togeter * updated functionality to only allow for single data type in array to be compatible with postgres * updated test_array_append * replaced {} with [] for matching in postgres * fixed redshift * Added cast_array_to_string macro * updated postgres cast_array_to_string * change name of create_array macro to array_construct * add array_concat macro and integration tests * updated readme and added empty array_contruct to intergation tests * added default array data_type for postgres func * added data_type arg * postgres fix * fix variable name * changed default array data type to integer * updated default data_type to use api.Column.translate_type
- Loading branch information
1 parent
b4931fe
commit ffddc49
Showing
12 changed files
with
249 additions
and
3 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,2 @@ | ||
array_as_string,element,result_as_string | ||
"[1,2,3]",4,"[1,2,3,4]" |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,2 @@ | ||
array_1_as_string,array_2_as_string,result_as_string | ||
"[1,2,3]","[4,5,6]","[1,2,3,4,5,6]" |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,3 @@ | ||
num_input_1,num_input_2,num_input_3,result_as_string | ||
1,2,3,"[1,2,3]" | ||
4,5,6,"[4,5,6]" |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
29 changes: 29 additions & 0 deletions
29
integration_tests/models/cross_db_utils/test_array_append.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,29 @@ | ||
with data as ( | ||
|
||
select | ||
data_array_append.element, | ||
data_array_append.result_as_string, | ||
data_array_construct.num_input_1, | ||
data_array_construct.num_input_2, | ||
data_array_construct.num_input_3 | ||
from {{ ref('data_array_append') }} as data_array_append | ||
left join {{ ref('data_array_construct') }} as data_array_construct | ||
on data_array_append.array_as_string = data_array_construct.result_as_string | ||
|
||
), | ||
|
||
appended_array as ( | ||
|
||
select | ||
{{ dbt_utils.array_append(dbt_utils.array_construct(['num_input_1', 'num_input_2', 'num_input_3']), 'element') }} as array_actual, | ||
result_as_string as expected | ||
from data | ||
|
||
) | ||
|
||
-- we need to cast the arrays to strings in order to compare them to the output in our seed file | ||
select | ||
array_actual, | ||
{{ dbt_utils.cast_array_to_string('array_actual') }} as actual, | ||
expected | ||
from appended_array |
36 changes: 36 additions & 0 deletions
36
integration_tests/models/cross_db_utils/test_array_concat.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,36 @@ | ||
with data as ( | ||
|
||
select | ||
data_array_concat.result_as_string, | ||
array_1.num_input_1 as array_1_num_input_1, | ||
array_1.num_input_2 as array_1_num_input_2, | ||
array_1.num_input_3 as array_1_num_input_3, | ||
array_2.num_input_1 as array_2_num_input_1, | ||
array_2.num_input_2 as array_2_num_input_2, | ||
array_2.num_input_3 as array_2_num_input_3 | ||
from {{ ref('data_array_concat') }} as data_array_concat | ||
left join {{ ref('data_array_construct') }} as array_1 | ||
on data_array_concat.array_1_as_string = array_1.result_as_string | ||
left join {{ ref('data_array_construct') }} as array_2 | ||
on data_array_concat.array_2_as_string = array_2.result_as_string | ||
|
||
), | ||
|
||
concat_array as ( | ||
|
||
select | ||
{{ dbt_utils.array_concat( | ||
dbt_utils.array_construct(['array_1_num_input_1', 'array_1_num_input_2', 'array_1_num_input_3']), | ||
dbt_utils.array_construct(['array_2_num_input_1', 'array_2_num_input_2', 'array_2_num_input_3']) | ||
) }} as array_actual, | ||
result_as_string as expected | ||
from data | ||
|
||
) | ||
|
||
-- we need to cast the arrays to strings in order to compare them to the output in our seed file | ||
select | ||
array_actual, | ||
{{ dbt_utils.cast_array_to_string('array_actual') }} as actual, | ||
expected | ||
from concat_array |
27 changes: 27 additions & 0 deletions
27
integration_tests/models/cross_db_utils/test_array_construct.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,27 @@ | ||
with data as ( | ||
|
||
select * from {{ ref('data_array_construct') }} | ||
|
||
), | ||
|
||
array_construct as ( | ||
select | ||
{{ dbt_utils.array_construct(['num_input_1', 'num_input_2', 'num_input_3']) }} as array_actual, | ||
result_as_string as expected | ||
|
||
from data | ||
|
||
union all | ||
|
||
select | ||
{{ dbt_utils.array_construct() }} as array_actual, | ||
'[]' as expected | ||
|
||
) | ||
|
||
-- we need to cast the arrays to strings in order to compare them to the output in our seed file | ||
select | ||
array_actual, | ||
{{ dbt_utils.cast_array_to_string('array_actual') }} as actual, | ||
expected | ||
from array_construct |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,16 @@ | ||
{% macro array_append(array, new_element) -%} | ||
{{ return(adapter.dispatch('array_append', 'dbt_utils')(array, new_element)) }} | ||
{%- endmacro %} | ||
|
||
{# new_element must be the same data type as elements in array to match postgres functionality #} | ||
{% macro default__array_append(array, new_element) -%} | ||
array_append({{ array }}, {{ new_element }}) | ||
{%- endmacro %} | ||
|
||
{% macro bigquery__array_append(array, new_element) -%} | ||
{{ dbt_utils.array_concat(array, dbt_utils.array_construct([new_element])) }} | ||
{%- endmacro %} | ||
|
||
{% macro redshift__array_append(array, new_element) -%} | ||
{{ dbt_utils.array_concat(array, dbt_utils.array_construct([new_element])) }} | ||
{%- endmacro %} |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,15 @@ | ||
{% macro array_concat(array_1, array_2) -%} | ||
{{ return(adapter.dispatch('array_concat', 'dbt_utils')(array_1, array_2)) }} | ||
{%- endmacro %} | ||
|
||
{% macro default__array_concat(array_1, array_2) -%} | ||
array_cat({{ array_1 }}, {{ array_2 }}) | ||
{%- endmacro %} | ||
|
||
{% macro bigquery__array_concat(array_1, array_2) -%} | ||
array_concat({{ array_1 }}, {{ array_2 }}) | ||
{%- endmacro %} | ||
|
||
{% macro redshift__array_concat(array_1, array_2) -%} | ||
array_concat({{ array_1 }}, {{ array_2 }}) | ||
{%- endmacro %} |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,24 @@ | ||
{% macro array_construct(inputs = [], data_type = api.Column.translate_type('integer')) -%} | ||
{{ return(adapter.dispatch('array_construct', 'dbt_utils')(inputs, data_type)) }} | ||
{%- endmacro %} | ||
|
||
{# all inputs must be the same data type to match postgres functionality #} | ||
{% macro default__array_construct(inputs, data_type) -%} | ||
{% if inputs|length > 0 %} | ||
array[ {{ inputs|join(' , ') }} ] | ||
{% else %} | ||
array[]::{{data_type}}[] | ||
{% endif %} | ||
{%- endmacro %} | ||
|
||
{% macro snowflake__array_construct(inputs, data_type) -%} | ||
array_construct( {{ inputs|join(' , ') }} ) | ||
{%- endmacro %} | ||
|
||
{% macro redshift__array_construct(inputs, data_type) -%} | ||
array( {{ inputs|join(' , ') }} ) | ||
{%- endmacro %} | ||
|
||
{% macro bigquery__array_construct(inputs, data_type) -%} | ||
[ {{ inputs|join(' , ') }} ] | ||
{%- endmacro %} |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,22 @@ | ||
{% macro cast_array_to_string(array) %} | ||
{{ adapter.dispatch('cast_array_to_string', 'dbt_utils') (array) }} | ||
{% endmacro %} | ||
|
||
{% macro default__cast_array_to_string(array) %} | ||
cast({{ array }} as {{ dbt_utils.type_string() }}) | ||
{% endmacro %} | ||
|
||
{# when casting as array to string, postgres uses {} (ex: {1,2,3}) while other dbs use [] (ex: [1,2,3]) #} | ||
{% macro postgres__cast_array_to_string(array) %} | ||
{%- set array_as_string -%}cast({{ array }} as {{ dbt_utils.type_string() }}){%- endset -%} | ||
{{ dbt_utils.replace(dbt_utils.replace(array_as_string,"'}'","']'"),"'{'","'['") }} | ||
{% endmacro %} | ||
|
||
{# redshift should use default instead of postgres #} | ||
{% macro redshift__cast_array_to_string(array) %} | ||
cast({{ array }} as {{ dbt_utils.type_string() }}) | ||
{% endmacro %} | ||
|
||
{% macro bigquery__cast_array_to_string(array) %} | ||
'['||(select string_agg(cast(element as string), ',') from unnest({{ array }}) element)||']' | ||
{% endmacro %} |