diff --git a/.sqlfluff b/.sqlfluff index 9d2fd3a..668e0fe 100644 --- a/.sqlfluff +++ b/.sqlfluff @@ -4,4 +4,4 @@ dialect = trino max_line_length = 120 # Allow up to 100k bytes for file sizes large_file_skip_byte_limit = 100000 -exclude_rules=RF02,AL01 +exclude_rules=RF02,AL01,AL02,ST06 diff --git a/queries.yml b/queries.yml index 25db917..f8319db 100644 --- a/queries.yml +++ b/queries.yml @@ -50,6 +50,7 @@ query_ids: - 4611255 # Lockup: Grouped Withdrawal Data - 4611179 # Lockup: Remaining Balances - 4665542 # Lockup: Remaining Balances (Accounted for Cancelations) + - 4676715 # Lockup: Airdrop Revenues - 4611374 # Lockup: Adjusted Remaining Balances - 4611349 # Lockup: Priced Adjusted Remaining Balances - 4611402 # Lockup: Total Value Locked (TVL) @@ -64,6 +65,11 @@ query_ids: - 4666198 # Lockup: Most Used Stablecoins - 4606813 # Unified: Cumulative Stablecoin Volume - 4606999 # Unified: Median Stablecoin Deposit + - 4687435 # Unified: Withdrawal Revenues - 4600695 # Unified: Stream Creation Count - 4600977 # Unified: Unique User Count - 4646207 # Unified: Number of Created Streams (Past 24 Hours) + - 4714783 # Unified: Median Daily Revenue + - 4687721 # Unified: Total Protocol Revenues + - 4687516 # Unified: Protocol Revenues (Protocol Revenue Distribution by Category, Protocol Revenue Distribution by Chain) + - 4687748 # Unified: Daily Protocol Revenues diff --git a/queries/lockup:_airdrop_revenues___4676715.sql b/queries/lockup:_airdrop_revenues___4676715.sql new file mode 100644 index 0000000..5daa2f3 --- /dev/null +++ b/queries/lockup:_airdrop_revenues___4676715.sql @@ -0,0 +1,208 @@ +-- part of a query repo +-- query name: Lockup: Airdrop Revenues +-- query link: https://dune.com/queries/4676715 + + +SELECT + 'Ethereum' AS chain, + 'ETH' AS currency, + t1.block_time, + COALESCE(t2.value, 0) / 1e18 airdrop_fee +FROM + ethereum.logs t1 +LEFT JOIN ethereum.transactions t2 ON t1.tx_hash = t2.hash +WHERE + ( + ( + t1.topic0 = 0x28b58397e03322f670d6b223cc863f8c148e368b8b615412e6798a641a22842d + OR t1.topic0 = 0x1dcd2362ae467d43bf31cbcac0526c0958b23eb063e011ab49a5179c839ed9a9 + ) + AND t2.value > 0 + ) +UNION ALL +SELECT + 'Base' AS chain, + 'ETH' AS currency, + t1.block_time, + COALESCE(t2.value, 0) / 1e18 airdrop_fee +FROM + base.logs t1 +LEFT JOIN base.transactions t2 ON t1.tx_hash = t2.hash +WHERE + ( + ( + t1.topic0 = 0x28b58397e03322f670d6b223cc863f8c148e368b8b615412e6798a641a22842d + OR t1.topic0 = 0x1dcd2362ae467d43bf31cbcac0526c0958b23eb063e011ab49a5179c839ed9a9 + ) + AND t2.value > 0 + ) +UNION ALL +SELECT + 'Arbitrum' AS chain, + 'ETH' AS currency, + t1.block_time, + COALESCE(t2.value, 0) / 1e18 airdrop_fee +FROM + arbitrum.logs t1 +LEFT JOIN arbitrum.transactions t2 ON t1.tx_hash = t2.hash +WHERE + ( + ( + t1.topic0 = 0x28b58397e03322f670d6b223cc863f8c148e368b8b615412e6798a641a22842d + OR t1.topic0 = 0x1dcd2362ae467d43bf31cbcac0526c0958b23eb063e011ab49a5179c839ed9a9 + ) + AND t2.value > 0 + ) +UNION ALL +SELECT + 'Optimism' AS chain, + 'ETH' AS currency, + t1.block_time, + COALESCE(t2.value, 0) / 1e18 airdrop_fee +FROM + optimism.logs t1 +LEFT JOIN optimism.transactions t2 ON t1.tx_hash = t2.hash +WHERE + ( + ( + t1.topic0 = 0x28b58397e03322f670d6b223cc863f8c148e368b8b615412e6798a641a22842d + OR t1.topic0 = 0x1dcd2362ae467d43bf31cbcac0526c0958b23eb063e011ab49a5179c839ed9a9 + ) + AND t2.value > 0 + ) +UNION ALL +SELECT + 'Linea' AS chain, + 'ETH' AS currency, + t1.block_time, + COALESCE(t2.value, 0) / 1e18 airdrop_fee +FROM + linea.logs t1 +LEFT JOIN linea.transactions t2 ON t1.tx_hash = t2.hash +WHERE + ( + ( + t1.topic0 = 0x28b58397e03322f670d6b223cc863f8c148e368b8b615412e6798a641a22842d + OR t1.topic0 = 0x1dcd2362ae467d43bf31cbcac0526c0958b23eb063e011ab49a5179c839ed9a9 + ) + AND t2.value > 0 + ) +UNION ALL +SELECT + 'zkSync' AS chain, + 'ETH' AS currency, + t1.block_time, + COALESCE(t2.value, 0) / 1e18 airdrop_fee +FROM + zksync.logs t1 +LEFT JOIN zksync.transactions t2 ON t1.tx_hash = t2.hash +WHERE + ( + ( + t1.topic0 = 0x28b58397e03322f670d6b223cc863f8c148e368b8b615412e6798a641a22842d + OR t1.topic0 = 0x1dcd2362ae467d43bf31cbcac0526c0958b23eb063e011ab49a5179c839ed9a9 + ) + AND t2.value > 0 + ) +UNION ALL +SELECT + 'Scroll' AS chain, + 'ETH' AS currency, + t1.block_time, + COALESCE(t2.value, 0) / 1e18 airdrop_fee +FROM + scroll.logs t1 +LEFT JOIN scroll.transactions t2 ON t1.tx_hash = t2.hash +WHERE + ( + ( + t1.topic0 = 0x28b58397e03322f670d6b223cc863f8c148e368b8b615412e6798a641a22842d + OR t1.topic0 = 0x1dcd2362ae467d43bf31cbcac0526c0958b23eb063e011ab49a5179c839ed9a9 + ) + AND t2.value > 0 + ) +UNION ALL +SELECT + 'Abstract' AS chain, + 'ETH' AS currency, + t1.block_time, + COALESCE(t2.value, 0) / 1e18 airdrop_fee +FROM + abstract.logs t1 +LEFT JOIN abstract.transactions t2 ON t1.tx_hash = t2.hash +WHERE + ( + ( + t1.topic0 = 0x28b58397e03322f670d6b223cc863f8c148e368b8b615412e6798a641a22842d + OR t1.topic0 = 0x1dcd2362ae467d43bf31cbcac0526c0958b23eb063e011ab49a5179c839ed9a9 + ) + AND t2.value > 0 + ) +UNION ALL +SELECT + 'Avalanche' AS chain, + 'AVAX' AS currency, + t1.block_time, + COALESCE(t2.value, 0) / 1e18 airdrop_fee +FROM + avalanche_c.logs t1 +LEFT JOIN avalanche_c.transactions t2 ON t1.tx_hash = t2.hash +WHERE + ( + ( + t1.topic0 = 0x28b58397e03322f670d6b223cc863f8c148e368b8b615412e6798a641a22842d + OR t1.topic0 = 0x1dcd2362ae467d43bf31cbcac0526c0958b23eb063e011ab49a5179c839ed9a9 + ) + AND t2.value > 0 + ) +UNION ALL +SELECT + 'Polygon' AS chain, + 'POL' AS currency, + t1.block_time, + COALESCE(t2.value, 0) / 1e18 airdrop_fee +FROM + polygon.logs t1 +LEFT JOIN polygon.transactions t2 ON t1.tx_hash = t2.hash +WHERE + ( + ( + t1.topic0 = 0x28b58397e03322f670d6b223cc863f8c148e368b8b615412e6798a641a22842d + OR t1.topic0 = 0x1dcd2362ae467d43bf31cbcac0526c0958b23eb063e011ab49a5179c839ed9a9 + ) + AND t2.value > 0 + ) +UNION ALL +SELECT + 'BNB Chain' AS chain, + 'BNB' AS currency, + t1.block_time, + COALESCE(t2.value, 0) / 1e18 airdrop_fee +FROM + bnb.logs t1 +LEFT JOIN bnb.transactions t2 ON t1.tx_hash = t2.hash +WHERE + ( + ( + t1.topic0 = 0x28b58397e03322f670d6b223cc863f8c148e368b8b615412e6798a641a22842d + OR t1.topic0 = 0x1dcd2362ae467d43bf31cbcac0526c0958b23eb063e011ab49a5179c839ed9a9 + ) + AND t2.value > 0 + ) +UNION ALL +SELECT + 'Gnosis Chain' AS chain, + 'GNO' AS currency, + t1.block_time, + COALESCE(t2.value, 0) / 1e18 airdrop_fee +FROM + gnosis.logs t1 +LEFT JOIN gnosis.transactions t2 ON t1.tx_hash = t2.hash +WHERE + ( + ( + t1.topic0 = 0x28b58397e03322f670d6b223cc863f8c148e368b8b615412e6798a641a22842d + OR t1.topic0 = 0x1dcd2362ae467d43bf31cbcac0526c0958b23eb063e011ab49a5179c839ed9a9 + ) + AND t2.value > 0 + ) diff --git a/queries/lockup:_grouped_withdrawal_dat___4611255.sql b/queries/lockup:_grouped_withdrawal_dat___4611255.sql index 90d06c9..768f2e2 100644 --- a/queries/lockup:_grouped_withdrawal_dat___4611255.sql +++ b/queries/lockup:_grouped_withdrawal_dat___4611255.sql @@ -19,7 +19,6 @@ STREAMAGGREGATION AS ( CHAIN, CONTRACT_ADDRESS, RELEASE_VERSION, - CONTRACT, STREAMID, TOKEN ) diff --git a/queries/unified:_daily_protocol_revenu___4687748.sql b/queries/unified:_daily_protocol_revenu___4687748.sql new file mode 100644 index 0000000..6f64346 --- /dev/null +++ b/queries/unified:_daily_protocol_revenu___4687748.sql @@ -0,0 +1,12 @@ +-- part of a query repo +-- query name: Unified: Daily Protocol Revenues +-- query link: https://dune.com/queries/4687748 + + +SELECT + date_trunc('day', block_time) AS "day", + sum(protocol_revenues_usd) AS revenue +FROM + query_4687516 +GROUP BY + date_trunc('day', block_time) diff --git a/queries/unified:_median_daily_revenue___4714783.sql b/queries/unified:_median_daily_revenue___4714783.sql new file mode 100644 index 0000000..ed19d7c --- /dev/null +++ b/queries/unified:_median_daily_revenue___4714783.sql @@ -0,0 +1,16 @@ +-- part of a query repo +-- query name: Unified: Median Daily Revenue +-- query link: https://dune.com/queries/4714783 + + +SELECT approx_percentile(revenue, 0.5) AS median +FROM + ( + SELECT + date_trunc('day', block_time) AS "day", + sum(protocol_revenues_usd) AS revenue + FROM + query_4687516 + GROUP BY + date_trunc('day', block_time) + ) diff --git a/queries/unified:_protocol_revenues___4687516.sql b/queries/unified:_protocol_revenues___4687516.sql new file mode 100644 index 0000000..d8f596f --- /dev/null +++ b/queries/unified:_protocol_revenues___4687516.sql @@ -0,0 +1,56 @@ +-- part of a query repo +-- query name: Unified: Protocol Revenues +-- query link: https://dune.com/queries/4687516 + + +WITH price_lookup AS ( + SELECT + currency, + price + FROM ( + SELECT + CASE blockchain + WHEN 'avalanche_c' THEN 'AVAX' + WHEN 'ethereum' THEN 'ETH' + WHEN 'bnb' THEN 'BNB' + WHEN 'polygon' THEN 'POL' + WHEN 'gnosis' THEN 'XDAI' + END AS currency, + price, + ROW_NUMBER() OVER ( + PARTITION BY blockchain + ORDER BY timestamp DESC + ) AS rn + FROM prices.day + WHERE + blockchain IN ('avalanche_c', 'ethereum', 'bnb', 'polygon', 'gnosis') + AND contract_address = 0x0000000000000000000000000000000000000000 + ) sub + WHERE rn = 1 +) + +SELECT + t.category, + t.chain, + t.currency, + t.block_time, + t.protocol_revenues, + t.protocol_revenues * p.price AS protocol_revenues_usd +FROM ( + SELECT + 'Airdrops' AS category, + chain, + currency, + block_time, + airdrop_fee AS protocol_revenues + FROM query_4676715 + UNION ALL + SELECT + 'Withdrawals' AS category, + chain, + currency, + block_time, + withdrawal_fee AS protocol_revenues + FROM query_4687435 +) t +LEFT JOIN price_lookup p ON t.currency = p.currency; diff --git a/queries/unified:_total_protocol_revenu___4687721.sql b/queries/unified:_total_protocol_revenu___4687721.sql new file mode 100644 index 0000000..216b93c --- /dev/null +++ b/queries/unified:_total_protocol_revenu___4687721.sql @@ -0,0 +1,6 @@ +-- part of a query repo +-- query name: Unified: Total Protocol Revenues +-- query link: https://dune.com/queries/4687721 + + +SELECT SUM(protocol_revenues_usd) FROM query_4687516 diff --git a/queries/unified:_withdrawal_revenues___4687435.sql b/queries/unified:_withdrawal_revenues___4687435.sql new file mode 100644 index 0000000..3189b12 --- /dev/null +++ b/queries/unified:_withdrawal_revenues___4687435.sql @@ -0,0 +1,186 @@ +-- part of a query repo +-- query name: Unified: Withdrawal Revenues +-- query link: https://dune.com/queries/4687435 + + +SELECT + 'Ethereum' AS chain, + 'ETH' AS currency, + block_time, + "value" / 1e18 AS withdrawal_fee +FROM + ethereum.traces +WHERE + ( + "from" = 0x7c01aa3783577e15fd7e272443d44b92d5b21056 -- Lockup v2.0 + OR "from" = 0x3df2aaede81d2f6b261f79047517713b8e844e04 -- Flow v1.1 + ) + AND "value" > 0 +UNION ALL +SELECT + 'Abstract' AS chain, + 'ETH' AS currency, + block_time, + "value" / 1e18 AS withdrawal_fee +FROM + abstract.traces +WHERE + ( + "from" = 0x14eb4ab47b2ec2a71763eaba202a252e176fae88 -- Lockup v2.0 + OR "from" = 0x555b0766f494c641bb522086da4e728ac08c1420 -- Flow v1.1 + ) + AND "value" > 0 +UNION ALL +SELECT + 'Arbitrum' AS chain, + 'ETH' AS currency, + block_time, + "value" / 1e18 AS withdrawal_fee +FROM + arbitrum.traces +WHERE + ( + "from" = 0x467d5bf8cfa1a5f99328fbdcb9c751c78934b725 -- Lockup v2.0 + OR "from" = 0x87cf87ec5de33deb4a88787065373563ba85ee72 -- Flow v1.1 + ) + AND "value" > 0 +UNION ALL +SELECT + 'Avalanche' AS chain, + 'AVAX' AS currency, + block_time, + "value" / 1e18 AS withdrawal_fee +FROM + avalanche_c.traces +WHERE + ( + "from" = 0x3c81bbbe72ef8ef3fb1d19b0bd6310ad0dd27e82 -- Lockup v2.0 + OR "from" = 0xac7cb985d4022a5ebd4a385374ac3d3b487b3c63 -- Flow v1.1 + ) + AND "value" > 0 +UNION ALL +SELECT + 'Base' AS chain, + 'ETH' AS currency, + block_time, + "value" / 1e18 AS withdrawal_fee +FROM + base.traces +WHERE + ( + "from" = 0xb5d78dd3276325f5faf3106cc4acc56e28e0fe3b -- Lockup v2.0 + OR "from" = 0x6fe93c7f6cd1dc394e71591e3c42715be7180a6a -- Flow v1.1 + ) + AND "value" > 0 +UNION ALL +SELECT + 'Blast' AS chain, + 'ETH' AS currency, + block_time, + "value" / 1e18 AS withdrawal_fee +FROM + blast.traces +WHERE + ( + "from" = 0xdbb6e9653d7e41766712db22eb08ed3f21009fdd -- Lockup v2.0 + OR "from" = 0x16b50eb5eaef0366f1a4da594e2a8c8943a297e0 -- Flow v1.1 + ) + AND "value" > 0 +UNION ALL +SELECT + 'BNB Chain' AS chain, + 'BNB' AS currency, + block_time, + "value" / 1e18 AS withdrawal_fee +FROM + bnb.traces +WHERE + ( + "from" = 0x6e0bad2c077d699841f1929b45bfb93fafbed395 -- Lockup v2.0 + OR "from" = 0x4c4610af3f3861ec99b6f6f8066c03e4c3a0e023 -- Flow v1.1 + ) + AND "value" > 0 +UNION ALL +SELECT + 'Gnosis Chain' AS chain, + 'xDAI' AS currency, + block_time, + "value" / 1e18 AS withdrawal_fee +FROM + gnosis.traces +WHERE + ( + "from" = 0x007af5dc7b1caa66cf7ebcc01e2e6ba4d55d3e92 -- Lockup v2.0 + OR "from" = 0x34bc0c2bf1f2da51c65cd821ba4133afcacdb8f5 -- Flow v1.1 + ) + AND "value" > 0 +UNION ALL +SELECT + 'Linea' AS chain, + 'ETH' AS currency, + block_time, + "value" / 1e18 AS withdrawal_fee +FROM + linea.traces +WHERE + ( + "from" = 0x6964252561e8762dd10267176eac5078b6291e51 -- Lockup v2.0 + OR "from" = 0xefc6e4c7dc5faa0cfbfebb5e04ea7cd47f64012f -- Flow v1.1 + ) + AND "value" > 0 +UNION ALL +SELECT + 'Optimism' AS chain, + 'ETH' AS currency, + block_time, + "value" / 1e18 AS withdrawal_fee +FROM + optimism.traces +WHERE + ( + "from" = 0x822e9c4852e978104d82f0f785bfa663c2b700c1 -- Lockup v2.0 + OR "from" = 0xc5612fea2d370127ac67048115bd6b1df7b7f7c0 -- Flow v1.1 + ) + AND "value" > 0 +UNION ALL +SELECT + 'Polygon' AS chain, + 'POL' AS currency, + block_time, + "value" / 1e18 AS withdrawal_fee +FROM + polygon.traces +WHERE + ( + "from" = 0xe0bfe071da104e571298f8b6e0fce44c512c1ff4 -- Lockup v2.0 + OR "from" = 0x3e5c4130ea7cfbd364fa5f170289d697865ca94b -- Flow v1.1 + ) + AND "value" > 0 +UNION ALL +SELECT + 'Scroll' AS chain, + 'ETH' AS currency, + block_time, + "value" / 1e18 AS withdrawal_fee +FROM + scroll.traces +WHERE + ( + "from" = 0xcb0b1f1d116ed62135848d8c90eb61afda936da8 -- Lockup v2.0 + OR "from" = 0xc4f104ce12cb12484ff67cf0c4bd0561f0014ec2 -- Flow v1.1 + ) + AND "value" > 0 +UNION ALL +SELECT + 'zkSync' AS chain, + 'ETH' AS currency, + block_time, + "value" / 1e18 AS withdrawal_fee +FROM + zksync.traces +WHERE + ( + "from" = 0x7bccb3595aa81dbe8a69dd8c46f5c2a3cf76594a -- Lockup v2.0 + OR "from" = 0xe3747379bf7282e0ab5389a63ea053a5256042df -- Flow v1.1 + ) + AND "value" > 0