diff --git a/.gitignore b/.gitignore new file mode 100644 index 0000000..d99e9bd --- /dev/null +++ b/.gitignore @@ -0,0 +1,18 @@ + +target/ +dbt_modules/ +# newer versions of dbt use this directory instead of dbt_modules for test dependencies +dbt_packages/ +logs/ + +.venv/ +.python-version + +# Visual Studio Code files +*/.vscode +*.code-workspace +.history/ +**/.DS_Store +.vscode/ +.env +dbt-env/ \ No newline at end of file diff --git a/README.md b/README.md index 186eba7..2227d8d 100644 --- a/README.md +++ b/README.md @@ -1 +1,97 @@ -# base-models \ No newline at end of file +## Profile Set Up + +#### Use the following within profiles.yml +---- + +```yml +base: + target: dev + outputs: + dev: + type: snowflake + account: + role: + user: + password: + region: + database: BASE_DEV + warehouse: + schema: silver + threads: 12 + client_session_keep_alive: False + query_tag: + prod: + type: snowflake + account: + role: + user: + password: + region: + database: BASE + warehouse: + schema: silver + threads: 12 + client_session_keep_alive: False + query_tag: +``` +### Variables + +To control the creation of UDF or SP macros with dbt run: +* UPDATE_UDFS_AND_SPS +When True, executes all macros included in the on-run-start hooks within dbt_project.yml on model run as normal +When False, none of the on-run-start macros are executed on model run + +Default values are False + +* Usage: +dbt run --var '{"UPDATE_UDFS_AND_SPS":True}' -m ... + +### Resources: +- Learn more about dbt [in the docs](https://docs.getdbt.com/docs/introduction) +- Check out [Discourse](https://discourse.getdbt.com/) for commonly asked questions and answers +- Join the [chat](https://community.getdbt.com/) on Slack for live discussions and support +- Find [dbt events](https://events.getdbt.com) near you +- Check out [the blog](https://blog.getdbt.com/) for the latest news on dbt's development and best practices + + +## Applying Model Tags + +### Database / Schema level tags + +Database and schema tags are applied via the `add_database_or_schema_tags` macro. These tags are inherited by their downstream objects. To add/modify tags call the appropriate tag set function within the macro. + +``` +{{ set_database_tag_value('SOME_DATABASE_TAG_KEY','SOME_DATABASE_TAG_VALUE') }} +{{ set_schema_tag_value('SOME_SCHEMA_TAG_KEY','SOME_SCHEMA_TAG_VALUE') }} +``` + +### Model tags + +To add/update a model's snowflake tags, add/modify the `meta` model property under `config`. Only table level tags are supported at this time via DBT. + +``` +{{ config( + ..., + meta={ + 'database_tags':{ + 'table': { + 'PURPOSE': 'SOME_PURPOSE' + } + } + }, + ... +) }} +``` + +By default, model tags are pushed to Snowflake on each load. You can disable this by setting the `UPDATE_SNOWFLAKE_TAGS` project variable to `False` during a run. + +``` +dbt run --var '{"UPDATE_SNOWFLAKE_TAGS":False}' -s models/core/core__fact_blocks.sql +``` + +### Querying for existing tags on a model in snowflake + +``` +select * +from table(base.information_schema.tag_references('base.core.fact_blocks', 'table')); +``` \ No newline at end of file diff --git a/analysis/.gitkeep b/analysis/.gitkeep new file mode 100644 index 0000000..e69de29 diff --git a/data/.gitkeep b/data/.gitkeep new file mode 100644 index 0000000..e69de29 diff --git a/dbt_project.yml b/dbt_project.yml new file mode 100644 index 0000000..d7dd9a3 --- /dev/null +++ b/dbt_project.yml @@ -0,0 +1,46 @@ +# Name your project! Project names should contain only lowercase characters +# and underscores. A good package name should reflect your organization's +# name or the intended use of these models +name: "base_models" +version: "1.0.0" +config-version: 2 + +# This setting configures which "profile" dbt uses for this project. +profile: "base" + +# These configurations specify where dbt should look for different types of files. +# The `source-paths` config, for example, states that models in this project can be +# found in the "models/" directory. You probably won't need to change these! +model-paths: ["models"] +analysis-paths: ["analysis"] +test-paths: ["tests"] +seed-paths: ["data"] +macro-paths: ["macros"] +snapshot-paths: ["snapshots"] + +target-path: "target" # directory which will store compiled SQL files +clean-targets: # directories to be removed by `dbt clean` + - "target" + - "dbt_modules" + - "dbt_packages" + +tests: + +store_failures: true # all tests + +on-run-start: + - "{{ create_sps() }}" + +on-run-end: + - '{{ apply_meta_as_tags(results) }}' + +# Configuring models +# Full documentation: https://docs.getdbt.com/docs/configuring-models + +# In this example config, we tell dbt to build all models in the example/ directory +# as tables. These settings can be overridden in the individual model files +# using the `{{ config(...) }}` macro. + +vars: + "dbt_date:time_zone": GMT + UPDATE_UDFS_AND_SPS: False + UPDATE_SNOWFLAKE_TAGS: True \ No newline at end of file diff --git a/macros/.gitkeep b/macros/.gitkeep new file mode 100644 index 0000000..e69de29 diff --git a/macros/create_sps.sql b/macros/create_sps.sql new file mode 100644 index 0000000..eb14341 --- /dev/null +++ b/macros/create_sps.sql @@ -0,0 +1,8 @@ +{% macro create_sps() %} + {% if var("UPDATE_UDFS_AND_SPS") %} + {% if target.database == 'BASE' %} + CREATE schema IF NOT EXISTS _internal; + {{ sp_create_prod_clone('_internal') }}; + {% endif %} + {% endif %} +{% endmacro %} diff --git a/macros/custom_naming_macros.sql b/macros/custom_naming_macros.sql new file mode 100644 index 0000000..0f4a72c --- /dev/null +++ b/macros/custom_naming_macros.sql @@ -0,0 +1,11 @@ +{% macro generate_schema_name(custom_schema_name=none, node=none) -%} + {% set node_name = node.name %} + {% set split_name = node_name.split('__') %} + {{ split_name[0] | trim }} +{%- endmacro %} + +{% macro generate_alias_name(custom_alias_name=none, node=none) -%} + {% set node_name = node.name %} + {% set split_name = node_name.split('__') %} + {{ split_name[1] | trim }} +{%- endmacro %} diff --git a/macros/custom_query_tag.sql b/macros/custom_query_tag.sql new file mode 100644 index 0000000..809e1bb --- /dev/null +++ b/macros/custom_query_tag.sql @@ -0,0 +1,11 @@ +{% macro set_query_tag() -%} + {% set new_json = {"repo":project_name, "object":this.table, "profile":target.profile_name, "env":target.name, "existing_tag":get_current_query_tag() } %} +{% set new_query_tag = tojson(new_json) | as_text %} + {% if new_query_tag %} + {% set original_query_tag = get_current_query_tag() %} + {{ log("Setting query_tag to '" ~ new_query_tag ~ "'. Will reset to '" ~ original_query_tag ~ "' after materialization.") }} + {% do run_query("alter session set query_tag = '{}'".format(new_query_tag)) %} + {{ return(original_query_tag)}} + {% endif %} + {{ return(none)}} +{% endmacro %} \ No newline at end of file diff --git a/macros/run_sp_create_prod_clone.sql b/macros/run_sp_create_prod_clone.sql new file mode 100644 index 0000000..ced835e --- /dev/null +++ b/macros/run_sp_create_prod_clone.sql @@ -0,0 +1,10 @@ +{% macro run_sp_create_prod_clone() %} + {% set clone_query %} + call base._internal.create_prod_clone( + 'base', + 'base_dev', + 'internal_dev' + ); +{% endset %} + {% do run_query(clone_query) %} +{% endmacro %} diff --git a/macros/sp_create_prod_clone.sql b/macros/sp_create_prod_clone.sql new file mode 100644 index 0000000..20ee897 --- /dev/null +++ b/macros/sp_create_prod_clone.sql @@ -0,0 +1,44 @@ +{% macro sp_create_prod_clone(target_schema) -%} + +create or replace procedure {{ target_schema }}.create_prod_clone(source_db_name string, destination_db_name string, role_name string) +returns boolean +language javascript +execute as caller +as +$$ + snowflake.execute({sqlText: `BEGIN TRANSACTION;`}); + try { + snowflake.execute({sqlText: `CREATE OR REPLACE DATABASE ${DESTINATION_DB_NAME} CLONE ${SOURCE_DB_NAME}`}); + snowflake.execute({sqlText: `DROP SCHEMA IF EXISTS ${DESTINATION_DB_NAME}._INTERNAL`}); /* this only needs to be in prod */ + + snowflake.execute({sqlText: `GRANT OWNERSHIP ON ALL SCHEMAS IN DATABASE ${DESTINATION_DB_NAME} TO ROLE ${ROLE_NAME} COPY CURRENT GRANTS;`}); + snowflake.execute({sqlText: `GRANT OWNERSHIP ON ALL FUNCTIONS IN DATABASE ${DESTINATION_DB_NAME} TO ROLE ${ROLE_NAME} COPY CURRENT GRANTS;`}); + snowflake.execute({sqlText: `GRANT OWNERSHIP ON ALL PROCEDURES IN DATABASE ${DESTINATION_DB_NAME} TO ROLE ${ROLE_NAME} COPY CURRENT GRANTS;`}); + snowflake.execute({sqlText: `GRANT OWNERSHIP ON ALL VIEWS IN DATABASE ${DESTINATION_DB_NAME} TO ROLE ${ROLE_NAME} COPY CURRENT GRANTS;`}); + snowflake.execute({sqlText: `GRANT OWNERSHIP ON ALL STAGES IN DATABASE ${DESTINATION_DB_NAME} TO ROLE ${ROLE_NAME} COPY CURRENT GRANTS;`}); + snowflake.execute({sqlText: `GRANT OWNERSHIP ON ALL TABLES IN DATABASE ${DESTINATION_DB_NAME} TO ROLE ${ROLE_NAME} COPY CURRENT GRANTS;`}); + snowflake.execute({sqlText: `GRANT OWNERSHIP ON FUTURE FUNCTIONS IN DATABASE ${DESTINATION_DB_NAME} TO ROLE ${ROLE_NAME};`}); + snowflake.execute({sqlText: `GRANT OWNERSHIP ON FUTURE PROCEDURES IN DATABASE ${DESTINATION_DB_NAME} TO ROLE ${ROLE_NAME};`}); + snowflake.execute({sqlText: `GRANT OWNERSHIP ON FUTURE VIEWS IN DATABASE ${DESTINATION_DB_NAME} TO ROLE ${ROLE_NAME};`}); + snowflake.execute({sqlText: `GRANT OWNERSHIP ON FUTURE STAGES IN DATABASE ${DESTINATION_DB_NAME} TO ROLE ${ROLE_NAME};`}); + snowflake.execute({sqlText: `GRANT OWNERSHIP ON FUTURE TABLES IN DATABASE ${DESTINATION_DB_NAME} TO ROLE ${ROLE_NAME};`}); + + snowflake.execute({sqlText: `GRANT OWNERSHIP ON DATABASE ${DESTINATION_DB_NAME} TO ROLE ${ROLE_NAME} COPY CURRENT GRANTS;`}) + + var existing_tags = snowflake.execute({sqlText: `SHOW TAGS IN DATABASE ${DESTINATION_DB_NAME};`}); + while (existing_tags.next()) { + var schema = existing_tags.getColumnValue(4); + var tag_name = existing_tags.getColumnValue(2) + snowflake.execute({sqlText: `GRANT OWNERSHIP ON TAG ${DESTINATION_DB_NAME}.${schema}.${tag_name} TO ROLE ${ROLE_NAME} COPY CURRENT GRANTS;`}); + } + + snowflake.execute({sqlText: `COMMIT;`}); + } catch (err) { + snowflake.execute({sqlText: `ROLLBACK;`}); + throw(err); + } + + return true +$$ + +{%- endmacro %} \ No newline at end of file diff --git a/macros/tags/add_database_or_schema_tags.sql b/macros/tags/add_database_or_schema_tags.sql new file mode 100644 index 0000000..f22737b --- /dev/null +++ b/macros/tags/add_database_or_schema_tags.sql @@ -0,0 +1,4 @@ +{% macro add_database_or_schema_tags() %} + {{ set_database_tag_value('BLOCKCHAIN_NAME','BASE') }} + {{ set_database_tag_value('BLOCKCHAIN_TYPE','EVM, L2') }} +{% endmacro %} \ No newline at end of file diff --git a/macros/tags/snowflake_tagging.sql b/macros/tags/snowflake_tagging.sql new file mode 100644 index 0000000..bc25e69 --- /dev/null +++ b/macros/tags/snowflake_tagging.sql @@ -0,0 +1,127 @@ +{% macro apply_meta_as_tags(results) %} + {% if var("UPDATE_SNOWFLAKE_TAGS") %} + {{ log('apply_meta_as_tags', info=False) }} + {{ log(results, info=False) }} + {% if execute %} + + {%- set tags_by_schema = {} -%} + {% for res in results -%} + {% if res.node.meta.database_tags %} + + {%- set model_database = res.node.database -%} + {%- set model_schema = res.node.schema -%} + {%- set model_schema_full = model_database+'.'+model_schema -%} + {%- set model_alias = res.node.alias -%} + + {% if model_schema_full not in tags_by_schema.keys() %} + {{ log('need to fetch tags for schema '+model_schema_full, info=False) }} + {%- call statement('main', fetch_result=True) -%} + show tags in {{model_database}}.{{model_schema}} + {%- endcall -%} + {%- set _ = tags_by_schema.update({model_schema_full: load_result('main')['table'].columns.get('name').values()|list}) -%} + {{ log('Added tags to cache', info=False) }} + {% else %} + {{ log('already have tag info for schema', info=False) }} + {% endif %} + + {%- set current_tags_in_schema = tags_by_schema[model_schema_full] -%} + {{ log('current_tags_in_schema:', info=False) }} + {{ log(current_tags_in_schema, info=False) }} + {{ log("========== Processing tags for "+model_schema_full+"."+model_alias+" ==========", info=False) }} + + {% set line -%} + node: {{ res.node.unique_id }}; status: {{ res.status }} (message: {{ res.message }}) + node full: {{ res.node}} + meta: {{ res.node.meta}} + materialized: {{ res.node.config.materialized }} + {%- endset %} + {{ log(line, info=False) }} + + {%- call statement('main', fetch_result=True) -%} + select LEVEL,UPPER(TAG_NAME) as TAG_NAME,TAG_VALUE from table(information_schema.tag_references_all_columns('{{model_schema}}.{{model_alias}}', 'table')) + {%- endcall -%} + {%- set existing_tags_for_table = load_result('main')['data'] -%} + {{ log('Existing tags for table:', info=False) }} + {{ log(existing_tags_for_table, info=False) }} + + {{ log('--', info=False) }} + {% for table_tag in res.node.meta.database_tags.table %} + + {{ create_tag_if_missing(current_tags_in_schema,table_tag|upper) }} + {% set desired_tag_value = res.node.meta.database_tags.table[table_tag] %} + + {{set_table_tag_value_if_different(model_schema,model_alias,table_tag,desired_tag_value,existing_tags_for_table)}} + {% endfor %} + {{ log("========== Finished processing tags for "+model_alias+" ==========", info=False) }} + {% endif %} + {% endfor %} + {% endif %} + {% endif %} +{% endmacro %} + + +{% macro create_tag_if_missing(all_tag_names,table_tag) %} + {% if table_tag not in all_tag_names %} + {{ log('Creating missing tag '+table_tag, info=False) }} + {%- call statement('main', fetch_result=True) -%} + create tag if not exists silver.{{table_tag}} + {%- endcall -%} + {{ log(load_result('main').data, info=False) }} + {% else %} + {{ log('Tag already exists: '+table_tag, info=False) }} + {% endif %} +{% endmacro %} + +{% macro set_table_tag_value_if_different(model_schema,table_name,tag_name,desired_tag_value,existing_tags) %} + {{ log('Ensuring tag '+tag_name+' has value '+desired_tag_value+' at table level', info=False) }} + {%- set existing_tag_for_table = existing_tags|selectattr('0','equalto','TABLE')|selectattr('1','equalto',tag_name|upper)|list -%} + {{ log('Filtered tags for table:', info=False) }} + {{ log(existing_tag_for_table[0], info=False) }} + {% if existing_tag_for_table|length > 0 and existing_tag_for_table[0][2]==desired_tag_value %} + {{ log('Correct tag value already exists', info=False) }} + {% else %} + {{ log('Setting tag value for '+tag_name+' to value '+desired_tag_value, info=False) }} + {%- call statement('main', fetch_result=True) -%} + alter table {{model_schema}}.{{table_name}} set tag {{tag_name}} = '{{desired_tag_value}}' + {%- endcall -%} + {{ log(load_result('main').data, info=False) }} + {% endif %} +{% endmacro %} + +{% macro set_column_tag_value_if_different(table_name,column_name,tag_name,desired_tag_value,existing_tags) %} + {{ log('Ensuring tag '+tag_name+' has value '+desired_tag_value+' at column level', info=False) }} + {%- set existing_tag_for_column = existing_tags|selectattr('0','equalto','COLUMN')|selectattr('1','equalto',tag_name|upper)|list -%} + {{ log('Filtered tags for column:', info=False) }} + {{ log(existing_tag_for_column[0], info=False) }} + {% if existing_tag_for_column|length > 0 and existing_tag_for_column[0][2]==desired_tag_value %} + {{ log('Correct tag value already exists', info=False) }} + {% else %} + {{ log('Setting tag value for '+tag_name+' to value '+desired_tag_value, info=False) }} + {%- call statement('main', fetch_result=True) -%} + alter table {{table_name}} modify column {{column_name}} set tag {{tag_name}} = '{{desired_tag_value}}' + {%- endcall -%} + {{ log(load_result('main').data, info=False) }} + {% endif %} +{% endmacro %} + +{% macro set_database_tag_value(tag_name,tag_value) %} + {% set query %} + create tag if not exists silver.{{tag_name}} + {% endset %} + {% do run_query(query) %} + {% set query %} + alter database {{target.database}} set tag {{target.database}}.silver.{{tag_name}} = '{{tag_value}}' + {% endset %} + {% do run_query(query) %} +{% endmacro %} + +{% macro set_schema_tag_value(target_schema,tag_name,tag_value) %} + {% set query %} + create tag if not exists silver.{{tag_name}} + {% endset %} + {% do run_query(query) %} + {% set query %} + alter schema {{target.database}}.{{target_schema}} set tag {{target.database}}.silver.{{tag_name}} = '{{tag_value}}' + {% endset %} + {% do run_query(query) %} +{% endmacro %} \ No newline at end of file diff --git a/macros/tests/sequence_gaps.sql b/macros/tests/sequence_gaps.sql new file mode 100644 index 0000000..9425003 --- /dev/null +++ b/macros/tests/sequence_gaps.sql @@ -0,0 +1,34 @@ +{% test sequence_gaps( + model, + partition_by, + column_name +) %} +{%- set partition_sql = partition_by | join(", ") -%} +{%- set previous_column = "prev_" ~ column_name -%} +WITH source AS ( + SELECT + {{ partition_sql + "," if partition_sql }} + {{ column_name }}, + LAG( + {{ column_name }}, + 1 + ) over ( + {{ "PARTITION BY " ~ partition_sql if partition_sql }} + ORDER BY + {{ column_name }} ASC + ) AS {{ previous_column }} + FROM + {{ model }} +) +SELECT + {{ partition_sql + "," if partition_sql }} + {{ previous_column }}, + {{ column_name }}, + {{ column_name }} - {{ previous_column }} + - 1 AS gap +FROM + source +WHERE + {{ column_name }} - {{ previous_column }} <> 1 +ORDER BY + gap DESC {% endtest %} diff --git a/macros/tests/tx_block_count.sql b/macros/tests/tx_block_count.sql new file mode 100644 index 0000000..fac6ce1 --- /dev/null +++ b/macros/tests/tx_block_count.sql @@ -0,0 +1,14 @@ +{% test tx_block_count( + model, + column_name +) %} + +SELECT + {{ column_name }}, + COUNT(DISTINCT block_number) AS num_blocks +FROM + {{ model }} +GROUP BY {{ column_name }} +HAVING num_blocks > 1 + +{% endtest %} \ No newline at end of file diff --git a/macros/tests/tx_gaps.sql b/macros/tests/tx_gaps.sql new file mode 100644 index 0000000..a9d93df --- /dev/null +++ b/macros/tests/tx_gaps.sql @@ -0,0 +1,33 @@ +{% macro tx_gaps( + model + ) %} + WITH block_base AS ( + SELECT + block_number, + tx_count + FROM + {{ ref('silver__blocks') }} + ), + model_name AS ( + SELECT + block_number, + COUNT( + DISTINCT tx_hash + ) AS model_tx_count + FROM + {{ model }} + GROUP BY + block_number + ) +SELECT + block_base.block_number, + tx_count, + model_name.block_number AS model_block_number, + model_tx_count +FROM + block_base + LEFT JOIN model_name + ON block_base.block_number = model_name.block_number +WHERE + tx_count <> model_tx_count +{% endmacro %} diff --git a/models/sources.yml b/models/sources.yml new file mode 100644 index 0000000..b338613 --- /dev/null +++ b/models/sources.yml @@ -0,0 +1,8 @@ +version: 2 + +sources: + - name: ethereum + database: ethereum + schema: core + tables: + - name: fact_hourly_token_prices \ No newline at end of file diff --git a/packages.yml b/packages.yml new file mode 100644 index 0000000..6d21eb8 --- /dev/null +++ b/packages.yml @@ -0,0 +1,7 @@ +packages: + - package: calogica/dbt_expectations + version: 0.8.0 + - package: dbt-labs/dbt_external_tables + version: 0.8.0 + - package: dbt-labs/dbt_utils + version: 0.9.2 \ No newline at end of file diff --git a/profiles.yml b/profiles.yml new file mode 100644 index 0000000..2370faa --- /dev/null +++ b/profiles.yml @@ -0,0 +1,31 @@ +base: + target: prod + outputs: + dev: + type: snowflake + account: "{{ env_var('ACCOUNT') }}" + role: "{{ env_var('ROLE') }}" + user: "{{ env_var('USER') }}" + password: "{{ env_var('PASSWORD') }}" + region: "{{ env_var('REGION') }}" + database: "{{ env_var('DATABASE') }}" + warehouse: "{{ env_var('WAREHOUSE') }}" + schema: SILVER + threads: 4 + client_session_keep_alive: False + query_tag: base_curator + prod: + type: snowflake + account: "{{ env_var('ACCOUNT') }}" + role: "{{ env_var('ROLE') }}" + user: "{{ env_var('USER') }}" + password: "{{ env_var('PASSWORD') }}" + region: "{{ env_var('REGION') }}" + database: "{{ env_var('DATABASE') }}" + warehouse: "{{ env_var('WAREHOUSE') }}" + schema: SILVER + threads: 4 + client_session_keep_alive: False + query_tag: base_curator + config: + send_anonymous_usage_stats: False \ No newline at end of file diff --git a/snapshots/.gitkeep b/snapshots/.gitkeep new file mode 100644 index 0000000..e69de29