From 11695ff978a1f3714e802e2bb980ef3e7ce27c6e Mon Sep 17 00:00:00 2001 From: Abhishek Singh Date: Mon, 11 Mar 2024 20:40:07 -0700 Subject: [PATCH 1/2] v1.7.3 changes - Added support for Python 3.12 - oracledb driver upgraded to 2.1.0 - Added support for delete+insert incremental strategy addressing https://github.com/oracle/dbt-oracle/issues/128 - Added support for new config `partition_config` --- .github/workflows/oracle-xe-adapter-tests.yml | 2 +- Makefile | 2 +- dbt/adapters/oracle/__version__.py | 2 +- dbt/adapters/oracle/impl.py | 2 +- dbt/include/oracle/macros/adapters.sql | 2 + .../incremental/strategies.sql | 39 +++++++++++++++++ .../models/us_product_delete_insert.sql | 43 +++++++++++++++++++ .../us_product_sales_channel_ranking.sql | 4 +- dbt_adbs_test_project/profiles.yml | 6 --- requirements.txt | 2 +- setup.cfg | 5 ++- setup.py | 7 +-- tox.ini | 2 +- 13 files changed, 99 insertions(+), 19 deletions(-) create mode 100644 dbt_adbs_test_project/models/us_product_delete_insert.sql diff --git a/.github/workflows/oracle-xe-adapter-tests.yml b/.github/workflows/oracle-xe-adapter-tests.yml index 3ef8723..d0bc693 100644 --- a/.github/workflows/oracle-xe-adapter-tests.yml +++ b/.github/workflows/oracle-xe-adapter-tests.yml @@ -8,7 +8,7 @@ jobs: fail-fast: true matrix: os: [ ubuntu-latest ] - python-version: [ '3.8', '3.9', '3.10', '3.11' ] + python-version: [ '3.8', '3.9', '3.10', '3.11', '3.12'] services: oracle_db_xe: diff --git a/Makefile b/Makefile index b02c0a3..bd7cb70 100644 --- a/Makefile +++ b/Makefile @@ -1,5 +1,5 @@ # Configuration variables -VERSION=1.7.2 +VERSION=1.7.3 PROJ_DIR?=$(shell pwd) VENV_DIR?=${PROJ_DIR}/.bldenv BUILD_DIR=${PROJ_DIR}/build diff --git a/dbt/adapters/oracle/__version__.py b/dbt/adapters/oracle/__version__.py index 2f57bae..05c3e08 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.7.7" +version = "1.7.9" diff --git a/dbt/adapters/oracle/impl.py b/dbt/adapters/oracle/impl.py index e0a7f7b..ceaeb7a 100644 --- a/dbt/adapters/oracle/impl.py +++ b/dbt/adapters/oracle/impl.py @@ -397,7 +397,7 @@ def quote_seed_column( return column def valid_incremental_strategies(self): - return ["append", "merge"] + return ["append", "merge", "delete+insert"] @available @classmethod diff --git a/dbt/include/oracle/macros/adapters.sql b/dbt/include/oracle/macros/adapters.sql index c1c2fb2..d7f7e1a 100644 --- a/dbt/include/oracle/macros/adapters.sql +++ b/dbt/include/oracle/macros/adapters.sql @@ -146,6 +146,7 @@ {%- set parallel = config.get('parallel', none) -%} {%- set compression_clause = config.get('table_compression_clause', none) -%} {%- set contract_config = config.get('contract') -%} + {%- set partition_clause = config.get('partition_config', {}).get('clause') -%} {{ sql_header if sql_header is not none }} create {% if temporary -%} global temporary @@ -157,6 +158,7 @@ {% endif %} {% if temporary -%} on commit preserve rows {%- endif %} {% if not temporary -%} + {% if partition_clause %} {{ partition_clause }} {% endif %} {% if parallel %} parallel {{ parallel }}{% endif %} {% if compression_clause %} {{ compression_clause }} {% endif %} {%- endif %} diff --git a/dbt/include/oracle/macros/materializations/incremental/strategies.sql b/dbt/include/oracle/macros/materializations/incremental/strategies.sql index d155c94..e993b80 100644 --- a/dbt/include/oracle/macros/materializations/incremental/strategies.sql +++ b/dbt/include/oracle/macros/materializations/incremental/strategies.sql @@ -149,3 +149,42 @@ {% macro oracle__get_incremental_default_sql(arg_dict) %} {% do return(get_incremental_merge_sql(arg_dict)) %} {% endmacro %} + +{% macro oracle__get_incremental_delete_insert_sql(args_dict) %} + {%- set parallel = config.get('parallel', none) -%} + {%- set dest_columns = args_dict["dest_columns"] -%} + {%- set temp_relation = args_dict["temp_relation"] -%} + {%- set target_relation = args_dict["target_relation"] -%} + {%- set unique_key = args_dict["unique_key"] -%} + {%- set dest_column_names = dest_columns | map(attribute='name') | list -%} + {%- set dest_cols_csv = get_quoted_column_csv(model, dest_column_names) -%} + {%- set merge_update_columns = config.get('merge_update_columns') -%} + {%- set merge_exclude_columns = config.get('merge_exclude_columns') -%} + {%- set incremental_predicates = args_dict["incremental_predicates"] -%} + {%- set update_columns = get_merge_update_columns(merge_update_columns, merge_exclude_columns, dest_columns) -%} + {%- if unique_key -%} + {%- set unique_key_result = oracle_check_and_quote_unique_key_for_incremental_merge(unique_key, incremental_predicates) -%} + {%- set unique_key_list = unique_key_result['unique_key_list'] -%} + {%- set unique_key_merge_predicates = unique_key_result['unique_key_merge_predicates'] -%} + BEGIN + EXECUTE IMMEDIATE 'merge {% if parallel %} /*+parallel({{ parallel }})*/ {% endif %} into {{ target_relation }} DBT_INTERNAL_DEST + using {{ temp_relation }} DBT_INTERNAL_SOURCE + on ({{ unique_key_merge_predicates | join(' AND ') }}) + when matched then + update set + {% for col in update_columns if (col.upper() not in unique_key_list and col not in unique_key_list) -%} + DBT_INTERNAL_DEST.{{ col }} = DBT_INTERNAL_SOURCE.{{ col }}{% if not loop.last %}, {% endif %} + {% endfor -%} + DELETE WHERE 1=1'; + EXECUTE IMMEDIATE 'insert {% if parallel %} /*+parallel({{ parallel }})*/ {% endif %} into {{ target_relation }} ({{ dest_cols_csv }})( + select {{ dest_cols_csv }} + from {{ temp_relation }})'; + END; + {%- else -%} + insert {% if parallel %} /*+parallel({{ parallel }})*/ {% endif %} into {{ target_relation }} ({{ dest_cols_csv }}) + ( + select {{ dest_cols_csv }} + from {{ temp_relation }} + ) + {%- endif -%} +{% endmacro %} \ No newline at end of file diff --git a/dbt_adbs_test_project/models/us_product_delete_insert.sql b/dbt_adbs_test_project/models/us_product_delete_insert.sql new file mode 100644 index 0000000..5453a42 --- /dev/null +++ b/dbt_adbs_test_project/models/us_product_delete_insert.sql @@ -0,0 +1,43 @@ +{# + Copyright (c) 2024, 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. +#} +{{ + config( + materialized='incremental', + incremental_strategy='delete+insert', + parallel=4, + partition_config={"clause": "PARTITION BY HASH(PROD_NAME) PARTITIONS 4"}, + table_compression_clause='COLUMN STORE COMPRESS FOR QUERY LOW') +}} + +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') }}, + {{ source('sh_database', 'times') }}, {{ source('sh_database', 'channels') }}, {{ source('sh_database', 'countries') }} +WHERE sales.prod_id=products.prod_id AND sales.cust_id=customers.cust_id + AND customers.country_id = countries.country_id AND sales.time_id=times.time_id + AND sales.channel_id=channels.channel_id + AND country_iso_code='US' + +{% if is_incremental() %} + + AND times.calendar_month_desc > (SELECT MAX(calendar_month_desc) FROM {{ this }}) + +{% endif %} + +GROUP BY prod_name, channel_desc, calendar_month_desc \ No newline at end of file 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 e412c9d..4baeb15 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 @@ -1,5 +1,5 @@ {# - Copyright (c) 2022, Oracle and/or its affiliates. + Copyright (c) 2024, 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. @@ -17,8 +17,8 @@ config( materialized='incremental', unique_key='group_id', - full_refresh=false, parallel=4, + partition_config={"clause": "PARTITION BY HASH(PROD_NAME) PARTITIONS 4"}, table_compression_clause='COLUMN STORE COMPRESS FOR QUERY LOW') }} diff --git a/dbt_adbs_test_project/profiles.yml b/dbt_adbs_test_project/profiles.yml index 727fb8c..faeceed 100644 --- a/dbt_adbs_test_project/profiles.yml +++ b/dbt_adbs_test_project/profiles.yml @@ -19,12 +19,6 @@ dbt_test: module: "dbt-module-1.5.2" retry_count: 1 retry_delay: 5 - shardingkey: - - skey - supershardingkey: - - sskey - cclass: CONNECTIVITY_CLASS - purity: self threads: 1 test: type: oracle diff --git a/requirements.txt b/requirements.txt index 8f5539a..cd6be84 100644 --- a/requirements.txt +++ b/requirements.txt @@ -1,3 +1,3 @@ dbt-core~=1.7,<1.8 cx_Oracle==8.3.0 -oracledb==2.0.1 +oracledb==2.1.0 diff --git a/setup.cfg b/setup.cfg index 31bcdea..ef80d22 100644 --- a/setup.cfg +++ b/setup.cfg @@ -1,6 +1,6 @@ [metadata] name = dbt-oracle -version = 1.7.2 +version = 1.7.3 description = dbt (data build tool) adapter for Oracle Autonomous Database long_description = file: README.md long_description_content_type = text/markdown @@ -16,6 +16,7 @@ classifiers = Programming Language :: Python :: 3.9 Programming Language :: Python :: 3.10 Programming Language :: Python :: 3.11 + Programming Language :: Python :: 3.12 # Map or URL names to links # Github, PyPI and documentations urls should be added below @@ -34,7 +35,7 @@ include_package_data = True install_requires = dbt-core~=1.7,<1.8 cx_Oracle==8.3.0 - oracledb==2.0.1 + oracledb==2.1.0 test_suite=tests test_requires = dbt-tests-adapter~=1.7,<1.8 diff --git a/setup.py b/setup.py index aaa6d8b..a061e7f 100644 --- a/setup.py +++ b/setup.py @@ -42,7 +42,7 @@ requirements = [ "dbt-core~=1.7,<1.8", "cx_Oracle==8.3.0", - "oracledb==2.0.1" + "oracledb==2.1.0" ] test_requirements = [ @@ -60,7 +60,7 @@ url = 'https://github.com/oracle/dbt-oracle' -VERSION = '1.7.2' +VERSION = '1.7.3' setup( author="Oracle", python_requires='>=3.8', @@ -73,7 +73,8 @@ 'Programming Language :: Python :: 3.8', 'Programming Language :: Python :: 3.9', 'Programming Language :: Python :: 3.10', - 'Programming Language :: Python :: 3.11' + 'Programming Language :: Python :: 3.11', + 'Programming Language :: Python :: 3.12' ], description="dbt (data build tool) adapter for Oracle Autonomous Database", install_requires=requirements, diff --git a/tox.ini b/tox.ini index 94b05d5..8379c06 100644 --- a/tox.ini +++ b/tox.ini @@ -1,5 +1,5 @@ [tox] -envlist = py3{8,9,10,11} +envlist = py3{8,9,10,11,12} [testenv] passenv = From 1e2db1cfdc2c4c588e67f30522ebba3ec8c2c5fa Mon Sep 17 00:00:00 2001 From: Abhishek Singh Date: Tue, 12 Mar 2024 14:36:57 -0700 Subject: [PATCH 2/2] Updated Readme and added newlines in missing files --- README.md | 10 ++++++++++ .../macros/materializations/incremental/strategies.sql | 2 +- .../models/us_product_delete_insert.sql | 2 +- 3 files changed, 12 insertions(+), 2 deletions(-) diff --git a/README.md b/README.md index faefd3f..833d11d 100644 --- a/README.md +++ b/README.md @@ -22,6 +22,12 @@ pip install dbt-oracle Please refer to the [Oracle setup on dbt docs website][1] for documentation. +## Help + +Questions can be asked either in [db-oracle community Slack channel][6] or in [GitHub Discussions][7] + +Bugs reports or feature requests can be raised in [GitHub Issues][8] + ## Sample project To get started, a sample dbt project can be found in the directory [/dbt_adbs_test_project][5]. @@ -42,3 +48,7 @@ dbt-oracle is licensed under Apache 2.0 License which you can find [here][4]. [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 +[6]: https://getdbt.slack.com/archives/C01PWH4TXLY +[7]: https://github.com/oracle/dbt-oracle/discussions +[8]: https://github.com/oracle/dbt-oracle/issues + diff --git a/dbt/include/oracle/macros/materializations/incremental/strategies.sql b/dbt/include/oracle/macros/materializations/incremental/strategies.sql index e993b80..d22b170 100644 --- a/dbt/include/oracle/macros/materializations/incremental/strategies.sql +++ b/dbt/include/oracle/macros/materializations/incremental/strategies.sql @@ -187,4 +187,4 @@ from {{ temp_relation }} ) {%- endif -%} -{% endmacro %} \ No newline at end of file +{% endmacro %} diff --git a/dbt_adbs_test_project/models/us_product_delete_insert.sql b/dbt_adbs_test_project/models/us_product_delete_insert.sql index 5453a42..4e17b8d 100644 --- a/dbt_adbs_test_project/models/us_product_delete_insert.sql +++ b/dbt_adbs_test_project/models/us_product_delete_insert.sql @@ -40,4 +40,4 @@ WHERE sales.prod_id=products.prod_id AND sales.cust_id=customers.cust_id {% endif %} -GROUP BY prod_name, channel_desc, calendar_month_desc \ No newline at end of file +GROUP BY prod_name, channel_desc, calendar_month_desc