Skip to content

Commit ba65246

Browse files
author
sam
committed
feat(sushiswap): sushiswap analytics package
1 parent ed28437 commit ba65246

17 files changed

+491
-55
lines changed

CHANGELOG.md

Lines changed: 0 additions & 51 deletions
This file was deleted.

VERSION

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -1 +1 @@
1-
2021-02-10
1+
2021-02-22

dune/index.json

Lines changed: 30 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -332,6 +332,7 @@
332332
{ "type": "file", "name": "yVault_yaLINK_Cumulative.sql" }
333333
]
334334
},
335+
{ "type": "file", "name": "directory.json" },
335336
{
336337
"type": "directory",
337338
"name": "gas",
@@ -513,6 +514,11 @@
513514
"name": "makermcd",
514515
"contents": [{ "type": "file", "name": "collateral_addresses.sql" }]
515516
},
517+
{
518+
"type": "directory",
519+
"name": "mev",
520+
"contents": [{ "type": "file", "name": "zero_gwei.sql" }]
521+
},
516522
{
517523
"type": "directory",
518524
"name": "oneinch",
@@ -573,7 +579,11 @@
573579
{
574580
"type": "directory",
575581
"name": "yearn",
576-
"contents": [{ "type": "file", "name": "view_ytokens.sql" }]
582+
"contents": [
583+
{ "type": "file", "name": "view_ytokens.sql" },
584+
{ "type": "file", "name": "ycrv_deposit.sql" },
585+
{ "type": "file", "name": "yvault_ycrv_cul.sql" }
586+
]
577587
},
578588
{
579589
"type": "directory",
@@ -590,8 +600,26 @@
590600
]
591601
}
592602
]
603+
},
604+
{
605+
"type": "directory",
606+
"name": "sushiswap",
607+
"contents": [
608+
{ "type": "file", "name": "7d_protocol_fees.sql" },
609+
{ "type": "file", "name": "GMV_sushiswap.sql" },
610+
{ "type": "file", "name": "LP_timeline_growth.sql" },
611+
{ "type": "file", "name": "LP_timeline_ratio.sql" },
612+
{ "type": "file", "name": "compare_sushi_uniswap_pools.sql" },
613+
{ "type": "file", "name": "culmulative_volume_sushiswap.sql" },
614+
{ "type": "file", "name": "daily_Unique_Sushi_transactions.sql" },
615+
{ "type": "file", "name": "daily_unique_claims.sql" },
616+
{ "type": "file", "name": "deposits_sushipool_counts.sql" },
617+
{ "type": "file", "name": "top500_Sushi_hodlers.sql" },
618+
{ "type": "file", "name": "top_masterChef_LPs.sql" },
619+
{ "type": "file", "name": "unique_7d_traders.sql" }
620+
]
593621
}
594622
]
595623
},
596-
{ "type": "report", "directories": 67, "files": 232 }
624+
{ "type": "report", "directories": 69, "files": 248 }
597625
]

dune/sushiswap/7d_protocol_fees.sql

Lines changed: 43 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,43 @@
1+
WITH prices AS (
2+
SELECT *
3+
FROM prices.usd
4+
where minute > now() - interval '6 months'
5+
),
6+
7+
users AS (
8+
SELECT block_time, a.trader_a AS trader
9+
FROM dex.trades a
10+
WHERE block_time > now() - interval '6 months'
11+
and project = 'Sushiswap'
12+
UNION
13+
SELECT block_time, a.trader_b AS trader
14+
FROM dex.trades a
15+
WHERE block_time > now() - interval '6 months'
16+
and project = 'Sushiswap'
17+
)
18+
19+
SELECT date_trunc('week', t.block_time) as week,
20+
COUNT(DISTINCT u.trader) AS unique_traders,
21+
(SUM(COALESCE(
22+
usd_amount,
23+
token_a_amount * a.price,
24+
token_b_amount * b.price
25+
))) as usd_volume,
26+
SUM(COALESCE(
27+
usd_amount,
28+
token_a_amount * a.price,
29+
token_b_amount * b.price
30+
)*0.0025) as usd_protocol_fees,
31+
SUM(COALESCE(
32+
usd_amount,
33+
token_a_amount * a.price,
34+
token_b_amount * b.price
35+
)*0.0005) as usd_tokenholder_fees
36+
FROM dex."trades" t
37+
LEFT JOIN prices a ON date_trunc('minute', block_time) = a.minute AND token_a_address = a.contract_address
38+
LEFT JOIN prices b ON date_trunc('minute', block_time) = b.minute AND token_b_address = b.contract_address
39+
LEFT JOIN users u ON t.block_time = u.block_time
40+
WHERE t.block_time > now() - interval '6 months'
41+
and t.project = 'Sushiswap'
42+
GROUP BY 1
43+
ORDER BY 1 DESC;

dune/sushiswap/GMV_sushiswap.sql

Lines changed: 29 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,29 @@
1+
WITH recet120 AS
2+
(SELECT date_trunc('day', block_time) as date,
3+
sum(usd_amount) AS daily_usd_amount
4+
FROM dex."trades" t
5+
WHERE project = 'Sushiswap'
6+
AND date_trunc('day', block_time) > now() - interval '240 days'
7+
GROUP BY 1
8+
ORDER BY 1 DESC),
9+
10+
F0_30 AS
11+
(SELECT daily_usd_amount,date
12+
FROM recet120
13+
LIMIT 30),
14+
15+
F90_120 AS
16+
(SELECT daily_usd_amount,date
17+
FROM recet120
18+
LIMIT 30 OFFSET 90),
19+
20+
-- SELECT sum(a.daily_usd_amount) as recent0_30
21+
-- FROM F0_30 a, F90_120 b
22+
23+
a as (SELECT sum(daily_usd_amount) as total_usd_amount from F0_30),
24+
b as (SELECT sum(daily_usd_amount) as total_usd_amount from F90_120)
25+
26+
select a.total_usd_amount as total_usd_volume_0_30,
27+
b.total_usd_amount as total_usd_volume_90_120,
28+
POWER(a.total_usd_amount/b.total_usd_amount , 4) -1 as annualized_growth_rate
29+
from a a,b b

dune/sushiswap/LP_timeline_growth.sql

Lines changed: 50 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,50 @@
1+
/*
2+
SELECT d.pid, d.sum as deposit, w.sum as withdraw, d.sum - w.sum as liquidity FROM
3+
( select pid, 0 as "type", sum(amount) / 1e18 as sum , count(*) as count from sushi."MasterChef_evt_Deposit" group by pid order by pid) as d
4+
LEFT JOIN
5+
(select pid, 1 as "type", sum(amount) / 1e18 as sum, count(*) as count from sushi."MasterChef_evt_Withdraw" group by pid order by pid) as w
6+
ON d.pid = w.pid
7+
8+
*/
9+
DROP TABLE IF EXISTS lp_names;
10+
11+
CREATE TEMP TABLE lp_names(
12+
pid INT,
13+
name char(20),
14+
pair1 char(10),
15+
pair2 char(10)
16+
);
17+
INSERT INTO lp_names(pid, name) values(0, '0:WETH/USDT');
18+
INSERT INTO lp_names(pid, name) values(1, '1:ETH/USDC');
19+
INSERT INTO lp_names(pid, name) values(2, '2:DAI/WETH');
20+
INSERT INTO lp_names(pid, name) values(3, '3:Synth/WETH');
21+
INSERT INTO lp_names(pid, name) values(4, '4:COMP/WETH');
22+
INSERT INTO lp_names(pid, name) values(5, '5:LEND/WETH');
23+
INSERT INTO lp_names(pid, name) values(6, '6:Synthetix/WETH');
24+
INSERT INTO lp_names(pid, name) values(7, '7:UMA/WETH');
25+
INSERT INTO lp_names(pid, name) values(8, '8:LINK/WETH');
26+
INSERT INTO lp_names(pid, name) values(9, '9:BAND/WETH');
27+
INSERT INTO lp_names(pid, name) values(10, '10:WETH/AMPL');
28+
INSERT INTO lp_names(pid, name) values(11, '11:FYI/WETH');
29+
INSERT INTO lp_names(pid, name) values(12, '12:SUSHI/WETH');
30+
INSERT INTO lp_names(pid, name) values(13, '13:REN/WETH');
31+
INSERT INTO lp_names(pid, name) values(14, '14:Synth/$BASED');
32+
INSERT INTO lp_names(pid, name) values(15, '15:SERUM/WETH');
33+
INSERT INTO lp_names(pid, name) values(16, '16:YAM2/WETH');
34+
INSERT INTO lp_names(pid, name) values(17, '17:WETH/CRV');
35+
36+
WITH data AS(
37+
SELECT day, name, s.pid, deposit, withdraw, liquidity, count FROM (
38+
SELECT d.day, d.pid, d.sum as deposit, w.sum as withdraw, d.sum - w.sum as liquidity, w.count FROM
39+
( SELECT date_trunc('day', evt_block_time) as day, pid, sum(amount) / 1e18 as sum , count(*) as count from sushi."MasterChef_evt_Deposit" GROUP BY 1, 2) as d
40+
LEFT JOIN
41+
( SELECT date_trunc('day', evt_block_time) as day, pid, sum(amount) / 1e18 as sum , count(*) as count from sushi."MasterChef_evt_Withdraw" GROUP BY 1, 2) as w
42+
ON d.pid = w.pid AND d.day = w.day
43+
) as s
44+
INNER JOIN lp_names as l ON l.pid = s.pid
45+
)
46+
47+
SELECT
48+
day, name,
49+
sum(liquidity) over (partition by name order by day asc rows between unbounded preceding and current row) as liquidity
50+
FROM data WHERE day <= current_date - interval '1 day';

dune/sushiswap/LP_timeline_ratio.sql

Lines changed: 50 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,50 @@
1+
/*
2+
SELECT d.pid, d.sum as deposit, w.sum as withdraw, d.sum - w.sum as liquidity FROM
3+
( select pid, 0 as "type", sum(amount) / 1e18 as sum , count(*) as count from sushi."MasterChef_evt_Deposit" group by pid order by pid) as d
4+
LEFT JOIN
5+
(select pid, 1 as "type", sum(amount) / 1e18 as sum, count(*) as count from sushi."MasterChef_evt_Withdraw" group by pid order by pid) as w
6+
ON d.pid = w.pid
7+
8+
*/
9+
DROP TABLE IF EXISTS lp_names;
10+
11+
CREATE TEMP TABLE lp_names(
12+
pid INT,
13+
name char(20),
14+
pair1 char(10),
15+
pair2 char(10)
16+
);
17+
INSERT INTO lp_names(pid, name) values(0, '0:WETH/USDT');
18+
INSERT INTO lp_names(pid, name) values(1, '1:ETH/USDC');
19+
INSERT INTO lp_names(pid, name) values(2, '2:DAI/WETH');
20+
INSERT INTO lp_names(pid, name) values(3, '3:Synth/WETH');
21+
INSERT INTO lp_names(pid, name) values(4, '4:COMP/WETH');
22+
INSERT INTO lp_names(pid, name) values(5, '5:LEND/WETH');
23+
INSERT INTO lp_names(pid, name) values(6, '6:Synthetix/WETH');
24+
INSERT INTO lp_names(pid, name) values(7, '7:UMA/WETH');
25+
INSERT INTO lp_names(pid, name) values(8, '8:LINK/WETH');
26+
INSERT INTO lp_names(pid, name) values(9, '9:BAND/WETH');
27+
INSERT INTO lp_names(pid, name) values(10, '10:WETH/AMPL');
28+
INSERT INTO lp_names(pid, name) values(11, '11:FYI/WETH');
29+
INSERT INTO lp_names(pid, name) values(12, '12:SUSHI/WETH');
30+
INSERT INTO lp_names(pid, name) values(13, '13:REN/WETH');
31+
INSERT INTO lp_names(pid, name) values(14, '14:Synth/$BASED');
32+
INSERT INTO lp_names(pid, name) values(15, '15:SERUM/WETH');
33+
INSERT INTO lp_names(pid, name) values(16, '16:YAM2/WETH');
34+
INSERT INTO lp_names(pid, name) values(17, '17:WETH/CRV');
35+
36+
WITH data AS(
37+
SELECT day, name, s.pid, deposit, withdraw, liquidity, count FROM (
38+
SELECT d.day, d.pid, d.sum as deposit, w.sum as withdraw, d.sum - w.sum as liquidity, w.count FROM
39+
( SELECT date_trunc('day', evt_block_time) as day, pid, sum(amount) / 1e18 as sum , count(*) as count from sushi."MasterChef_evt_Deposit" GROUP BY 1, 2) as d
40+
LEFT JOIN
41+
( SELECT date_trunc('day', evt_block_time) as day, pid, sum(amount) / 1e18 as sum , count(*) as count from sushi."MasterChef_evt_Withdraw" GROUP BY 1, 2) as w
42+
ON d.pid = w.pid AND d.day = w.day
43+
) as s
44+
INNER JOIN lp_names as l ON l.pid = s.pid
45+
)
46+
47+
SELECT
48+
day, name,
49+
sum(liquidity) over (partition by name order by day asc rows between unbounded preceding and current row) as liquidity
50+
FROM data WHERE day <= current_date - interval '1 day';
Lines changed: 47 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,47 @@
1+
-- Pair, Uni, decimals, Sushi
2+
-- ETH/WBTC 0xbb2b8038a1640196fbe3e38816f3e67cba72d940 - 8 - 0xceff51756c56ceffca006cd410b03ffc46dd3a58
3+
-- ETH/USDT 0x0d4a11d5eeaac28ec3f61d100daf4d40471f1852 - 6 - 0x06da0fd433c1a5d7a4faa01111c044910a184553
4+
-- ETH/DAI 0xa478c2975ab1ea89e8196811f51a7b7ade33eb11 - 18 - 0xc3d03e4f041fd4cd388c549ee2a29a9e5075882f
5+
-- ETH/USDC 0xb4e16d0168e52d35cacd2c6185b44281ec28c9dc - 6 - 0x397ff1542f962076d0bfe58ea045ffa2d347aca0
6+
WITH prices AS (
7+
SELECT date_trunc('hour', minute) as hour,
8+
AVG(price) as price
9+
FROM prices.layer1_usd
10+
WHERE symbol = 'ETH'
11+
GROUP BY 1
12+
)
13+
14+
select
15+
*, eth * 2 * a.price / 1e17 as val
16+
from (
17+
select
18+
avg(CASE
19+
WHEN contract_address in (
20+
'\x0d4a11d5eeaac28ec3f61d100daf4d40471f1852', '\x06da0fd433c1a5d7a4faa01111c044910a184553'
21+
) THEN reserve0
22+
ELSE reserve1
23+
END) / 1e1 as eth,
24+
date_trunc('hour', evt_block_time) as h,
25+
CASE
26+
WHEN contract_address = '\xbb2b8038a1640196fbe3e38816f3e67cba72d940' THEN 'eth-wbtc'
27+
WHEN contract_address = '\x0d4a11d5eeaac28ec3f61d100daf4d40471f1852' THEN 'eth-usdt'
28+
WHEN contract_address = '\xa478c2975ab1ea89e8196811f51a7b7ade33eb11' THEN 'eth-dai'
29+
WHEN contract_address = '\xb4e16d0168e52d35cacd2c6185b44281ec28c9dc' THEN 'eth-usdc'
30+
--Sushi Swap Contracts
31+
when contract_address = '\xceff51756c56ceffca006cd410b03ffc46dd3a58' THEN 'eth-wbtc'
32+
when contract_address = '\x06da0fd433c1a5d7a4faa01111c044910a184553' THEN 'eth-usdt'
33+
when contract_address = '\xc3d03e4f041fd4cd388c549ee2a29a9e5075882f' THEN 'eth-dai'
34+
when contract_address = '\x397ff1542f962076d0bfe58ea045ffa2d347aca0' THEN 'eth-usdc'
35+
END as pool,
36+
protocol
37+
from (
38+
select *, 'uni' as protocol from uniswap_v2."Pair_evt_Sync"
39+
union
40+
select *, 'sushi' as protocol from sushi."Pair_evt_Sync"
41+
) y
42+
where contract_address in ('\xbb2b8038a1640196fbe3e38816f3e67cba72d940','\x0d4a11d5eeaac28ec3f61d100daf4d40471f1852','\xa478c2975ab1ea89e8196811f51a7b7ade33eb11','\xb4e16d0168e52d35cacd2c6185b44281ec28c9dc','\xceff51756c56ceffca006cd410b03ffc46dd3a58','\x06da0fd433c1a5d7a4faa01111c044910a184553','\xc3d03e4f041fd4cd388c549ee2a29a9e5075882f','\x397ff1542f962076d0bfe58ea045ffa2d347aca0')
43+
group by contract_address, h, protocol
44+
) x
45+
JOIN prices a
46+
ON x.h = a.hour
47+
where pool = {{ pools }}
Lines changed: 33 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,33 @@
1+
WITH prices AS (
2+
SELECT MINUTE,
3+
contract_address,
4+
price
5+
FROM prices.usd
6+
where date_trunc('day', MINUTE) > now() - interval '120 days'
7+
and date_trunc('day', MINUTE) < date_trunc('day', now())
8+
)
9+
SELECT day,
10+
SUM(usd_volume) OVER (ORDER BY DAY) as cumulative_usd_volume
11+
FROM (
12+
SELECT date_trunc('day', block_time) AS DAY,
13+
SUM(CASE
14+
WHEN token_a_address = a.contract_address
15+
THEN token_a_amount * a.price -- Use token A when there's USD price for it
16+
17+
ELSE token_b_amount * b.price -- Else use token b
18+
19+
END) AS usd_volume
20+
FROM (
21+
SELECT *
22+
FROM dex."trades" t
23+
WHERE project = 'Sushiswap'
24+
and date_trunc('day', block_time) > now() - interval '120 days'
25+
and date_trunc('day', block_time) < date_trunc('day', now())
26+
) AS trades
27+
LEFT JOIN prices a ON date_trunc('minute', block_time) = a.minute
28+
AND token_a_address = a.contract_address -- Joining with prices on time and token address for token A
29+
LEFT JOIN prices b ON date_trunc('minute', block_time) = b.minute
30+
AND token_b_address = b.contract_address -- Joining with prices on time and token address for token B
31+
GROUP BY DAY
32+
) AS days
33+
;
Lines changed: 22 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,22 @@
1+
select
2+
count(DISTINCT(address)) as number_current_holders,
3+
t.day
4+
-- sushi_balance from (SELECT address, SUM(amount)/1e18 as sushi_balance
5+
FROM (
6+
SELECT
7+
date_trunc('day',evt_block_time) as day,
8+
"from" AS address, -value AS amount
9+
FROM erc20."ERC20_evt_Transfer" e
10+
WHERE contract_address='\x6b3595068778dd592e39a122f4f5a5cf09c90fe2'
11+
UNION ALL
12+
SELECT
13+
date_trunc('day',evt_block_time) as day,
14+
"to" AS address, value AS amount
15+
FROM erc20."ERC20_evt_Transfer" e
16+
WHERE contract_address='\x6b3595068778dd592e39a122f4f5a5cf09c90fe2'
17+
) t
18+
WHERE address not in ('\xf942dba4159cb61f8ad88ca4a83f5204e8f4a6bd','\xce84867c3c02b05dc570d0135103d3fb9cc19433','\x3f5ce5fbfe3e9af3971dd833d26ba9b5c936f0be','\xe93381fb4c4f14bda253907b18fad305d799241a','\xc2edad668740f1aa35e4d8f227fb8e17dca888cd','\x6cc5f688a315f3dc28a7781717a9a798a59fda7b','\x1c4b70a3968436b9a0a9cf5205c787eb81bb558c','\x4938960c507a4d7094c53a8cddcf925835393b8f','\xc8d02f2669ef9aabe6b3b75e2813695aed63748d','\x0211f3cedbef3143223d3acf0e589747933e8527','\x2faf487a4414fe77e2327f0bf4ae2a264a776ad2','\xd2e8827d4b1c44f64d1fa01bfbc14dc8545eca41')
19+
GROUP BY 2
20+
LIMIT 1000000
21+
-- GROUP BY 1
22+
-- ORDER BY sushi_balance DESC

0 commit comments

Comments
 (0)