mirror of
https://github.com/FlipsideCrypto/crosschain-models.git
synced 2026-02-06 15:56:47 +00:00
Token-flows-and-tvl stats (#482)
* checks * tvl view and transfer summary with quality users * pr comments, add protocol TVL * rename to add in chain to the table name
This commit is contained in:
parent
23880c4731
commit
83ded831a6
220
models/gold/stats/stats__ez_transfer_metrics_daily.sql
Normal file
220
models/gold/stats/stats__ez_transfer_metrics_daily.sql
Normal file
@ -0,0 +1,220 @@
|
||||
-- depends_on: {{ ref('silver__transfers') }}
|
||||
-- depends_on: {{ ref('price__ez_prices_hourly') }}
|
||||
-- depends_on: {{ ref('silver__native_fee_token') }}
|
||||
{{ config(
|
||||
materialized = 'incremental',
|
||||
incremental_strategy = 'merge',
|
||||
merge_exclude_columns = ["inserted_timestamp"],
|
||||
unique_key = ['blockchain','block_date'],
|
||||
cluster_by = ['blockchain','block_date'],
|
||||
tags = ['metrics_daily']
|
||||
) }}
|
||||
|
||||
{% if execute %}
|
||||
|
||||
{% if is_incremental() %}
|
||||
{% set max_mod_query %}
|
||||
|
||||
SELECT
|
||||
MAX(modified_timestamp) modified_timestamp
|
||||
FROM
|
||||
{{ this }}
|
||||
|
||||
{% endset %}
|
||||
{% set max_mod = run_query(max_mod_query) [0] [0] %}
|
||||
{% if not max_mod or max_mod == 'None' %}
|
||||
{% set max_mod = '2099-01-01' %}
|
||||
{% endif %}
|
||||
{% endif %}
|
||||
|
||||
--get the distinct blockchains & block dates that we are processing
|
||||
{% set dates_query %}
|
||||
CREATE
|
||||
OR REPLACE temporary TABLE silver.ez_transfer_metrics__intermediate_tmp AS
|
||||
SELECT
|
||||
DISTINCT blockchain,
|
||||
block_timestamp :: DATE AS block_date
|
||||
FROM
|
||||
{{ ref('silver__transfers') }}
|
||||
WHERE
|
||||
block_timestamp :: DATE < SYSDATE() :: DATE
|
||||
|
||||
{% if is_incremental() %}
|
||||
AND modified_timestamp >= '{{ max_mod }}'
|
||||
{% else %}
|
||||
AND block_timestamp :: DATE >= '2025-01-01'
|
||||
{% endif %}
|
||||
|
||||
{% endset %}
|
||||
{% do run_query(dates_query) %}
|
||||
--create a dynamic where clause with literal block dates
|
||||
{% set date_query %}
|
||||
SELECT
|
||||
DISTINCT block_date
|
||||
FROM
|
||||
silver.ez_transfer_metrics__intermediate_tmp {% endset %}
|
||||
{% set date_results = run_query(date_query) %}
|
||||
{% set date_filter %}
|
||||
A.block_timestamp :: DATE IN ({% if date_results.rows | length > 0 %}
|
||||
{% for date in date_results %}
|
||||
'{{ date[0] }}' {% if not loop.last %},
|
||||
{% endif %}
|
||||
{% endfor %}
|
||||
{% else %}
|
||||
'2099-01-01'
|
||||
{% endif %}) {% endset %}
|
||||
--roll transactions up to the hour/sender level
|
||||
{% set inc_query %}
|
||||
CREATE
|
||||
OR REPLACE temporary TABLE silver.ez_transfer_metrics__xfer_intermediate_tmp AS
|
||||
SELECT
|
||||
A.blockchain,
|
||||
{# A.block_timestamp :: DATE AS block_date, #}
|
||||
DATE_TRUNC(
|
||||
'hour',
|
||||
A.block_timestamp
|
||||
) AS block_timestamp_hour,
|
||||
A.from_address,
|
||||
SUM(
|
||||
A.amount_usd
|
||||
) AS amount_usd,
|
||||
SUM(amount) AS amount
|
||||
FROM
|
||||
{{ ref('silver__transfers') }} A
|
||||
JOIN silver.ez_transfer_metrics__intermediate_tmp b
|
||||
ON A.blockchain = b.blockchain
|
||||
AND A.block_timestamp :: DATE = b.block_date
|
||||
WHERE
|
||||
{{ date_filter }}
|
||||
AND A.token_is_verified
|
||||
GROUP BY
|
||||
A.blockchain,
|
||||
block_timestamp_hour,
|
||||
from_address {% endset %}
|
||||
{% do run_query(inc_query) %}
|
||||
--find distinct score dates
|
||||
{% set score_dates_query %}
|
||||
CREATE
|
||||
OR REPLACE temporary TABLE silver.ez_transfer_metrics__score_dates_intermediate_tmp AS
|
||||
SELECT
|
||||
DISTINCT A.blockchain,
|
||||
A.score_date
|
||||
FROM
|
||||
{{ source(
|
||||
'datascience_onchain_scores',
|
||||
'all_scores'
|
||||
) }} A {% endset %}
|
||||
{% do run_query(score_dates_query) %}
|
||||
--find block dates where we do not have a score for that exact date
|
||||
{% set score_asof_query %}
|
||||
CREATE
|
||||
OR REPLACE temporary TABLE silver.ez_transfer_metrics__scores_asof_intermediate_tmp AS
|
||||
SELECT
|
||||
DISTINCT A.blockchain,
|
||||
A.block_date,
|
||||
b.score_date
|
||||
FROM
|
||||
ez_transfer_metrics__intermediate_tmp A asof
|
||||
JOIN silver.ez_transfer_metrics__score_dates_intermediate_tmp b match_condition (
|
||||
A.block_date >= score_date
|
||||
)
|
||||
ON A.blockchain = b.blockchain qualify ROW_NUMBER() over (
|
||||
PARTITION BY A.blockchain,
|
||||
A.block_Date
|
||||
ORDER BY
|
||||
ABS(DATEDIFF('day', score_date, A.block_date))
|
||||
) = 1 {% endset %}
|
||||
{% do run_query(score_asof_query) %}
|
||||
--Get the score for that block date or the closest date we have prior to that date
|
||||
{% set scores_query %}
|
||||
CREATE
|
||||
OR REPLACE temporary TABLE silver.ez_transfer_metrics__scores_intermediate_tmp AS
|
||||
SELECT
|
||||
A.blockchain,
|
||||
A.user_address,
|
||||
b.block_date,
|
||||
A.total_score
|
||||
FROM
|
||||
{{ source(
|
||||
'datascience_onchain_scores',
|
||||
'all_scores'
|
||||
) }} A
|
||||
JOIN silver.ez_transfer_metrics__scores_asof_intermediate_tmp b
|
||||
ON A.blockchain = b.blockchain
|
||||
AND A.score_date = b.score_date {% endset %}
|
||||
{% do run_query(scores_query) %}
|
||||
--delete the scores temp with a score less than 4 or the additional rows from the asof join
|
||||
{% set scores_del_query %}
|
||||
DELETE FROM
|
||||
silver.ez_transfer_metrics__scores_intermediate_tmp
|
||||
WHERE
|
||||
total_score < 4 {% endset %}
|
||||
{% do run_query(scores_del_query) %}
|
||||
{% endif %}
|
||||
|
||||
--Final aggregate of the data to the daily level
|
||||
WITH prices AS (
|
||||
SELECT
|
||||
A.hour,
|
||||
b.blockchain,
|
||||
A.price
|
||||
FROM
|
||||
{{ ref('price__ez_prices_hourly') }} A
|
||||
JOIN {{ ref('silver__native_fee_token') }}
|
||||
b
|
||||
ON A.blockchain = COALESCE(
|
||||
b.blockchain_override,
|
||||
b.blockchain
|
||||
)
|
||||
AND COALESCE(
|
||||
A.token_address,
|
||||
''
|
||||
) = COALESCE(
|
||||
b.address,
|
||||
''
|
||||
)
|
||||
AND A.symbol = b.symbol
|
||||
WHERE
|
||||
--three day look back to make sure we fill any gaps
|
||||
HOUR :: DATE >= (
|
||||
SELECT
|
||||
MIN(block_date) -3
|
||||
FROM
|
||||
silver.ez_transfer_metrics__intermediate_tmp
|
||||
)
|
||||
)
|
||||
SELECT
|
||||
A.blockchain,
|
||||
A.block_timestamp_hour :: DATE AS block_date,
|
||||
SUM(amount_usd) AS total_transfer_volume_usd,
|
||||
SUM(
|
||||
amount_usd / price
|
||||
) AS in_unit_total_transfer_volume,
|
||||
SUM(
|
||||
CASE
|
||||
WHEN C.blockchain IS NOT NULL THEN amount_usd
|
||||
ELSE 0
|
||||
END
|
||||
) AS quality_total_transfer_volume_usd,
|
||||
SUM(
|
||||
CASE
|
||||
WHEN C.blockchain IS NOT NULL THEN amount_usd / price
|
||||
ELSE 0
|
||||
END
|
||||
) AS in_unit_quality_total_transfer_volume,
|
||||
{{ dbt_utils.generate_surrogate_key(['a.blockchain','A.block_timestamp_hour :: DATE']) }} AS ez_transfer_metrics_daily_id,
|
||||
SYSDATE() AS inserted_timestamp,
|
||||
SYSDATE() AS modified_timestamp
|
||||
FROM
|
||||
silver.ez_transfer_metrics__xfer_intermediate_tmp A asof
|
||||
JOIN prices b match_condition (
|
||||
A.block_timestamp_hour >= b.hour
|
||||
)
|
||||
ON A.blockchain = b.blockchain
|
||||
LEFT JOIN silver.ez_transfer_metrics__scores_intermediate_tmp C
|
||||
ON A.blockchain = C.blockchain
|
||||
AND A.from_address = C.user_address
|
||||
AND A.block_timestamp_hour :: DATE = C.block_date
|
||||
GROUP BY
|
||||
A.blockchain,
|
||||
A.block_timestamp_hour :: DATE
|
||||
34
models/gold/stats/stats__ez_transfer_metrics_daily.yml
Normal file
34
models/gold/stats/stats__ez_transfer_metrics_daily.yml
Normal file
@ -0,0 +1,34 @@
|
||||
version: 2
|
||||
models:
|
||||
- name: stats__ez_transfer_metrics_daily
|
||||
description: "An aggregated daily view of transfer metrics, including transfer USD volume, and USD volumne for quality users grouped by blockchain"
|
||||
tests:
|
||||
- dbt_utils.unique_combination_of_columns:
|
||||
combination_of_columns:
|
||||
- BLOCK_DATE
|
||||
- BLOCKCHAIN
|
||||
|
||||
columns:
|
||||
- name: BLOCKCHAIN
|
||||
description: '{{ doc("blockchain_column") }}'
|
||||
- name: BLOCK_DATE
|
||||
description: '{{ doc("block_date") }}'
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_row_values_to_have_recent_data:
|
||||
datepart: day
|
||||
interval: 2
|
||||
- name: total_transfer_volume_usd
|
||||
description: 'USD value of all stablecoin transfers on the blockchain'
|
||||
- name: quality_total_transfer_volume_usd
|
||||
description: 'USD value of all stablecoin transfers on the blockchain for quality users'
|
||||
- name: in_unit_total_transfer_volume
|
||||
description: 'Total transfer volume in native units for the blockchain'
|
||||
- name: quality_in_unit_total_transfer_volume
|
||||
description: 'Total transfer volume in native units for the blockchain for quality users'
|
||||
- name: EZ_TRANSFER_METRICS_DAILY_ID
|
||||
description: '{{ doc("pk") }}'
|
||||
- name: INSERTED_TIMESTAMP
|
||||
description: '{{ doc("inserted_timestamp") }}'
|
||||
- name: MODIFIED_TIMESTAMP
|
||||
description: '{{ doc("modified_timestamp") }}'
|
||||
125
models/gold/stats/stats__ez_tvl_chain_metrics_daily.sql
Normal file
125
models/gold/stats/stats__ez_tvl_chain_metrics_daily.sql
Normal file
@ -0,0 +1,125 @@
|
||||
{{ config(
|
||||
materialized = 'view',
|
||||
tags = ['metrics_daily']
|
||||
) }}
|
||||
|
||||
WITH source_data AS (
|
||||
-- Using daily data directly
|
||||
|
||||
SELECT
|
||||
DATE :: DATE AS DATE,
|
||||
chain,
|
||||
LOWER(
|
||||
SPLIT_PART(
|
||||
chain,
|
||||
'-',
|
||||
1
|
||||
)
|
||||
) AS clean_chain,
|
||||
tvl_usd AS daily_tvl
|
||||
FROM
|
||||
{{ source(
|
||||
'external_defillama',
|
||||
'fact_chain_tvl'
|
||||
) }}
|
||||
WHERE
|
||||
DATE IS NOT NULL
|
||||
AND tvl_usd > 0
|
||||
AND clean_chain NOT IN (
|
||||
'dcAndLsOverlap',
|
||||
'liquidstaking',
|
||||
'doublecounted',
|
||||
'borrowed'
|
||||
) qualify ROW_NUMBER() over (
|
||||
PARTITION BY clean_chain,
|
||||
DATE
|
||||
ORDER BY
|
||||
tvl_usd DESC
|
||||
) = 1
|
||||
),
|
||||
tvl_metrics AS (
|
||||
SELECT
|
||||
DATE,
|
||||
clean_chain AS blockchain,
|
||||
daily_tvl AS current_tvl,
|
||||
-- Lagged TVL values for daily change calculations
|
||||
LAG(
|
||||
daily_tvl,
|
||||
1
|
||||
) over (
|
||||
PARTITION BY clean_chain
|
||||
ORDER BY
|
||||
DATE
|
||||
) AS prev_1_day_tvl,
|
||||
LAG(
|
||||
daily_tvl,
|
||||
7
|
||||
) over (
|
||||
PARTITION BY clean_chain
|
||||
ORDER BY
|
||||
DATE
|
||||
) AS prev_7_day_tvl,
|
||||
LAG(
|
||||
daily_tvl,
|
||||
30
|
||||
) over (
|
||||
PARTITION BY clean_chain
|
||||
ORDER BY
|
||||
DATE
|
||||
) AS prev_30_day_tvl,
|
||||
LAG(
|
||||
daily_tvl,
|
||||
90
|
||||
) over (
|
||||
PARTITION BY clean_chain
|
||||
ORDER BY
|
||||
DATE
|
||||
) AS prev_90_day_tvl,
|
||||
-- Calculate rolling volatility (90-day standard deviation)
|
||||
STDDEV(daily_tvl) over (
|
||||
PARTITION BY clean_chain
|
||||
ORDER BY
|
||||
DATE rows BETWEEN 89 preceding
|
||||
AND CURRENT ROW
|
||||
) AS tvl_volatility_90d,
|
||||
-- Calculate rolling max drawdown (90-day)
|
||||
MAX(daily_tvl) over (
|
||||
PARTITION BY clean_chain
|
||||
ORDER BY
|
||||
DATE rows BETWEEN 89 preceding
|
||||
AND CURRENT ROW
|
||||
) AS rolling_90d_max_tvl,
|
||||
MIN(daily_tvl) over (
|
||||
PARTITION BY clean_chain
|
||||
ORDER BY
|
||||
DATE rows BETWEEN 89 preceding
|
||||
AND CURRENT ROW
|
||||
) AS rolling_90d_min_tvl,
|
||||
-- Calculate 14-day rolling average TVL for ranking
|
||||
AVG(daily_tvl) over (
|
||||
PARTITION BY clean_chain
|
||||
ORDER BY
|
||||
DATE rows BETWEEN 13 preceding
|
||||
AND CURRENT ROW
|
||||
) AS rolling_14d_avg_tvl
|
||||
FROM
|
||||
source_data
|
||||
)
|
||||
SELECT
|
||||
blockchain,
|
||||
DATE AS block_date,
|
||||
current_tvl,
|
||||
current_tvl - prev_1_day_tvl AS day_1_change,
|
||||
-- Absolute daily changes
|
||||
ROUND((day_1_change / NULLIF(prev_1_day_tvl, 0)) * 100, 2) AS pct_change_1d,
|
||||
-- Percentage changes over different periods
|
||||
ROUND((tvl_volatility_90d / NULLIF(current_tvl, 0)) * 100, 2) AS volatility_score_90d,
|
||||
-- Rolling 90-day volatility score (normalized by current TVL)
|
||||
ROUND(
|
||||
((rolling_90d_min_tvl - rolling_90d_max_tvl) / NULLIF(rolling_90d_max_tvl, 0)) * 100,
|
||||
2
|
||||
) AS max_drawdown_pct_90d,
|
||||
-- Rolling 90-day maximum drawdown percentage,,
|
||||
{{ dbt_utils.generate_surrogate_key(['blockchain','block_date']) }} AS ez_tvl_metrics_daily_id
|
||||
FROM
|
||||
tvl_metrics
|
||||
35
models/gold/stats/stats__ez_tvl_chain_metrics_daily.yml
Normal file
35
models/gold/stats/stats__ez_tvl_chain_metrics_daily.yml
Normal file
@ -0,0 +1,35 @@
|
||||
version: 2
|
||||
models:
|
||||
- name: stats__ez_tvl_chain_metrics_daily
|
||||
description: "An daily view of total value locked by blockchain with metrics related to the to the previous day and last 90 days. This data is soruced from defillama"
|
||||
tests:
|
||||
- dbt_utils.unique_combination_of_columns:
|
||||
combination_of_columns:
|
||||
- BLOCK_DATE
|
||||
- BLOCKCHAIN
|
||||
|
||||
columns:
|
||||
- name: BLOCKCHAIN
|
||||
description: '{{ doc("blockchain_column") }}'
|
||||
- name: BLOCK_DATE
|
||||
description: '{{ doc("block_date") }}'
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_row_values_to_have_recent_data:
|
||||
datepart: day
|
||||
interval: 2
|
||||
- name: current_tvl
|
||||
description: 'The current total value locked for this chain for this date'
|
||||
tests:
|
||||
- not_null
|
||||
- name: day_1_change
|
||||
description: 'The one day change in total value locked from the previous day'
|
||||
- name: pct_change_1d
|
||||
description: 'The one day percentage change in total value locked from the previous day'
|
||||
- name: volatility_score_90d
|
||||
description: 'Rolling 90-day volatility score (normalized by current TVL)'
|
||||
- name: max_drawdown_pct_90d
|
||||
description: 'Rolling 90-day maximum drawdown percentage'
|
||||
|
||||
- name: EZ_TVL_METRICS_DAILY_ID
|
||||
description: '{{ doc("pk") }}'
|
||||
137
models/gold/stats/stats__ez_tvl_protocol_metrics_daily.sql
Normal file
137
models/gold/stats/stats__ez_tvl_protocol_metrics_daily.sql
Normal file
@ -0,0 +1,137 @@
|
||||
{{ config(
|
||||
materialized = 'view',
|
||||
tags = ['metrics_daily']
|
||||
) }}
|
||||
|
||||
WITH source_data AS (
|
||||
-- Using daily data directly
|
||||
|
||||
SELECT
|
||||
DATE :: DATE AS DATE,
|
||||
chain,
|
||||
LOWER(
|
||||
SPLIT_PART(
|
||||
chain,
|
||||
'-',
|
||||
1
|
||||
)
|
||||
) AS clean_chain,
|
||||
LOWER(protocol) AS clean_protocol,
|
||||
chain_tvl AS daily_tvl
|
||||
FROM
|
||||
{{ source(
|
||||
'external_defillama',
|
||||
'fact_protocol_tvl'
|
||||
) }}
|
||||
WHERE
|
||||
DATE IS NOT NULL
|
||||
AND chain_tvl > 0
|
||||
AND clean_chain NOT IN (
|
||||
'dcAndLsOverlap',
|
||||
'liquidstaking',
|
||||
'doublecounted',
|
||||
'borrowed'
|
||||
) qualify ROW_NUMBER() over (
|
||||
PARTITION BY clean_chain,
|
||||
clean_protocol,
|
||||
DATE
|
||||
ORDER BY
|
||||
chain_tvl DESC
|
||||
) = 1
|
||||
),
|
||||
tvl_metrics AS (
|
||||
SELECT
|
||||
DATE,
|
||||
clean_chain AS blockchain,
|
||||
clean_protocol AS protocol,
|
||||
daily_tvl AS current_tvl,
|
||||
-- Lagged TVL values for daily change calculations
|
||||
LAG(
|
||||
daily_tvl,
|
||||
1
|
||||
) over (
|
||||
PARTITION BY clean_chain,
|
||||
clean_protocol
|
||||
ORDER BY
|
||||
DATE
|
||||
) AS prev_1_day_tvl,
|
||||
LAG(
|
||||
daily_tvl,
|
||||
7
|
||||
) over (
|
||||
PARTITION BY clean_chain,
|
||||
clean_protocol
|
||||
ORDER BY
|
||||
DATE
|
||||
) AS prev_7_day_tvl,
|
||||
LAG(
|
||||
daily_tvl,
|
||||
30
|
||||
) over (
|
||||
PARTITION BY clean_chain,
|
||||
clean_protocol
|
||||
ORDER BY
|
||||
DATE
|
||||
) AS prev_30_day_tvl,
|
||||
LAG(
|
||||
daily_tvl,
|
||||
90
|
||||
) over (
|
||||
PARTITION BY clean_chain,
|
||||
clean_protocol
|
||||
ORDER BY
|
||||
DATE
|
||||
) AS prev_90_day_tvl,
|
||||
-- Calculate rolling volatility (90-day standard deviation)
|
||||
STDDEV(daily_tvl) over (
|
||||
PARTITION BY clean_chain,
|
||||
clean_protocol
|
||||
ORDER BY
|
||||
DATE rows BETWEEN 89 preceding
|
||||
AND CURRENT ROW
|
||||
) AS tvl_volatility_90d,
|
||||
-- Calculate rolling max drawdown (90-day)
|
||||
MAX(daily_tvl) over (
|
||||
PARTITION BY clean_chain,
|
||||
clean_protocol
|
||||
ORDER BY
|
||||
DATE rows BETWEEN 89 preceding
|
||||
AND CURRENT ROW
|
||||
) AS rolling_90d_max_tvl,
|
||||
MIN(daily_tvl) over (
|
||||
PARTITION BY clean_chain,
|
||||
clean_protocol
|
||||
ORDER BY
|
||||
DATE rows BETWEEN 89 preceding
|
||||
AND CURRENT ROW
|
||||
) AS rolling_90d_min_tvl,
|
||||
-- Calculate 14-day rolling average TVL for ranking
|
||||
AVG(daily_tvl) over (
|
||||
PARTITION BY clean_chain,
|
||||
clean_protocol
|
||||
ORDER BY
|
||||
DATE rows BETWEEN 13 preceding
|
||||
AND CURRENT ROW
|
||||
) AS rolling_14d_avg_tvl
|
||||
FROM
|
||||
source_data
|
||||
)
|
||||
SELECT
|
||||
blockchain,
|
||||
protocol,
|
||||
DATE AS block_date,
|
||||
current_tvl,
|
||||
current_tvl - prev_1_day_tvl AS day_1_change,
|
||||
-- Absolute daily changes
|
||||
ROUND((day_1_change / NULLIF(prev_1_day_tvl, 0)) * 100, 2) AS pct_change_1d,
|
||||
-- Percentage changes over different periods
|
||||
ROUND((tvl_volatility_90d / NULLIF(current_tvl, 0)) * 100, 2) AS volatility_score_90d,
|
||||
-- Rolling 90-day volatility score (normalized by current TVL)
|
||||
ROUND(
|
||||
((rolling_90d_min_tvl - rolling_90d_max_tvl) / NULLIF(rolling_90d_max_tvl, 0)) * 100,
|
||||
2
|
||||
) AS max_drawdown_pct_90d,
|
||||
-- Rolling 90-day maximum drawdown percentage,,
|
||||
{{ dbt_utils.generate_surrogate_key(['blockchain','block_date','protocol']) }} AS ez_tvl_protocol_metrics_daily_id
|
||||
FROM
|
||||
tvl_metrics
|
||||
38
models/gold/stats/stats__ez_tvl_protocol_metrics_daily.yml
Normal file
38
models/gold/stats/stats__ez_tvl_protocol_metrics_daily.yml
Normal file
@ -0,0 +1,38 @@
|
||||
version: 2
|
||||
models:
|
||||
- name: stats__ez_tvl_protocol_metrics_daily
|
||||
description: "An daily view of total value locked by blockchain and protocol with metrics related to the to the previous day and last 90 days. This data is soruced from defillama"
|
||||
tests:
|
||||
- dbt_utils.unique_combination_of_columns:
|
||||
combination_of_columns:
|
||||
- BLOCK_DATE
|
||||
- BLOCKCHAIN
|
||||
- PROTOCOL
|
||||
|
||||
columns:
|
||||
- name: BLOCKCHAIN
|
||||
description: '{{ doc("blockchain_column") }}'
|
||||
- name: BLOCK_DATE
|
||||
description: '{{ doc("block_date") }}'
|
||||
tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_row_values_to_have_recent_data:
|
||||
datepart: day
|
||||
interval: 2
|
||||
- name: PROTOCOL
|
||||
description: 'The protocol name for this chain'
|
||||
- name: current_tvl
|
||||
description: 'The current total value locked for this chain for this date'
|
||||
tests:
|
||||
- not_null
|
||||
- name: day_1_change
|
||||
description: 'The one day change in total value locked from the previous day'
|
||||
- name: pct_change_1d
|
||||
description: 'The one day percentage change in total value locked from the previous day'
|
||||
- name: volatility_score_90d
|
||||
description: 'Rolling 90-day volatility score (normalized by current TVL)'
|
||||
- name: max_drawdown_pct_90d
|
||||
description: 'Rolling 90-day maximum drawdown percentage'
|
||||
|
||||
- name: EZ_TVL_METRICS_DAILY_ID
|
||||
description: '{{ doc("pk") }}'
|
||||
@ -924,3 +924,4 @@ SELECT
|
||||
'{{ invocation_id }}' AS _invocation_id
|
||||
FROM
|
||||
base
|
||||
where address is not null
|
||||
|
||||
@ -742,6 +742,8 @@ sources:
|
||||
- name: fact_dex_volume
|
||||
- name: fact_bridge_volume_by_chain
|
||||
- name: dim_protocols
|
||||
- name: fact_chain_tvl
|
||||
- name: fact_protocol_tvl
|
||||
|
||||
- name: external_tokenlists
|
||||
database: external
|
||||
|
||||
Loading…
Reference in New Issue
Block a user