diff --git a/.github/workflows/dbt_docs_update.yml b/.github/workflows/dbt_docs_update.yml new file mode 100644 index 0000000..4d70569 --- /dev/null +++ b/.github/workflows/dbt_docs_update.yml @@ -0,0 +1,68 @@ +name: docs_update + +on: + push: + branches: + - "main" + +env: + DBT_PROFILES_DIR: ./ + + ACCOUNT: "${{ vars.ACCOUNT }}" + ROLE: "${{ vars.ROLE }}" + USER: "${{ vars.USER }}" + PASSWORD: "${{ secrets.PASSWORD }}" + REGION: "${{ vars.REGION }}" + DATABASE: "${{ vars.DATABASE }}" + WAREHOUSE: "${{ vars.WAREHOUSE }}" + SCHEMA: "${{ vars.SCHEMA }}" + +concurrency: + group: ${{ github.workflow }} + +jobs: + scheduled_run: + name: docs_update + runs-on: ubuntu-latest + environment: + name: workflow_prod + + steps: + - uses: actions/checkout@v3 + + - uses: actions/setup-python@v1 + with: + python-version: "3.7.x" + + - name: install dependencies + run: | + pip install dbt-snowflake==${{ vars.DBT_VERSION }} + dbt deps + - name: checkout docs branch + run: | + git checkout -b docs origin/main + + - name: generate dbt docs + run: dbt docs generate -t prod + + - name: move files to docs directory + run: | + mkdir -p ./docs + cp target/{catalog.json,manifest.json,index.html} docs/ + - name: clean up target directory + run: dbt clean + + - name: check for changes + run: git status + + - name: stage changed files + run: git add . + + - name: commit changed files + run: | + git config user.email "abc@xyz" + git config user.name "github-actions" + git commit -am "Auto-update docs" + - name: push changes to docs + run: | + git push -f --set-upstream origin docs \ No newline at end of file diff --git a/.github/workflows/dbt_run_adhoc.yml b/.github/workflows/dbt_run_adhoc.yml new file mode 100644 index 0000000..b116e3e --- /dev/null +++ b/.github/workflows/dbt_run_adhoc.yml @@ -0,0 +1,68 @@ +name: dbt_run_adhoc +run-name: dbt_run_adhoc + +on: + workflow_dispatch: + branches: + - "main" + inputs: + environment: + type: choice + description: DBT Run Environment + required: true + options: + - dev + - prod + default: dev + warehouse: + type: choice + description: Snowflake warehouse + required: true + options: + - DBT + - DBT_CLOUD + - DBT_EMERGENCY + default: DBT + dbt_command: + type: string + description: 'DBT Run Command' + required: true + +env: + DBT_PROFILES_DIR: ./ + + ACCOUNT: "${{ vars.ACCOUNT }}" + ROLE: "${{ vars.ROLE }}" + USER: "${{ vars.USER }}" + PASSWORD: "${{ secrets.PASSWORD }}" + REGION: "${{ vars.REGION }}" + DATABASE: "${{ vars.DATABASE }}" + WAREHOUSE: "${{ inputs.warehouse }}" + SCHEMA: "${{ vars.SCHEMA }}" + +concurrency: + group: ${{ github.workflow }} + +jobs: + run_dbt_jobs: + runs-on: ubuntu-latest + environment: + name: workflow_${{ inputs.environment }} + strategy: + matrix: + command: ${{fromJson(inputs.dbt_command)}} + + steps: + - uses: actions/checkout@v3 + + - uses: actions/setup-python@v1 + with: + python-version: "3.7.x" + + - name: install dependencies + run: | + pip3 install dbt-snowflake==${{ vars.DBT_VERSION }} cli_passthrough requests click + dbt deps + - name: Run DBT Jobs + run: | + ${{ matrix.command }} \ No newline at end of file diff --git a/.github/workflows/dbt_run_dev_refresh.yml b/.github/workflows/dbt_run_dev_refresh.yml new file mode 100644 index 0000000..ea29450 --- /dev/null +++ b/.github/workflows/dbt_run_dev_refresh.yml @@ -0,0 +1,44 @@ +name: dbt_run_dev_refresh +run-name: dbt_run_dev_refresh + +on: + workflow_dispatch: + schedule: + # Runs "at 9:00 UTC" (see https://crontab.guru) + - cron: '0 9 * * *' + +env: + DBT_PROFILES_DIR: ./ + + ACCOUNT: "${{ vars.ACCOUNT }}" + ROLE: "${{ vars.ROLE }}" + USER: "${{ vars.USER }}" + PASSWORD: "${{ secrets.PASSWORD }}" + REGION: "${{ vars.REGION }}" + DATABASE: "${{ vars.DATABASE }}" + WAREHOUSE: "${{ vars.WAREHOUSE }}" + SCHEMA: "${{ vars.SCHEMA }}" + +concurrency: + group: ${{ github.workflow }} + +jobs: + run_dbt_jobs: + runs-on: ubuntu-latest + environment: + name: workflow_prod + + steps: + - uses: actions/checkout@v3 + + - uses: actions/setup-python@v1 + with: + python-version: "3.7.x" + + - name: install dependencies + run: | + pip3 install dbt-snowflake==${{ vars.DBT_VERSION }} cli_passthrough requests click + dbt deps + - name: Run DBT Jobs + run: | + dbt run-operation run_sp_create_prod_clone \ No newline at end of file diff --git a/.gitignore b/.gitignore new file mode 100644 index 0000000..e7f63fa --- /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 +.DS_Store +.user.yml \ No newline at end of file diff --git a/README.md b/README.md new file mode 100644 index 0000000..b7f4b5c --- /dev/null +++ b/README.md @@ -0,0 +1,74 @@ +## Profile Set Up + +#### Use the following within profiles.yml +---- + +```yml +sei: + target: dev + outputs: + dev: + type: snowflake + account: + role: + user: + password: + region: + database: OSMOSIS_DEV + warehouse: + schema: silver + threads: 4 + client_session_keep_alive: False + query_tag: +``` + +### 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 + +- 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 not pushed to snowflake on each load. You can push a tag update for a model by specifying the `UPDATE_SNOWFLAKE_TAGS` project variable during a run. + +``` +dbt run --var '{"UPDATE_SNOWFLAKE_TAGS":True}' -s models/core/core__fact_swaps.sql +``` + +### Querying for existing tags on a model in snowflake + +``` +select * +from table(sei.information_schema.tag_references('sei.core.fact_blocks', 'table')); +``` \ No newline at end of file diff --git a/analyses/.gitkeep b/analyses/.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..2713c77 --- /dev/null +++ b/dbt_project.yml @@ -0,0 +1,54 @@ +# 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: "sei_models" +version: "1.0.0" +config-version: 2 + +require-dbt-version: ">=1.4.0" + +# This setting configures which "profile" dbt uses for this project. +profile: "sei" + +# These configurations specify where dbt should look for different types of files. +# The `model-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" + +# 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. +models: + +copy_grants: true + +persist_docs: + relation: true + columns: true + +on_schema_change: "append_new_columns" + +vars: + "dbt_date:time_zone": GMT + "UPDATE_SNOWFLAKE_TAGS": TRUE + +tests: + +store_failures: true # all tests + +on-run-start: + - '{{create_sps()}}' + - '{{create_udfs()}}' + +on-run-end: + - '{{ apply_meta_as_tags(results) }}' \ No newline at end of file diff --git a/docs/.gitkeep b/docs/.gitkeep new file mode 100644 index 0000000..e69de29 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..85be433 --- /dev/null +++ b/macros/create_sps.sql @@ -0,0 +1,6 @@ +{% macro create_sps() %} + {% if target.database == 'OSMOSIS' %} + CREATE SCHEMA IF NOT EXISTS _internal; + {{ sp_create_prod_clone('_internal') }}; + {% endif %} +{% endmacro %} \ No newline at end of file diff --git a/macros/create_udfs.sql b/macros/create_udfs.sql new file mode 100644 index 0000000..cccf887 --- /dev/null +++ b/macros/create_udfs.sql @@ -0,0 +1,5 @@ +{% macro create_udfs() %} + {% set sql %} + {% endset %} + {% do run_query(sql) %} +{% endmacro %} diff --git a/macros/custom_naming_macros.sql b/macros/custom_naming_macros.sql new file mode 100644 index 0000000..cb6fc87 --- /dev/null +++ b/macros/custom_naming_macros.sql @@ -0,0 +1,23 @@ +{% 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 %} + +{% macro generate_tmp_view_name(model_name) -%} + {% set node_name = model_name.name %} + {% set split_name = node_name.split('__') %} + {{ target.database ~ '.' ~ split_name[0] ~ '.' ~ split_name [1] ~ '__dbt_tmp' | 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..1085a52 --- /dev/null +++ b/macros/run_sp_create_prod_clone.sql @@ -0,0 +1,7 @@ +{% macro run_sp_create_prod_clone() %} +{% set clone_query %} +call osmosis._internal.create_prod_clone('sei', 'sei_dev', 'internal_dev'); +{% endset %} + +{% do run_query(clone_query) %} +{% endmacro %} \ No newline at end of file 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..962426d --- /dev/null +++ b/macros/tags/add_database_or_schema_tags.sql @@ -0,0 +1,10 @@ +{% macro add_database_or_schema_tags() %} + {{ set_database_tag_value( + 'BLOCKCHAIN_NAME', + 'SEI' + ) }} + {{ set_database_tag_value( + 'BLOCKCHAIN_TYPE', + 'IBC' + ) }} +{% endmacro %} 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/compare_model_subset.sql b/macros/tests/compare_model_subset.sql new file mode 100644 index 0000000..18aa624 --- /dev/null +++ b/macros/tests/compare_model_subset.sql @@ -0,0 +1,29 @@ +{% test compare_model_subset(model, compare_model, compare_columns, model_condition) %} + +{% set compare_cols_csv = compare_columns | join(', ') %} + +with a as ( + select {{compare_cols_csv}} from {{ model }} + {{ model_condition }} +), +b as ( + select {{compare_cols_csv}} from {{ compare_model }} +), +a_minus_b as ( + select * from a + except + select * from b +), +b_minus_a as ( + select * from b + except + select * from a +), +unioned as ( + select 'in_actual_not_in_expected' as which_diff, a_minus_b.* from a_minus_b + union all + select 'in_expected_not_in_actual' as which_diff, b_minus_a.* from b_minus_a +) +select * from unioned + +{% endtest %} \ 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..84a9aa9 --- /dev/null +++ b/macros/tests/sequence_gaps.sql @@ -0,0 +1,37 @@ +{% macro sequence_gaps( + table, + partition_by, + column + ) %} + {%- set partition_sql = partition_by | join(", ") -%} + {%- set previous_column = "prev_" ~ column -%} + WITH source AS ( + SELECT + {{ partition_sql + "," if partition_sql }} + {{ column }}, + LAG( + {{ column }}, + 1 + ) over ( + {{ "PARTITION BY " ~ partition_sql if partition_sql }} + ORDER BY + {{ column }} ASC + ) AS {{ previous_column }} + FROM + {{ table }} + WHERE + block_timestamp::date <= current_date - 1 + ) +SELECT + {{ partition_sql + "," if partition_sql }} + {{ previous_column }}, + {{ column }}, + {{ column }} - {{ previous_column }} + - 1 AS gap +FROM + source +WHERE + {{ column }} - {{ previous_column }} <> 1 +ORDER BY + gap DESC +{% endmacro %} diff --git a/macros/tests/tx_gaps.sql b/macros/tests/tx_gaps.sql new file mode 100644 index 0000000..82b449f --- /dev/null +++ b/macros/tests/tx_gaps.sql @@ -0,0 +1,33 @@ +{% macro tx_gaps( + model + ) %} + WITH block_base AS ( + SELECT + block_id, + tx_count + FROM + {{ ref('silver__blocks') }} + ), + model_name AS ( + SELECT + block_id, + COUNT( + DISTINCT tx_id + ) AS model_tx_count + FROM + {{ model }} + GROUP BY + block_id + ) +SELECT + block_base.block_id, + tx_count, + model_name.block_id, + model_tx_count +FROM + block_base + LEFT JOIN model_name + ON block_base.block_id = model_name.block_id +WHERE + tx_count <> model_tx_count +{% endmacro %} diff --git a/models/descriptions/__overview__.md b/models/descriptions/__overview__.md new file mode 100644 index 0000000..0a1b793 --- /dev/null +++ b/models/descriptions/__overview__.md @@ -0,0 +1,74 @@ +{% docs __overview__ %} + +# Welcome to the Flipside Crypto SEI Models Documentation + +## **What does this documentation cover?** +The documentation included here details the design of the SEI + tables and views available via [Flipside Crypto.](https://flipsidecrypto.xyz/) For more information on how these models are built, please see [the github repository.](https://github.com/flipsideCrypto/sei-models/) + +## **How do I use these docs?** +The easiest way to navigate this documentation is to use the Quick Links below. These links will take you to the documentation for each table, which contains a description, a list of the columns, and other helpful information. + +If you are experienced with dbt docs, feel free to use the sidebar to navigate the documentation, as well as explore the relationships between tables and the logic building them. + +There is more information on how to use dbt docs in the last section of this document. + +## **Quick Links to Table Documentation** + +**Click on the links below to jump to the documentation for each schema.** + +### Core Tables (`SEI`.`CORE`.``) + +**Dimension Tables:** + + +**Fact Tables:** + + + +**Convenience Tables:** + + + + +## **Data Model Overview** + +The SEI + models are built a few different ways, but the core fact tables are built using three layers of sql models: **bronze, silver, and gold (or core).** + +- Bronze: Data is loaded in from the source as a view +- Silver: All necessary parsing, filtering, de-duping, and other transformations are done here +- Gold (or core): Final views and tables that are available publicly + +The dimension tables are sourced from a variety of on-chain and off-chain sources. + +Convenience views (denoted ez_) are a combination of different fact and dimension tables. These views are built to make it easier to query the data. + +## **Using dbt docs** +### Navigation + +You can use the ```Project``` and ```Database``` navigation tabs on the left side of the window to explore the models in the project. + +### Database Tab + +This view shows relations (tables and views) grouped into database schemas. Note that ephemeral models are *not* shown in this interface, as they do not exist in the database. + +### Graph Exploration + +You can click the blue icon on the bottom-right corner of the page to view the lineage graph of your models. + +On model pages, you'll see the immediate parents and children of the model you're exploring. By clicking the Expand button at the top-right of this lineage pane, you'll be able to see all of the models that are used to build, or are built from, the model you're exploring. + +Once expanded, you'll be able to use the ```--models``` and ```--exclude``` model selection syntax to filter the models in the graph. For more information on model selection, check out the [dbt docs](https://docs.getdbt.com/docs/model-selection-syntax). + +Note that you can also right-click on models to interactively filter and explore the graph. + + +### **More information** +- [Flipside](https://flipsidecrypto.xyz/) +- [Velocity](https://app.flipsidecrypto.com/velocity?nav=Discover) +- [Tutorials](https://docs.flipsidecrypto.com/our-data/tutorials) +- [Github](https://github.com/FlipsideCrypto/sei-models) +- [What is dbt?](https://docs.getdbt.com/docs/introduction) + +{% enddocs %} \ No newline at end of file diff --git a/models/sources.yml b/models/sources.yml new file mode 100644 index 0000000..975f43d --- /dev/null +++ b/models/sources.yml @@ -0,0 +1,10 @@ +version: 2 + +sources: + - name: crosschain + database: "{{ 'crosschain' if target.database == 'SEI' else 'crosschain_dev' }}" + schema: core + tables: + - name: dim_date_hours + - name: address_tags + - name: dim_dates diff --git a/packages.yml b/packages.yml new file mode 100644 index 0000000..181d652 --- /dev/null +++ b/packages.yml @@ -0,0 +1,5 @@ +packages: + - package: dbt-labs/dbt_utils + version: 0.9.2 + - package: calogica/dbt_expectations + version: [">=0.4.0", "<0.9.0"] diff --git a/profiles.yml b/profiles.yml new file mode 100644 index 0000000..c91b990 --- /dev/null +++ b/profiles.yml @@ -0,0 +1,29 @@ +sei: + target: dev + outputs: + dev: + type: snowflake + account: "{{ env_var('ACCOUNT') }}" + user: "{{ env_var('USER') }}" + password: "{{ env_var('PASSWORD') }}" + role: "{{ env_var('ROLE') }}" + schema: "{{ env_var('SCHEMA') }}" + region: "{{ env_var('REGION') }}" + database: "{{ env_var('DATABASE') }}" + warehouse: "{{ env_var('WAREHOUSE') }}" + threads: 8 + client_session_keep_alive: False + prod: + type: snowflake + account: "{{ env_var('ACCOUNT') }}" + user: "{{ env_var('USER') }}" + password: "{{ env_var('PASSWORD') }}" + role: "{{ env_var('ROLE') }}" + schema: "{{ env_var('SCHEMA') }}" + region: "{{ env_var('REGION') }}" + database: "{{ env_var('DATABASE') }}" + warehouse: "{{ env_var('WAREHOUSE') }}" + threads: 8 + client_session_keep_alive: False + 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