diff --git a/README.md b/README.md
index 394b507..807cf4a 100644
--- a/README.md
+++ b/README.md
@@ -3,185 +3,21 @@
[](https://pypi.python.org/pypi/dbt-oracle)

-dbt "adapters" are responsible for adapting dbt's functionality to a given database. `dbt-oracle` implements dbt functionalities for the Oracle database. To learn more about building adapters, check
-https://docs.getdbt.com/docs/contributing/building-a-new-adapter
+dbt "adapters" are responsible for adapting dbt's functionality to a given database. `dbt-oracle` implements dbt functionalities for the Oracle database.
> Prior to version 1.0.0, dbt-oracle was created and maintained by [Indicium](https://indicium.tech/) on [their GitHub repo](https://github.com/techindicium/dbt-oracle). Contributors in this repo are credited for laying the groundwork and maintaining the adapter till version 0.4.3.
From version 1.0.0, dbt-oracle is maintained and distributed by Oracle.
-## What is dbt?
-
-dbt does the T in ELT (Extract, Load, Transform). To work with dbt you need a copy of your data already loaded in your warehouse.
-
-### dbt features
-- With dbt, you can express all transforms with SQL select
- - Different materialization strategies.
- - view
- - table
- - incremental; selective rebuild for new rows
- - ephemeral; Model 1 interpolated into Model 2 as a Common Table Expression (CTE)
- - No need to write boilerplate code
- - All code to create table or views is generated using macros.
- - Idempotence; rerun models
- - If your source data were to stop updating, successive runs of your transformations would still result in the same tables and views in your warehouse.
- - If your production deployment of your transformations were interrupted, the next run of the transformations would result in the same tables and views as if the deployment had not been interrupted.
- - If you manually triggered transformations between scheduled runs, the scheduled run would result in the same tables and views as if the manual runs had not been triggered.
- - All transformation code is accessible and can be version controlled.
-- Dependency resolution
- - Use of ref() function ``select * from {{ ref('MODEL_NAME')}}``
- - dbt automatically resolves dependencies in between models and builds a Directed Acyclic Graph (DAG).
- Each path in the DAG can be independently executed using multiple threads.
- - Interpolates the name of database schema
-- Includes a built-in testing framework to ensure model accuracy
- - not null
- - unique
- - contains accepted values
- - relationships
- - custom tests
-- Generate documentation for your project and render it as a website.
-- Use macros to write reusable SQL
-
-### An example
-
-dbt model
-```sql
---models/sales_internet_channel.sql
-{{ config(materialized='table') }}
-WITH sales_internet AS (
- SELECT * FROM {{ source('sh_database', 'sales') }}
- WHERE channel_id = 4 )
-SELECT * FROM sales_internet
-```
-dbt compiles the above SQL template to run the below DDL statement.
-```sql
-CREATE TABLE dbt_test.sales_internet_channel AS
-WITH sales_internet AS (
- SELECT * from sh.sales
- WHERE channel_id = 4 )
-SELECT * FROM sales_internet
-```
For dbt documentation, refer https://docs.getdbt.com/docs/introduction
-## Installation
-
-dbt-oracle can be installed via the Python Package Index (PyPI) using pip
-
-`pip install -U dbt-oracle`
-
-### Support
-
-dbt-oracle will provide support for the following
-
-- Python versions 3.6, 3.7, 3.8 and 3.9
-- Autonomous Database versions 19c and 21c
-- OS
- - Linux
- - MacOS
- - Windows
-
-### Core dependencies
-dbt-oracle requires the following 3 python packages.
-
-`dbt-core`
-
- - Open source framework for data transformation
- - Jinja Templating and core SQL compilation logic
- - Latest version of dbt-core is preferred; From version 1.0.0, dbt-core supports Python 3.7 or higher
- - For Python 3.6, pip will fallback to version 0.21.1 of dbt-core
-
-`cx-Oracle`
- - Python driver for Oracle database
- - Oracle client libraries should be installed on the system. For details check, https://cx-oracle.readthedocs.io/en/latest/user_guide/installation.html
-
-`dataclasses; python_version < '3.7'`
- - dataclasses package was introduced in the standard Python library from Python 3.7. This is conditional dependency and required only for Python 3.6
-
-## Getting Started
-
-Create a dbt project for oracle database using the `dbt init` command. The init command is interactive and will help you get started with a new project.
-
-`dbt init` will:
-
-* ask you the name of the project
-* ask you the database adapter you are using i.e. oracle
-* prompt to specify necessary connection details
-
-This example shows initialization of test project `dbt_oracle_test_project`
-
-```text
->> dbt init
-
-Running with dbt=1.0.4
-Enter a name for your project (letters, digits, underscore): dbt_oracle_test_project
-Which database would you like to use?
-[1] oracle
- Enter a number: 1
- protocol (tcp or tcps) [tcps]:
- host (adb..oraclecloud.com) [{{ env_var('DBT_ORACLE_HOST') }}]:
- port [1522]:
- user [{{ env_var('DBT_ORACLE_USER') }}]:
- password [{{ env_var('DBT_ORACLE_PASSWORD') }}]:
- service (service name in tnsnames.ora) [{{ env_var('DBT_ORACLE_SERVICE') }}]:
- dbname (database name in which dbt objects should be created) [{{ env_var('DBT_ORACLE_DATABASE') }}]:
- schema (database schema in which dbt objects should be created) [{{ env_var('DBT_ORACLE_SCHEMA') }}]:
- threads (1 or more) [1]: 4
-Profile dbt_oracle_test_project written to ~/.dbt/profiles.yml using target's profile_template.yml and your supplied values. Run 'dbt debug' to validate the connection.
-Your new dbt project "dbt_oracle_test_project" was created!
-
-```
-
-Then dbt init command will:
-
-1. Create the following folder with project name and sample files to get you started
- ```text
- ├── README.md
- ├── analyses
- ├── dbt_project.yml
- ├── macros
- ├── models
- │ └── example
- ├── seeds
- ├── snapshots
- └── tests
- ```
-2. Create a connection profile on your local machine. The default location is `~/.dbt/profiles.yml`
+## Installation
- Next step, [configure connection][1] related parameters and test if dbt connection works using dbt debug command
-
- ```text
- >> dbt debug
-
- os info: macOS-11.6-x86_64-i386-64bit
- Using profiles.yml file at ~/.dbt/profiles.yml
- Using dbt_project.yml file at /dbt_oracle_test_project/dbt_project.yml
- Configuration:
- profiles.yml file [OK found and valid]
- dbt_project.yml file [OK found and valid]
- Required dependencies:
- - git [OK found]
- Connection:
- user: ***
- database: ga01d76d2ecd5e0_db202112221108
- schema: ***
- protocol: tcps
- host: adb.us-ashburn-1.oraclecloud.com
- port: 1522
- service: _high.adb.oraclecloud.com
- connection_string: None
- shardingkey: []
- supershardingkey: []
- cclass: None
- purity: None
- Connection test: [OK connection ok]
-
- All checks passed!
- ```
+For installation, read how you can set up [Oracle profile][1] for dbt
-## Documentation [TODO]
-Link to the homepage - https://oracle.github.io/dbt-oracle
+## Sample project
-Link to documentation - https://dbt-oracle.readthedocs.io
+To get started, a sample dbt project can be found in the directory [/dbt_adbs_test_project][5]
## Contributing
This project welcomes contributions from the community. Before submitting a pull request, please review our [contribution guide][2].
@@ -192,7 +28,8 @@ Please consult the [security guide][3] for our responsible security vulnerabilit
## License
dbt-oracle is licensed under Apache 2.0 License which you can find [here][4]
-[1]: https://github.com/oracle/dbt-oracle/blob/main/dbt_adbs_test_project/profiles.yml
+[1]: https://docs.getdbt.com/reference/warehouse-profiles/oracle-profile
[2]: https://github.com/oracle/dbt-oracle/blob/main/CONTRIBUTING.md
[3]: https://github.com/oracle/dbt-oracle/blob/main/SECURITY.md
[4]: https://github.com/oracle/dbt-oracle/blob/main/LICENSE.txt
+[5]: https://github.com/oracle/dbt-oracle/tree/main/dbt_adbs_test_project
diff --git a/dbt/adapters/oracle/__version__.py b/dbt/adapters/oracle/__version__.py
index ce926da..a209144 100644
--- a/dbt/adapters/oracle/__version__.py
+++ b/dbt/adapters/oracle/__version__.py
@@ -14,4 +14,4 @@
See the License for the specific language governing permissions and
limitations under the License.
"""
-version = "1.0.6"
+version = "1.0.7"
diff --git a/dbt/adapters/oracle/impl.py b/dbt/adapters/oracle/impl.py
index 5762a45..532c15b 100644
--- a/dbt/adapters/oracle/impl.py
+++ b/dbt/adapters/oracle/impl.py
@@ -28,6 +28,8 @@
from dbt.adapters.oracle.relation import OracleRelation
from dbt.contracts.graph.manifest import Manifest
+from dbt.exceptions import raise_compiler_error
+from dbt.utils import filter_null_values
import agate
@@ -117,6 +119,21 @@ def verify_database(self, database):
# return an empty string on success so macros can call this
return ''
+ def _make_match_kwargs(self, database, schema, identifier):
+ quoting = self.config.quoting
+ if identifier is not None and quoting["identifier"] is False:
+ identifier = identifier.upper()
+
+ if schema is not None and quoting["schema"] is False:
+ schema = schema.upper()
+
+ if database is not None and quoting["database"] is False:
+ database = database.upper()
+
+ return filter_null_values(
+ {"identifier": identifier, "schema": schema, "database": database}
+ )
+
def get_rows_different_sql(
self,
relation_a: OracleRelation,
@@ -212,3 +229,23 @@ def list_relations_without_caching(
type=_type
))
return relations
+
+ @available
+ def quote_seed_column(
+ self, column: str, quote_config: Optional[bool]
+ ) -> str:
+ quote_columns: bool = False
+ if isinstance(quote_config, bool):
+ quote_columns = quote_config
+ elif quote_config is None:
+ pass
+ else:
+ raise_compiler_error(
+ f'The seed configuration value of "quote_columns" has an '
+ f'invalid type {type(quote_config)}'
+ )
+
+ if quote_columns:
+ return self.quote(column)
+ else:
+ return column
diff --git a/dbt/include/oracle/macros/adapters.sql b/dbt/include/oracle/macros/adapters.sql
index 6776fba..0d28bd4 100644
--- a/dbt/include/oracle/macros/adapters.sql
+++ b/dbt/include/oracle/macros/adapters.sql
@@ -25,11 +25,12 @@
{{ return(load_result('get_columns_in_query').table.columns | map(attribute='name') | list) }}
{% endmacro %}
-{% macro oracle__create_schema(database_name, schema_name) -%}
+
+{% macro oracle__create_schema(relation, schema_name) -%}
{% if relation.database -%}
{{ adapter.verify_database(relation.database) }}
{%- endif -%}
- {%- call statement('drop_schema') -%}
+ {%- call statement('create_schema') -%}
-- Noop for not breaking tests, oracle
-- schemas are actualy users, we can't
-- create it here
@@ -121,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 %}
@@ -172,8 +173,8 @@
from sys.all_tab_columns
)
select
- lower(column_name) as "name",
- lower(data_type) as "type",
+ column_name as "name",
+ data_type as "type",
char_length as "character_maximum_length",
numeric_precision as "numeric_precision",
numeric_scale as "numeric_scale"
@@ -204,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) -%}
@@ -217,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 %}
@@ -233,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 %}
@@ -256,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
@@ -268,14 +269,17 @@
{% endmacro %}
{% macro oracle__truncate_relation(relation) -%}
- {% call statement('truncate_relation') -%}
- truncate table {{ relation.quote(schema=False, identifier=False) }}
- {%- endcall %}
+ {#-- 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.include(False, True, True).quote(schema=False, identifier=False) }}
+ {%- endcall %}
+ {% endif %}
{% endmacro %}
{% macro oracle__rename_relation(from_relation, to_relation) -%}
{% call statement('rename_relation') -%}
- rename {{ from_relation.include(False, False, True).quote(schema=False, identifier=False) }} 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 %}
@@ -291,7 +295,7 @@
{{ adapter.verify_database(database) }}
{%- endif -%}
{% call statement('list_schemas', fetch_result=True, auto_begin=False) -%}
- select lower(username) as "name"
+ select username as "name"
from sys.all_users
order by username
{% endcall %}
@@ -329,9 +333,9 @@
'VIEW'
from sys.all_views
)
- select lower(table_catalog) as "database_name"
- ,lower(table_name) as "name"
- ,lower(table_schema) as "schema_name"
+ select table_catalog as "database_name"
+ ,table_name as "name"
+ ,table_schema as "schema_name"
,case table_type
when 'BASE TABLE' then 'table'
when 'VIEW' then 'view'
@@ -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 %}
@@ -361,4 +365,4 @@
{% set results = run_query("select SYS_CONTEXT('userenv', 'DB_NAME') FROM DUAL") %}
{% set db_name = results.columns[0].values()[0] %}
{{ return(db_name) }}
-{% endmacro %}
\ No newline at end of file
+{% endmacro %}
diff --git a/dbt/include/oracle/macros/catalog.sql b/dbt/include/oracle/macros/catalog.sql
index 8bd8327..c1b2673 100644
--- a/dbt/include/oracle/macros/catalog.sql
+++ b/dbt/include/oracle/macros/catalog.sql
@@ -90,18 +90,18 @@
from sys.all_views
)
select
- lower(tables.table_catalog) as "table_database",
- lower(tables.table_schema) as "table_schema",
- lower(tables.table_name) as "table_name",
- lower(tables.table_type) as "table_type",
+ tables.table_catalog as "table_database",
+ tables.table_schema as "table_schema",
+ tables.table_name as "table_name",
+ tables.table_type as "table_type",
all_tab_comments.comments as "table_comment",
- lower(columns.column_name) as "column_name",
+ columns.column_name as "column_name",
ordinal_position as "column_index",
- lower(case
+ case
when data_type like '%CHAR%'
then data_type || '(' || cast(char_length as varchar(10)) || ')'
else data_type
- end) as "column_type",
+ end as "column_type",
all_col_comments.comments as "column_comment",
tables.table_schema as "table_owner"
from tables
diff --git a/dbt/include/oracle/macros/materializations/incremental/helpers.sql b/dbt/include/oracle/macros/materializations/incremental/helpers.sql
index 54290a5..515de65 100644
--- a/dbt/include/oracle/macros/materializations/incremental/helpers.sql
+++ b/dbt/include/oracle/macros/materializations/incremental/helpers.sql
@@ -44,23 +44,21 @@
on (temp.{{ unique_key }} = target.{{ unique_key }})
when matched then
update set
- {% for col in dest_columns if col.name != unique_key %}
- target.{{ col.name }} = temp.{{ col.name }}
- {% if not loop.last %}, {% endif %}
- {% endfor %}
+ {% for col in dest_columns if col.name.upper() != unique_key.upper() -%}
+ target.{{ col.name }} = temp.{{ col.name }}{% if not loop.last %}, {% endif %}
+ {% endfor -%}
when not matched then
- insert( {{ dest_cols_csv }} )
+ insert({{ dest_cols_csv }})
values(
- {% for col in dest_columns %}
- temp.{{ col.name }}
- {% if not loop.last %}, {% endif %}
- {% endfor %}
+ {% for col in dest_columns -%}
+ temp.{{ col.name }}{% if not loop.last %}, {% endif %}
+ {% endfor -%}
)
- {%- else %}
+ {%- else -%}
insert into {{ target_relation }} ({{ dest_cols_csv }})
(
select {{ dest_cols_csv }}
from {{ tmp_relation }}
)
- {% endif %}
+ {%- endif -%}
{%- endmacro %}
diff --git a/dbt/include/oracle/macros/materializations/incremental/incremental.sql b/dbt/include/oracle/macros/materializations/incremental/incremental.sql
index 7c08d5a..6f2a8f4 100644
--- a/dbt/include/oracle/macros/materializations/incremental/incremental.sql
+++ b/dbt/include/oracle/macros/materializations/incremental/incremental.sql
@@ -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 %}
@@ -62,6 +65,7 @@
{% do adapter.commit() %}
{% for rel in to_drop %}
+ {% do adapter.truncate_relation(rel) %}
{% do adapter.drop_relation(rel) %}
{% endfor %}
diff --git a/dbt/include/oracle/macros/materializations/snapshot/snapshot.sql b/dbt/include/oracle/macros/materializations/snapshot/snapshot.sql
index 1b8d6b5..c53bfc3 100644
--- a/dbt/include/oracle/macros/materializations/snapshot/snapshot.sql
+++ b/dbt/include/oracle/macros/materializations/snapshot/snapshot.sql
@@ -35,8 +35,9 @@
{{ adapter.dispatch('post_snapshot')(staging_relation) }}
{% endmacro %}
-{% macro default__post_snapshot(staging_relation) %}
- {# no-op #}
+{% macro oracle__post_snapshot(staging_relation) %}
+ {% do adapter.truncate_relation(staging_relation) %}
+ {% do adapter.drop_relation(staging_relation) %}
{% endmacro %}
diff --git a/dbt/include/oracle/macros/materializations/table/table.sql b/dbt/include/oracle/macros/materializations/table/table.sql
index d327bc7..48541a0 100644
--- a/dbt/include/oracle/macros/materializations/table/table.sql
+++ b/dbt/include/oracle/macros/materializations/table/table.sql
@@ -68,7 +68,11 @@
-- cleanup
{% if old_relation is not none %}
- {{ adapter.rename_relation(old_relation, backup_relation) }}
+ {% if old_relation.is_view %}
+ {% do adapter.drop_relation(old_relation) %}
+ {% else %}
+ {% do adapter.rename_relation(old_relation, backup_relation) %}
+ {% endif %}
{% endif %}
{{ adapter.rename_relation(intermediate_relation, target_relation) }}
diff --git a/dbt/include/oracle/macros/materializations/view/view.sql b/dbt/include/oracle/macros/materializations/view/view.sql
index fc09856..7edcda8 100644
--- a/dbt/include/oracle/macros/materializations/view/view.sql
+++ b/dbt/include/oracle/macros/materializations/view/view.sql
@@ -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
@@ -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) }}
diff --git a/dbt_adbs_test_project/README.md b/dbt_adbs_test_project/README.md
index 103a0cd..606b866 100644
--- a/dbt_adbs_test_project/README.md
+++ b/dbt_adbs_test_project/README.md
@@ -9,39 +9,15 @@ To test the integration with ADBS, you can use OCI's [Always Free Autonomous Dat
The database also provides a read-only Sales History data set. Any user can start querying the tables in this Sales History `sh` schema. Models in this test project refer the `sh` schema. You do not need to load any other dataset.
-## Set the environment variables
+## Setup the oracle profile
-The following environment variables should be set to test integration with ADBS.
+To setup [profiles.yml](profiles.yml) read [setup & installation instructions][1] on dbt docs website
-```bash
- # cx_oracle needs lib_dir parameter pointing to the folder
- # containing the libraries from an unzipped Instant Client Basic or Basic Light package.
- # If lib_dir is not passed client libraries are looked for in the Operating system search path
- # or set in the following environment variables.
- DYLD_LIBRARY_PATH # For MacOS
- LD_LIBRARY_PATH # For Linux
-
- # For ADBS, cx_oracle will need the path to the folder
- # containing client wallet, sqlnet.ora and tnsnames.ora
- TNS_ADMIN
-
- # Database connection config - dbt specific variables
- DBT_ORACLE_USER
- DBT_ORACLE_HOST
- DBT_ORACLE_PORT
- DBT_ORACLE_SERVICE
- DBT_ORACLE_PASSWORD
- DBT_ORACLE_DATABASE
- DBT_ORACLE_SCHEMA
-```
-Check [profiles.yml](profiles.yml) to understand how these environment variables are used.
+Install dbt-oracle in your project's virtual environment.
-Also read about [connecting to Oracle Database](https://cx-oracle.readthedocs.io/en/latest/user_guide/connection_handling.html) using cx_Oracle
## dbt project
-Install dbt-oracle in your local development environment.
-
Next, run the `dbt compile` command in this project directory to compile the models and resolve dependencies.
```bash
dbt compile --profiles-dir ./
@@ -124,3 +100,5 @@ Following directory structure shows the 10 models, seed, test, analysis and snap
## Tests [TODO]
- Metrics - Experimental feature introduced in dbt-core==1.0.0
+
+[1]: https://docs.getdbt.com/reference/warehouse-profiles/oracle-profile
diff --git a/dbt_adbs_test_project/dbt_project.yml b/dbt_adbs_test_project/dbt_project.yml
index c8516fb..b56b954 100644
--- a/dbt_adbs_test_project/dbt_project.yml
+++ b/dbt_adbs_test_project/dbt_project.yml
@@ -4,6 +4,11 @@ version: 1.0
profile: dbt_test
analysis-paths: ['analysis']
test-paths: ['test']
+clean-targets: # directories to be removed by `dbt clean`
+ - "target"
+ - "dbt_packages"
+ - "dbt_modules"
+ - "logs"
quoting:
database: false
diff --git a/dbt_adbs_test_project/macros/generate_schema_name.sql b/dbt_adbs_test_project/macros/generate_schema_name.sql
new file mode 100644
index 0000000..57fcbc9
--- /dev/null
+++ b/dbt_adbs_test_project/macros/generate_schema_name.sql
@@ -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 %}
\ No newline at end of file
diff --git a/dbt_adbs_test_project/models/eu/countries.sql b/dbt_adbs_test_project/models/eu/countries.sql
index e84e29c..0690196 100644
--- a/dbt_adbs_test_project/models/eu/countries.sql
+++ b/dbt_adbs_test_project/models/eu/countries.sql
@@ -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',
diff --git a/dbt_adbs_test_project/models/people.sql b/dbt_adbs_test_project/models/people.sql
index 62a6717..8e6dd54 100644
--- a/dbt_adbs_test_project/models/people.sql
+++ b/dbt_adbs_test_project/models/people.sql
@@ -13,5 +13,5 @@
See the License for the specific language governing permissions and
limitations under the License.
#}
-{{config(materialized='view')}}
+{{config(materialized='table')}}
select * from {{ ref('seed') }}
diff --git a/dbt_adbs_test_project/models/schema.yml b/dbt_adbs_test_project/models/schema.yml
index ab667d8..87fbc8b 100644
--- a/dbt_adbs_test_project/models/schema.yml
+++ b/dbt_adbs_test_project/models/schema.yml
@@ -22,12 +22,20 @@ models:
columns:
- name: id
tests:
+ - dbt_constraints.primary_key
- not_null
- unique
- name: gender
tests:
- accepted_values:
values: ['Male', 'Female']
+ - name: countries
+ columns:
+ - name: country_id
+ tests:
+ - dbt_constraints.primary_key
+ - not_null
+ - unique
- name: eu_direct_sales_channels_promo_costs
columns:
- name: country_id
@@ -35,5 +43,8 @@ models:
- relationships:
to: ref('countries')
field: country_id
+ - dbt_constraints.foreign_key:
+ pk_table_name: ref('countries')
+ pk_column_name: country_id
diff --git a/dbt_adbs_test_project/models/us_product_sales_channel_ranking.sql b/dbt_adbs_test_project/models/us_product_sales_channel_ranking.sql
index 36dd660..f0096e7 100644
--- a/dbt_adbs_test_project/models/us_product_sales_channel_ranking.sql
+++ b/dbt_adbs_test_project/models/us_product_sales_channel_ranking.sql
@@ -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') }},
diff --git a/dbt_adbs_test_project/packages.yml b/dbt_adbs_test_project/packages.yml
index c486183..781deed 100644
--- a/dbt_adbs_test_project/packages.yml
+++ b/dbt_adbs_test_project/packages.yml
@@ -1,2 +1,4 @@
packages:
- - git: https://github.com/fishtown-analytics/dbt-utils.git
\ No newline at end of file
+ - git: https://github.com/fishtown-analytics/dbt-utils.git
+ - git: https://github.com/Snowflake-Labs/dbt_constraints.git
+ revision: dbt-oracle-support
\ No newline at end of file
diff --git a/setup.cfg b/setup.cfg
index 0a5d2d5..f2fc0a8 100644
--- a/setup.cfg
+++ b/setup.cfg
@@ -1,6 +1,6 @@
[metadata]
name = dbt-oracle
-version = 1.0.2
+version = 1.0.3
description = dbt (data build tool) adapter for the Oracle database
long_description = file: README.md
long_description_content_type = text/markdown
diff --git a/setup.py b/setup.py
index 683c0a2..3f08482 100644
--- a/setup.py
+++ b/setup.py
@@ -43,7 +43,7 @@
url = 'https://github.com/oracle/dbt-oracle'
-VERSION='1.0.2'
+VERSION='1.0.3'
setup(
author="Oracle",
python_requires='>=3.6',