forked from dbt-labs/dbt-snowflake
-
Notifications
You must be signed in to change notification settings - Fork 0
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
ADAP-865: Parameterize where clause, add option to supply list of rel…
…ations (dbt-labs#758) * parameterize where clause, add option to supply list of relations * parameterize where clause, add option to supply list of relations * revert whitespace fix * revert whitespace fix * revert whitespace fix * fix missing macro keyword * point to the dev branch on core, revert before pushing to main * add new macro get_catalog_relations, update get_catalog to share common logic with get_catalog_relations * fixed reference in get_catalog_relations, added original dict version of relations temporarily for testing * remove dict version of relations based get_catalog, point to List[BaseRelation] version * point dev reqs back to main on core * fix typo in schemas argument * add feature flag to turn on relation filtering for get_catalog * update changelog to point to the PR instead of a broken url * Support changes to dbt-core capability system --------- Co-authored-by: Peter Allen Webb <[email protected]>
- Loading branch information
1 parent
4d299f4
commit 2a10e81
Showing
3 changed files
with
129 additions
and
67 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
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,6 @@ | ||
kind: Features | ||
body: Support limiting get_catalog by object name | ||
time: 2023-08-29T15:24:12.649104-04:00 | ||
custom: | ||
Author: mikealfare | ||
Issue: "758" |
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 |
---|---|---|
@@ -1,72 +1,123 @@ | ||
{% macro snowflake__get_catalog(information_schema, schemas) -%} | ||
{% set query %} | ||
with tables as ( | ||
|
||
select | ||
table_catalog as "table_database", | ||
table_schema as "table_schema", | ||
table_name as "table_name", | ||
table_type as "table_type", | ||
comment as "table_comment", | ||
|
||
-- note: this is the _role_ that owns the table | ||
table_owner as "table_owner", | ||
|
||
'Clustering Key' as "stats:clustering_key:label", | ||
clustering_key as "stats:clustering_key:value", | ||
'The key used to cluster this table' as "stats:clustering_key:description", | ||
(clustering_key is not null) as "stats:clustering_key:include", | ||
|
||
'Row Count' as "stats:row_count:label", | ||
row_count as "stats:row_count:value", | ||
'An approximate count of rows in this table' as "stats:row_count:description", | ||
(row_count is not null) as "stats:row_count:include", | ||
|
||
'Approximate Size' as "stats:bytes:label", | ||
bytes as "stats:bytes:value", | ||
'Approximate size of the table as reported by Snowflake' as "stats:bytes:description", | ||
(bytes is not null) as "stats:bytes:include", | ||
|
||
'Last Modified' as "stats:last_modified:label", | ||
to_varchar(convert_timezone('UTC', last_altered), 'yyyy-mm-dd HH24:MI'||'UTC') as "stats:last_modified:value", | ||
'The timestamp for last update/change' as "stats:last_modified:description", | ||
(last_altered is not null and table_type='BASE TABLE') as "stats:last_modified:include" | ||
|
||
from {{ information_schema }}.tables | ||
where ( | ||
{%- for schema in schemas -%} | ||
upper("table_schema") = upper('{{ schema }}'){%- if not loop.last %} or {% endif -%} | ||
{%- endfor -%} | ||
) | ||
|
||
), | ||
|
||
columns as ( | ||
|
||
select | ||
table_catalog as "table_database", | ||
table_schema as "table_schema", | ||
table_name as "table_name", | ||
|
||
column_name as "column_name", | ||
ordinal_position as "column_index", | ||
data_type as "column_type", | ||
comment as "column_comment" | ||
|
||
from {{ information_schema }}.columns | ||
where ( | ||
{%- for schema in schemas -%} | ||
upper("table_schema") = upper('{{ schema }}'){%- if not loop.last %} or {% endif -%} | ||
{%- endfor -%} | ||
) | ||
) | ||
|
||
select * | ||
from tables | ||
join columns using ("table_database", "table_schema", "table_name") | ||
order by "column_index" | ||
|
||
{% set query %} | ||
with tables as ( | ||
{{ snowflake__get_catalog_tables_sql(information_schema) }} | ||
{{ snowflake__get_catalog_schemas_where_clause_sql(schemas) }} | ||
), | ||
columns as ( | ||
{{ snowflake__get_catalog_columns_sql(information_schema) }} | ||
{{ snowflake__get_catalog_schemas_where_clause_sql(schemas) }} | ||
) | ||
{{ snowflake__get_catalog_results_sql() }} | ||
{%- endset -%} | ||
|
||
{{ return(run_query(query)) }} | ||
|
||
{%- endmacro %} | ||
|
||
|
||
{% macro snowflake__get_catalog_relations(information_schema, relations) -%} | ||
|
||
{% set query %} | ||
with tables as ( | ||
{{ snowflake__get_catalog_tables_sql(information_schema) }} | ||
{{ snowflake__get_catalog_relations_where_clause_sql(relations) }} | ||
), | ||
columns as ( | ||
{{ snowflake__get_catalog_columns_sql(information_schema) }} | ||
{{ snowflake__get_catalog_relations_where_clause_sql(relations) }} | ||
) | ||
{{ snowflake__get_catalog_results_sql() }} | ||
{%- endset -%} | ||
|
||
{{ return(run_query(query)) }} | ||
{{ return(run_query(query)) }} | ||
|
||
{%- endmacro %} | ||
|
||
|
||
{% macro snowflake__get_catalog_tables_sql(information_schema) -%} | ||
select | ||
table_catalog as "table_database", | ||
table_schema as "table_schema", | ||
table_name as "table_name", | ||
table_type as "table_type", | ||
comment as "table_comment", | ||
|
||
-- note: this is the _role_ that owns the table | ||
table_owner as "table_owner", | ||
|
||
'Clustering Key' as "stats:clustering_key:label", | ||
clustering_key as "stats:clustering_key:value", | ||
'The key used to cluster this table' as "stats:clustering_key:description", | ||
(clustering_key is not null) as "stats:clustering_key:include", | ||
|
||
'Row Count' as "stats:row_count:label", | ||
row_count as "stats:row_count:value", | ||
'An approximate count of rows in this table' as "stats:row_count:description", | ||
(row_count is not null) as "stats:row_count:include", | ||
|
||
'Approximate Size' as "stats:bytes:label", | ||
bytes as "stats:bytes:value", | ||
'Approximate size of the table as reported by Snowflake' as "stats:bytes:description", | ||
(bytes is not null) as "stats:bytes:include", | ||
|
||
'Last Modified' as "stats:last_modified:label", | ||
to_varchar(convert_timezone('UTC', last_altered), 'yyyy-mm-dd HH24:MI'||'UTC') as "stats:last_modified:value", | ||
'The timestamp for last update/change' as "stats:last_modified:description", | ||
(last_altered is not null and table_type='BASE TABLE') as "stats:last_modified:include" | ||
from {{ information_schema }}.tables | ||
{%- endmacro %} | ||
|
||
|
||
{% macro snowflake__get_catalog_columns_sql(information_schema) -%} | ||
select | ||
table_catalog as "table_database", | ||
table_schema as "table_schema", | ||
table_name as "table_name", | ||
|
||
column_name as "column_name", | ||
ordinal_position as "column_index", | ||
data_type as "column_type", | ||
comment as "column_comment" | ||
from {{ information_schema }}.columns | ||
{%- endmacro %} | ||
|
||
|
||
{% macro snowflake__get_catalog_results_sql() -%} | ||
select * | ||
from tables | ||
join columns using ("table_database", "table_schema", "table_name") | ||
order by "column_index" | ||
{%- endmacro %} | ||
|
||
|
||
{% macro snowflake__get_catalog_schemas_where_clause_sql(schemas) -%} | ||
where ({%- for schema in schemas -%} | ||
upper("table_schema") = upper('{{ schema }}'){%- if not loop.last %} or {% endif -%} | ||
{%- endfor -%}) | ||
{%- endmacro %} | ||
|
||
|
||
{% macro snowflake__get_catalog_relations_where_clause_sql(relations) -%} | ||
where ( | ||
{%- for relation in relations -%} | ||
{% if relation.schema and relation.identifier %} | ||
( | ||
upper("table_schema") = upper('{{ relation.schema }}') | ||
and upper("table_name") = upper('{{ relation.identifier }}') | ||
) | ||
{% elif relation.schema %} | ||
( | ||
upper("table_schema") = upper('{{ relation.schema }}') | ||
) | ||
{% else %} | ||
{% do exceptions.raise_compiler_error( | ||
'`get_catalog_relations` requires a list of relations, each with a schema' | ||
) %} | ||
{% endif %} | ||
|
||
{%- if not loop.last %} or {% endif -%} | ||
{%- endfor -%} | ||
) | ||
{%- endmacro %} |