-
Notifications
You must be signed in to change notification settings - Fork 1.2k
New issue
Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.
By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.
Already on GitHub? Sign in to your account
Add queries for TON Dune Index metrics #7621
base: main
Are you sure you want to change the base?
Changes from all commits
File filter
Filter by extension
Conversations
Jump to
Diff view
Diff view
There are no files selected for viewing
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,15 @@ | ||
version: 2 | ||
|
||
models: | ||
- name: metrics_ton_gas_fees_daily | ||
meta: | ||
sector: metrics | ||
contributors: shuva10v | ||
config: | ||
tags: ['metrics', 'fees', 'gas', 'daily', 'ton'] | ||
description: "Sum of total fees spent per day" | ||
data_tests: | ||
- dbt_utils.unique_combination_of_columns: | ||
combination_of_columns: | ||
- blockchain | ||
- block_date |
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,59 @@ | ||
{{ config( | ||
schema = 'metrics_ton' | ||
, alias = 'gas_fees_daily' | ||
, materialized = 'incremental' | ||
, file_format = 'delta' | ||
, incremental_strategy = 'merge' | ||
, unique_key = ['blockchain', 'block_date'] | ||
, incremental_predicates = [incremental_predicate('DBT_INTERNAL_DEST.block_date')] | ||
) | ||
}} | ||
|
||
with ton_prices as ( -- get price of TON for each day to estimate USD value | ||
select | ||
date_trunc('day', minute) as block_date | ||
, avg(price) as price | ||
from {{ source('prices', 'usd') }} | ||
where true | ||
and symbol = 'TON' | ||
group by 1 | ||
), fees as ( | ||
-- Low-level fees overview - https://docs.ton.org/v3/documentation/smart-contracts/transaction-fees/fees-low-level | ||
-- fees paid inside transactions - storage fee, gas fee, compute fee, action fee | ||
select block_date, sum( | ||
coalesce(t.total_fees * 1e-9, 0.0) * p.price | ||
) as fees | ||
from | ||
{{ source('ton', 'transactions') }} t | ||
join ton_prices p using(block_date) | ||
where | ||
1 = 1 | ||
{% if is_incremental() %} | ||
and | ||
{{ incremental_predicate('block_date') }} | ||
{% endif %} | ||
group by | ||
1 | ||
|
||
union all | ||
|
||
-- fee paid for sending messages | ||
select block_date, sum( | ||
coalesce(m.fwd_fee * 1e-9, 0.0) * p.price | ||
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. Instead do |
||
) as fees | ||
from | ||
{{ source('ton', 'messages') }} m | ||
join ton_prices p using(block_date) | ||
where | ||
1 = 1 | ||
{% if is_incremental() %} | ||
and | ||
{{ incremental_predicate('block_date') }} | ||
{% endif %} | ||
group by | ||
1 | ||
) | ||
select 'ton' as blockchain, block_date, sum(fees) as gas_fees_usd | ||
from fees | ||
group by 1, 2 | ||
|
Original file line number | Diff line number | Diff line change |
---|---|---|
|
@@ -24,6 +24,7 @@ | |
, 'scroll' | ||
, 'sei' | ||
, 'solana' | ||
, 'ton' | ||
, 'tron' | ||
, 'zkevm' | ||
, 'zksync' | ||
|
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,15 @@ | ||
version: 2 | ||
|
||
models: | ||
- name: metrics_ton_transactions_daily | ||
meta: | ||
sector: metrics | ||
contributors: shuva10v | ||
config: | ||
tags: ['metrics', 'transactions', 'daily', 'ton'] | ||
description: "Sum of total tx's per day" | ||
data_tests: | ||
- dbt_utils.unique_combination_of_columns: | ||
combination_of_columns: | ||
- blockchain | ||
- block_date |
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,66 @@ | ||
{{ config( | ||
schema = 'metrics_ton' | ||
, alias = 'transactions_daily' | ||
, materialized = 'incremental' | ||
, file_format = 'delta' | ||
, incremental_strategy = 'merge' | ||
, unique_key = ['blockchain', 'block_date'] | ||
, incremental_predicates = [incremental_predicate('DBT_INTERNAL_DEST.block_date')] | ||
) | ||
}} | ||
|
||
with ton_prices as ( -- get price of TON for each day to estimate USD value | ||
select | ||
date_trunc('day', minute) as price_day | ||
, avg(price) as price | ||
from {{ source('prices', 'usd') }} | ||
where true | ||
and symbol = 'TON' | ||
group by 1 | ||
), jetton_prices as ( | ||
-- jetton prices based on onchain data, see https://github.com/ton-studio/dune-queries?tab=readme-ov-file#duneton_foundationresult_jetton_price_daily | ||
select jp.token_address as jetton_master, ts as block_date, avg(price_usd) as price_usd | ||
from dune.ton_foundation.result_jetton_price_daily jp | ||
group by 1, 2 | ||
), | ||
significant_transactions as ( | ||
-- TON transfers | ||
select | ||
M.block_date | ||
, M.tx_hash | ||
from | ||
{{ source('ton', 'messages') }} M | ||
join {{ source('ton', 'transactions') }} T | ||
on M.tx_hash = T.hash and M.direction = 'in' and M.block_date = T.block_date | ||
join ton_prices | ||
on M.block_date = ton_prices.price_day | ||
where | ||
1 = 1 | ||
and value / 1e9 * ton_prices.price > 1 -- 1$ filter | ||
{% if is_incremental() %} | ||
and {{ incremental_predicate('M.block_date') }} | ||
and {{ incremental_predicate('T.block_date') }} | ||
{% endif %} | ||
|
||
union all | ||
-- Jetton transfers | ||
|
||
select | ||
block_date | ||
, J.tx_hash | ||
from | ||
{{ source('ton', 'jetton_events') }} J | ||
join jetton_prices | ||
using (block_date, jetton_master) | ||
where | ||
1 = 1 | ||
and amount * jetton_prices.price_usd > 1 -- 1$ filter | ||
{% if is_incremental() %} | ||
and {{ incremental_predicate('block_date') }} | ||
{% endif %} | ||
) | ||
select 'ton' as blockchain | ||
, block_date | ||
, approx_distinct(tx_hash) as tx_count | ||
from significant_transactions | ||
group by 1, 2 |
Original file line number | Diff line number | Diff line change |
---|---|---|
|
@@ -24,6 +24,7 @@ | |
, 'scroll' | ||
, 'sei' | ||
, 'solana' | ||
, 'ton' | ||
, 'tron' | ||
, 'zkevm' | ||
, 'zksync' | ||
|
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,105 @@ | ||
{{ config( | ||
schema = 'metrics_ton' | ||
, alias = 'transfers_daily' | ||
, materialized = 'incremental' | ||
, file_format = 'delta' | ||
, incremental_strategy = 'merge' | ||
, unique_key = ['blockchain', 'block_date'] | ||
, incremental_predicates = [incremental_predicate('DBT_INTERNAL_DEST.block_date')] | ||
) | ||
}} | ||
|
||
|
||
with ton_prices as ( -- get price of TON for each day to estimate USD value | ||
select | ||
date_trunc('day', minute) as block_date | ||
, avg(price) as price | ||
from {{ source('prices', 'usd') }} | ||
where true | ||
and symbol = 'TON' | ||
group by 1 | ||
), jetton_prices as ( | ||
-- jetton prices based on onchain data, see https://github.com/ton-studio/dune-queries?tab=readme-ov-file#duneton_foundationresult_jetton_price_daily | ||
select jp.token_address as jetton_master, ts as block_date, avg(price_usd) as price_usd | ||
from dune.ton_foundation.result_jetton_price_daily jp | ||
group by 1, 2 | ||
), | ||
ton_flow as ( | ||
select block_date, source as address, -1 * value as ton_flow | ||
from | ||
{{ source('ton', 'messages') }} | ||
where | ||
direction = 'in' | ||
{% if is_incremental() %} | ||
and {{ incremental_predicate('block_date') }} | ||
{% endif %} | ||
|
||
union all | ||
|
||
select block_date, destination as address, value as ton_flow | ||
from | ||
{{ source('ton', 'messages') }} | ||
where | ||
direction = 'in' | ||
{% if is_incremental() %} | ||
and {{ incremental_predicate('block_date') }} | ||
{% endif %} | ||
), transfers_amount_ton as ( | ||
select block_date, address, | ||
sum(case when ton_flow > 0 then ton_flow * price else 0 end) / 1e9 as transfer_amount_usd_received, | ||
sum(case when ton_flow < 0 then ton_flow * price else 0 end) / 1e9 as transfer_amount_usd_sent | ||
from ton_flow | ||
join ton_prices using(block_date) | ||
group by 1, 2 | ||
), | ||
jettons_flow as ( | ||
select block_date, jetton_master, source as address, -1 * amount as jetton_flow | ||
from | ||
{{ source('ton', 'jetton_events') }} | ||
where | ||
type = 'transfer' | ||
and jetton_master != upper('0:8cdc1d7640ad5ee326527fc1ad0514f468b30dc84b0173f0e155f451b4e11f7c') -- pTON | ||
and jetton_master != upper('0:671963027f7f85659ab55b821671688601cdcf1ee674fc7fbbb1a776a18d34a3') -- pTON | ||
and not tx_aborted | ||
{% if is_incremental() %} | ||
and {{ incremental_predicate('block_date') }} | ||
{% endif %} | ||
|
||
union all | ||
|
||
select block_date, jetton_master, destination as address, amount as jetton_flow | ||
from | ||
{{ source('ton', 'jetton_events') }} | ||
where | ||
type = 'transfer' | ||
and jetton_master != upper('0:8cdc1d7640ad5ee326527fc1ad0514f468b30dc84b0173f0e155f451b4e11f7c') -- pTON | ||
and jetton_master != upper('0:671963027f7f85659ab55b821671688601cdcf1ee674fc7fbbb1a776a18d34a3') -- pTON | ||
and not tx_aborted | ||
{% if is_incremental() %} | ||
and {{ incremental_predicate('block_date') }} | ||
{% endif %} | ||
), transfers_amount_jetton as ( | ||
select block_date, address, | ||
sum(case when jetton_flow > 0 then jetton_flow * price_usd else 0 end) as transfer_amount_usd_received, | ||
sum(case when jetton_flow < 0 then jetton_flow * price_usd else 0 end) as transfer_amount_usd_sent | ||
from jettons_flow | ||
join jetton_prices using(jetton_master, block_date) | ||
group by 1, 2 | ||
), transfers_amount as ( | ||
select * from transfers_amount_jetton | ||
union all | ||
select * from transfers_amount_ton | ||
), net_transfers as ( | ||
select block_date, address, | ||
sum(coalesce(transfer_amount_usd_received, 0)) as transfer_amount_usd_received, | ||
sum(coalesce(transfer_amount_usd_sent, 0)) as transfer_amount_usd_sent, | ||
sum(coalesce(transfer_amount_usd_sent, 0)) + sum(coalesce(transfer_amount_usd_received, 0)) as net_transfer_amount_usd | ||
from transfers_amount group by 1, 2 | ||
) | ||
select 'ton' as blockchain | ||
, block_date | ||
, sum(transfer_amount_usd_sent) as transfer_amount_usd_sent | ||
, sum(transfer_amount_usd_received) as transfer_amount_usd_received | ||
, sum(abs(transfer_amount_usd_sent)) + sum(abs(transfer_amount_usd_received)) as transfer_amount_usd | ||
, sum(net_transfer_amount_usd) as net_transfer_amount_usd | ||
from net_transfers group by 1, 2 |
Original file line number | Diff line number | Diff line change |
---|---|---|
|
@@ -24,6 +24,7 @@ | |
, 'scroll' | ||
, 'sei' | ||
, 'solana' | ||
, 'ton' | ||
, 'tron' | ||
, 'zkevm' | ||
, 'zksync' | ||
|
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
Add
and blockchain IS NOT NULL
to filter for only TON prices, the TON symbol on ethereum is Tokamak Network Token (TON) for which the prices are different