Skip to content

Fix/manage objects in different schema #16

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

Merged
merged 4 commits into from
Jun 9, 2022
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
30 changes: 17 additions & 13 deletions dbt/include/oracle/macros/adapters.sql
Original file line number Diff line number Diff line change
Expand Up @@ -25,8 +25,12 @@
{{ return(load_result('get_columns_in_query').table.columns | map(attribute='name') | list) }}
{% endmacro %}

{% macro oracle__create_schema(database_name, schema_name) -%}
{%- call statement('drop_schema') -%}

{% macro oracle__create_schema(relation, schema_name) -%}
{% if relation.database -%}
{{ adapter.verify_database(relation.database) }}
{%- endif -%}
{%- call statement('create_schema') -%}
-- Noop for not breaking tests, oracle
-- schemas are actualy users, we can't
-- create it here
Expand Down Expand Up @@ -118,7 +122,7 @@
{%- set sql_header = config.get('sql_header', none) -%}

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

{% endmacro %}
Expand Down Expand Up @@ -201,7 +205,7 @@
{% macro oracle__alter_relation_comment(relation, comment) %}
{% set escaped_comment = oracle_escape_comment(comment) %}
{# "comment on table" even for views #}
comment on table {{ relation.quote(schema=False, identifier=False) }} is {{ escaped_comment }}
comment on table {{ relation.include(False, True, True).quote(schema=False, identifier=False) }} is {{ escaped_comment }}
{% endmacro %}

{% macro oracle__persist_docs(relation, model, for_relation, for_columns) -%}
Expand All @@ -214,7 +218,7 @@
{% set comment = column_dict[column_name]['description'] %}
{% set escaped_comment = oracle_escape_comment(comment) %}
{% call statement('alter _column comment', fetch_result=False) -%}
comment on column {{ relation.quote(schema=False, identifier=False) }}.{{ column_name }} is {{ escaped_comment }}
comment on column {{ relation.include(False, True, True).quote(schema=False, identifier=False) }}.{{ column_name }} is {{ escaped_comment }}
{%- endcall %}
{% endfor %}
{% endif %}
Expand All @@ -230,16 +234,16 @@
{%- set tmp_column = column_name + "__dbt_alter" -%}

{% call statement('alter_column_type 1', fetch_result=False) %}
alter table {{ relation.quote(schema=False, identifier=False) }} add column {{ adapter.quote(tmp_column) }} {{ new_column_type }}
alter table {{ relation.include(False, True, True).quote(schema=False, identifier=False) }} add column {{ tmp_column }} {{ new_column_type }}
{% endcall %}
{% call statement('alter_column_type 2', fetch_result=False) %}
update {{ relation.quote(schema=False, identifier=False) }} set {{ adapter.quote(tmp_column) }} = {{ adapter.quote(column_name) }}
update {{ relation.include(False, True, True).quote(schema=False, identifier=False) }} set {{ tmp_column }} = {{ column_name }}
{% endcall %}
{% call statement('alter_column_type 3', fetch_result=False) %}
alter table {{ relation.quote(schema=False, identifier=False) }} drop column {{ adapter.quote(column_name) }} cascade
alter table {{ relation.include(False, True, True).quote(schema=False, identifier=False) }} drop column {{ column_name }} cascade
{% endcall %}
{% call statement('alter_column_type 4', fetch_result=False) %}
rename column {{ relation.quote(schema=False, identifier=False) }}.{{ adapter.quote(tmp_column) }} to {{ adapter.quote(column_name) }}
alter table {{ relation.include(False, True, True).quote(schema=False, identifier=False) }} rename column {{ tmp_column }} to {{ column_name }}
{% endcall %}

{% endmacro %}
Expand All @@ -253,7 +257,7 @@
pragma EXCEPTION_INIT(attempted_ddl_on_in_use_GTT, -14452);
BEGIN
SAVEPOINT start_transaction;
EXECUTE IMMEDIATE 'DROP {{ relation.type }} {{ relation.quote(schema=False, identifier=False) }} cascade constraint';
EXECUTE IMMEDIATE 'DROP {{ relation.type }} {{ relation.include(False, True, True).quote(schema=False, identifier=False) }} cascade constraint';
COMMIT;
EXCEPTION
WHEN attempted_ddl_on_in_use_GTT THEN
Expand All @@ -268,14 +272,14 @@
{#-- To avoid `ORA-01702: a view is not appropriate here` we check that the relation to be truncated is a table #}
{% if relation.is_table %}
{% call statement('truncate_relation') -%}
truncate table {{ relation.quote(schema=False, identifier=False) }}
truncate table {{ relation.include(False, True, True).quote(schema=False, identifier=False) }}
{%- endcall %}
{% endif %}
{% endmacro %}

{% macro oracle__rename_relation(from_relation, to_relation) -%}
{% call statement('rename_relation') -%}
alter table {{ from_relation.include(False, True, True).quote(schema=False, identifier=False) }} rename to {{ to_relation.include(False, False, True).quote(schema=False, identifier=False) }}
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) }}
{%- endcall %}
{% endmacro %}

Expand Down Expand Up @@ -352,7 +356,7 @@
{% set dtstring = dt.strftime("%H%M%S") %}
{% set tmp_identifier = 'o$pt_' ~ base_relation.identifier ~ dtstring %}
{% set tmp_relation = base_relation.incorporate(
path={"identifier": tmp_identifier}) -%}
path={"identifier": tmp_identifier, "schema": None}) -%}

{% do return(tmp_relation) %}
{% endmacro %}
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -36,8 +36,11 @@
{% set backup_identifier = existing_relation.identifier ~ "__dbt_backup" %}
{% set backup_relation = existing_relation.incorporate(path={"identifier": backup_identifier}) %}
{% do adapter.drop_relation(backup_relation) %}

{% do adapter.rename_relation(target_relation, backup_relation) %}
{% if existing_relation.is_view %}
{% do adapter.drop_relation(existing_relation) %}
{% else %}
{% do adapter.rename_relation(existing_relation, backup_relation) %}
{% endif %}
{% set build_sql = create_table_as(False, target_relation, sql) %}
{% do to_drop.append(backup_relation) %}
{% else %}
Expand Down
25 changes: 6 additions & 19 deletions dbt/include/oracle/macros/materializations/view/view.sql
Original file line number Diff line number Diff line change
Expand Up @@ -17,20 +17,11 @@
{%- materialization view, adapter='oracle' -%}

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

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

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

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

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

-- if old_relation was a table
{% if old_relation is not none and old_relation.type == 'table' %}
{{ adapter.rename_relation(old_relation, backup_relation) }}
{% endif %}

-- build model
{% call statement('main') -%}
{{ create_view_as(intermediate_relation, sql) }}
{{ create_view_as(target_relation, sql) }}
{%- endcall %}

-- cleanup
-- move the existing view out of the way
{% if old_relation is not none %}
{{ adapter.rename_relation(old_relation, backup_relation) }}
{% endif %}
{{ adapter.rename_relation(intermediate_relation, target_relation) }}

{% do persist_docs(target_relation, model) %}

{{ run_hooks(post_hooks, inside_transaction=True) }}
Expand Down
25 changes: 25 additions & 0 deletions dbt_adbs_test_project/macros/generate_schema_name.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,25 @@
{#
Copyright (c) 2022, Oracle and/or its affiliates.

Licensed under the Apache License, Version 2.0 (the "License");
you may not use this file except in compliance with the License.
You may obtain a copy of the License at

https://www.apache.org/licenses/LICENSE-2.0

Unless required by applicable law or agreed to in writing, software
distributed under the License is distributed on an "AS IS" BASIS,
WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
See the License for the specific language governing permissions and
limitations under the License.
#}
{% macro generate_schema_name(custom_schema_name, node) -%}

{%- set default_schema = target.schema -%}
{%- if custom_schema_name is none -%}
{{ default_schema }}
{%- else -%}
{{ custom_schema_name | trim }}
{%- endif -%}

{%- endmacro %}
3 changes: 2 additions & 1 deletion dbt_adbs_test_project/models/eu/countries.sql
Original file line number Diff line number Diff line change
Expand Up @@ -13,7 +13,8 @@
See the License for the specific language governing permissions and
limitations under the License.
#}
{{config(materialized='table')}}
{{config(materialized='table',
schema=env_var('DBT_ORACLE_CUSTOM_SCHEMA')) }}
SELECT * FROM {{ source('sh_database', 'countries')}}
where country_iso_code in ('AT', 'BE', 'BG', 'DK', 'CZ', 'DE', 'IT',
'FI', 'FR', 'GR', 'NL', 'IE', 'HU', 'ES', 'SE',
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -16,11 +16,12 @@
{{
config(
materialized='incremental',
unique_key='calendar_month_desc'
)
unique_key='group_id')
}}

SELECT prod_name, channel_desc, calendar_month_desc, TO_CHAR(SUM(amount_sold), '9,999,999,999') SALES$,
SELECT prod_name, channel_desc, calendar_month_desc,
{{ snapshot_hash_arguments(['prod_name', 'channel_desc', 'calendar_month_desc']) }} AS group_id,
TO_CHAR(SUM(amount_sold), '9,999,999,999') SALES$,
RANK() OVER (ORDER BY SUM(amount_sold)) AS default_rank,
RANK() OVER (ORDER BY SUM(amount_sold) DESC NULLS LAST) AS custom_rank
FROM {{ source('sh_database', 'sales') }}, {{ source('sh_database', 'products') }}, {{ source('sh_database', 'customers') }},
Expand Down