Skip to content
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

Competitor AMMs KPIs #61

Merged
merged 25 commits into from
Nov 27, 2024
Merged
Show file tree
Hide file tree
Changes from 5 commits
Commits
Show all changes
25 commits
Select commit Hold shift + click to select a range
fcdb0bd
New queries to measure the kpis from competitors
PoloX2021 Nov 6, 2024
7bb4668
new parameter added because of the previous queries
PoloX2021 Nov 6, 2024
dd0dccc
Excludes possible negative tvls because of issues with ERC20/ETH tran…
PoloX2021 Nov 6, 2024
45d3f2a
Formatting
PoloX2021 Nov 6, 2024
752bf52
Added a missing blockchain parameter
PoloX2021 Nov 6, 2024
9fc431a
Simplified the querying of all tranactions from a curve pool
PoloX2021 Nov 15, 2024
7060d6d
Few comments and adapting to remarks for Curve
PoloX2021 Nov 15, 2024
db8459a
Added filter by x largest pools
PoloX2021 Nov 15, 2024
cb41f52
Added/propagated through queries number_of_pools parameter and variou…
PoloX2021 Nov 18, 2024
27ac2db
Removed the union for inactive pools. THe left join does the work
PoloX2021 Nov 19, 2024
1f328eb
Fixed the sqlfluff
PoloX2021 Nov 19, 2024
0bf6622
Moved the folder to kpis/competitors
PoloX2021 Nov 20, 2024
0d0f7f5
New query to replace the uni style querying. they are now grouped in …
PoloX2021 Nov 20, 2024
72f5c6a
Added the project value to classify the pools: uni/ pancake/sushi
PoloX2021 Nov 22, 2024
73a55b2
Comments
PoloX2021 Nov 22, 2024
77c8121
Added parameter for time window, and removed avg(tvl), avg(fee)
PoloX2021 Nov 22, 2024
a6478fa
upadated default parameter
PoloX2021 Nov 22, 2024
d53d5c0
Added syncs inline to kpis.
PoloX2021 Nov 22, 2024
7f4dbb9
Added flag uni/pancake/Sushi and parameter for time window
PoloX2021 Nov 22, 2024
5b26df3
New default value for day, few comments and renaming
PoloX2021 Nov 26, 2024
cd66d9f
Changed deployer contract addres for uniswap
PoloX2021 Nov 26, 2024
694d5cf
Query to regroup all the different projects kpis together
PoloX2021 Nov 26, 2024
df49fb1
Typo for chain_id
PoloX2021 Nov 26, 2024
f162872
fixed typo and added base
PoloX2021 Nov 26, 2024
f08a4b5
updated kpis to filter before joining and improve performance
PoloX2021 Nov 26, 2024
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
1 change: 1 addition & 0 deletions cowamm/.sqlfluff
Original file line number Diff line number Diff line change
Expand Up @@ -8,3 +8,4 @@ start_time='2024-08-20 00:00:00'
end_time='2024-08-27 00:00:00'
results=final_results_per_solver,cow_surplus_per_batch
cow_budget=30000
number_of_pools=500
31 changes: 31 additions & 0 deletions cowamm/profitability/competitor_kpis/curve/curve_kpis_4232873.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,31 @@
-- Computes volume, tvl and APR for Curve pools
-- APR is measured as the fees earned per $ invested, over the last 24 hours, projected over 1 year
-- Input: blockchain
select
r.contract_address,
sum(amount_usd) as volume,
365 * sum(amount_usd * fee / tvl) as apr,
avg(fee) as fee,
avg(tvl) as tvl
PoloX2021 marked this conversation as resolved.
Show resolved Hide resolved
from "query_4232976(blockchain='{{blockchain}}')" as r
left join curve.trades as t
on
r.contract_address = t.project_contract_address
and r.tx_hash = t.tx_hash
where
t.block_time >= date_add('day', -1, now())
-- This test avoids any possible issue with reconstructing the reserves of the pool
and tvl > 0
group by r.contract_address

union distinct
select
contract_address,
0 as volume,
0 as apr,
fee,
tvl
from "query_4232976(blockchain='{{blockchain}}')"
where
time < date_add('day', -1, now())
and latest = 1
PoloX2021 marked this conversation as resolved.
Show resolved Hide resolved
Original file line number Diff line number Diff line change
@@ -0,0 +1,65 @@
-- Finds all the curve pools with 2 tokens and their TVLs
-- Input: blockchain

with
-- filters pools with 2 tokens
pools as(
select pool_address as contract_address,
coin0 as token0,
coin1 as token1,
mid_fee*power(10,-10) as fee
from curvefi_{{blockchain}}.view_pools
where coin2 = 0x0000000000000000000000000000000000000000),
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Why is this needed? Intuitively this looks to me as if this is an invalid pool (with coin2 being the 0 address). Could you add a comment in code please?

Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Curve can have multi-tokens pools, which would not make sense to compare with CoW AMM for now


-- finds all transfers in and out of the pools to rebuild the reserves
transfers as(
PoloX2021 marked this conversation as resolved.
Show resolved Hide resolved
select p.contract_address, token0, token1, -value as transfer0, 0 as transfer1, evt_index, evt_tx_hash as tx_hash, evt_block_time as time, fee
from pools p
join erc20_{{blockchain}}.evt_transfer t0
on p.contract_address = t0."from"
and p.token0 = t0.contract_address
union
select p.contract_address, token0, token1, value as transfer0, 0 as transfer1, evt_index, evt_tx_hash as tx_hash, evt_block_time as time, fee
from pools p
join erc20_{{blockchain}}.evt_transfer t0
on p.contract_address = t0.to
and p.token0 = t0.contract_address
union
select p.contract_address, token0, token1, 0 as transfer0, -value as transfer1, evt_index, evt_tx_hash as tx_hash, evt_block_time as time, fee
from pools p
join erc20_{{blockchain}}.evt_transfer t1
on p.contract_address = t1."from"
and p.token1 = t1.contract_address
union
select p.contract_address, token0, token1, 0 as transfer0, value as transfer1, evt_index, evt_tx_hash as tx_hash, evt_block_time as time, fee
from pools p
join erc20_{{blockchain}}.evt_transfer t1
on p.contract_address = t1.to
and p.token1 = t1.contract_address),

-- rebuilds the reserves from the transfers
-- ETH transfers are not considered
reserves as(
select contract_address, token0, token1, tx_hash, time,
sum(transfer0) over (partition by contract_address order by time, evt_index) as reserve0,
sum(transfer1) over (partition by contract_address order by time, evt_index) as reserve1,
fee,
ROW_NUMBER() OVER (PARTITION BY tx_hash,contract_address ORDER BY evt_index DESC) AS row_num,
ROW_NUMBER() OVER (PARTITION BY contract_address ORDER BY time DESC) AS latest
from transfers)

-- finds the TVL of the pools
select r.contract_address, token0, token1, time, tx_hash,
reserve0, reserve1,
(reserve0 * p0.price / pow(10, p0.decimals)) + (reserve1 * p1.price / pow(10, p1.decimals)) as tvl,
fee, latest
from reserves r
inner join prices.usd as p0
on
date_trunc('minute', time) = p0.minute
and token0 = p0.contract_address
inner join prices.usd as p1
on
date_trunc('minute', time) = p1.minute
and token1 = p1.contract_address
where row_num = 1
Original file line number Diff line number Diff line change
@@ -0,0 +1,79 @@
-- Computes volume, tvl and APR for Pancakeswap pools
-- APR is measured as the fees earned per $ invested, over the last 24 hours, projected over 1 year
-- Input: blockchain

with
-- select the pool with the largest latest k
pool as (
select
contract_address,
token0,
token1
from "query_4232660(blockchain='{{blockchain}}')"
where latest = 1
),

swaps as (
select
tx_hash as evt_tx_hash,
index as evt_index,
block_time as evt_block_time,
block_number as evt_block_number,
contract_address,
varbinary_to_uint256(substr(data, 1, 32)) as amount0In,
varbinary_to_uint256(substr(data, 33, 32)) as amount1In,
varbinary_to_uint256(substr(data, 65, 32)) as amount0Out,
varbinary_to_uint256(substr(data, 97, 32)) as amount1Out
from {{blockchain}}.logs
where
topic0 = 0xd78ad95fa46c994b6551d0da85fc275fe613ce37657fb8d5e3d130840159d822 -- Swap
and contract_address in (select contract_address from pool)
),

-- gets the swapped volume and tvl at the time of the swap for each swap
tvl_volume_per_swap as (
select
syncs.contract_address as contract_address,
syncs.evt_block_time,
syncs.evt_tx_hash,
(amount0In * p0.price / pow(10, p0.decimals)) + (amount1In * p1.price / pow(10, p1.decimals)) as volume_in,
(amount0Out * p0.price / pow(10, p0.decimals)) + (amount1Out * p1.price / pow(10, p1.decimals)) as volume_out,
(reserve0 * p0.price / pow(10, p0.decimals)) + (reserve1 * p1.price / pow(10, p1.decimals)) as tvl
from "query_4232660(blockchain='{{blockchain}}')" as syncs
inner join swaps
on
syncs.evt_tx_hash = swaps.evt_tx_hash
and syncs.contract_address = swaps.contract_address
and syncs.evt_index + 1 = swaps.evt_index
inner join pool
on syncs.contract_address = pool.contract_address
inner join prices.usd as p0
on
date_trunc('minute', syncs.evt_block_time) = p0.minute
and syncs.token0 = p0.contract_address
inner join prices.usd as p1
on
date_trunc('minute', syncs.evt_block_time) = p1.minute
and syncs.token1 = p1.contract_address
where syncs.evt_block_time >= date(date_add('day', -7, now()))
)

select
contract_address,
sum((volume_in + volume_out) / 2) as volume,
avg(tvl) as tvl,
365*sum((volume_in + volume_out) / 2 / tvl) * 0.003 as apr,
0.003 as fee
from tvl_volume_per_swap
where evt_block_time >= date_add('day', -1, now())
group by contract_address

union
PoloX2021 marked this conversation as resolved.
Show resolved Hide resolved
select
pool_address as contract_address,
0 as volume,
tvl,
0 as apr,
0.003 as fee
from "query_4232597(blockchain='{{blockchain}}')"
where pool_address not in (select contract_address from tvl_volume_per_swap)
Original file line number Diff line number Diff line change
@@ -0,0 +1,64 @@
-- Computes the TVL for every Pancakeswap pool
-- Then returns the top {{number_of_pools}} pools by TVL
PoloX2021 marked this conversation as resolved.
Show resolved Hide resolved
-- Input: blockchain, number_of_pools to return

with
-- finds the pools which have been active since 2024-10-01
data as (
select
p.contract_address as pool_address,
p.call_block_time as time,
p.output__reserve0 as balance0,
p.output__reserve1 as balance1,
rank() over (partition by p.contract_address order by p.call_block_time desc) as latest
from pancakeswap_v2_{{blockchain}}.PancakePair_call_getReserves as p
PoloX2021 marked this conversation as resolved.
Show resolved Hide resolved
where date_trunc('day', p.call_block_time) >= date_trunc('day', cast('2024-10-01' as date))
),

--Gets the token0 and token1 addresses for each pool
t0 as (
select
contract_address,
max(output_0) as token0
from pancakeswap_v2_{{blockchain}}.PancakePair_call_token0
group by contract_address
),

t1 as (
select
contract_address,
max(output_0) as token1
from pancakeswap_v2_{{blockchain}}.PancakePair_call_token1
group by contract_address
),

--computes the tvl for each pool
-- for each pool we could get multiple balance values if the function was called multiple times in a same block
-- we arbitrarily choose the maximum value for each pool
PoloX2021 marked this conversation as resolved.
Show resolved Hide resolved
recent_tvl as (
select
pool_address,
token0,
max(balance0) as balance0,
token1,
max(balance1) as balance1,
max(
least(balance0, balance1) * greatest(p0.price / pow(10, p0.decimals), p1.price / pow(10, p1.decimals))
+ greatest(balance0, balance1) * least(p0.price / pow(10, p0.decimals), p1.price / pow(10, p1.decimals))
) as tvl
from data
inner join t0
on pool_address = t0.contract_address
inner join t1
on pool_address = t1.contract_address
inner join prices.usd_latest as p0
on token0 = p0.contract_address
inner join prices.usd_latest as p1
on token1 = p1.contract_address
where latest = 1
group by 1, 2, 4
)

select * from recent_tvl
order by tvl desc
limit {{number_of_pools}}
Original file line number Diff line number Diff line change
@@ -0,0 +1,27 @@
-- Finds the pancakeswap v2 pool address given tokens specified in query parameters (regardless of order)
PoloX2021 marked this conversation as resolved.
Show resolved Hide resolved
with pools as (
select
substr(data, 13, 20) as contract_address,
substr(topic1, 13, 20) as token0,
substr(topic2, 13, 20) as token1
from {{blockchain}}.logs
where
topic0 = 0x0d3648bd0f6ba80134a33ba9275ac585d9d315f0ad8355cddefde31afa28d0e9 -- PairCreated
-- topic1: 0x0...0<token0>, topic2: 0x0...0<token1>
and substr(data, 13, 20) in (select pool_address from "query_4232597(blockchain='{{blockchain}}')")
)

select
pools.*,
tx_hash as evt_tx_hash,
index as evt_index,
block_time as evt_block_time,
block_number as evt_block_number,
varbinary_to_uint256(substr(data, 1, 32)) as reserve0,
varbinary_to_uint256(substr(data, 33, 32)) as reserve1,
rank() over (partition by (logs.contract_address) order by block_time desc) as latest
from {{blockchain}}.logs
inner join pools
on logs.contract_address = pools.contract_address
where
topic0 = 0x1c411e9a96e071241c2f21f7726b17ae89e3cab4c78be50e062b03a9fffbbad1 -- Sync
Original file line number Diff line number Diff line change
@@ -0,0 +1,79 @@
-- Computes volume, tvl and APR for Sushiswap pools
-- APR is measured as the fees earned per $ invested, over the last 24 hours, projected over 1 year
-- Input: blockchain

with
PoloX2021 marked this conversation as resolved.
Show resolved Hide resolved
-- select the pool with the largest latest k
pool as (
select
contract_address,
token0,
token1
from "query_4227247(blockchain='{{blockchain}}')"
where latest = 1
),

swaps as (
select
tx_hash as evt_tx_hash,
index as evt_index,
block_time as evt_block_time,
block_number as evt_block_number,
contract_address,
varbinary_to_uint256(substr(data, 1, 32)) as amount0In,
varbinary_to_uint256(substr(data, 33, 32)) as amount1In,
varbinary_to_uint256(substr(data, 65, 32)) as amount0Out,
varbinary_to_uint256(substr(data, 97, 32)) as amount1Out
from {{blockchain}}.logs
where
topic0 = 0xd78ad95fa46c994b6551d0da85fc275fe613ce37657fb8d5e3d130840159d822 -- Swap
and contract_address in (select contract_address from pool)
),

-- gets the swapped volume and tvl at the time of the swap for each swap
tvl_volume_per_swap as (
select
syncs.contract_address,
syncs.evt_block_time,
syncs.evt_tx_hash,
(amount0In * p0.price / pow(10, p0.decimals)) + (amount1In * p1.price / pow(10, p1.decimals)) as volume_in,
(amount0Out * p0.price / pow(10, p0.decimals)) + (amount1Out * p1.price / pow(10, p1.decimals)) as volume_out,
(reserve0 * p0.price / pow(10, p0.decimals)) + (reserve1 * p1.price / pow(10, p1.decimals)) as tvl
from "query_4227247(blockchain='{{blockchain}}')" as syncs
inner join swaps
on
syncs.evt_tx_hash = swaps.evt_tx_hash
and syncs.contract_address = swaps.contract_address
and syncs.evt_index + 1 = swaps.evt_index
inner join pool
on syncs.contract_address = pool.contract_address
inner join prices.usd as p0
on
date_trunc('minute', syncs.evt_block_time) = p0.minute
and syncs.token0 = p0.contract_address
inner join prices.usd as p1
on
date_trunc('minute', syncs.evt_block_time) = p1.minute
and syncs.token1 = p1.contract_address
where syncs.evt_block_time >= date(date_add('day', -7, now()))
)

select
contract_address,
sum((volume_in + volume_out) / 2) as volume,
avg(tvl) as tvl,
365 * sum((volume_in + volume_out) / 2 / tvl) * 0.003 as apr,
0.003 as fee
from tvl_volume_per_swap
where evt_block_time >= date_add('day', -1, now())
group by contract_address

union distinct
select
pool_address as contract_address,
0 as volume,
tvl,
0 as apr,
0.003 as fee
from "query_4223554(blockchain='{{blockchain}}')"
where pool_address not in (select contract_address from tvl_volume_per_swap)
Loading
Loading