diff --git a/cowprotocol/coincidence_of_wants/.sqlfluff b/cowprotocol/coincidence_of_wants/.sqlfluff new file mode 100644 index 00000000..eae7b0de --- /dev/null +++ b/cowprotocol/coincidence_of_wants/.sqlfluff @@ -0,0 +1,4 @@ +[sqlfluff:templater:jinja:context] +start_time='2024-08-01 12:00' +end_time='2024-08-02 12:00' +blockchain='ethereum' \ No newline at end of file diff --git a/cowprotocol/coincidence_of_wants/balance_changes_4021257.sql b/cowprotocol/coincidence_of_wants/balance_changes_4021257.sql new file mode 100644 index 00000000..c0f04125 --- /dev/null +++ b/cowprotocol/coincidence_of_wants/balance_changes_4021257.sql @@ -0,0 +1,241 @@ +-- This is a base query for monitoring balance changes on CoW Protocol +-- +-- The query collects all balance changes to the settlement contract. Those changes can come from +-- - erc20 transfers +-- - native transfers +-- - chain specific event like deposits and withdrawals +-- +-- Parameters: +-- {{start_time}} - the timestamp for which the analysis should start (inclusively) +-- {{end_time}} - the timestamp for which the analysis should end (exclusively) +-- {{blockchain}} - network to run the analysis on +-- +-- The columns of the result are: +-- - block_time: time of settlement transaction +-- - tx_hash: settlement transaction hash +-- - token_address: address of token with a balance change. contract address for erc20 tokens, +-- 0xeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeee for native token +-- - sender: origin of transfers sending tokens to the settlement contract, +-- 0x0000000000000000000000000000000000000000 for deposits/withdrawals +-- - receiver: destination of transfer sending tokens from the settlement contract, +-- 0x0000000000000000000000000000000000000000 for deposits/withdrawals +-- - amount: value of the balance change in atoms of the token + +-- 1) data on all chains +-- 1.1) erc20 +-- 1.2) native transfers + +-- 1.1) all the erc20 transfers to/from cow amms +with erc20_transfers as ( + select + evt_block_time as block_time, + evt_tx_hash as tx_hash, + contract_address as token_address, + "from" as sender, + to as receiver, + value as amount + from erc20_{{blockchain}}.evt_transfer + where + evt_block_time >= cast('{{start_time}}' as timestamp) and evt_block_time < cast('{{end_time}}' as timestamp) -- partition column + and 0x9008D19f58AAbD9eD0D60971565AA8510560ab41 in ("from", to) +), + +-- 1.2) all native token transfers +native_transfers as ( + select + block_time, + tx_hash, + 0xeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeee as token_address, + "from" as sender, + to as receiver, + value as amount + from {{blockchain}}.traces + where + block_time >= cast('{{start_time}}' as timestamp) and block_time < cast('{{end_time}}' as timestamp) -- partition column + and value > cast(0 as uint256) + and success = true + and 0x9008d19f58aabd9ed0d60971565aa8510560ab41 in (to, "from") +), + +-- 2) chain specific data +-- 2.1) ethereum +-- special treatmet of +-- 2.1.1) WETH +-- 2.1.2) sDAI + +-- 2.1.1) all deposit and withdrawal events for WETH +weth_deposits_withdrawals_ethereum as ( + -- deposits (contract deposits ETH to get WETH) + select + evt_block_time as block_time, + evt_tx_hash as tx_hash, + contract_address as token_address, + 0x0000000000000000000000000000000000000000 as sender, + 0x9008d19f58aabd9ed0d60971565aa8510560ab41 as receiver, + wad as amount + from zeroex_ethereum.WETH9_evt_Deposit + where + evt_block_time >= cast('{{start_time}}' as timestamp) and evt_block_time < cast('{{end_time}}' as timestamp) -- partition column + and dst = 0x9008d19f58aabd9ed0d60971565aa8510560ab41 + union distinct + -- withdrawals (contract withdraws ETH by returning WETH) + select + evt_block_time as block_time, + evt_tx_hash as tx_hash, + contract_address as token_address, + 0x9008d19f58aabd9ed0d60971565aa8510560ab41 as sender, + 0x0000000000000000000000000000000000000000 as receiver, + wad as amount + from zeroex_ethereum.WETH9_evt_Withdrawal + where + evt_block_time >= cast('{{start_time}}' as timestamp) and evt_block_time < cast('{{end_time}}' as timestamp) -- partition column + and src = 0x9008d19f58aabd9ed0d60971565aa8510560ab41 +), + +-- 2.1.2) all deposit and withdrawal events for sDAI +sdai_deposits_withdraws_ethereum as ( + -- deposits + select + evt_block_time as block_time, + evt_tx_hash as tx_hash, + contract_address as token_address, + 0x0000000000000000000000000000000000000000 as sender, + 0x9008d19f58aabd9ed0d60971565aa8510560ab41 as receiver, + shares as amount_wei + from maker_ethereum.SavingsDai_evt_Deposit + where + evt_block_time >= cast('{{start_time}}' as timestamp) and evt_block_time < cast('{{end_time}}' as timestamp) -- partition column + and owner = 0x9008d19f58aabd9ed0d60971565aa8510560ab41 + union distinct + -- withdraws + select + evt_block_time as block_time, + evt_tx_hash as tx_hash, + contract_address as token_address, + 0x9008d19f58aabd9ed0d60971565aa8510560ab41 as sender, + 0x0000000000000000000000000000000000000000 as receiver, + shares as amount_wei + from maker_ethereum.SavingsDai_evt_Withdraw + where + evt_block_time >= cast('{{start_time}}' as timestamp) and evt_block_time < cast('{{end_time}}' as timestamp) -- partition column + and owner = 0x9008d19f58aabd9ed0d60971565aa8510560ab41 +), + +special_balance_changes_ethereum as ( + select * from weth_deposits_withdrawals_ethereum + union all + select * from sdai_deposits_withdraws_ethereum +), + +-- 2.2) gnosis +-- special treatmet of +-- 2.2.1) WXDAI +-- 2.2.2) sDAI + +-- 2.2.1) all deposit and withdrawal events for WXDAI +wxdai_deposits_withdrawals_gnosis as ( + -- deposits (contract deposits XDAI to get WXDAI) + select + evt_block_time as block_time, + evt_tx_hash as tx_hash, + contract_address as token_address, + 0x0000000000000000000000000000000000000000 as sender, + 0x9008d19f58aabd9ed0d60971565aa8510560ab41 as receiver, + wad as amount + from wxdai_gnosis.WXDAI_evt_Deposit + where + evt_block_time >= cast('{{start_time}}' as timestamp) and evt_block_time < cast('{{end_time}}' as timestamp) -- partition column + and dst = 0x9008d19f58aabd9ed0d60971565aa8510560ab41 + union distinct + -- withdrawals (contract withdraws XDAI by returning WXDAI) + select + evt_block_time as block_time, + evt_tx_hash as tx_hash, + contract_address as token_address, + 0x9008d19f58aabd9ed0d60971565aa8510560ab41 as sender, + 0x0000000000000000000000000000000000000000 as receiver, + wad as amount + from wxdai_gnosis.WXDAI_evt_Withdrawal + where + evt_block_time >= cast('{{start_time}}' as timestamp) and evt_block_time < cast('{{end_time}}' as timestamp) -- partition column + and src = 0x9008d19f58aabd9ed0d60971565aa8510560ab41 +), + +-- 2.2.2) all deposit and withdrawal events for sDAI +sdai_deposits_withdraws_gnosis as ( + -- deposits + select + evt_block_time as block_time, + evt_tx_hash as tx_hash, + contract_address as token_address, + 0x0000000000000000000000000000000000000000 as sender, + 0x9008d19f58aabd9ed0d60971565aa8510560ab41 as receiver, + shares as amount_wei + from sdai_gnosis.SavingsXDai_evt_Deposit + where + evt_block_time >= cast('{{start_time}}' as timestamp) and evt_block_time < cast('{{end_time}}' as timestamp) -- partition column + and owner = 0x9008d19f58aabd9ed0d60971565aa8510560ab41 + union distinct + -- withdraws + select + evt_block_time as block_time, + evt_tx_hash as tx_hash, + contract_address as token_address, + 0x9008d19f58aabd9ed0d60971565aa8510560ab41 as sender, + 0x0000000000000000000000000000000000000000 as receiver, + shares as amount_wei + from sdai_gnosis.SavingsXDai_evt_Withdraw + where + evt_block_time >= cast('{{start_time}}' as timestamp) and evt_block_time < cast('{{end_time}}' as timestamp) -- partition column + and owner = 0x9008d19f58aabd9ed0d60971565aa8510560ab41 +), + +special_balance_changes_gnosis as ( -- noqa: ST03 + select * from wxdai_deposits_withdrawals_gnosis + union all + select * from sdai_deposits_withdraws_gnosis +), + +-- 2.3) arbitrum +-- special treatmet of +-- 2.3.1) WETH + +-- 2.3.1) all deposit and withdrawal events for WETH +weth_deposits_withdrawals_arbitrum as ( + -- deposits (contract deposits ETH to get WETH) + select + evt_block_time as block_time, + evt_tx_hash as tx_hash, + contract_address as token_address, + 0x0000000000000000000000000000000000000000 as sender, + 0x9008d19f58aabd9ed0d60971565aa8510560ab41 as receiver, + wad as amount + from mindgames_weth_arbitrum.WETH9_evt_Deposit + where + evt_block_time >= cast('{{start_time}}' as timestamp) and evt_block_time < cast('{{end_time}}' as timestamp) -- partition column + and dst = 0x9008d19f58aabd9ed0d60971565aa8510560ab41 + union distinct + -- withdrawals (contract withdraws ETH by returning WETH) + select + evt_block_time as block_time, + evt_tx_hash as tx_hash, + contract_address as token_address, + 0x9008d19f58aabd9ed0d60971565aa8510560ab41 as sender, + 0x0000000000000000000000000000000000000000 as receiver, + wad as amount + from mindgames_weth_arbitrum.WETH9_evt_Withdrawal + where + evt_block_time >= cast('{{start_time}}' as timestamp) and evt_block_time < cast('{{end_time}}' as timestamp) -- partition column + and src = 0x9008d19f58aabd9ed0d60971565aa8510560ab41 +), + +special_balance_changes_arbitrum as ( -- noqa: ST03 + select * from weth_deposits_withdrawals_arbitrum +) + +-- combine results +select * from erc20_transfers +union all +select * from native_transfers +union all +select * from special_balance_changes_{{blockchain}} diff --git a/cowprotocol/coincidence_of_wants/classified_balance_changes_4021306.sql b/cowprotocol/coincidence_of_wants/classified_balance_changes_4021306.sql new file mode 100644 index 00000000..7fa3e141 --- /dev/null +++ b/cowprotocol/coincidence_of_wants/classified_balance_changes_4021306.sql @@ -0,0 +1,85 @@ +-- This query is part of a base query for computing CoWs +-- +-- Parameters: +-- {{start_time}} - the timestamp for which the analysis should start (inclusively) +-- {{end_time}} - the timestamp for which the analysis should end (exclusively) +-- {{blockchain}} - network to run the analysis on +-- +-- The query tags all transfers to and from the settlement contract as one of +-- - user_in: amounts sent by users, tokens flowing into the settlement contract +-- - user_out: amount sent to users, tokens flowing out of the settlement contract +-- - amm_in: tokens flowing into the settlement contract but coming from users +-- - amm_out:tokens flowing out of the settlement contract but not towards users +-- - slippage_in: final imbalance of the settlement contract if that imbalance is positive +-- - slippage_out: final imbalance of the settlement contract of that imbalance is negative +-- +-- The classification into user transfers and amm transfers depends on a clear separation of addresses into +-- trader addresses and amm addresses. If an address is used in a trade, all interactions with that address +-- are classified as user transfers, even in other transactions. +-- +-- The common edge case of the settlement contract acting as a trader is implicitly handled sa follows: +-- The settlement contract will appear as a trader. There will be a transfer from the settlement contract to itself. +-- The corresponding balance change is accounted for as 'user_in'. +-- This behavior will be wrong when an order is created with receiver set to the settlement contract. + +with filtered_trades as ( + select * + from cow_protocol_{{blockchain}}.trades + where block_time >= cast('{{start_time}}' as timestamp) and block_time < cast('{{end_time}}' as timestamp) +), + +traders as ( + select + trader as sender, + receiver + from filtered_trades +), + +balance_changes as ( + select * + from "query_4021257(blockchain='{{blockchain}}',start_time='{{start_time}}',end_time='{{end_time}}')" +), + +-- classify balance changes +balance_changes_with_types as ( + select + block_time, + tx_hash, + token_address, + amount, + case + -- user in + when ( + sender in (select sender from traders) -- transfer coming from a trader + or sender = 0x40a50cf069e992aa4536211b23f286ef88752187 + ) -- transfer coming from ETH flow + and receiver = 0x9008D19f58AAbD9eD0D60971565AA8510560ab41 -- transfer going to the settlement contract + then 'user_in' + -- user out + when + receiver in (select receiver from traders) -- transfer going to a trader + and sender = 0x9008D19f58AAbD9eD0D60971565AA8510560ab41 -- transfer coming from the settlement contract + then 'user_out' + -- amm in + when receiver = 0x9008D19f58AAbD9eD0D60971565AA8510560ab41 + then 'amm_in' + -- amm out + when sender = 0x9008D19f58AAbD9eD0D60971565AA8510560ab41 + then 'amm_out' + end as transfer_type + from balance_changes +), + +slippage as ( + select + block_time, + tx_hash, + token_address, + case when amount >= 0 then cast(amount as uint256) else cast(-amount as uint256) end as amount, + case when amount >= 0 then 'slippage_in' else 'slippage_out' end as transfer_type + from "query_4021644(blockchain='{{blockchain}}',start_time='{{start_time}}',end_time='{{end_time}}')" +) + +select * from balance_changes_with_types +union all +select * from slippage diff --git a/cowprotocol/coincidence_of_wants/cow_per_batch_4025739.sql b/cowprotocol/coincidence_of_wants/cow_per_batch_4025739.sql new file mode 100644 index 00000000..f9ad75a3 --- /dev/null +++ b/cowprotocol/coincidence_of_wants/cow_per_batch_4025739.sql @@ -0,0 +1,73 @@ +-- This query computes Coincidence of Wants fractions on CoW Protocol for individual tokens +-- +-- Parameters: +-- {{start_time}} - the timestamp for which the analysis should start (inclusively) +-- {{end_time}} - the timestamp for which the analysis should end (exclusively) +-- {{blockchain}} - network to run the analysis on +-- +-- It computes a CoW fraction per batch by averaging the CoW fractions from query 4021555 weighted by usd volume +-- +-- The query is based on a Master's Thesis by Vigan Lladrovci +-- https://wwwmatthes.in.tum.de/pages/y9xcjv094zhn/Master-s-Thesis-Vigan-Lladrovci + +with cow_per_token as ( + select * from "query_4021555(blockchain='{{blockchain}}',start_time='{{start_time}}',end_time='{{end_time}}')" +), + +-- get prices from trades table +token_prices as ( + select * from "query_4031637(blockchain='{{blockchain}}',start_time='{{start_time}}',end_time='{{end_time}}')" +), + +-- join token amounts with prices from trades table +cow_per_token_with_prices as ( + select + cpt.*, + token_price + from cow_per_token as cpt + left outer join token_prices as tp + on cpt.tx_hash = tp.tx_hash and cpt.token_address = tp.token_address +), + +-- convert amounts to dollar values +cow_per_token_usd as ( + select + block_time, + tx_hash, + token_address, + naive_cow_potential, + naive_cow, + naive_cow_averaged, + token_price * user_in as user_in, + token_price * user_out as user_out, + token_price * amm_in as amm_in, + token_price * amm_out as amm_out, + token_price * slippage_in as slippage_in, + token_price * slippage_out as slippage_out + from cow_per_token_with_prices +), + +-- aggregate token volumes +cow_volume_per_batch as ( + select + block_time, + tx_hash, + sum(user_in) as user_in, + sum(user_out) as user_out, + sum(amm_in) as amm_in, + sum(amm_out) as amm_out, + sum(slippage_in) as slippage_in, + sum(slippage_out) as slippage_out, + sum(user_out * naive_cow_potential) as naive_cow_potential_volume, + sum(user_out * naive_cow) as naive_cow_volume + from cow_per_token_usd + group by block_time, tx_hash +) + +-- compute cow values per batch +select + *, + case when user_out > 0 then naive_cow_potential_volume / user_out end as naive_cow_potential, + case when user_out > 0 then naive_cow_volume / user_out end as naive_cow, + case when user_in + user_out > 0 then naive_cow_averaged_volume / (user_in + user_out) end as naive_cow_averaged +from cow_volume_per_batch diff --git a/cowprotocol/coincidence_of_wants/cow_per_token_4021555.sql b/cowprotocol/coincidence_of_wants/cow_per_token_4021555.sql new file mode 100644 index 00000000..907ea11d --- /dev/null +++ b/cowprotocol/coincidence_of_wants/cow_per_token_4021555.sql @@ -0,0 +1,53 @@ +-- This query computes Coincidence of Wants fractions on CoW Protocol for individual tokens +-- +-- It uses transfer information from query 4021306. +-- +-- Parameters: +-- {{start_time}} - the timestamp for which the analysis should start (inclusively) +-- {{end_time}} - the timestamp for which the analysis should end (exclusively) +-- {{blockchain}} - network to run the analysis on +-- +-- The cow metrics computed are +-- - naive_cow_potential: min(user_in / user_out, 1) +-- This quantity indicates what fraction of the amount bought of a token is sold by other users. +-- - naive_cow: max(min((user_in - amm_out - slippage_in) / user_out, 1), 0) +-- This quantity indicates what fraction of the amount bought is not traded via AMMs or internalizations (showing as slippage). +-- - naive_cow_averaged: max(((user_in + user_out) - (amm_in + amm_out) - (slippage_in + slippage_out)) / (user_in + user_out), 0) +-- This quantity indicates what fraction of the amount bought and sold is not traded via AMMs or internalizations (showing as slippage). +-- +-- The query also returns aggregated amounts for user_in, user_out, amm_in, amm_out, slippage_in, slippage_out for all tokens. +-- +-- The query is based on a Master's Thesis by Vigan Lladrovci +-- https://wwwmatthes.in.tum.de/pages/y9xcjv094zhn/Master-s-Thesis-Vigan-Lladrovci + +with aggregate_transfers_with_types as ( + select + block_time, + tx_hash, + token_address, + transfer_type, + sum(amount) as amount + from "query_4021306(blockchain='{{blockchain}}',start_time='{{start_time}}',end_time='{{end_time}}')" + group by block_time, tx_hash, token_address, transfer_type +), + +transfers_per_token as ( + select + block_time, + tx_hash, + token_address, + sum(case when transfer_type = 'user_in' then cast(amount as int256) else 0 end) as user_in, -- sum is selecting the only entry + sum(case when transfer_type = 'user_out' then cast(amount as int256) else 0 end) as user_out, + sum(case when transfer_type = 'amm_in' then cast(amount as int256) else 0 end) as amm_in, + sum(case when transfer_type = 'amm_out' then cast(amount as int256) else 0 end) as amm_out, + sum(case when transfer_type = 'slippage_in' then cast(amount as int256) else 0 end) as slippage_in, + sum(case when transfer_type = 'slippage_out' then cast(amount as int256) else 0 end) as slippage_out + from aggregate_transfers_with_types + group by block_time, tx_hash, token_address +) + +select + *, + case when user_out > 0 then least(1.0 * user_in / user_out, 1.0) end as naive_cow_potential, + case when user_out > 0 then greatest(least(1.0 * (user_in - amm_out - slippage_in) / user_out, 1.0), 0.0) end as naive_cow +from transfers_per_token diff --git a/cowprotocol/coincidence_of_wants/cow_total_4025865.sql b/cowprotocol/coincidence_of_wants/cow_total_4025865.sql new file mode 100644 index 00000000..c4e4c6dc --- /dev/null +++ b/cowprotocol/coincidence_of_wants/cow_total_4025865.sql @@ -0,0 +1,20 @@ +-- aggregate volume and cow volume from query 4025739 +-- +-- Parameters: +-- {{start_time}} - the timestamp for which the analysis should start (inclusively) +-- {{end_time}} - the timestamp for which the analysis should end (exclusively) +-- {{blockchain}} - network to run the analysis on + +with t as ( + select + sum(naive_cow_potential_volume) as naive_cow_potential_volume, + sum(naive_cow_volume) as naive_cow_volume, + sum(user_out) as total_volume + from "query_4025739(blockchain='{{blockchain}}',start_time='{{start_time}}',end_time='{{end_time}}')" +) + +select + *, + naive_cow_potential_volume / total_volume as naive_cow_potential_fraction, + naive_cow_volume / total_volume as naive_cow_fraction +from t diff --git a/cowprotocol/coincidence_of_wants/imbalances_4021644.sql b/cowprotocol/coincidence_of_wants/imbalances_4021644.sql new file mode 100644 index 00000000..c7d34293 --- /dev/null +++ b/cowprotocol/coincidence_of_wants/imbalances_4021644.sql @@ -0,0 +1,16 @@ +-- This a base query for computing token imbalances of the CoW Protocol contract +-- +-- It is based on query 4021257 and aggregates the transfers from that query into imbalances per token +-- +-- Parameters: +-- {{start_time}} - the timestamp for which the analysis should start (inclusively) +-- {{end_time}} - the timestamp for which the analysis should end (exclusively) +-- {{blockchain}} - network to run the analysis on + +select + block_time, + tx_hash, + token_address, + sum(case when receiver = 0x9008D19f58AAbD9eD0D60971565AA8510560ab41 then cast(amount as int256) else -cast(amount as int256) end) as amount -- this classifies transfers from the settlement contract to itself as incoming transfers +from "query_4021257(blockchain='{{blockchain}}',start_time='{{start_time}}',end_time='{{end_time}}')" +group by block_time, tx_hash, token_address diff --git a/cowprotocol/coincidence_of_wants/token_prices_4031637.sql b/cowprotocol/coincidence_of_wants/token_prices_4031637.sql new file mode 100644 index 00000000..eef642c4 --- /dev/null +++ b/cowprotocol/coincidence_of_wants/token_prices_4031637.sql @@ -0,0 +1,74 @@ +-- This query returns prices for tokens traded via CoW Protocol +-- +-- Parameters: +-- {{start_time}} - the timestamp for which the analysis should start (inclusively) +-- {{end_time}} - the timestamp for which the analysis should end (exclusively) +-- {{blockchain}} - network to run the analysis on +-- +-- The returned table has columns: +-- - block_time: time a a settlement transaction +-- - tx_hash: settlement transaction hash +-- - token_address: +-- - token_price: price in USD of one _atom_ of a token +-- +-- Prices are either fetched from the trades table which contains Dune prices if they exist, +-- or computes them from the exchange rate from the trade if the second traded token has a price on Dune. +-- If no trade with a dune price exists for a token, the price is set to zero. +-- +-- Prices are in USD _per atom_ to avoid special casing of trades involving tokens without an entry in erc20 tables. +-- This fits to naturally to other queries using amounts in atoms. If amounts in _units_ of a token are used, +-- prices need to be scaled using decimals of the token. + +with filtered_trades as ( + select * + from cow_protocol_{{blockchain}}.trades + where block_time >= cast('{{start_time}}' as timestamp) and block_time < cast('{{end_time}}' as timestamp) +), + +token_prices_from_trades as ( + select + block_time, + tx_hash, + sell_token_address, + buy_token_address, + order_uid, + sell_value_usd / atoms_sold as token_price_sell, -- in usd per atom + buy_value_usd / atoms_bought as token_price_buy, + buy_value_usd / atoms_sold as token_price_backup_sell, + sell_value_usd / atoms_bought as token_price_backup_buy + from filtered_trades +), + +token_prices_from_trades_sell as ( + select + block_time, + tx_hash, + sell_token_address as token_address, + token_price_sell as token_price, + token_price_backup_sell as token_price_backup + from token_prices_from_trades +), + +token_prices_from_trades_buy as ( + select + block_time, + tx_hash, + buy_token_address as token_address, + token_price_buy as token_price, + token_price_backup_buy as token_price_backup + from token_prices_from_trades +), + +token_prices_all as ( + select * from token_prices_from_trades_sell + union all + select * from token_prices_from_trades_buy +) + +select + block_time, + tx_hash, + token_address, + coalesce(max(token_price), avg(token_price_backup), 0) as token_price +from token_prices_all +group by block_time, tx_hash, token_address