Skip to content

Commit

Permalink
Support for changing database in model configuration (#126)
Browse files Browse the repository at this point in the history
* Support for changing database in model configuration

* Bumbed version

* Update dbt/include/sqlserver/macros/adapters.sql

* Removed unnecessary check

* drop redundancy

* 3-part versions from now on

* capitals as style guide

* document

* typo

* style: capitalized function words

Co-authored-by: Anders <swanson.anders@gmail.com>
  • Loading branch information
semcha and dataders authored May 25, 2021
1 parent 83b8357 commit 679b351
Show file tree
Hide file tree
Showing 4 changed files with 33 additions and 27 deletions.
8 changes: 7 additions & 1 deletion CHANGELOG.md
Original file line number Diff line number Diff line change
@@ -1,9 +1,15 @@
# Changelog
### v0.19.1

### v0.19.0.3
#### features:

- users can now delcare a model's database to be other than the one specified in the profile. This will only work for on-premise SQL Server and Azure SQL Managed Instance. [#126](https://github.com/dbt-msft/dbt-sqlserver/issues/126) thanks [@semcha](https://github.com/semcha)!

#### under the hood

- abandon four-part version names (`v0.19.0.2`) in favor of three-part version names because it isn't [SemVer](https://semver.org/) and it causes problems with the `~=` pip operator used dbt-synapse, a pacakge that depends on dbt-sqlserver
- allow CI to work with the lower-cost serverless Azure SQL [#132](https://github.com/dbt-msft/dbt-sqlserver/pull/132)

### v0.19.0.2

#### fixes
Expand Down
2 changes: 1 addition & 1 deletion dbt/adapters/sqlserver/__version__.py
Original file line number Diff line number Diff line change
@@ -1 +1 @@
version = '0.19.0.2'
version = '0.19.1'
48 changes: 24 additions & 24 deletions dbt/include/sqlserver/macros/adapters.sql
Original file line number Diff line number Diff line change
Expand Up @@ -26,15 +26,15 @@
else table_type
end as table_type

from information_schema.tables
from [{{ schema_relation.database }}].information_schema.tables
where table_schema like '{{ schema_relation.schema }}'
and table_catalog like '{{ schema_relation.database }}'
{% 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 }};

This comment has been minimized.

Copy link
@Elektry-On

Elektry-On Jun 9, 2021

@swanderz Hi Anders, with this change I fear you have added a bug to the synapse adapter. Receiving now a lot of those error messages:
dbt.exceptions.DatabaseException: Database Error ('42000', '[42000] [Microsoft][ODBC Driver 17 for SQL Server][SQL Server]USE statement is not supported to switch between databases. Use a new connection to connect to a different Database. (104455) (SQLExecDirectW)')

This is because the synapse macro macro synapse__list_schemas(database) redirects to this macro and as you know USE-statements are not allowed in Synapse.

select name as [schema]
from sys.schemas
{% endcall %}
Expand All @@ -43,7 +43,7 @@

{% macro sqlserver__create_schema(relation) -%}
{% call statement('create_schema') -%}
USE [{{ relation.database }}]
USE [{{ relation.database }}];
IF NOT EXISTS (SELECT * FROM sys.schemas WHERE name = '{{ relation.without_identifier().schema }}')
BEGIN
EXEC('CREATE SCHEMA {{ relation.without_identifier().schema }}')
Expand Down Expand Up @@ -72,17 +72,8 @@
{% endmacro %}

{% macro sqlserver__drop_relation(relation) -%}
{% if relation.type == 'view' -%}
{% set object_id_type = 'V' %}
{% elif relation.type == 'table'%}
{% set object_id_type = 'U' %}
{%- else -%} invalid target name
{% endif %}
{% call statement('drop_relation', auto_begin=False) -%}
if object_id ('{{ relation.include(database=False) }}','{{ object_id_type }}') is not null
begin
drop {{ relation.type }} {{ relation.include(database=False) }}
end
{{ sqlserver__drop_relation_script(relation) }}
{%- endcall %}
{% endmacro %}

Expand All @@ -93,6 +84,7 @@
{% 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) }}
Expand All @@ -107,14 +99,24 @@
{{ 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) -%}
create view {{ relation.schema }}.{{ relation.identifier }} as
{{ 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 *
Expand All @@ -128,6 +130,7 @@
{%- 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}}'
Expand All @@ -149,12 +152,13 @@

{{ sqlserver__drop_relation_script(relation) }}

EXEC('create view {{ tmp_relation.schema }}.{{ tmp_relation.identifier }} as
USE [{{ relation.database }}];
EXEC('create view {{ tmp_relation.include(database=False) }} as
{{ temp_view_sql }}
');

SELECT * INTO {{ relation.schema }}.{{ relation.identifier }} FROM
{{ tmp_relation.schema }}.{{ tmp_relation.identifier }}
SELECT * INTO {{ relation }} FROM
{{ tmp_relation }}

{{ sqlserver__drop_relation_script(tmp_relation) }}

Expand All @@ -165,11 +169,7 @@
{% endmacro %}_

{% macro sqlserver__insert_into_from(to_relation, from_relation) -%}
{%- set full_to_relation = to_relation.schema ~ '.' ~ to_relation.identifier -%}
{%- set full_from_relation = from_relation.schema ~ '.' ~ from_relation.identifier -%}

SELECT * INTO {{full_to_relation}} FROM {{full_from_relation}}

SELECT * INTO {{ to_relation }} FROM {{ from_relation }}
{% endmacro %}

{% macro sqlserver__current_timestamp() -%}
Expand All @@ -192,7 +192,7 @@
character_maximum_length,
numeric_precision,
numeric_scale
from INFORMATION_SCHEMA.COLUMNS
from [{{ relation.database }}].INFORMATION_SCHEMA.COLUMNS
where table_name = '{{ relation.identifier }}'
and table_schema = '{{ relation.schema }}'
UNION ALL
Expand Down
2 changes: 1 addition & 1 deletion setup.py
Original file line number Diff line number Diff line change
Expand Up @@ -28,7 +28,7 @@ def _dbt_sqlserver_version():
package_version = _dbt_sqlserver_version()
description = """A sqlserver adapter plugin for dbt (data build tool)"""

dbt_version = '0.19.0'
dbt_version = '0.19'
# the package version should be the dbt version, with maybe some things on the
# ends of it. (0.18.1 vs 0.18.1a1, 0.18.1.1, ...)
if not package_version.startswith(dbt_version):
Expand Down

0 comments on commit 679b351

Please sign in to comment.