Skip to content

Commit

Permalink
CoW AMM monitoring (#72)
Browse files Browse the repository at this point in the history
* New queries to measure the kpis from competitors

* new parameter added because of the previous queries

* Excludes possible negative tvls because of issues with ERC20/ETH transfers

* Formatting

* Added a missing blockchain parameter

* Simplified the querying of all tranactions from a curve pool

* Few comments and adapting to remarks for Curve

* Added filter by x largest pools

* Added/propagated through queries number_of_pools parameter and various comments

* Removed the union for inactive pools. THe left join does the work

* Fixed the sqlfluff

* Moved the folder to kpis/competitors

* New query to replace the uni style querying. they are now grouped in the same query

* Added the project value to classify the pools: uni/ pancake/sushi

* Comments

* Added parameter for time window, and removed avg(tvl), avg(fee)

* upadated default parameter

* Added syncs inline to kpis.

* Added flag uni/pancake/Sushi and parameter for time window

* New default value for day, few comments and renaming

* Changed deployer contract addres for uniswap

* Query to regroup all the different projects kpis together

* Typo for chain_id

Co-authored-by: Felix Leupold <[email protected]>

* fixed typo and added base

* updated kpis to filter before joining and improve performance

* increased number of pools to display

* Adding CoW AMMs to the list of AMMs to monitor

* typo in chain_id

* Adding parameter for time window

* wrong join leading to less pools visible

* Adapting the query to get the info for every chain

---------

Co-authored-by: Felix Leupold <[email protected]>
  • Loading branch information
PoloX2021 and fleupold authored Nov 29, 2024
1 parent 4046e60 commit dc1c512
Show file tree
Hide file tree
Showing 5 changed files with 158 additions and 11 deletions.
2 changes: 1 addition & 1 deletion cowamm/.sqlfluff
Original file line number Diff line number Diff line change
Expand Up @@ -8,5 +8,5 @@ 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
number_of_pools=1000
competitor_end_time = 2100-01-01
28 changes: 24 additions & 4 deletions cowamm/kpi/competitors/all_competitors_4335231.sql
Original file line number Diff line number Diff line change
Expand Up @@ -13,10 +13,10 @@ select
case
when '{{blockchain}}' = 'ethereum' then 1
when '{{blockchain}}' = 'gnosis' then 100
when '{{blockchain}}' = 'arbitrum' then 8453
when '{{blockchain}}' = 'base' then 8453
when '{{blockchain}}' = 'arbitrum' then 42161
end as chain_id
from "query_4304295(blockchain='{{blockchain}}')"
from "query_4304295(blockchain='{{blockchain}}', competitor_end_time='{{competitor_end_time}}')"

union distinct

Expand All @@ -31,7 +31,27 @@ select
case
when '{{blockchain}}' = 'ethereum' then 1
when '{{blockchain}}' = 'gnosis' then 100
when '{{blockchain}}' = 'arbitrum' then 8453
when '{{blockchain}}' = 'base' then 8453
when '{{blockchain}}' = 'arbitrum' then 42161
end as chain_id
from "query_4232873(blockchain='{{blockchain}}')"
from "query_4232873(blockchain='ethereum', competitor_end_time='{{competitor_end_time}}')"
-- there are no significant curve pools on arbitrum/gnosis
where {{blockchain}} = 'ethereum'

union distinct

--CoW AMM
select
contract_address,
tvl,
0 as fee,
coalesce(volume, 0) as volume,
coalesce(apr, 0) as apr,
'CoW AMM' as project,
case
when '{{blockchain}}' = 'ethereum' then 1
when '{{blockchain}}' = 'gnosis' then 100
when '{{blockchain}}' = 'base' then 8453
when '{{blockchain}}' = 'arbitrum' then 42161
end as chain_id
from "query_4340428(blockchain='{{blockchain}}', competitor_end_time='{{competitor_end_time}}')"
24 changes: 24 additions & 0 deletions cowamm/kpi/competitors/cow_amm/cow_amm_kpi_4340428.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,24 @@
-- Computes volume, tvl and APR for CoW AMM pools
-- APR is measured as the fees earned per $ invested, over the last 24 hours, projected over 1 year
-- Parameters:
-- {{blockchain}}: The blockchain to query
-- {{competitor_end_time}}: The end time of the time window (end_time - 1 day; end_time), defaults to now()

-- computes, surplus, tvl and thus relative surplus (per $100)
select
contract_address,
tvl,
sum(usd_value) over (partition by contract_address order by latest_per_pool) as volume,
365 * sum(surplus_usd / tvl) over (partition by contract_address order by latest_per_pool) as apr
from "query_4340356(blockchain='{{blockchain}}')" as tvl
left join
( --noqa: ST05
select *
from cow_protocol_{{blockchain}}.trades
where
block_time >= date_add('day', -1, (case when '{{competitor_end_time}}' = '2100-01-01' then now() else timestamp '{{competitor_end_time}}' end))
) as t
on
t.tx_hash = tvl.tx_hash
and tvl.contract_address = trader
where latest_per_pool = 1
82 changes: 82 additions & 0 deletions cowamm/kpi/competitors/cow_amm/tvl_all_cow_amms_4340356.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,82 @@
-- Computes the balances and their dollar value of all CoW AMM pools at every transaction where it changed
-- Parameters
-- {{blockchain}} - chain for which the query is running

with cow_amm_pool as (
select
created_at,
address,
token_1_address as token0,
token_2_address as token1
from query_3959044
where blockchain = '{{blockchain}}'
order by 1 desc
),

-- Computes the token balance changes of the relevant token per transaction
reserves_delta as (
select
evt_block_time,
evt_tx_hash,
p.address as pool,
contract_address as token,
MAX(evt_block_number) as evt_block_number,
MAX(evt_index) as evt_index,
SUM(case when "from" = p.address then -value else value end) as amount
from erc20_{{blockchain}}.evt_transfer as t
inner join cow_amm_pool as p
on
(
t."from" = p.address
or t.to = p.address
)
and (token0 = t.contract_address or token1 = t.contract_address)
group by 1, 2, 3, 4
),

-- sums token balance changes to get total balances of relevant tokens per transaction
balances_by_tx as (
select
evt_block_time,
evt_tx_hash,
pool,
token,
SUM(amount) over (partition by (pool, token) order by (evt_block_number, evt_index)) as balance
from reserves_delta
),

-- joins token balances with prices to get tvl of pool per transaction
tvl as (
select
evt_block_time as block_time,
evt_tx_hash as tx_hash,
b.pool,
b.token,
balance,
price,
balance * price / POW(10, decimals) as tvl
from balances_by_tx as b
inner join prices.usd as p
on
p.minute = DATE_TRUNC('minute', evt_block_time)
and b.token = p.contract_address
)

select
tvl1.block_time,
tvl1.tx_hash,
tvl1.pool as contract_address,
tvl1.token as token1,
tvl1.balance as balance1,
tvl1.price as price1,
tvl2.token as token2,
tvl2.balance as balance2,
tvl2.price as price2,
tvl1.tvl + tvl2.tvl as tvl,
ROW_NUMBER() over (partition by tvl1.pool order by tvl1.block_time desc) as latest_per_pool
from tvl as tvl1
inner join tvl as tvl2
on
tvl1.tx_hash = tvl2.tx_hash
and tvl1.pool = tvl2.pool
and tvl1.token > tvl2.token
Original file line number Diff line number Diff line change
Expand Up @@ -9,18 +9,39 @@ with pools as (
substr(topic1, 13, 20) as token0,
substr(topic2, 13, 20) as token1,
case
when contract_address = 0x1097053Fd2ea711dad45caCcc45EfF7548fCB362 then 'pancakeswap'
when contract_address = 0x5c69bee701ef814a2b6a3edd4b1652cb9cc5aa6f then 'uniswap'
when contract_address = 0xC0AEe478e3658e2610c5F7A4A2E1777cE9e4f2Ac then 'sushiswap'
when
contract_address in (
0x1097053Fd2ea711dad45caCcc45EfF7548fCB362,
0x02a84c1b3bbd7401a5f7fa98a384ebc70bb5749e
) then 'pancakeswap'
when
contract_address in (
0x5c69bee701ef814a2b6a3edd4b1652cb9cc5aa6f,
0xf1D7CC64Fb4452F05c498126312eBE29f30Fbcf9,
0x8909Dc15e40173Ff4699343b6eB8132c65e18eC6
)
then 'uniswap'
when
contract_address in (
0xC0AEe478e3658e2610c5F7A4A2E1777cE9e4f2Ac,
0xc35DADB65012eC5796536bD9864eD8773aBc74C4,
0x71524B4f93c58fcbF659783284E38825f0622859
)
then 'sushiswap'
end as project
from {{blockchain}}.logs
where
topic0 = 0x0d3648bd0f6ba80134a33ba9275ac585d9d315f0ad8355cddefde31afa28d0e9
and contract_address in
(
0x1097053Fd2ea711dad45caCcc45EfF7548fCB362,
0x5c69bee701ef814a2b6a3edd4b1652cb9cc5aa6f,
0xC0AEe478e3658e2610c5F7A4A2E1777cE9e4f2Ac
0x1097053Fd2ea711dad45caCcc45EfF7548fCB362, --eth, pancake
0x02a84c1b3bbd7401a5f7fa98a384ebc70bb5749e, --arb/bas, pancake
0x5c69bee701ef814a2b6a3edd4b1652cb9cc5aa6f, --eth, uni
0xf1D7CC64Fb4452F05c498126312eBE29f30Fbcf9, --arb, uni
0x8909Dc15e40173Ff4699343b6eB8132c65e18eC6, --bas, uni
0xC0AEe478e3658e2610c5F7A4A2E1777cE9e4f2Ac, --eth, sushi
0xc35DADB65012eC5796536bD9864eD8773aBc74C4, --arb/gno, sushi
0x71524B4f93c58fcbF659783284E38825f0622859 --bas, sushi
)
),

Expand Down

0 comments on commit dc1c512

Please sign in to comment.