-
Notifications
You must be signed in to change notification settings - Fork 166
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
Support for ingestion time partition table on BigQuery as incremental materialization #136
Merged
colin-rogers-dbt
merged 6 commits into
dbt-labs:main
from
Kayrnt:incremental-ingestion-time
Oct 20, 2022
Merged
Changes from all commits
Commits
Show all changes
6 commits
Select commit
Hold shift + click to select a range
492df78
Support for incremental materialization with ingestion time partition…
Kayrnt d562d69
Refactor incremental materialization for readibility
Kayrnt ad072c1
add changelog entry
Kayrnt 7fa4258
Merge branch 'main' into incremental-ingestion-time
McKnight-42 257f318
Merge branch 'main' into incremental-ingestion-time
colin-rogers-dbt 0c5673a
Merge branch 'main' into incremental-ingestion-time
colin-rogers-dbt File filter
Filter by extension
Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
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
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,7 @@ | ||
kind: Features | ||
body: Support for ingestion time partition table on BigQuery as incremental materialization | ||
time: 2022-08-07T16:42:27.232818+02:00 | ||
custom: | ||
Author: Kayrnt | ||
Issue: "75" | ||
PR: "136" |
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
22 changes: 22 additions & 0 deletions
22
dbt/include/bigquery/macros/materializations/incremental_strategy/common.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,22 @@ | ||
{% macro build_partition_time_exp(partition_by) %} | ||
{% if partition_by.data_type == 'timestamp' %} | ||
{% set partition_value = partition_by.field %} | ||
{% else %} | ||
{% set partition_value = 'timestamp(' + partition_by.field + ')' %} | ||
{% endif %} | ||
{{ return({'value': partition_value, 'field': partition_by.field}) }} | ||
{% endmacro %} | ||
|
||
{% macro declare_dbt_max_partition(relation, partition_by, complied_code, language='sql') %} | ||
|
||
{#-- TODO: revisit partitioning with python models --#} | ||
{%- if '_dbt_max_partition' in complied_code and language == 'sql' -%} | ||
|
||
declare _dbt_max_partition {{ partition_by.data_type }} default ( | ||
select max({{ partition_by.field }}) from {{ this }} | ||
where {{ partition_by.field }} is not null | ||
); | ||
|
||
{%- endif -%} | ||
|
||
{% endmacro %} |
93 changes: 93 additions & 0 deletions
93
dbt/include/bigquery/macros/materializations/incremental_strategy/insert_overwrite.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,93 @@ | ||
{% macro bq_generate_incremental_insert_overwrite_build_sql( | ||
tmp_relation, target_relation, sql, unique_key, partition_by, partitions, dest_columns, on_schema_change | ||
) %} | ||
{% if partition_by is none %} | ||
{% set missing_partition_msg -%} | ||
The 'insert_overwrite' strategy requires the `partition_by` config. | ||
{%- endset %} | ||
{% do exceptions.raise_compiler_error(missing_partition_msg) %} | ||
{% endif %} | ||
|
||
{% set build_sql = bq_insert_overwrite( | ||
tmp_relation, target_relation, sql, unique_key, partition_by, partitions, dest_columns, on_schema_change | ||
) %} | ||
|
||
{{ return(build_sql) }} | ||
|
||
{% endmacro %} | ||
|
||
{% macro bq_insert_overwrite( | ||
tmp_relation, target_relation, sql, unique_key, partition_by, partitions, dest_columns, tmp_relation_exists | ||
) %} | ||
|
||
{% if partitions is not none and partitions != [] %} {# static #} | ||
|
||
{% set predicate -%} | ||
{{ partition_by.render_wrapped(alias='DBT_INTERNAL_DEST') }} in ( | ||
{{ partitions | join (', ') }} | ||
) | ||
{%- endset %} | ||
|
||
{%- set source_sql -%} | ||
( | ||
{%- if partition_by.time_ingestion_partitioning -%} | ||
{{ wrap_with_time_ingestion_partitioning(build_partition_time_exp(partition_by), sql, True) }} | ||
{%- else -%} | ||
{{sql}} | ||
{%- endif -%} | ||
) | ||
{%- endset -%} | ||
|
||
{#-- Because we're putting the model SQL _directly_ into the MERGE statement, | ||
we need to prepend the MERGE statement with the user-configured sql_header, | ||
which may be needed to resolve that model SQL (e.g. referencing a variable or UDF in the header) | ||
in the "dynamic" case, we save the model SQL result as a temp table first, wherein the | ||
sql_header is included by the create_table_as macro. | ||
#} | ||
{{ get_insert_overwrite_merge_sql(target_relation, source_sql, dest_columns, [predicate], include_sql_header=true) }} | ||
|
||
{% else %} {# dynamic #} | ||
|
||
{% set predicate -%} | ||
{{ partition_by.render_wrapped(alias='DBT_INTERNAL_DEST') }} in unnest(dbt_partitions_for_replacement) | ||
{%- endset %} | ||
|
||
{%- set source_sql -%} | ||
( | ||
select | ||
{% if partition_by.time_ingestion_partitioning -%} | ||
_PARTITIONTIME, | ||
{%- endif -%} | ||
* from {{ tmp_relation }} | ||
) | ||
{%- endset -%} | ||
|
||
-- generated script to merge partitions into {{ target_relation }} | ||
declare dbt_partitions_for_replacement array<{{ partition_by.data_type }}>; | ||
|
||
{# have we already created the temp table to check for schema changes? #} | ||
{% if not tmp_relation_exists %} | ||
{{ declare_dbt_max_partition(this, partition_by, sql) }} | ||
|
||
-- 1. create a temp table | ||
{{ bq_create_table_as(partition_by.time_ingestion_partitioning, True, tmp_relation, compiled_code) }} | ||
{% else %} | ||
-- 1. temp table already exists, we used it to check for schema changes | ||
{% endif %} | ||
|
||
-- 2. define partitions to update | ||
set (dbt_partitions_for_replacement) = ( | ||
select as struct | ||
array_agg(distinct {{ partition_by.render_wrapped() }}) | ||
from {{ tmp_relation }} | ||
); | ||
|
||
-- 3. run the merge statement | ||
{{ get_insert_overwrite_merge_sql(target_relation, source_sql, dest_columns, [predicate]) }}; | ||
|
||
-- 4. clean up the temp table | ||
drop table if exists {{ tmp_relation }} | ||
|
||
{% endif %} | ||
|
||
{% endmacro %} |
Oops, something went wrong.
Add this suggestion to a batch that can be applied as a single commit.
This suggestion is invalid because no changes were made to the code.
Suggestions cannot be applied while the pull request is closed.
Suggestions cannot be applied while viewing a subset of changes.
Only one suggestion per line can be applied in a batch.
Add this suggestion to a batch that can be applied as a single commit.
Applying suggestions on deleted lines is not supported.
You must change the existing code in this line in order to create a valid suggestion.
Outdated suggestions cannot be applied.
This suggestion has been applied or marked resolved.
Suggestions cannot be applied from pending reviews.
Suggestions cannot be applied on multi-line comments.
Suggestions cannot be applied while the pull request is queued to merge.
Suggestion cannot be applied right now. Please check back later.
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
do we need to include "time" type here as well?
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
As far as I know, it's not possible to partition by "time", see https://cloud.google.com/bigquery/docs/partitioned-tables?hl=fr
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
ahh makes sense, thanks for the clarification!