Skip to content

Commit ec565b9

Browse files
authored
Optimizing competitor kpis (#89)
* Changing price from minute to daily to get the latest tvl. It increases largely the speed of the query * Filter the time window for prices.mintue * Fixed typos for date and ordering * Restructuring the curve query to improve efficiency for the curve query * changed the join to where * Additional comments * Simplified the time comparison, and changed time argument from start to end (more intuitive) as we are talking about dates * Linting * added a parameter wrongfully removed
1 parent 0627996 commit ec565b9

File tree

5 files changed

+68
-51
lines changed

5 files changed

+68
-51
lines changed

cowamm/.sqlfluff

+1-1
Original file line numberDiff line numberDiff line change
@@ -9,4 +9,4 @@ end_time='2024-08-27 00:00:00'
99
results=final_results_per_solver,cow_surplus_per_batch
1010
cow_budget=30000
1111
number_of_pools=1000
12-
competitor_end_time = 2100-01-01
12+
competitor_end_time='2024-08-27 00:00:00'

cowamm/kpi/competitors/curve/curve_kpis_4232873.sql

+29-15
Original file line numberDiff line numberDiff line change
@@ -2,35 +2,49 @@
22
-- APR is measured as the fees earned per $ invested, over the last 24 hours, projected over 1 year
33
-- Parameters:
44
-- {{blockchain}}: The blockchain to query
5-
-- {{competitor_end_time}}: The end time of the time window (end_time - 1 day; end_time), defaults to now()
6-
select
7-
contract_address,
8-
tvl,
9-
fee,
10-
volume,
11-
apr
12-
from (
5+
-- {{start_time}}: The start time of the analysis. date '{{start_time}}' <= evt_block_time < date '{{start_time}}' + 1 day
6+
-- By default, we look at the past full day
7+
8+
with accumulated_kpis as (
139
select
14-
contract_address,
10+
r.contract_address,
1511
fee,
1612
tvl,
17-
latest_per_pool,
18-
sum(amount_usd) over (partition by contract_address order by latest_per_pool) as volume,
19-
365 * sum(amount_usd * fee / tvl) over (partition by contract_address order by latest_per_pool) as apr
20-
-- The first call to 4232976 gets the tvl after each tx to compute volume/tvl
21-
from "query_4232976(blockchain='{{blockchain}}')" as r
13+
sum(amount_usd) over (partition by r.contract_address order by latest_per_pool desc) as volume,
14+
365 * sum(amount_usd * fee / (reserve0 * p0.price * power(10, -p0.decimals) + reserve1 * p1.price * power(10, -p1.decimals))) over (partition by r.contract_address order by latest_per_pool desc) as apr,
15+
-- new index to make sure rows don't get lost in the filtering later
16+
row_number() over (partition by r.contract_address order by r.evt_block_time desc) as latest_per_pool
17+
from "query_4232976(blockchain='{{blockchain}}', number_of_pools = '{{number_of_pools}}', start_time = '{{start_time}}')" as r
2218
left join
2319
( --noqa: ST05
2420
select *
2521
from curve.trades
2622
where
27-
block_time >= date_add('day', -1, (case when '{{competitor_end_time}}' = '2100-01-01' then now() else timestamp '{{competitor_end_time}}' end))
23+
block_time >= least(date('{{start_time}}'), date_add('day', -1, date(now())))
2824
) as t
2925
on
3026
r.contract_address = t.project_contract_address
3127
and r.tx_hash = t.tx_hash
28+
inner join prices.minute as p0
29+
on
30+
r.token0 = p0.contract_address
31+
and date_trunc('minute', r.evt_block_time) = p0.timestamp
32+
inner join prices.minute as p1
33+
on
34+
r.token1 = p1.contract_address
35+
and date_trunc('minute', r.evt_block_time) = p1.timestamp
3236
where
3337
-- This test avoids any possible issue with reconstructing the reserves of the pool
3438
tvl > 0
39+
and p0.timestamp between least(date('{{start_time}}'), date_add('day', -1, date(now()))) and least(date_add('day', 1, date('{{start_time}}')), date(now()))
40+
and p1.timestamp between least(date('{{start_time}}'), date_add('day', -1, date(now()))) and least(date_add('day', 1, date('{{start_time}}')), date(now()))
3541
)
42+
43+
select
44+
contract_address,
45+
fee,
46+
tvl,
47+
volume,
48+
apr
49+
from accumulated_kpis
3650
where latest_per_pool = 1

cowamm/kpi/competitors/curve/curve_largest_2token_pools_4232976.sql

+19-21
Original file line numberDiff line numberDiff line change
@@ -4,6 +4,8 @@
44
-- Parameters:
55
-- {{blockchain}}: The blockchain to query
66
-- {{number_of_pools}}: The number of largest pools to return
7+
-- {{start_time}}: The start time of the analysis. date '{{start_time}}' <= evt_block_time < date '{{start_time}}' + 1 day
8+
-- By default, we look at the past full day
79

810
with
911
-- filters pools with 2 tokens
@@ -54,46 +56,42 @@ reserves as (
5456
token0,
5557
token1,
5658
tx_hash,
57-
block_time,
59+
block_time as evt_block_time,
5860
fee,
5961
sum(transfer0) over (partition by contract_address order by block_time, evt_index) as reserve0,
6062
sum(transfer1) over (partition by contract_address order by block_time, evt_index) as reserve1,
6163
row_number() over (partition by tx_hash, contract_address order by evt_index desc) as latest_per_tx,
62-
row_number() over (partition by contract_address order by block_time desc) as latest_per_pool
64+
row_number() over (partition by contract_address order by block_time desc, evt_index desc) as latest_per_pool
6365
from transfers
66+
where block_time <= least(date_add('day', 1, date('{{start_time}}')), date(now()))
6467
),
6568

6669
-- finds the TVL of the pools
67-
recent_tvl as (
70+
latest_tvl as (
6871
select
6972
r.contract_address,
7073
token0,
7174
token1,
72-
block_time,
73-
tx_hash,
74-
reserve0,
75-
reserve1,
76-
fee,
77-
latest_per_pool,
7875
(reserve0 * p0.price / pow(10, p0.decimals)) + (reserve1 * p1.price / pow(10, p1.decimals)) as tvl
7976
from reserves as r
80-
inner join prices.minute as p0
77+
--using the daily value to get a better representation of the TVL over the 24 hour period
78+
inner join prices.day as p0
8179
on
82-
date_trunc('minute', block_time) = p0.timestamp
80+
p0.timestamp = least(date('{{start_time}}'), date_add('day', -1, date(now())))
8381
and token0 = p0.contract_address
84-
inner join prices.minute as p1
82+
inner join prices.day as p1
8583
on
86-
date_trunc('minute', block_time) = p1.timestamp
84+
p1.timestamp = least(date('{{start_time}}'), date_add('day', -1, date(now())))
8785
and token1 = p1.contract_address
88-
where latest_per_tx = 1
89-
)
90-
91-
92-
select * from recent_tvl
93-
where contract_address in (
94-
select contract_address
95-
from recent_tvl
9686
where latest_per_pool = 1
9787
order by tvl desc
9888
limit {{number_of_pools}}
9989
)
90+
91+
select
92+
reserves.*,
93+
tvl
94+
from reserves
95+
inner join latest_tvl
96+
on reserves.contract_address = latest_tvl.contract_address
97+
where latest_per_tx = 1

cowamm/kpi/competitors/uni_swap_style/largest_uni_style_kpis_4304295.sql

+8-4
Original file line numberDiff line numberDiff line change
@@ -3,7 +3,8 @@
33
-- Parameters:
44
-- {{blockchain}}: The blockchain to query
55
-- {{number_of_pools}}: The number of largest pools to return
6-
-- {{competitor_end_time}}: The end time of the time window (end_time - 1 day; end_time), defaults to now()
6+
-- {{start_time}}: The start time of the analysis. date '{{start_time}}' <= evt_block_time < date '{{start_time}}' + 1 day
7+
-- By default, we look at the past full day
78

89
-- select the pool with the largest latest k
910
with pool as (
@@ -13,7 +14,7 @@ with pool as (
1314
token0,
1415
token1,
1516
tvl
16-
from "query_4303563(blockchain='{{blockchain}}', number_of_pools = '{{number_of_pools}}')"
17+
from "query_4303563(blockchain='{{blockchain}}', number_of_pools = '{{number_of_pools}}', start_time = '{{start_time}}')"
1718
),
1819

1920
syncs as (
@@ -30,7 +31,7 @@ syncs as (
3031
inner join pool
3132
on logs.contract_address = pool.contract_address
3233
where
33-
block_time >= date_add('day', -1, (case when '{{competitor_end_time}}' = '2100-01-01' then now() else timestamp '{{competitor_end_time}}' end))
34+
block_time between least(date('{{start_time}}'), date_add('day', -1, date(now()))) and least(date_add('day', 1, date('{{start_time}}')), date(now()))
3435
and topic0 = 0x1c411e9a96e071241c2f21f7726b17ae89e3cab4c78be50e062b03a9fffbbad1 -- Sync
3536
),
3637

@@ -47,7 +48,7 @@ swaps as (
4748
varbinary_to_uint256(substr(data, 97, 32)) as amount1Out
4849
from {{blockchain}}.logs
4950
where
50-
block_time >= date(date_add('day', -1, now()))
51+
block_time between least(date('{{start_time}}'), date_add('day', -1, date(now()))) and least(date_add('day', 1, date('{{start_time}}')), date(now()))
5152
and topic0 = 0xd78ad95fa46c994b6551d0da85fc275fe613ce37657fb8d5e3d130840159d822 -- Swap
5253
and contract_address in (select contract_address from pool)
5354
),
@@ -77,6 +78,9 @@ tvl_volume_per_swap as (
7778
on
7879
date_trunc('minute', syncs.evt_block_time) = p1.timestamp
7980
and syncs.token1 = p1.contract_address
81+
where
82+
p0.timestamp between least(date('{{start_time}}'), date_add('day', -1, date(now()))) and least(date_add('day', 1, date('{{start_time}}')), date(now()))
83+
and p1.timestamp between least(date('{{start_time}}'), date_add('day', -1, date(now()))) and least(date_add('day', 1, date('{{start_time}}')), date(now()))
8084
)
8185

8286
select

cowamm/kpi/competitors/uni_swap_style/largest_uni_style_pools_4303563.sql

+11-10
Original file line numberDiff line numberDiff line change
@@ -2,6 +2,8 @@
22
-- Parameters:
33
-- {{blockchain}}: The blockchain to query
44
-- {{number_of_pools}}: The number of largest pools to return
5+
-- {{start_time}}: The start time of the analysis. date '{{start_time}}' <= evt_block_time < date '{{start_time}}' + 1 day
6+
-- By default, we look at the past full day
57

68
with pools as (
79
select
@@ -54,7 +56,7 @@ syncs as (
5456
date_trunc('minute', block_time) as evt_block_time,
5557
varbinary_to_uint256(substr(data, 1, 32)) as reserve0,
5658
varbinary_to_uint256(substr(data, 33, 32)) as reserve1,
57-
rank() over (partition by (logs.contract_address) order by block_time desc, index asc) as latest
59+
rank() over (partition by (logs.contract_address) order by block_time desc, index desc) as latest
5860
from {{blockchain}}.logs
5961
inner join pools
6062
on logs.contract_address = pools.contract_address
@@ -72,14 +74,13 @@ select distinct
7274
evt_block_time,
7375
reserve0 * p0.price * power(10, -p0.decimals) + reserve1 * p1.price * power(10, -p1.decimals) as tvl
7476
from syncs as s
75-
inner join prices.minute as p0
76-
on
77-
token0 = p0.contract_address
78-
and p0.timestamp = evt_block_time
79-
inner join prices.minute as p1
80-
on
81-
token1 = p1.contract_address
82-
and p1.timestamp = evt_block_time
83-
where latest = 1
77+
inner join prices.day as p0
78+
on token0 = p0.contract_address
79+
inner join prices.day as p1
80+
on token1 = p1.contract_address
81+
where
82+
latest = 1
83+
and p0.timestamp = least(date('{{start_time}}'), date_add('day', -1, date(now())))
84+
and p1.timestamp = least(date('{{start_time}}'), date_add('day', -1, date(now())))
8485
order by tvl desc
8586
limit {{number_of_pools}}

0 commit comments

Comments
 (0)