AN-4605/core-xfers-contracts (#16)

* transfers, contracts and prices + workflows/tests

* coalesce removed

* overview docs
This commit is contained in:
drethereum 2024-03-04 11:58:13 -07:00 committed by GitHub
parent 50b9503932
commit a333ea112e
No known key found for this signature in database
GPG Key ID: B5690EEEBB952194
41 changed files with 1638 additions and 2 deletions

View File

@ -0,0 +1,45 @@
name: dbt_run_heal_models
run-name: dbt_run_heal_models
on:
workflow_dispatch:
schedule:
# Runs at 02:00 on Wednesday (see https://crontab.guru)
- cron: '0 2 * * 3'
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@v4
with:
python-version: "3.10"
cache: "pip"
- name: install dependencies
run: |
pip install -r requirements.txt
dbt deps
- name: Run DBT Jobs
run: |
dbt run -m "blast_models,tag:heal" --vars '{"HEAL_MODEL":True}'

View File

@ -0,0 +1,52 @@
name: dbt_run_operation_reorg
run-name: dbt_run_operation_reorg
on:
workflow_dispatch:
schedule:
# Runs at minute 50 every 8 hours (see https://crontab.guru)
- cron: '50 */8 * * *'
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@v4
with:
python-version: "3.10"
cache: "pip"
- name: install dependencies
run: |
pip install -r requirements.txt
dbt deps
- name: List reorg models
id: list_models
run: |
reorg_model_list=$(dbt list --select "blast_models,tag:reorg" --resource-type model --output name | grep '__' | awk -F'.' '{print $NF}' | tr '\n' ',' | sed 's/,$//')
echo "model_list=$reorg_model_list" >> $GITHUB_OUTPUT
- name: Execute block_reorg macro
run: |
dbt run-operation fsc_utils.block_reorg --args "{reorg_model_list: '${{ steps.list_models.outputs.model_list }}', hours: '12'}" && awk '/SQL status/ {print; next} /DELETE FROM/{getline; print} /\/\* {/ {print}' logs/dbt.log

View File

@ -0,0 +1,19 @@
{{ config (
materialized = 'view'
) }}
SELECT
token_address,
id,
symbol,
blockchain,
provider,
_unique_key,
_inserted_timestamp
FROM
{{ source(
'silver_crosschain',
'asset_metadata_all_providers'
) }}
WHERE
blockchain = 'blast'

View File

@ -0,0 +1,17 @@
{{ config (
materialized = 'view'
) }}
SELECT
token_address,
symbol,
provider,
id,
_inserted_timestamp
FROM
{{ source(
'silver_crosschain',
'asset_metadata_priority'
) }}
WHERE
blockchain = 'blast'

View File

@ -0,0 +1,20 @@
{{ config (
materialized = 'view'
) }}
SELECT
HOUR,
token_address,
blockchain,
provider,
price,
is_imputed,
_inserted_timestamp,
_unique_key
FROM
{{ source(
'silver_crosschain',
'token_prices_all_providers_hourly'
) }}
WHERE
blockchain = 'blast'

View File

@ -0,0 +1,17 @@
{{ config (
materialized = 'view'
) }}
SELECT
HOUR,
token_address,
price,
is_imputed,
_inserted_timestamp
FROM
{{ source(
'silver_crosschain',
'token_prices_priority_hourly'
) }}
WHERE
blockchain = 'blast'

View File

@ -0,0 +1,18 @@
{{ config (
materialized = 'view'
) }}
SELECT
HOUR,
token_address,
price,
is_imputed,
_inserted_timestamp
FROM
{{ source(
'silver_crosschain',
'token_prices_priority_hourly'
) }}
WHERE
blockchain = 'ethereum'
AND token_address = '0xc02aaa39b223fe8d0a0e5c4f27ead9083c756cc2'

View File

@ -16,13 +16,27 @@ There is more information on how to use dbt docs in the last section of this doc
**Click on the links below to jump to the documentation for each schema.**
### Core Tables
### Core Tables (blast.core)
**Dimension Tables:**
- [dim_contracts](https://flipsidecrypto.github.io/blast-models/#!/model/model.blast_models.core__dim_contracts)
**Fact Tables:**
- [fact_blocks](https://flipsidecrypto.github.io/blast-models/#!/model/model.blast_models.core__fact_blocks)
- [fact_transactions](https://flipsidecrypto.github.io/blast-models/#!/model/model.blast_models.core__fact_transactions)
- [fact_event_logs](https://flipsidecrypto.github.io/blast-models/#!/model/model.blast_models.core__fact_event_logs)
- [fact_traces](https://flipsidecrypto.github.io/blast-models/#!/model/model.blast_models.core__fact_traces)
- [fact_transactions](https://flipsidecrypto.github.io/blast-models/#!/model/model.blast_models.core__fact_transactions)
- [fact_token_transfers](https://flipsidecrypto.github.io/blast-models/#!/model/model.blast_models.core__fact_token_transfers)
**Convenience Tables:**
- [ez_native_transfers](https://flipsidecrypto.github.io/blast-models/#!/model/model.blast_models.core__ez_native_transfers)
- [ez_token_transfers](https://flipsidecrypto.github.io/blast-models/#!/model/model.blast_models.core__ez_token_transfers)
### Price Tables (blast.price)
- [fact_hourly_token_prices](https://flipsidecrypto.github.io/blast-models/#!/model/model.blast_models.price__fact_hourly_token_prices)
- [ez_hourly_token_prices](https://flipsidecrypto.github.io/blast-models/#!/model/model.blast_models.price__ez_hourly_token_prices)
- [dim_asset_metadata](https://flipsidecrypto.github.io/blast-models/#!/model/model.blast_models.price__dim_asset_metadata)
- [ez_asset_metadata](https://flipsidecrypto.github.io/blast-models/#!/model/model.blast_models.price__ez_asset_metadata)
## **Helpful User-Defined Functions (UDFs)**

View File

@ -0,0 +1,28 @@
{{ config(
materialized = 'view',
persist_docs ={ "relation": true,
"columns": true }
) }}
SELECT
c0.created_contract_address AS address,
c1.token_symbol AS symbol,
c1.token_name AS NAME,
c1.token_decimals AS decimals,
c0.block_number AS created_block_number,
c0.block_timestamp AS created_block_timestamp,
c0.tx_hash AS created_tx_hash,
c0.creator_address AS creator_address,
c0.created_contracts_id AS dim_contracts_id,
GREATEST(COALESCE(c0.inserted_timestamp, '2000-01-01'), COALESCE(c1.inserted_timestamp, '2000-01-01')) AS inserted_timestamp,
GREATEST(COALESCE(c0.modified_timestamp, '2000-01-01'), COALESCE(c1.modified_timestamp, '2000-01-01')) AS modified_timestamp
FROM
{{ ref('silver__created_contracts') }}
c0
LEFT JOIN {{ ref('silver__contracts') }}
c1
ON LOWER(
c0.created_contract_address
) = LOWER(
c1.contract_address
)

View File

@ -0,0 +1,28 @@
version: 2
models:
- name: core__dim_contracts
description: This table contains all the contracts that are deployed on the Blast blockchain along with their on-chain metadata.
columns:
- name: ADDRESS
description: 'The address of the contract.'
- name: SYMBOL
description: 'The symbol of the contract.'
- name: NAME
description: 'The name of the contract.'
- name: DECIMALS
description: 'The number of decimals used to adjust amount for this contract.'
- name: CREATED_BLOCK_NUMBER
description: 'The block number when the contract was created'
- name: CREATED_BLOCK_TIMESTAMP
description: 'The block timestamp when the contract was created'
- name: CREATED_TX_HASH
description: 'The transaction hash when the contract was created'
- name: CREATOR_ADDRESS
description: 'The address of the creator of the contract'
- name: DIM_CONTRACTS_ID
description: '{{ doc("pk") }}'
- name: INSERTED_TIMESTAMP
description: '{{ doc("inserted_timestamp") }}'
- name: MODIFIED_TIMESTAMP
description: '{{ doc("modified_timestamp") }}'

View File

@ -0,0 +1,27 @@
{{ config(
materialized = 'view',
persist_docs ={ "relation": true,
"columns": true }
) }}
SELECT
tx_hash,
block_number,
block_timestamp,
tx_position,
trace_index,
identifier,
origin_from_address,
origin_to_address,
origin_function_signature,
from_address,
to_address,
amount,
amount_precise_raw,
amount_precise,
amount_usd,
native_transfers_id AS ez_native_transfers_id,
inserted_timestamp,
modified_timestamp
FROM
{{ ref('silver__native_transfers') }}

View File

@ -0,0 +1,42 @@
version: 2
models:
- name: core__ez_native_transfers
description: '{{ doc("blast_ez_eth_transfers_table_doc") }}'
columns:
- name: TX_HASH
description: '{{ doc("blast_transfer_tx_hash") }}'
- name: BLOCK_NUMBER
description: '{{ doc("blast_block_number") }}'
- name: BLOCK_TIMESTAMP
description: '{{ doc("blast_block_timestamp") }}'
- name: TX_POSITION
description: '{{ doc("blast_tx_position") }}'
- name: TRACE_INDEX
description: '{{ doc("blast_trace_index") }}'
- name: IDENTIFIER
description: '{{ doc("blast_traces_identifier") }}'
- name: ORIGIN_FROM_ADDRESS
description: '{{ doc("blast_origin_from") }}'
- name: ORIGIN_TO_ADDRESS
description: '{{ doc("blast_origin_to") }}'
- name: ORIGIN_FUNCTION_SIGNATURE
description: '{{ doc("blast_origin_sig") }}'
- name: FROM_ADDRESS
description: '{{ doc("blast_transfer_from_address") }}'
- name: TO_ADDRESS
description: '{{ doc("blast_transfer_to_address") }}'
- name: AMOUNT
description: '{{ doc("blast_eth_amount") }}'
- name: AMOUNT_PRECISE_RAW
description: '{{ doc("precise_amount_unadjusted") }}'
- name: AMOUNT_PRECISE
description: '{{ doc("precise_amount_adjusted") }}'
- name: AMOUNT_USD
description: '{{ doc("blast_eth_amount_usd") }}'
- name: EZ_NATIVE_TRANSFERS_ID
description: '{{ doc("pk") }}'
- name: INSERTED_TIMESTAMP
description: '{{ doc("inserted_timestamp") }}'
- name: MODIFIED_TIMESTAMP
description: '{{ doc("modified_timestamp") }}'

View File

@ -0,0 +1,34 @@
{{ config(
materialized = 'view',
persist_docs ={ "relation": true,
"columns": true }
) }}
SELECT
block_number,
block_timestamp,
tx_hash,
event_index,
origin_function_signature,
origin_from_address,
origin_to_address,
contract_address,
from_address,
to_address,
raw_amount_precise,
raw_amount,
amount_precise,
amount,
amount_usd,
decimals,
symbol,
token_price,
has_decimal,
has_price,
_log_id,
_inserted_timestamp,
transfers_id AS ez_token_transfers_id,
inserted_timestamp,
modified_timestamp
FROM
{{ ref('silver__transfers') }}

View File

@ -0,0 +1,56 @@
version: 2
models:
- name: core__ez_token_transfers
description: '{{ doc("blast_transfer_table_doc") }}'
columns:
- name: BLOCK_NUMBER
description: '{{ doc("blast_block_number") }}'
- name: BLOCK_TIMESTAMP
description: '{{ doc("blast_block_timestamp") }}'
- name: TX_HASH
description: '{{ doc("blast_transfer_tx_hash") }}'
- name: EVENT_INDEX
description: '{{ doc("blast_event_index") }}'
- name: ORIGIN_FUNCTION_SIGNATURE
description: '{{ doc("blast_origin_sig") }}'
- name: ORIGIN_FROM_ADDRESS
description: '{{ doc("blast_eth_origin_from") }}'
- name: ORIGIN_TO_ADDRESS
description: '{{ doc("blast_eth_origin_to") }}'
- name: CONTRACT_ADDRESS
description: '{{ doc("blast_transfer_contract_address") }}'
- name: FROM_ADDRESS
description: '{{ doc("blast_transfer_from_address") }}'
- name: TO_ADDRESS
description: '{{ doc("blast_transfer_to_address") }}'
- name: RAW_AMOUNT_PRECISE
description: '{{ doc("blast_transfer_raw_amount_precise") }}'
- name: RAW_AMOUNT
description: '{{ doc("blast_transfer_raw_amount") }}'
- name: AMOUNT_PRECISE
description: '{{ doc("blast_transfer_amount_precise") }}'
- name: AMOUNT
description: '{{ doc("blast_transfer_amount") }}'
- name: AMOUNT_USD
description: '{{ doc("blast_transfer_amount_usd") }}'
- name: DECIMALS
description: '{{ doc("blast_decimals") }}'
- name: SYMBOL
description: '{{ doc("blast_symbol") }}'
- name: TOKEN_PRICE
description: '{{ doc("blast_transfer_token_price") }}'
- name: HAS_DECIMAL
description: '{{ doc("blast_transfer_has_decimal") }}'
- name: HAS_PRICE
description: '{{ doc("blast_transfer_has_price") }}'
- name: _LOG_ID
description: '{{ doc("internal_column") }}'
- name: _INSERTED_TIMESTAMP
description: '{{ doc("internal_column") }}'
- name: EZ_TOKEN_TRANSFERS_ID
description: '{{ doc("pk") }}'
- name: INSERTED_TIMESTAMP
description: '{{ doc("inserted_timestamp") }}'
- name: MODIFIED_TIMESTAMP
description: '{{ doc("modified_timestamp") }}'

View File

@ -0,0 +1,36 @@
{{ config(
materialized = 'view',
persist_docs ={ "relation": true,
"columns": true }
) }}
SELECT
block_number,
block_timestamp,
tx_hash,
event_index,
origin_function_signature,
origin_from_address,
origin_to_address,
contract_address,
from_address,
to_address,
raw_amount,
raw_amount_precise,
_log_id,
COALESCE (
transfers_id,
{{ dbt_utils.generate_surrogate_key(
['tx_hash', 'event_index']
) }}
) AS fact_token_transfers_id,
COALESCE(
inserted_timestamp,
'2000-01-01'
) AS inserted_timestamp,
COALESCE(
modified_timestamp,
'2000-01-01'
) AS modified_timestamp
FROM
{{ ref('silver__transfers') }}

View File

@ -0,0 +1,38 @@
version: 2
models:
- name: core__fact_token_transfers
description: '{{ doc("blast_transfer_table_doc") }}'
columns:
- name: BLOCK_NUMBER
description: '{{ doc("blast_block_number") }}'
- name: BLOCK_TIMESTAMP
description: '{{ doc("blast_block_timestamp") }}'
- name: TX_HASH
description: '{{ doc("blast_transfer_tx_hash") }}'
- name: EVENT_INDEX
description: '{{ doc("blast_event_index") }}'
- name: ORIGIN_FUNCTION_SIGNATURE
description: '{{ doc("blast_origin_sig") }}'
- name: ORIGIN_FROM_ADDRESS
description: '{{ doc("blast_origin_from") }}'
- name: ORIGIN_TO_ADDRESS
description: '{{ doc("blast_origin_to") }}'
- name: CONTRACT_ADDRESS
description: '{{ doc("blast_transfer_contract_address") }}'
- name: FROM_ADDRESS
description: '{{ doc("blast_transfer_from_address") }}'
- name: TO_ADDRESS
description: '{{ doc("blast_transfer_to_address") }}'
- name: RAW_AMOUNT
description: '{{ doc("blast_transfer_raw_amount") }}'
- name: RAW_AMOUNT_PRECISE
description: '{{ doc("blast_transfer_raw_amount_precise") }}'
- name: _LOG_ID
description: '{{ doc("internal_column") }}'
- name: FACT_TOKEN_TRANSFERS_ID
description: '{{ doc("pk") }}'
- name: INSERTED_TIMESTAMP
description: '{{ doc("inserted_timestamp") }}'
- name: MODIFIED_TIMESTAMP
description: '{{ doc("modified_timestamp") }}'

View File

@ -0,0 +1,18 @@
{{ config(
materialized = 'view',
persist_docs ={ "relation": true,
"columns": true }
) }}
SELECT
token_address,
id,
symbol,
NAME,
decimals,
provider,
asset_metadata_all_providers_id AS dim_asset_metadata_id,
inserted_timestamp,
modified_timestamp
FROM
{{ ref('silver__asset_metadata_all_providers') }}

View File

@ -0,0 +1,31 @@
version: 2
models:
- name: price__dim_asset_metadata
description: A comprehensive dimensional table holding all provider asset metadata and other relevant details pertaining to each token_address.
tests:
- dbt_utils.unique_combination_of_columns:
combination_of_columns:
- PROVIDER
- ID
- TOKEN_ADDRESS
- SYMBOL
columns:
- name: PROVIDER
description: The provider or source of the data.
- name: ID
description: The unique identifier representing the asset.
- name: NAME
description: The name of asset.
- name: SYMBOL
description: The symbol of asset.
- name: TOKEN_ADDRESS
description: The specific address representing the asset in a specific platform.
- name: DECIMALS
description: The number of decimal places the token needs adjusted where token values exist.
- name: DIM_ASSET_METADATA_ID
description: '{{ doc("pk") }}'
- name: INSERTED_TIMESTAMP
description: '{{ doc("inserted_timestamp") }}'
- name: MODIFIED_TIMESTAMP
description: '{{ doc("modified_timestamp") }}'

View File

@ -0,0 +1,17 @@
{{ config(
materialized = 'view',
persist_docs ={ "relation": true,
"columns": true }
) }}
SELECT
token_address,
id,
symbol,
NAME,
decimals,
asset_metadata_priority_id AS ez_asset_metadata_id,
inserted_timestamp,
modified_timestamp
FROM
{{ ref('silver__asset_metadata_priority') }}

View File

@ -0,0 +1,26 @@
version: 2
models:
- name: price__ez_asset_metadata
description: A convenience table holding prioritized asset metadata and other relevant details pertaining to each token_address.
tests:
- dbt_utils.unique_combination_of_columns:
combination_of_columns:
- TOKEN_ADDRESS
columns:
- name: ID
description: The unique identifier representing the asset.
- name: NAME
description: The name of asset.
- name: SYMBOL
description: The symbol of asset.
- name: TOKEN_ADDRESS
description: The specific address representing the asset in a specific platform.
- name: DECIMALS
description: The number of decimal places the token needs adjusted where token values exist.
- name: EZ_ASSET_METADATA_ID
description: '{{ doc("pk") }}'
- name: INSERTED_TIMESTAMP
description: '{{ doc("inserted_timestamp") }}'
- name: MODIFIED_TIMESTAMP
description: '{{ doc("modified_timestamp") }}'

View File

@ -0,0 +1,18 @@
{{ config(
materialized = 'view',
persist_docs ={ "relation": true,
"columns": true }
) }}
SELECT
HOUR,
token_address,
symbol,
decimals,
price,
is_imputed,
hourly_prices_priority_id AS ez_hourly_token_prices_id,
inserted_timestamp,
modified_timestamp
FROM
{{ ref('silver__hourly_prices_priority') }}

View File

@ -0,0 +1,29 @@
version: 2
models:
- name: price__ez_hourly_token_prices
description: A convenience table for determining token prices by address.
tests:
- dbt_utils.unique_combination_of_columns:
combination_of_columns:
- HOUR
- TOKEN_ADDRESS
columns:
- name: HOUR
description: Hour that the price was recorded at
- name: TOKEN_ADDRESS
description: Address of the token
- name: SYMBOL
description: Symbol of the token
- name: DECIMALS
description: The number of decimals for token contract
- name: PRICE
description: Closing price of the recorded hour in USD
- name: IS_IMPUTED
description: Whether the price was imputed from an earlier record (generally used for low trade volume tokens)
- name: EZ_HOURLY_TOKEN_PRICES_ID
description: '{{ doc("pk") }}'
- name: INSERTED_TIMESTAMP
description: '{{ doc("inserted_timestamp") }}'
- name: MODIFIED_TIMESTAMP
description: '{{ doc("modified_timestamp") }}'

View File

@ -0,0 +1,17 @@
{{ config(
materialized = 'view',
persist_docs ={ "relation": true,
"columns": true }
) }}
SELECT
HOUR,
token_address,
price,
is_imputed,
provider,
hourly_prices_all_providers_id AS fact_hourly_token_prices_id,
inserted_timestamp,
modified_timestamp
FROM
{{ ref('silver__hourly_prices_all_providers') }}

View File

@ -0,0 +1,22 @@
version: 2
models:
- name: price__fact_hourly_token_prices
description: A comprehensive fact table holding provider specific hourly token prices.
columns:
- name: HOUR
description: Hour that the price was recorded at
- name: TOKEN_ADDRESS
description: Address of the token
- name: PROVIDER
description: Source of the token price.
- name: PRICE
description: Closing price of the recorded hour in USD
- name: IS_IMPUTED
description: Whether the price was imputed from an earlier record (generally used for low trade volume tokens)
- name: FACT_HOURLY_TOKEN_PRICES_ID
description: '{{ doc("pk") }}'
- name: INSERTED_TIMESTAMP
description: '{{ doc("inserted_timestamp") }}'
- name: MODIFIED_TIMESTAMP
description: '{{ doc("modified_timestamp") }}'

View File

@ -0,0 +1,48 @@
{{ config(
materialized = 'incremental',
merge_exclude_columns = ["inserted_timestamp"],
unique_key = ['token_address','symbol','id','provider'],
tags = ['non_realtime']
) }}
SELECT
token_address,
id,
COALESCE(
C.token_symbol,
p.symbol
) AS symbol,
token_name AS NAME,
token_decimals AS decimals,
provider,
p._inserted_timestamp,
{{ dbt_utils.generate_surrogate_key(
['token_address','symbol','id','provider']
) }} AS asset_metadata_all_providers_id,
SYSDATE() AS inserted_timestamp,
SYSDATE() AS modified_timestamp,
'{{ invocation_id }}' AS _invocation_id
FROM
{{ ref('bronze__asset_metadata_all_providers') }}
p
LEFT JOIN {{ ref('silver__contracts') }} C
ON LOWER(
C.contract_address
) = p.token_address
WHERE
1 = 1
{% if is_incremental() %}
AND p._inserted_timestamp >= (
SELECT
MAX(
_inserted_timestamp
)
FROM
{{ this }}
)
{% endif %}
qualify(ROW_NUMBER() over (PARTITION BY token_address, id, COALESCE(C.token_symbol, p.symbol), provider
ORDER BY
p._inserted_timestamp DESC)) = 1

View File

@ -0,0 +1,18 @@
version: 2
models:
- name: silver__asset_metadata_all_providers
tests:
- dbt_utils.unique_combination_of_columns:
combination_of_columns:
- TOKEN_ADDRESS
- SYMBOL
- PROVIDER
- ID
columns:
- name: TOKEN_ADDRESS
tests:
- not_null
- name: PROVIDER
tests:
- not_null

View File

@ -0,0 +1,52 @@
{{ config(
materialized = 'incremental',
unique_key = 'token_address',
merge_exclude_columns = ["inserted_timestamp"],
tags = ['non_realtime']
) }}
SELECT
p.token_address,
p.id,
COALESCE(
C.token_symbol,
p.symbol
) AS symbol,
C.token_name AS NAME,
C.token_decimals AS decimals,
p.provider,
CASE
WHEN p.provider = 'coingecko' THEN 1
WHEN p.provider = 'coinmarketcap' THEN 2
END AS priority,
p._inserted_timestamp,
{{ dbt_utils.generate_surrogate_key(
['p.token_address']
) }} AS asset_metadata_priority_id,
SYSDATE() AS inserted_timestamp,
SYSDATE() AS modified_timestamp,
'{{ invocation_id }}' AS _invocation_id
FROM
{{ ref('bronze__asset_metadata_priority') }}
p
LEFT JOIN {{ ref('silver__contracts') }} C
ON LOWER(
C.contract_address
) = p.token_address
WHERE
1 = 1
{% if is_incremental() %}
AND p._inserted_timestamp >= (
SELECT
MAX(
_inserted_timestamp
)
FROM
{{ this }}
)
{% endif %}
qualify(ROW_NUMBER() over (PARTITION BY token_address
ORDER BY
priority ASC)) = 1

View File

@ -0,0 +1,12 @@
version: 2
models:
- name: silver__asset_metadata_priority
tests:
- dbt_utils.unique_combination_of_columns:
combination_of_columns:
- TOKEN_ADDRESS
columns:
- name: TOKEN_ADDRESS
tests:
- not_null

View File

@ -0,0 +1,35 @@
{{ config(
materialized = 'incremental',
unique_key = ['token_address', 'hour', 'provider'],
merge_exclude_columns = ["inserted_timestamp"],
tags = ['non_realtime']
) }}
SELECT
HOUR,
token_address,
provider,
price,
is_imputed,
_inserted_timestamp,
{{ dbt_utils.generate_surrogate_key(
['token_address', 'hour', 'provider']
) }} AS hourly_prices_all_providers_id,
SYSDATE() AS inserted_timestamp,
SYSDATE() AS modified_timestamp,
'{{ invocation_id }}' AS _invocation_id
FROM
{{ ref('bronze__hourly_prices_all_providers') }}
WHERE
1 = 1
{% if is_incremental() %}
AND _inserted_timestamp >= (
SELECT
MAX(
_inserted_timestamp
)
FROM
{{ this }}
)
{% endif %}

View File

@ -0,0 +1,17 @@
version: 2
models:
- name: silver__hourly_prices_all_providers
tests:
- dbt_utils.unique_combination_of_columns:
combination_of_columns:
- TOKEN_ADDRESS
- HOUR
- PROVIDER
columns:
- name: HOUR
tests:
- not_null
- dbt_expectations.expect_row_values_to_have_recent_data:
datepart: day
interval: 1

View File

@ -0,0 +1,45 @@
{{ config(
materialized = 'incremental',
unique_key = ['token_address', 'hour'],
merge_exclude_columns = ["inserted_timestamp"],
tags = ['non_realtime']
) }}
SELECT
p.hour,
p.token_address,
p.price,
p.is_imputed,
p._inserted_timestamp,
COALESCE(
C.token_symbol,
m.symbol
) AS symbol,
C.token_decimals AS decimals,
{{ dbt_utils.generate_surrogate_key(
['p.token_address', 'p.hour']
) }} AS hourly_prices_priority_id,
SYSDATE() AS inserted_timestamp,
SYSDATE() AS modified_timestamp,
'{{ invocation_id }}' AS _invocation_id
FROM
{{ ref('bronze__hourly_prices_priority') }}
p
LEFT JOIN {{ ref('silver__asset_metadata_priority') }}
m
ON p.token_address = m.token_address
LEFT JOIN {{ ref('silver__contracts') }} C
ON p.token_address = C.contract_address
WHERE
1 = 1
{% if is_incremental() %}
AND p._inserted_timestamp >= (
SELECT
MAX(
_inserted_timestamp
) - INTERVAL '24 hours'
FROM
{{ this }}
)
{% endif %}

View File

@ -0,0 +1,16 @@
version: 2
models:
- name: silver__hourly_prices_priority
tests:
- dbt_utils.unique_combination_of_columns:
combination_of_columns:
- TOKEN_ADDRESS
- HOUR
columns:
- name: HOUR
tests:
- not_null
- dbt_expectations.expect_row_values_to_have_recent_data:
datepart: day
interval: 1

View File

@ -0,0 +1,34 @@
{{ config(
materialized = 'incremental',
unique_key = ['token_address', 'hour'],
merge_exclude_columns = ["inserted_timestamp"],
tags = ['non_realtime']
) }}
SELECT
HOUR,
token_address,
price,
is_imputed,
_inserted_timestamp,
{{ dbt_utils.generate_surrogate_key(
['token_address', 'hour']
) }} AS hourly_prices_priority_eth_id,
SYSDATE() AS inserted_timestamp,
SYSDATE() AS modified_timestamp,
'{{ invocation_id }}' AS _invocation_id
FROM
{{ ref('bronze__hourly_prices_priority_eth') }}
WHERE
1 = 1
{% if is_incremental() %}
AND _inserted_timestamp >= (
SELECT
MAX(
_inserted_timestamp
)
FROM
{{ this }}
)
{% endif %}

View File

@ -0,0 +1,16 @@
version: 2
models:
- name: silver__hourly_prices_priority_eth
tests:
- dbt_utils.unique_combination_of_columns:
combination_of_columns:
- TOKEN_ADDRESS
- HOUR
columns:
- name: HOUR
tests:
- not_null
- dbt_expectations.expect_row_values_to_have_recent_data:
datepart: day
interval: 1

View File

@ -0,0 +1,109 @@
{{ config(
materialized = 'incremental',
unique_key = 'contract_address',
merge_exclude_columns = ["inserted_timestamp"],
tags = ['non_realtime']
) }}
WITH base_metadata AS (
SELECT
contract_address,
block_number,
function_sig AS function_signature,
read_result AS read_output,
_inserted_timestamp
FROM
{{ ref('bronze_api__token_reads') }}
WHERE
read_result IS NOT NULL
AND read_result <> '0x'
{% if is_incremental() %}
AND _inserted_timestamp >= (
SELECT
MAX(
_inserted_timestamp
)
FROM
{{ this }}
)
{% endif %}
),
token_names AS (
SELECT
contract_address,
block_number,
function_signature,
read_output,
utils.udf_hex_to_string(
SUBSTR(read_output,(64 * 2 + 3), len(read_output))) AS token_name
FROM
base_metadata
WHERE
function_signature = '0x06fdde03'
AND token_name IS NOT NULL
),
token_symbols AS (
SELECT
contract_address,
block_number,
function_signature,
read_output,
utils.udf_hex_to_string(
SUBSTR(read_output,(64 * 2 + 3), len(read_output))) AS token_symbol
FROM
base_metadata
WHERE
function_signature = '0x95d89b41'
AND token_symbol IS NOT NULL
),
token_decimals AS (
SELECT
contract_address,
CASE
WHEN read_output IS NOT NULL THEN utils.udf_hex_to_int(
read_output :: STRING
)
ELSE NULL
END AS token_decimals,
LENGTH(token_decimals) AS dec_length
FROM
base_metadata
WHERE
function_signature = '0x313ce567'
AND read_output IS NOT NULL
AND read_output <> '0x'
),
contracts AS (
SELECT
contract_address,
MAX(_inserted_timestamp) AS _inserted_timestamp
FROM
base_metadata
GROUP BY
1
)
SELECT
c1.contract_address :: STRING AS contract_address,
token_name,
TRY_TO_NUMBER(token_decimals) AS token_decimals,
token_symbol,
_inserted_timestamp,
{{ dbt_utils.generate_surrogate_key(
['c1.contract_address']
) }} AS contracts_id,
SYSDATE() AS inserted_timestamp,
SYSDATE() AS modified_timestamp,
'{{ invocation_id }}' AS _invocation_id
FROM
contracts c1
LEFT JOIN token_names
ON c1.contract_address = token_names.contract_address
LEFT JOIN token_symbols
ON c1.contract_address = token_symbols.contract_address
LEFT JOIN token_decimals
ON c1.contract_address = token_decimals.contract_address
AND dec_length < 3 qualify(ROW_NUMBER() over(PARTITION BY c1.contract_address
ORDER BY
_inserted_timestamp DESC)) = 1

View File

@ -0,0 +1,109 @@
{{ config(
materialized = 'incremental',
incremental_strategy = 'delete+insert',
unique_key = 'block_number',
cluster_by = ['block_timestamp::DATE'],
post_hook = "ALTER TABLE {{ this }} ADD SEARCH OPTIMIZATION",
tags = ['non_realtime','reorg']
) }}
WITH eth_base AS (
SELECT
tx_hash,
block_number,
block_timestamp,
identifier,
from_address,
to_address,
eth_value,
_call_id,
_inserted_timestamp,
eth_value_precise_raw,
eth_value_precise,
tx_position,
trace_index
FROM
{{ ref('silver__traces') }}
WHERE
eth_value > 0
AND tx_status = 'SUCCESS'
AND trace_status = 'SUCCESS'
AND TYPE NOT IN (
'DELEGATECALL',
'STATICCALL'
)
{% if is_incremental() %}
AND _inserted_timestamp >= (
SELECT
MAX(_inserted_timestamp) - INTERVAL '72 hours'
FROM
{{ this }}
)
{% endif %}
),
tx_table AS (
SELECT
block_number,
tx_hash,
from_address AS origin_from_address,
to_address AS origin_to_address,
origin_function_signature
FROM
{{ ref('silver__transactions') }}
WHERE
tx_hash IN (
SELECT
DISTINCT tx_hash
FROM
eth_base
)
{% if is_incremental() %}
AND _inserted_timestamp >= (
SELECT
MAX(_inserted_timestamp) - INTERVAL '72 hours'
FROM
{{ this }}
)
{% endif %}
)
SELECT
tx_hash AS tx_hash,
block_number AS block_number,
block_timestamp AS block_timestamp,
identifier AS identifier,
origin_from_address,
origin_to_address,
origin_function_signature,
from_address,
to_address,
eth_value AS amount,
eth_value_precise_raw AS amount_precise_raw,
eth_value_precise AS amount_precise,
ROUND(
eth_value * price,
2
) AS amount_usd,
_call_id,
_inserted_timestamp,
tx_position,
trace_index,
{{ dbt_utils.generate_surrogate_key(
['tx_hash', 'trace_index']
) }} AS native_transfers_id,
SYSDATE() AS inserted_timestamp,
SYSDATE() AS modified_timestamp,
'{{ invocation_id }}' AS _invocation_id
FROM
eth_base A
LEFT JOIN {{ ref('silver__hourly_prices_priority_eth') }}
ON DATE_TRUNC(
'hour',
A.block_timestamp
) = HOUR
JOIN tx_table USING (
tx_hash,
block_number
)

View File

@ -0,0 +1,287 @@
-- depends_on: {{ ref('silver__hourly_prices_priority') }}
{{ config(
materialized = 'incremental',
incremental_strategy = 'delete+insert',
unique_key = "block_number",
cluster_by = ['block_timestamp::DATE', '_inserted_timestamp::DATE'],
tags = ['non_realtime','reorg','heal']
) }}
WITH logs AS (
SELECT
_log_id,
block_number,
tx_hash,
block_timestamp,
origin_function_signature,
origin_from_address,
origin_to_address,
contract_address :: STRING AS contract_address,
CONCAT('0x', SUBSTR(topics [1], 27, 40)) :: STRING AS from_address,
CONCAT('0x', SUBSTR(topics [2], 27, 40)) :: STRING AS to_address,
utils.udf_hex_to_int(SUBSTR(DATA, 3, 64)) AS raw_amount_precise,
raw_amount_precise :: FLOAT AS raw_amount,
event_index,
_inserted_timestamp
FROM
{{ ref('silver__logs') }}
WHERE
topics [0] :: STRING = '0xddf252ad1be2c89b69c2b068fc378daa952ba7f163c4a11628f55a4df523b3ef'
AND tx_status = 'SUCCESS'
{% if is_incremental() %}
AND _inserted_timestamp >= (
SELECT
MAX(
_inserted_timestamp
) - INTERVAL '36 hours'
FROM
{{ this }}
)
{% endif %}
),
token_transfers AS (
SELECT
block_number,
block_timestamp,
tx_hash,
event_index,
origin_function_signature,
origin_from_address,
origin_to_address,
t.contract_address,
from_address,
to_address,
raw_amount_precise,
raw_amount,
IFF(
C.token_decimals IS NOT NULL,
utils.udf_decimal_adjust(
raw_amount_precise,
C.token_decimals
),
NULL
) AS amount_precise,
amount_precise :: FLOAT AS amount,
IFF(
C.token_decimals IS NOT NULL
AND price IS NOT NULL,
amount * price,
NULL
) AS amount_usd,
C.token_decimals AS decimals,
C.token_symbol AS symbol,
price AS token_price,
CASE
WHEN C.token_decimals IS NULL THEN 'false'
ELSE 'true'
END AS has_decimal,
CASE
WHEN price IS NULL THEN 'false'
ELSE 'true'
END AS has_price,
_log_id,
_inserted_timestamp
FROM
logs t
LEFT JOIN {{ ref('price__ez_hourly_token_prices') }}
p
ON t.contract_address = p.token_address
AND DATE_TRUNC(
'hour',
t.block_timestamp
) = HOUR
LEFT JOIN {{ ref('silver__contracts') }} C USING (contract_address)
WHERE
raw_amount IS NOT NULL
AND to_address IS NOT NULL
AND from_address IS NOT NULL
)
{% if is_incremental() and var(
'HEAL_MODEL'
) %},
heal_model AS (
SELECT
t0.block_number,
t0.block_timestamp,
t0.tx_hash,
t0.event_index,
t0.origin_function_signature,
t0.origin_from_address,
t0.origin_to_address,
t0.contract_address,
t0.from_address,
t0.to_address,
t0.raw_amount_precise,
t0.raw_amount,
IFF(
C.token_decimals IS NOT NULL,
utils.udf_decimal_adjust(
t0.raw_amount_precise,
C.token_decimals
),
NULL
) AS amount_precise_heal,
amount_precise_heal :: FLOAT AS amount_heal,
IFF(
C.token_decimals IS NOT NULL
AND price IS NOT NULL,
amount_heal * p.price,
NULL
) AS amount_usd,
C.token_decimals AS decimals,
C.token_symbol AS symbol,
p.price AS token_price,
CASE
WHEN C.token_decimals IS NULL THEN 'false'
ELSE 'true'
END AS has_decimal,
CASE
WHEN p.price IS NULL THEN 'false'
ELSE 'true'
END AS has_price,
t0._log_id,
t0._inserted_timestamp
FROM
{{ this }}
t0
LEFT JOIN {{ ref('price__ez_hourly_token_prices') }}
p
ON t0.contract_address = p.token_address
AND DATE_TRUNC(
'hour',
t0.block_timestamp
) = HOUR
LEFT JOIN {{ ref('silver__contracts') }} C
ON C.contract_address = t0.contract_address
WHERE
t0.block_number IN (
SELECT
DISTINCT t1.block_number AS block_number
FROM
{{ this }}
t1
WHERE
t1.decimals IS NULL
AND _inserted_timestamp < (
SELECT
MAX(
_inserted_timestamp
) - INTERVAL '36 hours'
FROM
{{ this }}
)
AND EXISTS (
SELECT
1
FROM
{{ ref('silver__contracts') }} C
WHERE
C._inserted_timestamp > DATEADD('DAY', -14, SYSDATE())
AND C.token_decimals IS NOT NULL
AND C.contract_address = t1.contract_address)
)
OR t0.block_number IN (
SELECT
DISTINCT t2.block_number
FROM
{{ this }}
t2
WHERE
t2.token_price IS NULL
AND _inserted_timestamp < (
SELECT
MAX(
_inserted_timestamp
) - INTERVAL '36 hours'
FROM
{{ this }}
)
AND EXISTS (
SELECT
1
FROM
{{ ref('silver__hourly_prices_priority') }}
p
WHERE
p._inserted_timestamp > DATEADD('DAY', -14, SYSDATE())
AND p.price IS NOT NULL
AND p.token_address = t2.contract_address
AND p.hour = DATE_TRUNC(
'hour',
t2.block_timestamp
)
)
)
)
{% endif %}
SELECT
block_number,
block_timestamp,
tx_hash,
event_index,
origin_function_signature,
origin_from_address,
origin_to_address,
contract_address,
from_address,
to_address,
raw_amount_precise,
raw_amount,
amount_precise,
amount,
amount_usd,
decimals,
symbol,
token_price,
has_decimal,
has_price,
_log_id,
_inserted_timestamp,
{{ dbt_utils.generate_surrogate_key(
['tx_hash', 'event_index']
) }} AS transfers_id,
SYSDATE() AS inserted_timestamp,
SYSDATE() AS modified_timestamp,
'{{ invocation_id }}' AS _invocation_id
FROM
token_transfers
{% if is_incremental() and var(
'HEAL_MODEL'
) %}
UNION ALL
SELECT
block_number,
block_timestamp,
tx_hash,
event_index,
origin_function_signature,
origin_from_address,
origin_to_address,
contract_address,
from_address,
to_address,
raw_amount_precise,
raw_amount,
amount_precise_heal AS amount_precise,
amount_heal AS amount,
amount_usd,
decimals,
symbol,
token_price,
has_decimal,
has_price,
_log_id,
_inserted_timestamp,
{{ dbt_utils.generate_surrogate_key(
['tx_hash', 'event_index']
) }} AS transfers_id,
SYSDATE() AS inserted_timestamp,
SYSDATE() AS modified_timestamp,
'{{ invocation_id }}' AS _invocation_id
FROM
heal_model
{% endif %}

View File

@ -0,0 +1,9 @@
{{ config (
materialized = 'view',
tags = ['full_test']
) }}
SELECT
*
FROM
{{ ref('silver__transfers') }}

View File

@ -0,0 +1,70 @@
version: 2
models:
- name: test_silver__transfers_full
tests:
- dbt_utils.unique_combination_of_columns:
combination_of_columns:
- _LOG_ID
columns:
- name: BLOCK_NUMBER
tests:
- not_null
- dbt_expectations.expect_column_values_to_be_in_type_list:
column_type_list:
- NUMBER
- FLOAT
- name: BLOCK_TIMESTAMP
tests:
- not_null
- dbt_expectations.expect_row_values_to_have_recent_data:
datepart: day
interval: 1
- dbt_expectations.expect_column_values_to_be_in_type_list:
column_type_list:
- TIMESTAMP_NTZ
- TIMESTAMP_LTZ
- name: TX_HASH
tests:
- not_null
- dbt_expectations.expect_column_values_to_match_regex:
regex: 0[xX][0-9a-fA-F]+
- name: CONTRACT_ADDRESS
tests:
- not_null
- dbt_expectations.expect_column_values_to_match_regex:
regex: 0[xX][0-9a-fA-F]+
- name: FROM_ADDRESS
tests:
- not_null:
where: BLOCK_TIMESTAMP > '2021-08-01'
- dbt_expectations.expect_column_values_to_match_regex:
regex: 0[xX][0-9a-fA-F]+
- name: TO_ADDRESS
tests:
- not_null
- dbt_expectations.expect_column_values_to_match_regex:
regex: 0[xX][0-9a-fA-F]+
- name: RAW_AMOUNT
tests:
- not_null
- dbt_expectations.expect_column_values_to_be_in_type_list:
column_type_list:
- NUMBER
- FLOAT
- name: _LOG_ID
tests:
- not_null
- name: ORIGIN_FUNCTION_SIGNATURE
tests:
- not_null
- name: ORIGIN_FROM_ADDRESS
tests:
- not_null
- dbt_expectations.expect_column_values_to_match_regex:
regex: 0[xX][0-9a-fA-F]+
- name: ORIGIN_TO_ADDRESS
tests:
- dbt_expectations.expect_column_values_to_match_regex:
regex: 0[xX][0-9a-fA-F]+

View File

@ -0,0 +1,23 @@
{{ config (
materialized = 'view',
tags = ['recent_test']
) }}
WITH last_3_days AS (
SELECT
block_number
FROM
{{ ref("_block_lookback") }}
)
SELECT
*
FROM
{{ ref('silver__transfers') }}
WHERE
block_number >= (
SELECT
block_number
FROM
last_3_days
)

View File

@ -0,0 +1,67 @@
version: 2
models:
- name: test_silver__transfers_recent
tests:
- dbt_utils.unique_combination_of_columns:
combination_of_columns:
- _LOG_ID
columns:
- name: BLOCK_NUMBER
tests:
- not_null
- dbt_expectations.expect_column_values_to_be_in_type_list:
column_type_list:
- NUMBER
- FLOAT
- name: BLOCK_TIMESTAMP
tests:
- not_null
- dbt_expectations.expect_row_values_to_have_recent_data:
datepart: day
interval: 1
- dbt_expectations.expect_column_values_to_be_in_type_list:
column_type_list:
- TIMESTAMP_NTZ
- name: TX_HASH
tests:
- not_null
- dbt_expectations.expect_column_values_to_match_regex:
regex: 0[xX][0-9a-fA-F]+
- name: CONTRACT_ADDRESS
tests:
- not_null
- dbt_expectations.expect_column_values_to_match_regex:
regex: 0[xX][0-9a-fA-F]+
- name: FROM_ADDRESS
tests:
- not_null:
where: BLOCK_TIMESTAMP > '2021-08-01'
- dbt_expectations.expect_column_values_to_match_regex:
regex: 0[xX][0-9a-fA-F]+
- name: TO_ADDRESS
tests:
- not_null
- dbt_expectations.expect_column_values_to_match_regex:
regex: 0[xX][0-9a-fA-F]+
- name: RAW_AMOUNT
tests:
- not_null
- dbt_expectations.expect_column_values_to_be_in_type_list:
column_type_list:
- NUMBER
- FLOAT
- name: _LOG_ID
tests:
- not_null
- name: ORIGIN_FUNCTION_SIGNATURE
tests:
- not_null
- name: ORIGIN_FROM_ADDRESS
tests:
- not_null
- dbt_expectations.expect_column_values_to_match_regex:
regex: 0[xX][0-9a-fA-F]+
- name: ORIGIN_TO_ADDRESS
tests:
- dbt_expectations.expect_column_values_to_match_regex:
regex: 0[xX][0-9a-fA-F]+