Skip to content

Commit

Permalink
Merge pull request #18 from ArtemHU/handing-the-maximum-identifier-le…
Browse files Browse the repository at this point in the history
…ngth-is-63-bytes-case

- These changes will allow dbt_constraints to use a hash function to keep constraint names 63 characters or less on PostgreSQL and 30 characters or less on Oracle. 
- I also fixed a small issue on the Oracle macro related to upper/lower case table names that was causing FK to be skipped because the logic was not correctly looking up whether any PK/UK existed on the parent table.
  • Loading branch information
sfc-gh-dflippo authored Aug 11, 2022
2 parents 09ee668 + 5c87682 commit 822dd1b
Show file tree
Hide file tree
Showing 5 changed files with 105 additions and 4 deletions.
12 changes: 12 additions & 0 deletions integration_tests/models/fact_order_line_longcol.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,12 @@
/*
Test
dim_order_copy____________
*/
SELECT
l_orderkey as l_____________________orderkey,
l_linenumber as l___________________linenumber,
l_partkey as l______________________partkey,
l_suppkey l______________________suppkey,
integration_id as l_______________integration_id
FROM
{{ ref('fact_order_line') }} O
32 changes: 32 additions & 0 deletions integration_tests/models/schema.yml
Original file line number Diff line number Diff line change
Expand Up @@ -223,3 +223,35 @@ models:

- name: dim_part_supplier_missing_con
description: "Table is missing constraints to test FK won't be generated to it"

- name: fact_order_line_longcol
description: "Fact Order Lines with long column names"
columns:
- name: l_____________________orderkey
description: "FK to dim_orders and first key in PK"
tests:
- relationships:
to: ref('dim_orders')
field: o_orderkey
- name: l___________________linenumber
description: "Order Line Number and second key in PK"
- name: l_______________integration_id
description: "Concatenation of PK colums for the unique and not_null tests"
tests:
- unique
- not_null
tests:
# Demonstration that the primary_key test can accept multiple columns
- dbt_constraints.primary_key:
column_names:
- l_____________________orderkey
- l___________________linenumber
# Test multi-column FK
- dbt_constraints.foreign_key:
fk_column_names:
- l______________________partkey
- l______________________suppkey
pk_table_name: ref('dim_part_supplier')
pk_column_names:
- ps_partkey
- ps_suppkey
35 changes: 31 additions & 4 deletions macros/oracle__create_constraints.sql
Original file line number Diff line number Diff line change
@@ -1,6 +1,15 @@
{# Oracle specific implementation to create a primary key #}
{%- macro oracle__create_primary_key(table_relation, column_names, verify_permissions, quote_columns=false) -%}
{%- set constraint_name = (table_relation.identifier ~ "_" ~ column_names|join('_') ~ "_PK") | upper -%}

{%- if constraint_name|length > 30 %}
{%- set constraint_name_query %}
select 'PK_' || ora_hash( '{{ constraint_name }}' ) as "constraint_name" from dual
{%- endset -%}
{%- set results = run_query(constraint_name_query) -%}
{%- set constraint_name = results.columns[0].values()[0] -%}
{% endif %}

{%- set columns_csv = dbt_constraints.get_quoted_column_csv(column_names, quote_columns) -%}

{#- Check that the table does not already have this PK/UK -#}
Expand Down Expand Up @@ -35,6 +44,15 @@ END;
{# Oracle specific implementation to create a unique key #}
{%- macro oracle__create_unique_key(table_relation, column_names, verify_permissions, quote_columns=false) -%}
{%- set constraint_name = (table_relation.identifier ~ "_" ~ column_names|join('_') ~ "_UK") | upper -%}

{%- if constraint_name|length > 30 %}
{%- set constraint_name_query %}
select 'UK_' || ora_hash( '{{ constraint_name }}' ) as "constraint_name" from dual
{%- endset -%}
{%- set results = run_query(constraint_name_query) -%}
{%- set constraint_name = results.columns[0].values()[0] -%}
{% endif %}

{%- set columns_csv = dbt_constraints.get_quoted_column_csv(column_names, quote_columns) -%}

{#- Check that the table does not already have this PK/UK -#}
Expand Down Expand Up @@ -69,6 +87,15 @@ END;
{# Oracle specific implementation to create a foreign key #}
{%- macro oracle__create_foreign_key(pk_table_relation, pk_column_names, fk_table_relation, fk_column_names, verify_permissions, quote_columns=true) -%}
{%- set constraint_name = (fk_table_relation.identifier ~ "_" ~ fk_column_names|join('_') ~ "_FK") | upper -%}

{%- if constraint_name|length > 30 %}
{%- set constraint_name_query %}
select 'FK_' || ora_hash( '{{ constraint_name }}' ) as "constraint_name" from dual
{%- endset -%}
{%- set results = run_query(constraint_name_query) -%}
{%- set constraint_name = results.columns[0].values()[0] -%}
{% endif %}

{%- set fk_columns_csv = dbt_constraints.get_quoted_column_csv(fk_column_names, quote_columns) -%}
{%- set pk_columns_csv = dbt_constraints.get_quoted_column_csv(pk_column_names, quote_columns) -%}
{#- Check that the PK table has a PK or UK -#}
Expand Down Expand Up @@ -118,8 +145,8 @@ from
and cons.owner = cols.owner
where
cons.constraint_type in ( 'P', 'U' )
and cons.owner = '{{table_relation.schema}}'
and cons.table_name = '{{table_relation.identifier}}'
and upper(cons.owner) = upper('{{table_relation.schema}}')
and upper(cons.table_name) = upper('{{table_relation.identifier}}')
order by 1, 2
{%- endset -%}
{%- do log("Lookup: " ~ lookup_query, info=false) -%}
Expand Down Expand Up @@ -152,8 +179,8 @@ from
and cons.owner = cols.owner
where
cons.constraint_type in ( 'R' )
and cons.owner = '{{table_relation.schema}}'
and cons.table_name = '{{table_relation.identifier}}'
and upper(cons.owner) = upper('{{table_relation.schema}}')
and upper(cons.table_name) = upper('{{table_relation.identifier}}')
order by 1, 2
{%- endset -%}
{%- do log("Lookup: " ~ lookup_query, info=false) -%}
Expand Down
27 changes: 27 additions & 0 deletions macros/postgres__create_constraints.sql
Original file line number Diff line number Diff line change
@@ -1,6 +1,15 @@
{# PostgreSQL specific implementation to create a primary key #}
{%- macro postgres__create_primary_key(table_relation, column_names, verify_permissions, quote_columns=false) -%}
{%- set constraint_name = (table_relation.identifier ~ "_" ~ column_names|join('_') ~ "_PK") | upper -%}

{%- if constraint_name|length > 63 %}
{%- set constraint_name_query %}
select 'PK_' || md5( '{{ constraint_name }}' )::varchar as "constraint_name"
{%- endset -%}
{%- set results = run_query(constraint_name_query) -%}
{%- set constraint_name = results.columns[0].values()[0] -%}
{% endif %}

{%- set columns_csv = dbt_constraints.get_quoted_column_csv(column_names, quote_columns) -%}

{#- Check that the table does not already have this PK/UK -#}
Expand Down Expand Up @@ -30,6 +39,15 @@
{# PostgreSQL specific implementation to create a unique key #}
{%- macro postgres__create_unique_key(table_relation, column_names, verify_permissions, quote_columns=false) -%}
{%- set constraint_name = (table_relation.identifier ~ "_" ~ column_names|join('_') ~ "_UK") | upper -%}

{%- if constraint_name|length > 63 %}
{%- set constraint_name_query %}
select 'UK_' || md5( '{{ constraint_name }}' )::varchar as "constraint_name"
{%- endset -%}
{%- set results = run_query(constraint_name_query) -%}
{%- set constraint_name = results.columns[0].values()[0] -%}
{% endif %}

{%- set columns_csv = dbt_constraints.get_quoted_column_csv(column_names, quote_columns) -%}

{#- Check that the table does not already have this PK/UK -#}
Expand Down Expand Up @@ -59,6 +77,15 @@
{# PostgreSQL specific implementation to create a foreign key #}
{%- macro postgres__create_foreign_key(pk_table_relation, pk_column_names, fk_table_relation, fk_column_names, verify_permissions, quote_columns=true) -%}
{%- set constraint_name = (fk_table_relation.identifier ~ "_" ~ fk_column_names|join('_') ~ "_FK") | upper -%}

{%- if constraint_name|length > 63 %}
{%- set constraint_name_query %}
select 'FK_' || md5( '{{ constraint_name }}' )::varchar as "constraint_name"
{%- endset -%}
{%- set results = run_query(constraint_name_query) -%}
{%- set constraint_name = results.columns[0].values()[0] -%}
{% endif %}

{%- set fk_columns_csv = dbt_constraints.get_quoted_column_csv(fk_column_names, quote_columns) -%}
{%- set pk_columns_csv = dbt_constraints.get_quoted_column_csv(pk_column_names, quote_columns) -%}
{#- Check that the PK table has a PK or UK -#}
Expand Down
3 changes: 3 additions & 0 deletions packages.yml
Original file line number Diff line number Diff line change
@@ -0,0 +1,3 @@
packages:
- package: dbt-labs/dbt_utils
version: [">=0.8.0", "<0.9.0"]

0 comments on commit 822dd1b

Please sign in to comment.