From ea7bc7a860ca4ac8689ef1bb57af7115bce37a68 Mon Sep 17 00:00:00 2001 From: swanderz Date: Wed, 24 Nov 2021 12:56:13 -0800 Subject: [PATCH 1/3] align to global_project's dir structure --- dbt/include/sqlserver/macros/adapters.sql | 243 +----------------- .../sqlserver/macros/adapters/columns.sql | 63 +++++ .../sqlserver/macros/adapters/freshness.sql | 3 + .../macros/{ => adapters}/indexes.sql | 22 ++ .../sqlserver/macros/adapters/metadata.sql | 90 +++++++ .../macros/adapters/persist_docs.sql | 4 + .../sqlserver/macros/adapters/relation.sql | 39 +++ .../sqlserver/macros/adapters/schema.sql | 32 +++ dbt/include/sqlserver/macros/catalog.sql | 52 ---- .../models/incremental}/merge.sql | 8 +- .../models/table/create_table_as.sql | 26 ++ .../models/view/create_view_as.sql | 12 + .../{seed/seed.sql => seeds/helpers.sql} | 0 .../{snapshot => snapshots}/snapshot.sql | 0 .../snapshots/snapshot_merge.sql | 3 + .../{snapshot => snapshots}/strategies.sql | 4 + .../macros/materializations/tests/helpers.sql | 12 + .../materializations/{ => tests}/test.sql | 13 - 18 files changed, 316 insertions(+), 310 deletions(-) create mode 100644 dbt/include/sqlserver/macros/adapters/columns.sql create mode 100644 dbt/include/sqlserver/macros/adapters/freshness.sql rename dbt/include/sqlserver/macros/{ => adapters}/indexes.sql (88%) create mode 100644 dbt/include/sqlserver/macros/adapters/metadata.sql create mode 100644 dbt/include/sqlserver/macros/adapters/persist_docs.sql create mode 100644 dbt/include/sqlserver/macros/adapters/relation.sql create mode 100644 dbt/include/sqlserver/macros/adapters/schema.sql delete mode 100644 dbt/include/sqlserver/macros/catalog.sql rename dbt/include/sqlserver/macros/{ => materializations/models/incremental}/merge.sql (75%) create mode 100644 dbt/include/sqlserver/macros/materializations/models/table/create_table_as.sql create mode 100644 dbt/include/sqlserver/macros/materializations/models/view/create_view_as.sql rename dbt/include/sqlserver/macros/materializations/{seed/seed.sql => seeds/helpers.sql} (100%) rename dbt/include/sqlserver/macros/materializations/{snapshot => snapshots}/snapshot.sql (100%) create mode 100644 dbt/include/sqlserver/macros/materializations/snapshots/snapshot_merge.sql rename dbt/include/sqlserver/macros/materializations/{snapshot => snapshots}/strategies.sql (60%) create mode 100644 dbt/include/sqlserver/macros/materializations/tests/helpers.sql rename dbt/include/sqlserver/macros/materializations/{ => tests}/test.sql (74%) diff --git a/dbt/include/sqlserver/macros/adapters.sql b/dbt/include/sqlserver/macros/adapters.sql index 9b297c4e..38fbb762 100644 --- a/dbt/include/sqlserver/macros/adapters.sql +++ b/dbt/include/sqlserver/macros/adapters.sql @@ -1,242 +1,3 @@ -{% macro sqlserver__information_schema_name(database) -%} - information_schema -{%- endmacro %} - - -{% macro sqlserver__get_columns_in_query(select_sql) %} - {% call statement('get_columns_in_query', fetch_result=True, auto_begin=False) -%} - select TOP 0 * from ( - {{ select_sql }} - ) as __dbt_sbq - where 0 = 1 - {% endcall %} - - {{ return(load_result('get_columns_in_query').table.columns | map(attribute='name') | list) }} -{% endmacro %} - - -{% macro sqlserver__list_relations_without_caching(schema_relation) %} - {% call statement('list_relations_without_caching', fetch_result=True) -%} - select - table_catalog as [database], - table_name as [name], - table_schema as [schema], - case when table_type = 'BASE TABLE' then 'table' - when table_type = 'VIEW' then 'view' - else table_type - end as table_type - - from [{{ schema_relation.database }}].information_schema.tables - where table_schema like '{{ schema_relation.schema }}' - {% endcall %} - {{ return(load_result('list_relations_without_caching').table) }} -{% endmacro %} - -{% macro sqlserver__list_schemas(database) %} - {% call statement('list_schemas', fetch_result=True, auto_begin=False) -%} - USE {{ database }}; - select name as [schema] - from sys.schemas - {% endcall %} - {{ return(load_result('list_schemas').table) }} -{% endmacro %} - -{% macro sqlserver__create_schema(relation) -%} - {% call statement('create_schema') -%} - USE [{{ relation.database }}]; - IF NOT EXISTS (SELECT * FROM sys.schemas WHERE name = '{{ relation.without_identifier().schema }}') - BEGIN - EXEC('CREATE SCHEMA {{ relation.without_identifier().schema }}') - END - {% endcall %} -{% endmacro %} - -{% macro sqlserver__drop_schema(relation) -%} - {%- set tables_in_schema_query %} - SELECT TABLE_NAME FROM INFORMATION_SCHEMA.TABLES - WHERE TABLE_SCHEMA = '{{ relation.schema }}' - {% endset %} - {% set tables_to_drop = run_query(tables_in_schema_query).columns[0].values() %} - {% for table in tables_to_drop %} - {%- set schema_relation = adapter.get_relation(database=relation.database, - schema=relation.schema, - identifier=table) -%} - {% do drop_relation(schema_relation) %} - {%- endfor %} - - {% call statement('drop_schema') -%} - IF EXISTS (SELECT * FROM sys.schemas WHERE name = '{{ relation.schema }}') - BEGIN - EXEC('DROP SCHEMA {{ relation.schema }}') - END {% endcall %} -{% endmacro %} - -{% macro sqlserver__drop_relation(relation) -%} - {% call statement('drop_relation', auto_begin=False) -%} - {{ sqlserver__drop_relation_script(relation) }} - {%- endcall %} -{% endmacro %} - -{% macro sqlserver__drop_relation_script(relation) -%} - {% if relation.type == 'view' -%} - {% set object_id_type = 'V' %} - {% elif relation.type == 'table'%} - {% set object_id_type = 'U' %} - {%- else -%} invalid target name - {% endif %} - USE [{{ relation.database }}]; - if object_id ('{{ relation.include(database=False) }}','{{ object_id_type }}') is not null - begin - drop {{ relation.type }} {{ relation.include(database=False) }} - end -{% endmacro %} - -{% macro sqlserver__check_schema_exists(information_schema, schema) -%} - {% call statement('check_schema_exists', fetch_result=True, auto_begin=False) -%} - --USE {{ database_name }} - SELECT count(*) as schema_exist FROM sys.schemas WHERE name = '{{ schema }}' - {%- endcall %} - {{ return(load_result('check_schema_exists').table) }} -{% endmacro %} - - -{% macro sqlserver__create_view_exec(relation, sql) -%} - {%- set temp_view_sql = sql.replace("'", "''") -%} - execute('create view {{ relation.include(database=False) }} as - {{ temp_view_sql }} - '); -{% endmacro %} - - -{% macro sqlserver__create_view_as(relation, sql) -%} - USE [{{ relation.database }}]; - {{ sqlserver__create_view_exec(relation, sql) }} -{% endmacro %} - - -{% macro sqlserver__rename_relation(from_relation, to_relation) -%} - {% call statement('rename_relation') -%} - USE [{{ to_relation.database }}]; - EXEC sp_rename '{{ from_relation.schema }}.{{ from_relation.identifier }}', '{{ to_relation.identifier }}' - IF EXISTS( - SELECT * - FROM sys.indexes - WHERE name='{{ from_relation.schema }}_{{ from_relation.identifier }}_cci' and object_id = OBJECT_ID('{{ from_relation.schema }}.{{ to_relation.identifier }}')) - EXEC sp_rename N'{{ from_relation.schema }}.{{ to_relation.identifier }}.{{ from_relation.schema }}_{{ from_relation.identifier }}_cci', N'{{ from_relation.schema }}_{{ to_relation.identifier }}_cci', N'INDEX' - {%- endcall %} -{% endmacro %} - -{% macro sqlserver__create_clustered_columnstore_index(relation) -%} - {%- set cci_name = relation.schema ~ '_' ~ relation.identifier ~ '_cci' -%} - {%- set relation_name = relation.schema ~ '_' ~ relation.identifier -%} - {%- set full_relation = relation.schema ~ '.' ~ relation.identifier -%} - use [{{ relation.database }}]; - if EXISTS ( - SELECT * FROM - sys.indexes WHERE name = '{{cci_name}}' - AND object_id=object_id('{{relation_name}}') - ) - DROP index {{full_relation}}.{{cci_name}} - CREATE CLUSTERED COLUMNSTORE INDEX {{cci_name}} - ON {{full_relation}} -{% endmacro %} - -{% macro sqlserver__create_table_as(temporary, relation, sql) -%} - {%- set as_columnstore = config.get('as_columnstore', default=true) -%} - {% set tmp_relation = relation.incorporate( - path={"identifier": relation.identifier.replace("#", "") ~ '_temp_view'}, - type='view')-%} - {%- set temp_view_sql = sql.replace("'", "''") -%} - - {{ sqlserver__drop_relation_script(tmp_relation) }} - - {{ sqlserver__drop_relation_script(relation) }} - - USE [{{ relation.database }}]; - EXEC('create view {{ tmp_relation.include(database=False) }} as - {{ temp_view_sql }} - '); - - SELECT * INTO {{ relation }} FROM - {{ tmp_relation }} - - {{ sqlserver__drop_relation_script(tmp_relation) }} - - {% if not temporary and as_columnstore -%} - {{ sqlserver__create_clustered_columnstore_index(relation) }} - {% endif %} - -{% endmacro %} - -{% macro sqlserver__insert_into_from(to_relation, from_relation) -%} +{# {% macro sqlserver__insert_into_from(to_relation, from_relation) -%} SELECT * INTO {{ to_relation }} FROM {{ from_relation }} -{% endmacro %} - -{% macro sqlserver__current_timestamp() -%} - SYSDATETIME() -{%- endmacro %} - -{% macro sqlserver__get_columns_in_relation(relation) -%} - {% call statement('get_columns_in_relation', fetch_result=True) %} - SELECT - column_name, - data_type, - character_maximum_length, - numeric_precision, - numeric_scale - FROM - (select - ordinal_position, - column_name, - data_type, - character_maximum_length, - numeric_precision, - numeric_scale - from [{{ relation.database }}].INFORMATION_SCHEMA.COLUMNS - where table_name = '{{ relation.identifier }}' - and table_schema = '{{ relation.schema }}' - UNION ALL - select - ordinal_position, - column_name collate database_default, - data_type collate database_default, - character_maximum_length, - numeric_precision, - numeric_scale - from tempdb.INFORMATION_SCHEMA.COLUMNS - where table_name like '{{ relation.identifier }}%') cols - order by ordinal_position - - - {% endcall %} - {% set table = load_result('get_columns_in_relation').table %} - {{ return(sql_convert_columns_in_relation(table)) }} -{% endmacro %} - -{% macro sqlserver__make_temp_relation(base_relation, suffix) %} - {% set tmp_identifier = '#' ~ base_relation.identifier ~ suffix %} - {% set tmp_relation = base_relation.incorporate( - path={"identifier": tmp_identifier}) -%} - - {% do return(tmp_relation) %} -{% endmacro %} - -{% macro sqlserver__snapshot_string_as_time(timestamp) -%} - {%- set result = "CONVERT(DATETIME2, '" ~ timestamp ~ "')" -%} - {{ return(result) }} -{%- endmacro %} - -{% macro sqlserver__alter_column_type(relation, column_name, new_column_type) %} - - {%- set tmp_column = column_name + "__dbt_alter" -%} - - {% call statement('alter_column_type') -%} - - alter {{ relation.type }} {{ relation }} add {{ tmp_column }} {{ new_column_type }}; - update {{ relation }} set {{ tmp_column }} = {{ column_name }}; - alter {{ relation.type }} {{ relation }} drop column {{ column_name }}; - exec sp_rename '{{ relation | replace('"', '') }}.{{ tmp_column }}', '{{ column_name }}', 'column' - - {%- endcall -%} - -{% endmacro %} +{% endmacro %} #} diff --git a/dbt/include/sqlserver/macros/adapters/columns.sql b/dbt/include/sqlserver/macros/adapters/columns.sql new file mode 100644 index 00000000..df0f15e9 --- /dev/null +++ b/dbt/include/sqlserver/macros/adapters/columns.sql @@ -0,0 +1,63 @@ +{% macro sqlserver__get_columns_in_relation(relation) -%} + {% call statement('get_columns_in_relation', fetch_result=True) %} + SELECT + column_name, + data_type, + character_maximum_length, + numeric_precision, + numeric_scale + FROM + (select + ordinal_position, + column_name, + data_type, + character_maximum_length, + numeric_precision, + numeric_scale + from [{{ relation.database }}].INFORMATION_SCHEMA.COLUMNS + where table_name = '{{ relation.identifier }}' + and table_schema = '{{ relation.schema }}' + UNION ALL + select + ordinal_position, + column_name collate database_default, + data_type collate database_default, + character_maximum_length, + numeric_precision, + numeric_scale + from tempdb.INFORMATION_SCHEMA.COLUMNS + where table_name like '{{ relation.identifier }}%') cols + order by ordinal_position + + + {% endcall %} + {% set table = load_result('get_columns_in_relation').table %} + {{ return(sql_convert_columns_in_relation(table)) }} +{% endmacro %} + + +{% macro sqlserver__get_columns_in_query(select_sql) %} + {% call statement('get_columns_in_query', fetch_result=True, auto_begin=False) -%} + select TOP 0 * from ( + {{ select_sql }} + ) as __dbt_sbq + where 0 = 1 + {% endcall %} + + {{ return(load_result('get_columns_in_query').table.columns | map(attribute='name') | list) }} +{% endmacro %} + +{% macro sqlserver__alter_column_type(relation, column_name, new_column_type) %} + + {%- set tmp_column = column_name + "__dbt_alter" -%} + + {% call statement('alter_column_type') -%} + + alter {{ relation.type }} {{ relation }} add {{ tmp_column }} {{ new_column_type }}; + update {{ relation }} set {{ tmp_column }} = {{ column_name }}; + alter {{ relation.type }} {{ relation }} drop column {{ column_name }}; + exec sp_rename '{{ relation | replace('"', '') }}.{{ tmp_column }}', '{{ column_name }}', 'column' + + {%- endcall -%} + +{% endmacro %} \ No newline at end of file diff --git a/dbt/include/sqlserver/macros/adapters/freshness.sql b/dbt/include/sqlserver/macros/adapters/freshness.sql new file mode 100644 index 00000000..60268d6e --- /dev/null +++ b/dbt/include/sqlserver/macros/adapters/freshness.sql @@ -0,0 +1,3 @@ +{% macro sqlserver__current_timestamp() -%} + SYSDATETIME() +{%- endmacro %} \ No newline at end of file diff --git a/dbt/include/sqlserver/macros/indexes.sql b/dbt/include/sqlserver/macros/adapters/indexes.sql similarity index 88% rename from dbt/include/sqlserver/macros/indexes.sql rename to dbt/include/sqlserver/macros/adapters/indexes.sql index 7a2d37ce..fb863b8b 100644 --- a/dbt/include/sqlserver/macros/indexes.sql +++ b/dbt/include/sqlserver/macros/adapters/indexes.sql @@ -1,5 +1,27 @@ +{% macro sqlserver__create_clustered_columnstore_index(relation) -%} + {%- set cci_name = relation.schema ~ '_' ~ relation.identifier ~ '_cci' -%} + {%- set relation_name = relation.schema ~ '_' ~ relation.identifier -%} + {%- set full_relation = relation.schema ~ '.' ~ relation.identifier -%} + use [{{ relation.database }}]; + if EXISTS ( + SELECT * FROM + sys.indexes WHERE name = '{{cci_name}}' + AND object_id=object_id('{{relation_name}}') + ) + DROP index {{full_relation}}.{{cci_name}} + CREATE CLUSTERED COLUMNSTORE INDEX {{cci_name}} + ON {{full_relation}} +{% endmacro %} + + +{# TODO + move to dbt-postgres's index implementation strategy + https://github.com/dbt-msft/dbt-sqlserver/issues/163 + #} + {# most of this code is from https://github.com/jacobm001/dbt-mssql/blob/master/dbt/include/mssql/macros/indexes.sql #} + {% macro drop_xml_indexes() -%} {# Altered from https://stackoverflow.com/q/1344401/10415173 #} {# and https://stackoverflow.com/a/33785833/10415173 #} diff --git a/dbt/include/sqlserver/macros/adapters/metadata.sql b/dbt/include/sqlserver/macros/adapters/metadata.sql new file mode 100644 index 00000000..8dee2beb --- /dev/null +++ b/dbt/include/sqlserver/macros/adapters/metadata.sql @@ -0,0 +1,90 @@ + +{% macro sqlserver__get_catalog(information_schemas, schemas) -%} + + {%- call statement('catalog', fetch_result=True) -%} + + with tabs as ( + + select + TABLE_CATALOG as table_database, + TABLE_SCHEMA as table_schema, + TABLE_NAME as table_name, + TABLE_TYPE as table_type, + TABLE_SCHEMA as table_owner, + null as table_comment + from INFORMATION_SCHEMA.TABLES + + ), + + cols as ( + + select + table_catalog as table_database, + table_schema, + table_name, + column_name, + ordinal_position as column_index, + data_type as column_type, + null as column_comment + from information_schema.columns + + ) + + select + tabs.table_database, + tabs.table_schema, + tabs.table_name, + tabs.table_type, + tabs.table_comment, + tabs.table_owner, + cols.column_name, + cols.column_index, + cols.column_type, + cols.column_comment + from tabs + join cols on tabs.table_database = cols.table_database and tabs.table_schema = cols.table_schema and tabs.table_name = cols.table_name + order by column_index + + {%- endcall -%} + + {{ return(load_result('catalog').table) }} + +{%- endmacro %} + +{% macro sqlserver__information_schema_name(database) -%} + information_schema +{%- endmacro %} + +{% macro sqlserver__list_schemas(database) %} + {% call statement('list_schemas', fetch_result=True, auto_begin=False) -%} + USE {{ database }}; + select name as [schema] + from sys.schemas + {% endcall %} + {{ return(load_result('list_schemas').table) }} +{% endmacro %} + +{% macro sqlserver__check_schema_exists(information_schema, schema) -%} + {% call statement('check_schema_exists', fetch_result=True, auto_begin=False) -%} + --USE {{ database_name }} + SELECT count(*) as schema_exist FROM sys.schemas WHERE name = '{{ schema }}' + {%- endcall %} + {{ return(load_result('check_schema_exists').table) }} +{% endmacro %} + +{% macro sqlserver__list_relations_without_caching(schema_relation) %} + {% call statement('list_relations_without_caching', fetch_result=True) -%} + select + table_catalog as [database], + table_name as [name], + table_schema as [schema], + case when table_type = 'BASE TABLE' then 'table' + when table_type = 'VIEW' then 'view' + else table_type + end as table_type + + from [{{ schema_relation.database }}].information_schema.tables + where table_schema like '{{ schema_relation.schema }}' + {% endcall %} + {{ return(load_result('list_relations_without_caching').table) }} +{% endmacro %} \ No newline at end of file diff --git a/dbt/include/sqlserver/macros/adapters/persist_docs.sql b/dbt/include/sqlserver/macros/adapters/persist_docs.sql new file mode 100644 index 00000000..fb3f4fe8 --- /dev/null +++ b/dbt/include/sqlserver/macros/adapters/persist_docs.sql @@ -0,0 +1,4 @@ +{# we don't support "persist docs" today, but we'd like to! + https://github.com/dbt-msft/dbt-sqlserver/issues/134 + + #} \ No newline at end of file diff --git a/dbt/include/sqlserver/macros/adapters/relation.sql b/dbt/include/sqlserver/macros/adapters/relation.sql new file mode 100644 index 00000000..e327b670 --- /dev/null +++ b/dbt/include/sqlserver/macros/adapters/relation.sql @@ -0,0 +1,39 @@ +{% macro sqlserver__make_temp_relation(base_relation, suffix) %} + {% set tmp_identifier = '#' ~ base_relation.identifier ~ suffix %} + {% set tmp_relation = base_relation.incorporate( + path={"identifier": tmp_identifier}) -%} + + {% do return(tmp_relation) %} +{% endmacro %} + +{% macro sqlserver__drop_relation(relation) -%} + {% call statement('drop_relation', auto_begin=False) -%} + {{ sqlserver__drop_relation_script(relation) }} + {%- endcall %} +{% endmacro %} + +{% macro sqlserver__drop_relation_script(relation) -%} + {% if relation.type == 'view' -%} + {% set object_id_type = 'V' %} + {% elif relation.type == 'table'%} + {% set object_id_type = 'U' %} + {%- else -%} invalid target name + {% endif %} + USE [{{ relation.database }}]; + if object_id ('{{ relation.include(database=False) }}','{{ object_id_type }}') is not null + begin + drop {{ relation.type }} {{ relation.include(database=False) }} + end +{% endmacro %} + +{% macro sqlserver__rename_relation(from_relation, to_relation) -%} + {% call statement('rename_relation') -%} + USE [{{ to_relation.database }}]; + EXEC sp_rename '{{ from_relation.schema }}.{{ from_relation.identifier }}', '{{ to_relation.identifier }}' + IF EXISTS( + SELECT * + FROM sys.indexes + WHERE name='{{ from_relation.schema }}_{{ from_relation.identifier }}_cci' and object_id = OBJECT_ID('{{ from_relation.schema }}.{{ to_relation.identifier }}')) + EXEC sp_rename N'{{ from_relation.schema }}.{{ to_relation.identifier }}.{{ from_relation.schema }}_{{ from_relation.identifier }}_cci', N'{{ from_relation.schema }}_{{ to_relation.identifier }}_cci', N'INDEX' + {%- endcall %} +{% endmacro %} \ No newline at end of file diff --git a/dbt/include/sqlserver/macros/adapters/schema.sql b/dbt/include/sqlserver/macros/adapters/schema.sql new file mode 100644 index 00000000..d18d3a00 --- /dev/null +++ b/dbt/include/sqlserver/macros/adapters/schema.sql @@ -0,0 +1,32 @@ +{% macro sqlserver__create_schema(relation) -%} + {% call statement('create_schema') -%} + USE [{{ relation.database }}]; + IF NOT EXISTS (SELECT * FROM sys.schemas WHERE name = '{{ relation.without_identifier().schema }}') + BEGIN + EXEC('CREATE SCHEMA {{ relation.without_identifier().schema }}') + END + {% endcall %} +{% endmacro %} + +{% macro sqlserver__drop_schema(relation) -%} + {%- set tables_in_schema_query %} + SELECT TABLE_NAME FROM INFORMATION_SCHEMA.TABLES + WHERE TABLE_SCHEMA = '{{ relation.schema }}' + {% endset %} + {% set tables_to_drop = run_query(tables_in_schema_query).columns[0].values() %} + {% for table in tables_to_drop %} + {%- set schema_relation = adapter.get_relation(database=relation.database, + schema=relation.schema, + identifier=table) -%} + {% do drop_relation(schema_relation) %} + {%- endfor %} + + {% call statement('drop_schema') -%} + IF EXISTS (SELECT * FROM sys.schemas WHERE name = '{{ relation.schema }}') + BEGIN + EXEC('DROP SCHEMA {{ relation.schema }}') + END {% endcall %} +{% endmacro %} + + +{# there is no drop_schema... why? #} \ No newline at end of file diff --git a/dbt/include/sqlserver/macros/catalog.sql b/dbt/include/sqlserver/macros/catalog.sql deleted file mode 100644 index 1534ce7c..00000000 --- a/dbt/include/sqlserver/macros/catalog.sql +++ /dev/null @@ -1,52 +0,0 @@ - -{% macro sqlserver__get_catalog(information_schemas, schemas) -%} - - {%- call statement('catalog', fetch_result=True) -%} - - with tabs as ( - - select - TABLE_CATALOG as table_database, - TABLE_SCHEMA as table_schema, - TABLE_NAME as table_name, - TABLE_TYPE as table_type, - TABLE_SCHEMA as table_owner, - null as table_comment - from INFORMATION_SCHEMA.TABLES - - ), - - cols as ( - - select - table_catalog as table_database, - table_schema, - table_name, - column_name, - ordinal_position as column_index, - data_type as column_type, - null as column_comment - from information_schema.columns - - ) - - select - tabs.table_database, - tabs.table_schema, - tabs.table_name, - tabs.table_type, - tabs.table_comment, - tabs.table_owner, - cols.column_name, - cols.column_index, - cols.column_type, - cols.column_comment - from tabs - join cols on tabs.table_database = cols.table_database and tabs.table_schema = cols.table_schema and tabs.table_name = cols.table_name - order by column_index - - {%- endcall -%} - - {{ return(load_result('catalog').table) }} - -{%- endmacro %} diff --git a/dbt/include/sqlserver/macros/merge.sql b/dbt/include/sqlserver/macros/materializations/models/incremental/merge.sql similarity index 75% rename from dbt/include/sqlserver/macros/merge.sql rename to dbt/include/sqlserver/macros/materializations/models/incremental/merge.sql index f498dfeb..979ac5eb 100644 --- a/dbt/include/sqlserver/macros/merge.sql +++ b/dbt/include/sqlserver/macros/materializations/models/incremental/merge.sql @@ -9,10 +9,10 @@ {{ default__get_merge_sql(target, source, unique_key, dest_columns, predicates) }}; {% endmacro %} +{% macro sqlserver__get_delete_insert_merge_sql(target, source, dest_columns, predicates, include_sql_header) %} + {{ default__get_delete_insert_merge_sql(target, source, dest_columns, predicates, include_sql_header) }}; +{% endmacro %} + {% macro sqlserver__get_insert_overwrite_merge_sql(target, source, dest_columns, predicates, include_sql_header) %} {{ default__get_insert_overwrite_merge_sql(target, source, dest_columns, predicates, include_sql_header) }}; {% endmacro %} - -{% macro sqlserver__snapshot_merge_sql(target, source, insert_cols) %} - {{ default__snapshot_merge_sql(target, source, insert_cols) }}; -{% endmacro %} \ No newline at end of file diff --git a/dbt/include/sqlserver/macros/materializations/models/table/create_table_as.sql b/dbt/include/sqlserver/macros/materializations/models/table/create_table_as.sql new file mode 100644 index 00000000..ae0192c1 --- /dev/null +++ b/dbt/include/sqlserver/macros/materializations/models/table/create_table_as.sql @@ -0,0 +1,26 @@ +{% macro sqlserver__get_create_table_as_sql(temporary, relation, sql) -%} + {%- set as_columnstore = config.get('as_columnstore', default=true) -%} + {% set tmp_relation = relation.incorporate( + path={"identifier": relation.identifier.replace("#", "") ~ '_temp_view'}, + type='view')-%} + {%- set temp_view_sql = sql.replace("'", "''") -%} + + {{ sqlserver__drop_relation_script(tmp_relation) }} + + {{ sqlserver__drop_relation_script(relation) }} + + USE [{{ relation.database }}]; + EXEC('create view {{ tmp_relation.include(database=False) }} as + {{ temp_view_sql }} + '); + + SELECT * INTO {{ relation }} FROM + {{ tmp_relation }} + + {{ sqlserver__drop_relation_script(tmp_relation) }} + + {% if not temporary and as_columnstore -%} + {{ sqlserver__create_clustered_columnstore_index(relation) }} + {% endif %} + +{% endmacro %} \ No newline at end of file diff --git a/dbt/include/sqlserver/macros/materializations/models/view/create_view_as.sql b/dbt/include/sqlserver/macros/materializations/models/view/create_view_as.sql new file mode 100644 index 00000000..966a18f3 --- /dev/null +++ b/dbt/include/sqlserver/macros/materializations/models/view/create_view_as.sql @@ -0,0 +1,12 @@ +{% macro sqlserver__create_view_exec(relation, sql) -%} + {%- set temp_view_sql = sql.replace("'", "''") -%} + execute('create view {{ relation.include(database=False) }} as + {{ temp_view_sql }} + '); +{% endmacro %} + + +{% macro sqlserver__get_create_view_as_sql(relation, sql) -%} + USE [{{ relation.database }}]; + {{ sqlserver__create_view_exec(relation, sql) }} +{% endmacro %} \ No newline at end of file diff --git a/dbt/include/sqlserver/macros/materializations/seed/seed.sql b/dbt/include/sqlserver/macros/materializations/seeds/helpers.sql similarity index 100% rename from dbt/include/sqlserver/macros/materializations/seed/seed.sql rename to dbt/include/sqlserver/macros/materializations/seeds/helpers.sql diff --git a/dbt/include/sqlserver/macros/materializations/snapshot/snapshot.sql b/dbt/include/sqlserver/macros/materializations/snapshots/snapshot.sql similarity index 100% rename from dbt/include/sqlserver/macros/materializations/snapshot/snapshot.sql rename to dbt/include/sqlserver/macros/materializations/snapshots/snapshot.sql diff --git a/dbt/include/sqlserver/macros/materializations/snapshots/snapshot_merge.sql b/dbt/include/sqlserver/macros/materializations/snapshots/snapshot_merge.sql new file mode 100644 index 00000000..5c006f9f --- /dev/null +++ b/dbt/include/sqlserver/macros/materializations/snapshots/snapshot_merge.sql @@ -0,0 +1,3 @@ +{% macro sqlserver__snapshot_merge_sql(target, source, insert_cols) %} + {{ default__snapshot_merge_sql(target, source, insert_cols) }}; +{% endmacro %} \ No newline at end of file diff --git a/dbt/include/sqlserver/macros/materializations/snapshot/strategies.sql b/dbt/include/sqlserver/macros/materializations/snapshots/strategies.sql similarity index 60% rename from dbt/include/sqlserver/macros/materializations/snapshot/strategies.sql rename to dbt/include/sqlserver/macros/materializations/snapshots/strategies.sql index 2c8471e9..9763d4f8 100644 --- a/dbt/include/sqlserver/macros/materializations/snapshot/strategies.sql +++ b/dbt/include/sqlserver/macros/materializations/snapshots/strategies.sql @@ -4,3 +4,7 @@ {% endfor %}), 2) {% endmacro %} +{% macro sqlserver__snapshot_string_as_time(timestamp) -%} + {%- set result = "CONVERT(DATETIME2, '" ~ timestamp ~ "')" -%} + {{ return(result) }} +{%- endmacro %} diff --git a/dbt/include/sqlserver/macros/materializations/tests/helpers.sql b/dbt/include/sqlserver/macros/materializations/tests/helpers.sql new file mode 100644 index 00000000..1122df16 --- /dev/null +++ b/dbt/include/sqlserver/macros/materializations/tests/helpers.sql @@ -0,0 +1,12 @@ +{% macro sqlserver__get_test_sql(main_sql, fail_calc, warn_if, error_if, limit) -%} + select + {{ "top (" ~ limit ~ ')' if limit != none }} + {{ fail_calc }} as failures, + case when {{ fail_calc }} {{ warn_if }} + then 'true' else 'false' end as should_warn, + case when {{ fail_calc }} {{ error_if }} + then 'true' else 'false' end as should_error + from ( + {{ main_sql }} + ) dbt_internal_test +{%- endmacro %} diff --git a/dbt/include/sqlserver/macros/materializations/test.sql b/dbt/include/sqlserver/macros/materializations/tests/test.sql similarity index 74% rename from dbt/include/sqlserver/macros/materializations/test.sql rename to dbt/include/sqlserver/macros/materializations/tests/test.sql index 8942c4cc..ceebea5f 100644 --- a/dbt/include/sqlserver/macros/materializations/test.sql +++ b/dbt/include/sqlserver/macros/materializations/tests/test.sql @@ -1,16 +1,3 @@ -{% macro sqlserver__get_test_sql(main_sql, fail_calc, warn_if, error_if, limit) -%} - select - {{ "top (" ~ limit ~ ')' if limit != none }} - {{ fail_calc }} as failures, - case when {{ fail_calc }} {{ warn_if }} - then 'true' else 'false' end as should_warn, - case when {{ fail_calc }} {{ error_if }} - then 'true' else 'false' end as should_error - from ( - {{ main_sql }} - ) dbt_internal_test -{%- endmacro %} - {%- materialization test, adapter='sqlserver' -%} {% set relations = [] %} From 60183245972247c5e5777527ca192f1767a42d4d Mon Sep 17 00:00:00 2001 From: swanderz Date: Wed, 24 Nov 2021 14:46:39 -0800 Subject: [PATCH 2/3] use old names (for now?) --- .../macros/materializations/models/table/create_table_as.sql | 4 ++-- .../macros/materializations/models/view/create_view_as.sql | 4 ++-- 2 files changed, 4 insertions(+), 4 deletions(-) diff --git a/dbt/include/sqlserver/macros/materializations/models/table/create_table_as.sql b/dbt/include/sqlserver/macros/materializations/models/table/create_table_as.sql index ae0192c1..dbf99531 100644 --- a/dbt/include/sqlserver/macros/materializations/models/table/create_table_as.sql +++ b/dbt/include/sqlserver/macros/materializations/models/table/create_table_as.sql @@ -1,4 +1,4 @@ -{% macro sqlserver__get_create_table_as_sql(temporary, relation, sql) -%} +{% macro sqlserver__create_table_as(temporary, relation, sql) -%} {%- set as_columnstore = config.get('as_columnstore', default=true) -%} {% set tmp_relation = relation.incorporate( path={"identifier": relation.identifier.replace("#", "") ~ '_temp_view'}, @@ -23,4 +23,4 @@ {{ sqlserver__create_clustered_columnstore_index(relation) }} {% endif %} -{% endmacro %} \ No newline at end of file +{% endmacro %} diff --git a/dbt/include/sqlserver/macros/materializations/models/view/create_view_as.sql b/dbt/include/sqlserver/macros/materializations/models/view/create_view_as.sql index 966a18f3..5f140825 100644 --- a/dbt/include/sqlserver/macros/materializations/models/view/create_view_as.sql +++ b/dbt/include/sqlserver/macros/materializations/models/view/create_view_as.sql @@ -6,7 +6,7 @@ {% endmacro %} -{% macro sqlserver__get_create_view_as_sql(relation, sql) -%} +{% macro sqlserver__create_view_as(relation, sql) -%} USE [{{ relation.database }}]; {{ sqlserver__create_view_exec(relation, sql) }} -{% endmacro %} \ No newline at end of file +{% endmacro %} From cfc6d08f3137b7f46b1056a8c33274fbb5c688eb Mon Sep 17 00:00:00 2001 From: swanderz Date: Wed, 15 Dec 2021 15:01:54 -0800 Subject: [PATCH 3/3] arg typo --- .../macros/materializations/models/incremental/merge.sql | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/dbt/include/sqlserver/macros/materializations/models/incremental/merge.sql b/dbt/include/sqlserver/macros/materializations/models/incremental/merge.sql index 979ac5eb..e1bb3b9a 100644 --- a/dbt/include/sqlserver/macros/materializations/models/incremental/merge.sql +++ b/dbt/include/sqlserver/macros/materializations/models/incremental/merge.sql @@ -9,8 +9,8 @@ {{ default__get_merge_sql(target, source, unique_key, dest_columns, predicates) }}; {% endmacro %} -{% macro sqlserver__get_delete_insert_merge_sql(target, source, dest_columns, predicates, include_sql_header) %} - {{ default__get_delete_insert_merge_sql(target, source, dest_columns, predicates, include_sql_header) }}; +{% macro sqlserver__get_delete_insert_merge_sql(target, source, unique_key, dest_columns) %} + {{ default__get_delete_insert_merge_sql(target, source, unique_key, dest_columns) }}; {% endmacro %} {% macro sqlserver__get_insert_overwrite_merge_sql(target, source, dest_columns, predicates, include_sql_header) %}