Skip to content

Commit 59c3648

Browse files
committed
Added support for custom schema
1. Following macros changed or fixed in adapter.sql to use custom schema name - oracle__create_schema, oracle__create_view_as, oracle__alter_relation_comment, oracle__alter_column_type, oracle__drop_relation, oracle__truncate_relation, oracle__rename_relation, oracle__make_temp_relation 2. Changed view materialization strategy which unncessarily created an intermediate <model>__dbt_tmp view first and renamed it to the target view. Now we directly CREATE or REPLACE view <target_view_name> 3. Added generate_schema_name.sql as per dbt documentation in test project to determine the name of the schema that a model should be built in. 4. Changed a couple of models in the test project to use custom schema 5. Fixes Bug #14 6. Fixes Bug #2 7. Addresses issues raised in PR #15
1 parent bd03171 commit 59c3648

File tree

5 files changed

+53
-36
lines changed

5 files changed

+53
-36
lines changed

dbt/include/oracle/macros/adapters.sql

Lines changed: 15 additions & 14 deletions
Original file line numberDiff line numberDiff line change
@@ -25,11 +25,11 @@
2525
{{ return(load_result('get_columns_in_query').table.columns | map(attribute='name') | list) }}
2626
{% endmacro %}
2727

28-
{% macro oracle__create_schema(database_name, schema_name) -%}
28+
{% macro oracle__create_schema(relation, schema_name) -%}
2929
{% if relation.database -%}
3030
{{ adapter.verify_database(relation.database) }}
3131
{%- endif -%}
32-
{%- call statement('drop_schema') -%}
32+
{%- call statement('create_schema') -%}
3333
-- Noop for not breaking tests, oracle
3434
-- schemas are actualy users, we can't
3535
-- create it here
@@ -121,7 +121,7 @@
121121
{%- set sql_header = config.get('sql_header', none) -%}
122122

123123
{{ sql_header if sql_header is not none }}
124-
create view {{ relation.quote(schema=False, identifier=False) }} as
124+
create or replace view {{ relation.include(False, True, True).quote(schema=False, identifier=False) }} as
125125
{{ sql }}
126126

127127
{% endmacro %}
@@ -204,7 +204,7 @@
204204
{% macro oracle__alter_relation_comment(relation, comment) %}
205205
{% set escaped_comment = oracle_escape_comment(comment) %}
206206
{# "comment on table" even for views #}
207-
comment on table {{ relation.quote(schema=False, identifier=False) }} is {{ escaped_comment }}
207+
comment on table {{ relation.include(False, True, True).quote(schema=False, identifier=False) }} is {{ escaped_comment }}
208208
{% endmacro %}
209209

210210
{% macro oracle__persist_docs(relation, model, for_relation, for_columns) -%}
@@ -217,7 +217,7 @@
217217
{% set comment = column_dict[column_name]['description'] %}
218218
{% set escaped_comment = oracle_escape_comment(comment) %}
219219
{% call statement('alter _column comment', fetch_result=False) -%}
220-
comment on column {{ relation.quote(schema=False, identifier=False) }}.{{ column_name }} is {{ escaped_comment }}
220+
comment on column {{ relation.include(False, True, True).quote(schema=False, identifier=False) }}.{{ column_name }} is {{ escaped_comment }}
221221
{%- endcall %}
222222
{% endfor %}
223223
{% endif %}
@@ -233,16 +233,16 @@
233233
{%- set tmp_column = column_name + "__dbt_alter" -%}
234234

235235
{% call statement('alter_column_type 1', fetch_result=False) %}
236-
alter table {{ relation.quote(schema=False, identifier=False) }} add column {{ adapter.quote(tmp_column) }} {{ new_column_type }}
236+
alter table {{ relation.include(False, True, True).quote(schema=False, identifier=False) }} add column {{ tmp_column }} {{ new_column_type }}
237237
{% endcall %}
238238
{% call statement('alter_column_type 2', fetch_result=False) %}
239-
update {{ relation.quote(schema=False, identifier=False) }} set {{ adapter.quote(tmp_column) }} = {{ adapter.quote(column_name) }}
239+
update {{ relation.include(False, True, True).quote(schema=False, identifier=False) }} set {{ tmp_column }} = {{ column_name }}
240240
{% endcall %}
241241
{% call statement('alter_column_type 3', fetch_result=False) %}
242-
alter table {{ relation.quote(schema=False, identifier=False) }} drop column {{ adapter.quote(column_name) }} cascade
242+
alter table {{ relation.include(False, True, True).quote(schema=False, identifier=False) }} drop column {{ column_name }} cascade
243243
{% endcall %}
244244
{% call statement('alter_column_type 4', fetch_result=False) %}
245-
rename column {{ relation.quote(schema=False, identifier=False) }}.{{ adapter.quote(tmp_column) }} to {{ adapter.quote(column_name) }}
245+
alter table {{ relation.include(False, True, True).quote(schema=False, identifier=False) }} rename column {{ tmp_column }} to {{ column_name }}
246246
{% endcall %}
247247

248248
{% endmacro %}
@@ -256,7 +256,7 @@
256256
pragma EXCEPTION_INIT(attempted_ddl_on_in_use_GTT, -14452);
257257
BEGIN
258258
SAVEPOINT start_transaction;
259-
EXECUTE IMMEDIATE 'DROP {{ relation.type }} {{ relation.quote(schema=False, identifier=False) }} cascade constraint';
259+
EXECUTE IMMEDIATE 'DROP {{ relation.type }} {{ relation.include(False, True, True).quote(schema=False, identifier=False) }} cascade constraint';
260260
COMMIT;
261261
EXCEPTION
262262
WHEN attempted_ddl_on_in_use_GTT THEN
@@ -271,14 +271,14 @@
271271
{#-- To avoid `ORA-01702: a view is not appropriate here` we check that the relation to be truncated is a table #}
272272
{% if relation.is_table %}
273273
{% call statement('truncate_relation') -%}
274-
truncate table {{ relation.quote(schema=False, identifier=False) }}
274+
truncate table {{ relation.include(False, True, True).quote(schema=False, identifier=False) }}
275275
{%- endcall %}
276276
{% endif %}
277277
{% endmacro %}
278278

279279
{% macro oracle__rename_relation(from_relation, to_relation) -%}
280280
{% call statement('rename_relation') -%}
281-
rename {{ from_relation.include(False, False, True).quote(schema=False, identifier=False) }} to {{ to_relation.include(False, False, True).quote(schema=False, identifier=False) }}
281+
ALTER {{ from_relation.type }} {{ from_relation.include(False, True, True).quote(schema=False, identifier=False) }} rename to {{ to_relation.include(False, False, True).quote(schema=False, identifier=False) }}
282282
{%- endcall %}
283283
{% endmacro %}
284284

@@ -355,7 +355,7 @@
355355
{% set dtstring = dt.strftime("%H%M%S") %}
356356
{% set tmp_identifier = 'o$pt_' ~ base_relation.identifier ~ dtstring %}
357357
{% set tmp_relation = base_relation.incorporate(
358-
path={"identifier": tmp_identifier}) -%}
358+
path={"identifier": tmp_identifier, "schema": None}) -%}
359359

360360
{% do return(tmp_relation) %}
361361
{% endmacro %}
@@ -364,4 +364,5 @@
364364
{% set results = run_query("select SYS_CONTEXT('userenv', 'DB_NAME') FROM DUAL") %}
365365
{% set db_name = results.columns[0].values()[0] %}
366366
{{ return(db_name) }}
367-
{% endmacro %}
367+
{% endmacro %}
368+

dbt/include/oracle/macros/materializations/view/view.sql

Lines changed: 6 additions & 19 deletions
Original file line numberDiff line numberDiff line change
@@ -17,20 +17,11 @@
1717
{%- materialization view, adapter='oracle' -%}
1818

1919
{%- set identifier = model['alias'] -%}
20-
{%- set tmp_identifier = model['name'] + '__dbt_tmp' -%}
2120
{%- set backup_identifier = model['name'] + '__dbt_backup' -%}
2221

2322
{%- set old_relation = adapter.get_relation(database=database, schema=schema, identifier=identifier) -%}
2423
{%- set target_relation = api.Relation.create(identifier=identifier, schema=schema, database=database,
2524
type='view') -%}
26-
{%- set intermediate_relation = api.Relation.create(identifier=tmp_identifier,
27-
schema=schema, database=database, type='view') -%}
28-
-- the intermediate_relation should not already exist in the database; get_relation
29-
-- will return None in that case. Otherwise, we get a relation that we can drop
30-
-- later, before we try to use this name for the current operation
31-
{%- set preexisting_intermediate_relation = adapter.get_relation(identifier=tmp_identifier,
32-
schema=schema,
33-
database=database) -%}
3425
/*
3526
This relation (probably) doesn't exist yet. If it does exist, it's a leftover from
3627
a previous run, and we're going to try to drop it immediately. At the end of this
@@ -55,25 +46,21 @@
5546

5647
{{ run_hooks(pre_hooks, inside_transaction=False) }}
5748

58-
-- drop the temp relations if they exist already in the database
59-
{{ drop_relation_if_exists(preexisting_intermediate_relation) }}
6049
{{ drop_relation_if_exists(preexisting_backup_relation) }}
6150

6251
-- `BEGIN` happens here:
6352
{{ run_hooks(pre_hooks, inside_transaction=True) }}
6453

54+
-- if old_relation was a table
55+
{% if old_relation is not none and old_relation.type == 'table' %}
56+
{{ adapter.rename_relation(old_relation, backup_relation) }}
57+
{% endif %}
58+
6559
-- build model
6660
{% call statement('main') -%}
67-
{{ create_view_as(intermediate_relation, sql) }}
61+
{{ create_view_as(target_relation, sql) }}
6862
{%- endcall %}
6963

70-
-- cleanup
71-
-- move the existing view out of the way
72-
{% if old_relation is not none %}
73-
{{ adapter.rename_relation(old_relation, backup_relation) }}
74-
{% endif %}
75-
{{ adapter.rename_relation(intermediate_relation, target_relation) }}
76-
7764
{% do persist_docs(target_relation, model) %}
7865

7966
{{ run_hooks(post_hooks, inside_transaction=True) }}
Lines changed: 25 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,25 @@
1+
{#
2+
Copyright (c) 2022, Oracle and/or its affiliates.
3+
4+
Licensed under the Apache License, Version 2.0 (the "License");
5+
you may not use this file except in compliance with the License.
6+
You may obtain a copy of the License at
7+
8+
https://www.apache.org/licenses/LICENSE-2.0
9+
10+
Unless required by applicable law or agreed to in writing, software
11+
distributed under the License is distributed on an "AS IS" BASIS,
12+
WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
13+
See the License for the specific language governing permissions and
14+
limitations under the License.
15+
#}
16+
{% macro generate_schema_name(custom_schema_name, node) -%}
17+
18+
{%- set default_schema = target.schema -%}
19+
{%- if custom_schema_name is none -%}
20+
{{ default_schema }}
21+
{%- else -%}
22+
{{ custom_schema_name | trim }}
23+
{%- endif -%}
24+
25+
{%- endmacro %}

dbt_adbs_test_project/models/eu/countries.sql

Lines changed: 2 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -13,7 +13,8 @@
1313
See the License for the specific language governing permissions and
1414
limitations under the License.
1515
#}
16-
{{config(materialized='table')}}
16+
{{config(materialized='table',
17+
schema='dbt_test')}}
1718
SELECT * FROM {{ source('sh_database', 'countries')}}
1819
where country_iso_code in ('AT', 'BE', 'BG', 'DK', 'CZ', 'DE', 'IT',
1920
'FI', 'FR', 'GR', 'NL', 'IE', 'HU', 'ES', 'SE',

dbt_adbs_test_project/models/us_product_sales_channel_ranking.sql

Lines changed: 5 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -16,11 +16,14 @@
1616
{{
1717
config(
1818
materialized='incremental',
19-
unique_key='calendar_month_desc'
19+
unique_key='group_id',
20+
schema='dbt_test'
2021
)
2122
}}
2223

23-
SELECT prod_name, channel_desc, calendar_month_desc, TO_CHAR(SUM(amount_sold), '9,999,999,999') SALES$,
24+
SELECT prod_name, channel_desc, calendar_month_desc,
25+
{{ snapshot_hash_arguments(['prod_name', 'channel_desc', 'calendar_month_desc']) }} AS group_id,
26+
TO_CHAR(SUM(amount_sold), '9,999,999,999') SALES$,
2427
RANK() OVER (ORDER BY SUM(amount_sold)) AS default_rank,
2528
RANK() OVER (ORDER BY SUM(amount_sold) DESC NULLS LAST) AS custom_rank
2629
FROM {{ source('sh_database', 'sales') }}, {{ source('sh_database', 'products') }}, {{ source('sh_database', 'customers') }},

0 commit comments

Comments
 (0)