-
Notifications
You must be signed in to change notification settings - Fork 1.1k
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
initiate index metrics spells (#6924)
* initiate index metrics spells * add cast to tx_index * initiate daily dune index spell * update names to daily, add tests * fix ref names * initiate dune index stats view * fix missing columns, fix percent change cols * fix table name * fix remaining table names * remove chain specific index * add descriptions * update stats logic
- Loading branch information
Showing
9 changed files
with
391 additions
and
3 deletions.
There are no files selected for viewing
22 changes: 22 additions & 0 deletions
22
dbt_subprojects/hourly_spellbook/models/_metrics/dune_index/_schema.yml
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,22 @@ | ||
version: 2 | ||
|
||
models: | ||
- name: metrics_dune_index_daily | ||
meta: | ||
sector: metrics | ||
contributors: jeff-dude | ||
config: | ||
tags: ['metrics', 'dune', 'index', 'daily'] | ||
description: "Combine transactions, transfers and fees index values to get a daily dune index value" | ||
tests: | ||
- dbt_utils.unique_combination_of_columns: | ||
combination_of_columns: | ||
- blockchain | ||
- block_date | ||
- name: metrics_dune_index_stats | ||
meta: | ||
sector: metrics | ||
contributors: jeff-dude | ||
config: | ||
tags: ['metrics', 'dune', 'index', 'daily'] | ||
description: "View containing various time aggregations of the dune index" |
38 changes: 38 additions & 0 deletions
38
dbt_subprojects/hourly_spellbook/models/_metrics/dune_index/metrics_dune_index_daily.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,38 @@ | ||
{{ config( | ||
schema = 'metrics' | ||
, alias = 'dune_index_daily' | ||
, materialized = 'incremental' | ||
, file_format = 'delta' | ||
, incremental_strategy = 'merge' | ||
, unique_key = ['blockchain', 'block_date'] | ||
, incremental_predicates = [incremental_predicate('DBT_INTERNAL_DEST.block_date')] | ||
) | ||
}} | ||
|
||
select | ||
f.blockchain | ||
, f.block_date | ||
, f.fees_index | ||
, tr.transfers_index | ||
, tx.tx_index | ||
, (f.fees_index + tr.transfers_index + tx.tx_index) / 3 as dune_index | ||
, 100 as baseline | ||
from {{ ref('metrics_fees_index_daily') }} as f | ||
left join | ||
{{ ref('metrics_transfers_index_daily') }} as tr | ||
on f.blockchain = tr.blockchain | ||
and f.block_date = tr.block_date | ||
{% if is_incremental() %} | ||
and {{ incremental_predicate('tr.block_date') }} | ||
{% endif %} | ||
left join | ||
{{ ref('metrics_transactions_index_daily') }} as tx | ||
on f.blockchain = tx.blockchain | ||
and f.block_date = tx.block_date | ||
{% if is_incremental() %} | ||
and {{ incremental_predicate('tx.block_date') }} | ||
{% endif %} | ||
{% if is_incremental() %} | ||
where | ||
{{ incremental_predicate('f.block_date') }} | ||
{% endif %} |
160 changes: 160 additions & 0 deletions
160
dbt_subprojects/hourly_spellbook/models/_metrics/dune_index/metrics_dune_index_stats.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,160 @@ | ||
{{ config( | ||
schema = 'metrics' | ||
, alias = 'dune_index_stats' | ||
) | ||
}} | ||
|
||
with source as ( | ||
-- daily dune index per blockchain | ||
select | ||
blockchain | ||
, block_date | ||
, fees_index | ||
, transfers_index | ||
, tx_index | ||
, dune_index | ||
from | ||
{{ ref('metrics_dune_index_daily') }} | ||
), current_day as ( | ||
select | ||
blockchain | ||
, dune_index as last_1_days_dune_index | ||
from | ||
source | ||
where | ||
block_date >= date_trunc('day', now()) - interval '1' day | ||
and block_date < date_trunc('day', now()) | ||
), previous_day as ( | ||
select | ||
blockchain | ||
, dune_index as previous_1_days_dune_index | ||
from | ||
source | ||
where | ||
block_date >= date_trunc('day', now()) - interval '2' day | ||
and block_date < date_trunc('day', now()) - interval '1' day | ||
), total_current_day_dune_index as ( | ||
select | ||
sum(last_1_days_dune_index) AS total_cross_chain_last_1_days_dune_index | ||
from | ||
current_day | ||
), daily_stats as ( | ||
select | ||
c.blockchain | ||
, c.last_1_days_dune_index as last_1_days_dune_index_contribution | ||
, (c.last_1_days_dune_index / t.total_cross_chain_last_1_days_dune_index) * 100 as last_1_days_dune_index_contribution_percent | ||
, t.total_cross_chain_last_1_days_dune_index | ||
, p.previous_1_days_dune_index as previous_1_days_dune_index_contribution | ||
, ((c.last_1_days_dune_index - coalesce(p.previous_1_days_dune_index, 0)) / coalesce(p.previous_1_days_dune_index, 1)) * 100 AS daily_percent_change | ||
from | ||
current_day as c | ||
left join previous_day as p | ||
on c.blockchain = p.blockchain | ||
inner join total_current_day_dune_index as t | ||
on 1 = 1 | ||
), current_week as ( | ||
select | ||
blockchain | ||
, avg(dune_index) as last_7_days_dune_index | ||
from | ||
source | ||
where | ||
block_date >= date_trunc('day', now()) - interval '7' day | ||
and block_date < date_trunc('day', now()) | ||
group by | ||
blockchain | ||
), previous_week as ( | ||
select | ||
blockchain | ||
, avg(dune_index) as previous_7_days_dune_index | ||
from | ||
source | ||
where | ||
block_date >= date_trunc('day', now()) - interval '14' day | ||
and block_date < date_trunc('day', now()) - interval '7' day | ||
group by | ||
blockchain | ||
), total_current_week_dune_index as ( | ||
select | ||
sum(last_7_days_dune_index) AS total_cross_chain_last_7_days_dune_index | ||
from | ||
current_week | ||
), weekly_stats as ( | ||
select | ||
c.blockchain | ||
, c.last_7_days_dune_index as last_7_days_dune_index_contribution | ||
, (c.last_7_days_dune_index / t.total_cross_chain_last_7_days_dune_index) * 100 as last_7_days_dune_index_contribution_percent | ||
, t.total_cross_chain_last_7_days_dune_index | ||
, p.previous_7_days_dune_index as previous_7_days_dune_index_contribution | ||
, ((c.last_7_days_dune_index - coalesce(p.previous_7_days_dune_index, 0)) / coalesce(p.previous_7_days_dune_index, 1)) * 100 AS weekly_percent_change | ||
from | ||
current_week as c | ||
left join previous_week as p | ||
on c.blockchain = p.blockchain | ||
inner join total_current_week_dune_index as t | ||
on 1 = 1 | ||
), current_month as ( | ||
select | ||
blockchain | ||
, avg(dune_index) as last_30_days_dune_index | ||
from | ||
source | ||
where | ||
block_date >= date_trunc('day', now()) - interval '30' day | ||
and block_date < date_trunc('day', now()) | ||
group by | ||
blockchain | ||
), previous_month as ( | ||
select | ||
blockchain | ||
, avg(dune_index) as previous_30_days_dune_index | ||
from | ||
source | ||
where | ||
block_date >= date_trunc('day', now()) - interval '60' day | ||
and block_date < date_trunc('day', now()) - interval '30' day | ||
group by | ||
blockchain | ||
), total_current_month_dune_index as ( | ||
select | ||
sum(last_30_days_dune_index) AS total_cross_chain_last_30_days_dune_index | ||
from | ||
current_month | ||
), monthly_stats as ( | ||
select | ||
c.blockchain | ||
, c.last_30_days_dune_index as last_30_days_dune_index_contribution | ||
, (c.last_30_days_dune_index / t.total_cross_chain_last_30_days_dune_index) * 100 as last_30_days_dune_index_contribution_percent | ||
, t.total_cross_chain_last_30_days_dune_index | ||
, p.previous_30_days_dune_index as previous_30_days_dune_index_contribution | ||
, ((c.last_30_days_dune_index - coalesce(p.previous_30_days_dune_index, 0)) / coalesce(p.previous_30_days_dune_index, 1)) * 100 AS monthly_percent_change | ||
from | ||
current_month as c | ||
left join previous_month as p | ||
on c.blockchain = p.blockchain | ||
inner join total_current_month_dune_index as t | ||
on 1 = 1 | ||
) | ||
select | ||
d.blockchain | ||
, d.last_1_days_dune_index_contribution | ||
, d.last_1_days_dune_index_contribution_percent | ||
, d.total_cross_chain_last_1_days_dune_index | ||
, d.previous_1_days_dune_index_contribution | ||
, d.daily_percent_change | ||
, w.last_7_days_dune_index_contribution | ||
, w.last_7_days_dune_index_contribution_percent | ||
, w.total_cross_chain_last_7_days_dune_index | ||
, w.previous_7_days_dune_index_contribution | ||
, w.weekly_percent_change | ||
, m.last_30_days_dune_index_contribution | ||
, m.last_30_days_dune_index_contribution_percent | ||
, m.total_cross_chain_last_30_days_dune_index | ||
, m.previous_30_days_dune_index_contribution | ||
, m.monthly_percent_change | ||
from | ||
daily_stats as d | ||
inner join weekly_stats as w | ||
on d.blockchain = w.blockchain | ||
inner join monthly_stats as m | ||
on d.blockchain = m.blockchain |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
44 changes: 44 additions & 0 deletions
44
dbt_subprojects/hourly_spellbook/models/_metrics/fees/metrics_fees_index_daily.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,44 @@ | ||
{{ config( | ||
schema = 'metrics' | ||
, alias = 'fees_index_daily' | ||
, materialized = 'incremental' | ||
, file_format = 'delta' | ||
, incremental_strategy = 'merge' | ||
, unique_key = ['blockchain', 'block_date'] | ||
, incremental_predicates = [incremental_predicate('DBT_INTERNAL_DEST.block_date')] | ||
) | ||
}} | ||
|
||
{% set baseline_date = '2018-01-01' %} | ||
|
||
with baseline as ( | ||
select | ||
sum(gas_fees_usd) as baseline_gas_fees_usd -- sum is required due to blockchain being second unique key in source | ||
from | ||
{{ ref('metrics_gas_fees_daily') }} | ||
where | ||
block_date = date '{{ baseline_date }}' | ||
), daily as ( | ||
select | ||
blockchain | ||
, block_date | ||
, gas_fees_usd | ||
from | ||
{{ ref('metrics_gas_fees_daily') }} | ||
where | ||
block_date >= date '{{ baseline_date }}' | ||
{% if is_incremental() %} | ||
and {{ incremental_predicate('block_date') }} | ||
{% endif %} | ||
) | ||
select | ||
d.blockchain | ||
, d.block_date | ||
, d.gas_fees_usd | ||
, b.baseline_gas_fees_usd | ||
, (d.gas_fees_usd / b.baseline_gas_fees_usd) * 100 as fees_index | ||
from | ||
daily as d | ||
left join | ||
baseline as b | ||
on 1 = 1 |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
44 changes: 44 additions & 0 deletions
44
...ojects/hourly_spellbook/models/_metrics/transactions/metrics_transactions_index_daily.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,44 @@ | ||
{{ config( | ||
schema = 'metrics' | ||
, alias = 'transactions_index_daily' | ||
, materialized = 'incremental' | ||
, file_format = 'delta' | ||
, incremental_strategy = 'merge' | ||
, unique_key = ['blockchain', 'block_date'] | ||
, incremental_predicates = [incremental_predicate('DBT_INTERNAL_DEST.block_date')] | ||
) | ||
}} | ||
|
||
{% set baseline_date = '2018-01-01' %} | ||
|
||
with baseline as ( | ||
select | ||
sum(tx_count) as baseline_tx_count -- sum is required due to blockchain being second unique key in source | ||
from | ||
{{ ref('metrics_transactions_daily') }} | ||
where | ||
block_date = date '{{ baseline_date }}' | ||
), daily as ( | ||
select | ||
blockchain | ||
, block_date | ||
, tx_count | ||
from | ||
{{ ref('metrics_transactions_daily') }} | ||
where | ||
block_date >= date '{{ baseline_date }}' | ||
{% if is_incremental() %} | ||
and {{ incremental_predicate('block_date') }} | ||
{% endif %} | ||
) | ||
select | ||
d.blockchain | ||
, d.block_date | ||
, d.tx_count | ||
, b.baseline_tx_count | ||
, (cast(d.tx_count as double) / cast(b.baseline_tx_count as double)) * 100 as tx_index | ||
from | ||
daily as d | ||
left join | ||
baseline as b | ||
on 1 = 1 |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Oops, something went wrong.