diff --git a/dbt_subprojects/daily_spellbook/models/_metrics/dune_index/_schema.yml b/dbt_subprojects/daily_spellbook/models/_metrics/dune_index/_schema.yml index 0c19c70acf8..13d144cac9d 100644 --- a/dbt_subprojects/daily_spellbook/models/_metrics/dune_index/_schema.yml +++ b/dbt_subprojects/daily_spellbook/models/_metrics/dune_index/_schema.yml @@ -4,7 +4,7 @@ models: - name: metrics_dune_index_daily meta: sector: metrics - contributors: jeff-dude + contributors: jeff-dude, 0xRob config: tags: ['metrics', 'dune', 'index', 'daily'] description: "Combine transactions, transfers and fees index values to get a daily dune index value" @@ -13,10 +13,3 @@ models: 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" \ No newline at end of file diff --git a/dbt_subprojects/daily_spellbook/models/_metrics/dune_index/metrics_dune_index_daily.sql b/dbt_subprojects/daily_spellbook/models/_metrics/dune_index/metrics_dune_index_daily.sql index e5f68fe3345..62a1474fe9a 100644 --- a/dbt_subprojects/daily_spellbook/models/_metrics/dune_index/metrics_dune_index_daily.sql +++ b/dbt_subprojects/daily_spellbook/models/_metrics/dune_index/metrics_dune_index_daily.sql @@ -1,21 +1,71 @@ {{ config( schema = 'metrics' , alias = 'dune_index_daily' - , materialized = 'view' + , 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' %} +{% set start_date = '2015-08-21' %} + +with +fees as ( + select + blockchain + , block_date + , gas_fees_usd + , (gas_fees_usd / (select sum(gas_fees_usd) from {{ ref('metrics_gas_fees_daily') }} where block_date = date '{{ baseline_date }}')) * 10 as fees_index + from + {{ ref('metrics_gas_fees_daily') }} + where + block_date >= date '{{ start_date }}' + {% if is_incremental() %} + and {{ incremental_predicate('block_date') }} + {% endif %} +), +transactions as ( + select + blockchain + , block_date + , tx_count + , (tx_count / cast(select sum(tx_count) from {{ ref('metrics_transactions_daily') }} where block_date = date '{{ baseline_date }}' as double)) * 10 as tx_index + from + {{ ref('metrics_transactions_daily') }} + where + block_date >= date '{{ start_date }}' + {% if is_incremental() %} + and {{ incremental_predicate('block_date') }} + {% endif %} +) +,transfers as ( + select + blockchain + , block_date + , net_transfer_amount_usd + , (net_transfer_amount_usd / cast(select sum(net_transfer_amount_usd) from {{ ref('metrics_transfers_daily') }} where block_date = date '{{ baseline_date }}' as double)) * 10 as transfers_index + from + {{ ref('metrics_transfers_daily') }} + where + block_date >= date '{{ start_date }}' + {% if is_incremental() %} + and {{ incremental_predicate('block_date') }} + {% endif %} +) + select blockchain , block_date - , coalesce(f.fees_index,0) as fees_index - , coalesce(tr.transfers_index,0) as transfers_index - , coalesce(tx.tx_index,0) as tx_index - , coalesce(f.fees_index,0)*0.45 + coalesce(tr.transfers_index,0)*0.45 + coalesce(tx.tx_index,0)*0.10 as dune_index -from {{ ref('metrics_fees_index_daily') }} as f -left join - {{ ref('metrics_transfers_index_daily') }} as tr - using (blockchain, block_date) -left join - {{ ref('metrics_transactions_index_daily') }} as tx - using (blockchain, block_date) \ No newline at end of file + , 0.45 * coalesce(fees_index,0) + 0.45 * coalesce(transfers_index,0) + 0.10 * coalesce(tx_index,0) as dune_index + , coalesce(fees_index,0) as fees_index + , coalesce(transfers_index,0) as transfers_index + , coalesce(tx_index,0) as tx_index + , gas_fees_usd + , tx_count + , net_transfer_amount_usd +from fees +left join transfers using (blockchain, block_date) +left join transactions using (blockchain, block_date) diff --git a/dbt_subprojects/daily_spellbook/models/_metrics/dune_index/metrics_dune_index_stats.sql b/dbt_subprojects/daily_spellbook/models/_metrics/dune_index/metrics_dune_index_stats.sql deleted file mode 100644 index 7beb905d72b..00000000000 --- a/dbt_subprojects/daily_spellbook/models/_metrics/dune_index/metrics_dune_index_stats.sql +++ /dev/null @@ -1,160 +0,0 @@ -{{ 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 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) 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 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) 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 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) 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 \ No newline at end of file diff --git a/dbt_subprojects/daily_spellbook/models/_metrics/fees/_schema.yml b/dbt_subprojects/daily_spellbook/models/_metrics/fees/_schema.yml index 19335852960..e29e17c942c 100644 --- a/dbt_subprojects/daily_spellbook/models/_metrics/fees/_schema.yml +++ b/dbt_subprojects/daily_spellbook/models/_metrics/fees/_schema.yml @@ -13,22 +13,3 @@ models: combination_of_columns: - blockchain - block_date - - name: metrics_gas_fees_stats - meta: - sector: metrics - contributors: jeff-dude - config: - tags: ['metrics', 'fees', 'gas'] - description: "View of gas fees per blockchain aggregated to various levels. The goal is to output one row per chain with stats availble for use in counter visuals." - - name: metrics_fees_index_daily - meta: - sector: metrics - contributors: jeff-dude - config: - tags: ['metrics', 'fees', 'gas', 'index', 'daily'] - description: "Each day, per chain, compare the adoption of activity based on total gas fees relative to the baseline expectation" - data_tests: - - dbt_utils.unique_combination_of_columns: - combination_of_columns: - - blockchain - - block_date \ No newline at end of file diff --git a/dbt_subprojects/daily_spellbook/models/_metrics/fees/metrics_fees_index_daily.sql b/dbt_subprojects/daily_spellbook/models/_metrics/fees/metrics_fees_index_daily.sql deleted file mode 100644 index dd777d49048..00000000000 --- a/dbt_subprojects/daily_spellbook/models/_metrics/fees/metrics_fees_index_daily.sql +++ /dev/null @@ -1,38 +0,0 @@ -{{ config( - schema = 'metrics' - , alias = 'fees_index_daily' - , materialized = 'view' - ) -}} - -{% set baseline_date = '2018-01-01' %} -{% set start_date = '2015-08-21' %} - -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 '{{ start_date }}' -) -select - d.blockchain - , d.block_date - , d.gas_fees_usd - , b.baseline_gas_fees_usd - , (d.gas_fees_usd / b.baseline_gas_fees_usd) * 10 as fees_index -from - daily as d -left join - baseline as b - on 1 = 1 diff --git a/dbt_subprojects/daily_spellbook/models/_metrics/fees/metrics_gas_fees_stats.sql b/dbt_subprojects/daily_spellbook/models/_metrics/fees/metrics_gas_fees_stats.sql deleted file mode 100644 index ded73862c35..00000000000 --- a/dbt_subprojects/daily_spellbook/models/_metrics/fees/metrics_gas_fees_stats.sql +++ /dev/null @@ -1,158 +0,0 @@ -{{ config( - schema = 'metrics' - , alias = 'gas_fees_stats' - ) -}} - -with source as ( - -- daily aggregation of gas fees per blockchain - select - blockchain - , block_date - , gas_fees_usd - from - {{ ref('metrics_gas_fees_daily') }} -), current_day as ( - select - blockchain - , gas_fees_usd as last_1_days_gas_fees_usd - from - source - where - block_date >= date_trunc('day', now()) - interval '1' day - and block_date < date_trunc('day', now()) -), previous_day as ( - select - blockchain - , gas_fees_usd as previous_1_days_gas_fees_usd - 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_gas_fees as ( - select - sum(last_1_days_gas_fees_usd) AS total_cross_chain_last_1_days_gas_fees_usd - from - current_day -), daily_stats as ( - select - c.blockchain - , c.last_1_days_gas_fees_usd - , p.previous_1_days_gas_fees_usd - , (c.last_1_days_gas_fees_usd - coalesce(p.previous_1_days_gas_fees_usd, 0)) / coalesce(p.previous_1_days_gas_fees_usd, 1) AS daily_percent_change - , t.total_cross_chain_last_1_days_gas_fees_usd - , c.last_1_days_gas_fees_usd / t.total_cross_chain_last_1_days_gas_fees_usd AS percent_total_last_1_days_fees_usd - from - current_day as c - left join previous_day as p - on c.blockchain = p.blockchain - inner join total_current_day_gas_fees as t - on 1 = 1 -), current_week as ( - select - blockchain - , sum(gas_fees_usd) as last_7_days_gas_fees_usd - 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 - , sum(gas_fees_usd) as previous_7_days_gas_fees_usd - 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_gas_fees as ( - select - sum(last_7_days_gas_fees_usd) AS total_cross_chain_last_7_days_gas_fees_usd - from - current_week -), weekly_stats as ( - select - c.blockchain - , c.last_7_days_gas_fees_usd - , p.previous_7_days_gas_fees_usd - , (c.last_7_days_gas_fees_usd - coalesce(p.previous_7_days_gas_fees_usd, 0)) / coalesce(p.previous_7_days_gas_fees_usd, 1) AS weekly_percent_change - , t.total_cross_chain_last_7_days_gas_fees_usd - , c.last_7_days_gas_fees_usd / t.total_cross_chain_last_7_days_gas_fees_usd AS percent_total_last_7_days_gas_fees_usd - from - current_week as c - left join previous_week as p - on c.blockchain = p.blockchain - inner join total_current_week_gas_fees as t - on 1 = 1 -), current_month as ( - select - blockchain - , sum(gas_fees_usd) as last_30_days_gas_fees_usd - 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 - , sum(gas_fees_usd) as previous_30_days_gas_fees_usd - 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_gas_fees as ( - select - sum(last_30_days_gas_fees_usd) AS total_cross_chain_last_30_days_gas_fees_usd - from - current_month -), monthly_stats as ( - select - c.blockchain - , c.last_30_days_gas_fees_usd - , p.previous_30_days_gas_fees_usd - , (c.last_30_days_gas_fees_usd - coalesce(p.previous_30_days_gas_fees_usd, 0)) / coalesce(p.previous_30_days_gas_fees_usd, 1) AS monthly_percent_change - , t.total_cross_chain_last_30_days_gas_fees_usd - , c.last_30_days_gas_fees_usd / t.total_cross_chain_last_30_days_gas_fees_usd AS percent_total_last_30_days_gas_fees_usd - from - current_month as c - left join previous_month as p - on c.blockchain = p.blockchain - inner join total_current_month_gas_fees as t - on 1 = 1 -) -select - d.blockchain - , d.last_1_days_gas_fees_usd - , d.previous_1_days_gas_fees_usd - , d.daily_percent_change - , d.total_cross_chain_last_1_days_gas_fees_usd - , d.percent_total_last_1_days_fees_usd - , w.last_7_days_gas_fees_usd - , w.previous_7_days_gas_fees_usd - , w.weekly_percent_change - , w.total_cross_chain_last_7_days_gas_fees_usd - , w.percent_total_last_7_days_gas_fees_usd - , m.last_30_days_gas_fees_usd - , m.previous_30_days_gas_fees_usd - , m.monthly_percent_change - , m.total_cross_chain_last_30_days_gas_fees_usd - , m.percent_total_last_30_days_gas_fees_usd - , m.last_30_days_gas_fees_usd * 12 as gas_fees_usd_run_rate -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 \ No newline at end of file diff --git a/dbt_subprojects/daily_spellbook/models/_metrics/transactions/_schema.yml b/dbt_subprojects/daily_spellbook/models/_metrics/transactions/_schema.yml index 5f6e1f051ca..b8033066651 100644 --- a/dbt_subprojects/daily_spellbook/models/_metrics/transactions/_schema.yml +++ b/dbt_subprojects/daily_spellbook/models/_metrics/transactions/_schema.yml @@ -13,22 +13,3 @@ models: combination_of_columns: - blockchain - block_date - - name: metrics_transactions_stats - meta: - sector: metrics - contributors: jeff-dude - config: - tags: ['metrics', 'transactions'] - description: "View of tx's per blockchain aggregated to various levels. The goal is to output one row per chain with stats availble for use in counter visuals." - - name: metrics_transactions_index_daily - meta: - sector: metrics - contributors: jeff-dude - config: - tags: ['metrics', 'transactions', 'index', 'daily'] - description: "Each day, per chain, compare the adoption of total transactions relative to the baseline expectation" - data_tests: - - dbt_utils.unique_combination_of_columns: - combination_of_columns: - - blockchain - - block_date \ No newline at end of file diff --git a/dbt_subprojects/daily_spellbook/models/_metrics/transactions/metrics_transactions_index_daily.sql b/dbt_subprojects/daily_spellbook/models/_metrics/transactions/metrics_transactions_index_daily.sql deleted file mode 100644 index 194eb76b218..00000000000 --- a/dbt_subprojects/daily_spellbook/models/_metrics/transactions/metrics_transactions_index_daily.sql +++ /dev/null @@ -1,38 +0,0 @@ -{{ config( - schema = 'metrics' - , alias = 'transactions_index_daily' - , materialized = 'view' - ) -}} - -{% set baseline_date = '2018-01-01' %} -{% set start_date = '2015-08-21' %} - -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 '{{ start_date }}' -) -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)) * 10 as tx_index -from - daily as d -left join - baseline as b - on 1 = 1 diff --git a/dbt_subprojects/daily_spellbook/models/_metrics/transactions/metrics_transactions_stats.sql b/dbt_subprojects/daily_spellbook/models/_metrics/transactions/metrics_transactions_stats.sql deleted file mode 100644 index a03620af097..00000000000 --- a/dbt_subprojects/daily_spellbook/models/_metrics/transactions/metrics_transactions_stats.sql +++ /dev/null @@ -1,158 +0,0 @@ -{{ config( - schema = 'metrics' - , alias = 'transactions_stats' - ) -}} - -with source as ( - -- daily aggregation of tx's per blockchain - select - blockchain - , block_date - , tx_count - from - {{ ref('metrics_transactions_daily') }} -), current_day as ( - select - blockchain - , tx_count as last_1_days_tx_count - from - source - where - block_date >= date_trunc('day', now()) - interval '1' day - and block_date < date_trunc('day', now()) -), previous_day as ( - select - blockchain - , tx_count as previous_1_days_tx_count - 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_txs as ( - select - sum(last_1_days_tx_count) AS total_cross_chain_last_1_days_tx_count - from - current_day -), daily_stats as ( - select - c.blockchain - , c.last_1_days_tx_count - , p.previous_1_days_tx_count - , (cast(c.last_1_days_tx_count as double) - coalesce(cast(p.previous_1_days_tx_count as double), 0)) / coalesce(cast(p.previous_1_days_tx_count as double), 1) AS daily_percent_change - , t.total_cross_chain_last_1_days_tx_count - , cast(c.last_1_days_tx_count as double) / cast(t.total_cross_chain_last_1_days_tx_count as double) AS percent_total_last_1_days_tx_count - from - current_day as c - left join previous_day as p - on c.blockchain = p.blockchain - inner join total_current_day_txs as t - on 1 = 1 -), current_week as ( - select - blockchain - , sum(tx_count) as last_7_days_tx_count - 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 - , sum(tx_count) as previous_7_days_tx_count - 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_txs as ( - select - sum(last_7_days_tx_count) AS total_cross_chain_last_7_days_tx_count - from - current_week -), weekly_stats as ( - select - c.blockchain - , c.last_7_days_tx_count - , p.previous_7_days_tx_count - , (cast(c.last_7_days_tx_count as double) - coalesce(cast(p.previous_7_days_tx_count as double), 0)) / coalesce(cast(p.previous_7_days_tx_count as double), 1) AS weekly_percent_change - , t.total_cross_chain_last_7_days_tx_count - , cast(c.last_7_days_tx_count as double) / cast(t.total_cross_chain_last_7_days_tx_count as double) AS percent_total_last_7_days_tx_count - from - current_week as c - left join previous_week as p - on c.blockchain = p.blockchain - inner join total_current_week_txs as t - on 1 = 1 -), current_month as ( - select - blockchain - , sum(tx_count) as last_30_days_tx_count - 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 - , sum(tx_count) as previous_30_days_tx_count - 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_txs as ( - select - sum(last_30_days_tx_count) AS total_cross_chain_last_30_days_tx_count - from - current_month -), monthly_stats as ( - select - c.blockchain - , c.last_30_days_tx_count - , p.previous_30_days_tx_count - , (cast(c.last_30_days_tx_count as double) - coalesce(cast(p.previous_30_days_tx_count as double), 0)) / coalesce(cast(p.previous_30_days_tx_count as double), 1) AS monthly_percent_change - , t.total_cross_chain_last_30_days_tx_count - , cast(c.last_30_days_tx_count as double) / cast(t.total_cross_chain_last_30_days_tx_count as double) AS percent_total_last_30_days_tx_count - from - current_month as c - left join previous_month as p - on c.blockchain = p.blockchain - inner join total_current_month_txs as t - on 1 = 1 -) -select - d.blockchain - , d.last_1_days_tx_count - , d.previous_1_days_tx_count - , d.daily_percent_change - , d.total_cross_chain_last_1_days_tx_count - , d.percent_total_last_1_days_tx_count - , w.last_7_days_tx_count - , w.previous_7_days_tx_count - , w.weekly_percent_change - , w.total_cross_chain_last_7_days_tx_count - , w.percent_total_last_7_days_tx_count - , m.last_30_days_tx_count - , m.previous_30_days_tx_count - , m.monthly_percent_change - , m.total_cross_chain_last_30_days_tx_count - , m.percent_total_last_30_days_tx_count - , m.last_30_days_tx_count * 12 as tx_count_run_rate -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 \ No newline at end of file diff --git a/dbt_subprojects/daily_spellbook/models/_metrics/transfers/_schema.yml b/dbt_subprojects/daily_spellbook/models/_metrics/transfers/_schema.yml index e03f33be0d9..621fe25825e 100644 --- a/dbt_subprojects/daily_spellbook/models/_metrics/transfers/_schema.yml +++ b/dbt_subprojects/daily_spellbook/models/_metrics/transfers/_schema.yml @@ -60,22 +60,3 @@ models: combination_of_columns: - blockchain - block_date - - name: metrics_transfers_stats - meta: - sector: metrics - contributors: jeff-dude - config: - tags: ['metrics', 'transfers'] - description: "View of transfers per blockchain aggregated to various levels. The goal is to output one row per chain with stats availble for use in counter visuals." - - name: metrics_transfers_index_daily - meta: - sector: metrics - contributors: jeff-dude - config: - tags: ['metrics', 'transfers', 'index', 'daily'] - description: "Each day, per chain, compare the adoption of total transfers relative to the baseline expectation" - data_tests: - - dbt_utils.unique_combination_of_columns: - combination_of_columns: - - blockchain - - block_date diff --git a/dbt_subprojects/daily_spellbook/models/_metrics/transfers/metrics_transfers_index_daily.sql b/dbt_subprojects/daily_spellbook/models/_metrics/transfers/metrics_transfers_index_daily.sql deleted file mode 100644 index f13e4e1648c..00000000000 --- a/dbt_subprojects/daily_spellbook/models/_metrics/transfers/metrics_transfers_index_daily.sql +++ /dev/null @@ -1,38 +0,0 @@ -{{ config( - schema = 'metrics' - , alias = 'transfers_index_daily' - , materialized = 'view' - ) -}} - -{% set baseline_date = '2018-01-01' %} -{% set start_date = '2015-08-21' %} - -with baseline as ( - select - sum(net_transfer_amount_usd) as baseline_net_transfer_amount_usd -- sum is required due to blockchain being second unique key in source - from - {{ ref('metrics_transfers_daily') }} - where - block_date = date '{{ baseline_date }}' -), daily as ( - select - blockchain - , block_date - , net_transfer_amount_usd - from - {{ ref('metrics_transfers_daily') }} - where - block_date >= date '{{ start_date }}' -) -select - d.blockchain - , d.block_date - , d.net_transfer_amount_usd - , b.baseline_net_transfer_amount_usd - , (d.net_transfer_amount_usd / b.baseline_net_transfer_amount_usd) * 10 as transfers_index -from - daily as d -left join - baseline as b - on 1 = 1 diff --git a/dbt_subprojects/daily_spellbook/models/_metrics/transfers/metrics_transfers_stats.sql b/dbt_subprojects/daily_spellbook/models/_metrics/transfers/metrics_transfers_stats.sql deleted file mode 100644 index dfe6afb49b5..00000000000 --- a/dbt_subprojects/daily_spellbook/models/_metrics/transfers/metrics_transfers_stats.sql +++ /dev/null @@ -1,158 +0,0 @@ -{{ config( - schema = 'metrics' - , alias = 'transfers_stats' - ) -}} - -with source as ( - -- daily aggregation of transfers per blockchain - select - blockchain - , block_date - , net_transfer_amount_usd - from - {{ ref('metrics_transfers_daily') }} -), current_day as ( - select - blockchain - , net_transfer_amount_usd as last_1_days_net_transfer_amount_usd - from - source - where - block_date >= date_trunc('day', now()) - interval '1' day - and block_date < date_trunc('day', now()) -), previous_day as ( - select - blockchain - , net_transfer_amount_usd as previous_1_days_net_transfer_amount_usd - 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 as ( - select - sum(last_1_days_net_transfer_amount_usd) AS total_cross_chain_last_1_days_net_transfer_amount_usd - from - current_day -), daily_stats as ( - select - c.blockchain - , c.last_1_days_net_transfer_amount_usd - , p.previous_1_days_net_transfer_amount_usd - , (cast(c.last_1_days_net_transfer_amount_usd as double) - coalesce(cast(p.previous_1_days_net_transfer_amount_usd as double), 0)) / coalesce(cast(p.previous_1_days_net_transfer_amount_usd as double), 1) AS daily_percent_change - , t.total_cross_chain_last_1_days_net_transfer_amount_usd - , cast(c.last_1_days_net_transfer_amount_usd as double) / cast(t.total_cross_chain_last_1_days_net_transfer_amount_usd as double) AS percent_total_last_1_days_net_transfer_amount_usd - from - current_day as c - left join previous_day as p - on c.blockchain = p.blockchain - inner join total_current_day as t - on 1 = 1 -), current_week as ( - select - blockchain - , sum(net_transfer_amount_usd) as last_7_days_net_transfer_amount_usd - 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 - , sum(net_transfer_amount_usd) as previous_7_days_net_transfer_amount_usd - 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 as ( - select - sum(last_7_days_net_transfer_amount_usd) AS total_cross_chain_last_7_days_net_transfer_amount_usd - from - current_week -), weekly_stats as ( - select - c.blockchain - , c.last_7_days_net_transfer_amount_usd - , p.previous_7_days_net_transfer_amount_usd - , (cast(c.last_7_days_net_transfer_amount_usd as double) - coalesce(cast(p.previous_7_days_net_transfer_amount_usd as double), 0)) / coalesce(cast(p.previous_7_days_net_transfer_amount_usd as double), 1) AS weekly_percent_change - , t.total_cross_chain_last_7_days_net_transfer_amount_usd - , cast(c.last_7_days_net_transfer_amount_usd as double) / cast(t.total_cross_chain_last_7_days_net_transfer_amount_usd as double) AS percent_total_last_7_days_net_transfer_amount_usd - from - current_week as c - left join previous_week as p - on c.blockchain = p.blockchain - inner join total_current_week as t - on 1 = 1 -), current_month as ( - select - blockchain - , sum(net_transfer_amount_usd) as last_30_days_net_transfer_amount_usd - 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 - , sum(net_transfer_amount_usd) as previous_30_days_net_transfer_amount_usd - 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 as ( - select - sum(last_30_days_net_transfer_amount_usd) AS total_cross_chain_last_30_days_net_transfer_amount_usd - from - current_month -), monthly_stats as ( - select - c.blockchain - , c.last_30_days_net_transfer_amount_usd - , p.previous_30_days_net_transfer_amount_usd - , (cast(c.last_30_days_net_transfer_amount_usd as double) - coalesce(cast(p.previous_30_days_net_transfer_amount_usd as double), 0)) / coalesce(cast(p.previous_30_days_net_transfer_amount_usd as double), 1) AS monthly_percent_change - , t.total_cross_chain_last_30_days_net_transfer_amount_usd - , cast(c.last_30_days_net_transfer_amount_usd as double) / cast(t.total_cross_chain_last_30_days_net_transfer_amount_usd as double) AS percent_total_last_30_days_net_transfer_amount_usd - from - current_month as c - left join previous_month as p - on c.blockchain = p.blockchain - inner join total_current_month as t - on 1 = 1 -) -select - d.blockchain - , d.last_1_days_net_transfer_amount_usd - , d.previous_1_days_net_transfer_amount_usd - , d.daily_percent_change - , d.total_cross_chain_last_1_days_net_transfer_amount_usd - , d.percent_total_last_1_days_net_transfer_amount_usd - , w.last_7_days_net_transfer_amount_usd - , w.previous_7_days_net_transfer_amount_usd - , w.weekly_percent_change - , w.total_cross_chain_last_7_days_net_transfer_amount_usd - , w.percent_total_last_7_days_net_transfer_amount_usd - , m.last_30_days_net_transfer_amount_usd - , m.previous_30_days_net_transfer_amount_usd - , m.monthly_percent_change - , m.total_cross_chain_last_30_days_net_transfer_amount_usd - , m.percent_total_last_30_days_net_transfer_amount_usd - , m.last_30_days_net_transfer_amount_usd * 12 as net_transfer_amount_usd_run_rate -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 \ No newline at end of file