From 3475749012ec27ddc6704f9b6dc84ccc7fb98cb3 Mon Sep 17 00:00:00 2001 From: harisang Date: Mon, 9 Sep 2024 19:13:58 +0300 Subject: [PATCH 01/12] slippage query --- .../accounting/rewards/mainnet/.sqlfluff | 6 + .../mainnet/slippage_query_3427730.sql | 480 ++++++++++++++++++ 2 files changed, 486 insertions(+) create mode 100644 cowprotocol/accounting/rewards/mainnet/.sqlfluff create mode 100644 cowprotocol/accounting/rewards/mainnet/slippage_query_3427730.sql diff --git a/cowprotocol/accounting/rewards/mainnet/.sqlfluff b/cowprotocol/accounting/rewards/mainnet/.sqlfluff new file mode 100644 index 00000000..f064ee06 --- /dev/null +++ b/cowprotocol/accounting/rewards/mainnet/.sqlfluff @@ -0,0 +1,6 @@ +[sqlfluff:templater:jinja:context] +start_time='2024-08-01 12:00' +end_time='2024-08-02 12:00' +tx_hash='0xb548b6d5c99be70cc70162591e7699801f8841e59ce12aa653c9146f207f146e' +solver_address='0x008300082C3000009e63680088f8c7f4D3ff2E87' +cte_name = 'results' diff --git a/cowprotocol/accounting/rewards/mainnet/slippage_query_3427730.sql b/cowprotocol/accounting/rewards/mainnet/slippage_query_3427730.sql new file mode 100644 index 00000000..db5ed9b5 --- /dev/null +++ b/cowprotocol/accounting/rewards/mainnet/slippage_query_3427730.sql @@ -0,0 +1,480 @@ +-- https://github.com/cowprotocol/solver-rewards/pull/342 +with +block_range as ( + select + min("number") as start_block, + max("number") as end_block + from ethereum.blocks + where time >= cast('{{start_time}}' as timestamp) and time < cast('{{end_time}}' as timestamp) +) +,batch_meta as ( + select b.block_time, + b.block_number, + b.tx_hash, + case + when dex_swaps = 0 + -- Estimation made here: https://dune.com/queries/1646084 + then cast((gas_used - 73688 - (70528 * num_trades)) / 90000 as int) + else dex_swaps + end as dex_swaps, + num_trades, + b.solver_address + from cow_protocol_ethereum.batches b + where b.block_number >= (select start_block from block_range) and b.block_number <= (select end_block from block_range) + and (b.solver_address = from_hex('{{solver_address}}') or '{{solver_address}}' = '0x') + and (b.tx_hash = from_hex('{{tx_hash}}') or '{{tx_hash}}' = '0x') +) +,filtered_trades as ( + select t.tx_hash, + b.block_number, + case + when trader = 0x9008d19f58aabd9ed0d60971565aa8510560ab41 + then 0x0000000000000000000000000000000000000001 + else trader + end as trader_in, + receiver as trader_out, + sell_token_address as sell_token, + buy_token_address as buy_token, + atoms_sold - coalesce(surplus_fee, cast(0 as uint256)) as atoms_sold, + atoms_bought, + 0x9008d19f58aabd9ed0d60971565aa8510560ab41 as contract_address + from cow_protocol_ethereum.trades t + join cow_protocol_ethereum.batches b + on t.tx_hash = b.tx_hash + left outer join cow_protocol_ethereum.order_rewards f + on f.tx_hash = t.tx_hash + and f.order_uid = t.order_uid + where b.block_number >= (select start_block from block_range) and b.block_number <= (select end_block from block_range) + and t.block_number >= (select start_block from block_range) and t.block_number <= (select end_block from block_range) + and (b.solver_address = from_hex('{{solver_address}}') or '{{solver_address}}' = '0x') + and (t.tx_hash = from_hex('{{tx_hash}}') or '{{tx_hash}}' = '0x') +) +,batchwise_traders as ( + select + tx_hash, + block_number, + array_agg(trader_in) as traders_in, + array_agg(trader_out) as traders_out + from filtered_trades + group by tx_hash, block_number +) +,user_in as ( + select + tx_hash, + trader_in as sender, + contract_address as receiver, + sell_token as token, + cast(atoms_sold as int256) as amount_wei, + 'IN_USER' as transfer_type + from filtered_trades +) +,user_out as ( + select tx_hash, + contract_address as sender, + trader_out as receiver, + buy_token as token, + cast(atoms_bought as int256) as amount_wei, + 'OUT_USER' as transfer_type + from filtered_trades +) +,other_transfers as ( + select b.tx_hash, + "from" as sender, + to as receiver, + t.contract_address as token, + cast(value as int256) as amount_wei, + case + when to = 0x9008d19f58aabd9ed0d60971565aa8510560ab41 + then 'IN_AMM' + when "from" = 0x9008d19f58aabd9ed0d60971565aa8510560ab41 + then 'OUT_AMM' + end as transfer_type + from erc20_ethereum.evt_Transfer t + inner join cow_protocol_ethereum.batches b + on evt_block_number = b.block_number + and evt_tx_hash = b.tx_hash + inner join batchwise_traders bt + on evt_tx_hash = bt.tx_hash + where b.block_number >= (select start_block from block_range) and b.block_number <= (select end_block from block_range) + and 0x9008d19f58aabd9ed0d60971565aa8510560ab41 in (to, "from") + and not contains(traders_in, "from") + and not contains(traders_out, to) + and to != "from" + and "from" not in ( -- ETH FLOW ORDERS ARE NOT AMM TRANSFERS! + select distinct contract_address + from cow_protocol_ethereum.CoWSwapEthFlow_evt_OrderPlacement + ) + and (t.evt_tx_hash = from_hex('{{tx_hash}}') or '{{tx_hash}}' = '0x') + and (solver_address = from_hex('{{solver_address}}') or '{{solver_address}}' = '0x') +) +,eth_transfers as ( + select + bt.tx_hash, + "from" as sender, + to as receiver, + 0xeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeee as token, + cast(value as int256) as amount_wei, + case + when 0x9008d19f58aabd9ed0d60971565aa8510560ab41 = to + then 'AMM_IN' + else 'AMM_OUT' + end as transfer_type + from batchwise_traders bt + inner join ethereum.traces et + on bt.block_number = et.block_number + and bt.tx_hash = et.tx_hash + and value > cast(0 as uint256) + and success = true + and 0x9008d19f58aabd9ed0d60971565aa8510560ab41 in (to, "from") + -- WETH unwraps don't have cancelling WETH transfer. + and not 0xc02aaa39b223fe8d0a0e5c4f27ead9083c756cc2 in (to, "from") + -- ETH transfers to traders are already part of USER_OUT + and not contains(traders_out, to) +) +-- sDAI emits only one transfer event for deposits and withdrawals. +-- This reconstructs the missing transfer from event logs. +,sdai_deposit_withdrawal_transfers as ( + -- withdraw events result in additional AMM_IN transfer + select + tx_hash, + 0x9008d19f58aabd9ed0d60971565aa8510560ab41 as sender, + 0x0000000000000000000000000000000000000000 as receiver, + contract_address as token, + cast(shares as int256) as amount_wei, + 'AMM_IN' as transfer_type + from batch_meta bm + join maker_ethereum.SavingsDai_evt_Withdraw w + on w.evt_tx_hash= bm.tx_hash + where owner = 0x9008d19f58aabd9ed0d60971565aa8510560ab41 + union all + -- deposit events result in additional AMM_OUT transfer + select + tx_hash, + 0x0000000000000000000000000000000000000000 as sender, + 0x9008d19f58aabd9ed0d60971565aa8510560ab41 as receiver, + contract_address as token, + cast(shares as int256) as amount_wei, + 'AMM_OUT' as transfer_type + from batch_meta bm + join maker_ethereum.SavingsDai_evt_Deposit w + on w.evt_tx_hash= bm.tx_hash + where owner = 0x9008d19f58aabd9ed0d60971565aa8510560ab41 +) +,pre_batch_transfers as ( + select * from ( + select * from user_in + union all + select * from user_out + union all + select * from other_transfers + union all + select * from eth_transfers + union all + select * from sdai_deposit_withdrawal_transfers + ) as _ + order by tx_hash +) +,batch_transfers as ( + select + block_time, + block_number, + pbt.tx_hash, + dex_swaps, + num_trades, + solver_address, + sender, + receiver, + token, + amount_wei, + transfer_type + from batch_meta bm + join pre_batch_transfers pbt + on bm.tx_hash = pbt.tx_hash +) +,incoming_and_outgoing as ( + SELECT + block_time, + tx_hash, + dex_swaps, + solver_address, + case + when t.symbol = 'ETH' then 'WETH' + when t.symbol is not null then t.symbol + else cast(i.token as varchar) + end as symbol, + case + when token = 0xeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeee + then 0xc02aaa39b223fe8d0a0e5c4f27ead9083c756cc2 + else token + end as token, + case + when receiver = 0x9008d19f58aabd9ed0d60971565aa8510560ab41 + then amount_wei + when sender = 0x9008d19f58aabd9ed0d60971565aa8510560ab41 + then cast(-1 as int256) * amount_wei + end as amount, + transfer_type + from batch_transfers i + left outer join tokens.erc20 t + on i.token = t.contract_address + and blockchain = 'ethereum' +) + +,internalized_imbalances as ( + select b.block_time, + b.tx_hash, + b.solver_address, + t.symbol, + from_hex(i.token) as token, + cast(cast(i.amount as varchar) as int256) as amount, + 'PHANTOM_TRANSFER' as transfer_type + from cowswap.raw_internal_imbalance i + inner join cow_protocol_ethereum.batches b + on i.block_number = b.block_number + and from_hex(i.tx_hash) = b.tx_hash + join tokens.erc20 t + on contract_address = from_hex(token) + and blockchain = 'ethereum' + where i.block_number >= (select start_block from block_range) and i.block_number <= (select end_block from block_range) + and ('{{solver_address}}' = '0x' or b.solver_address = from_hex('{{solver_address}}')) + and ('{{tx_hash}}' = '0x' or b.tx_hash = from_hex('{{tx_hash}}')) +) +,incoming_and_outgoing_with_internalized_imbalances_temp as ( + select * from ( + select block_time, + tx_hash, + solver_address, + symbol, + token, + amount, + transfer_type + from incoming_and_outgoing + union all + select * from internalized_imbalances + ) as _ + order by block_time +) +-- add correction for protocol fees +,raw_protocol_fee_data as ( + select + order_uid, + tx_hash, + cast(cast(data.protocol_fee as varchar) as int256) as protocol_fee, + data.protocol_fee_token as protocol_fee_token, + cast(cast(data.surplus_fee as varchar) as int256) as surplus_fee, + solver, + symbol + from cowswap.raw_order_rewards ror + join tokens.erc20 t + on t.contract_address = from_hex(ror.data.protocol_fee_token) + and blockchain = 'ethereum' + where + block_number >= (select start_block from block_range) and block_number <= (select end_block from block_range) + and data.protocol_fee_native_price > 0 +) +,buy_token_imbalance_due_to_protocol_fee as ( + select + t.block_time as block_time, + from_hex(r.tx_hash) as tx_hash, + from_hex(r.solver) as solver_address, + symbol, + t.buy_token_address as token, + (-1) * r.protocol_fee as amount, + 'protocol_fee_correction' as transfer_type + from raw_protocol_fee_data r + join cow_protocol_ethereum.trades t + on from_hex(r.order_uid) = t.order_uid and from_hex(r.tx_hash) = t.tx_hash + where t.order_type='SELL' +) +,sell_token_imbalance_due_to_protocol_fee as ( + select + t.block_time as block_time, + from_hex(r.tx_hash) as tx_hash, + from_hex(r.solver) as solver_address, + symbol, + t.sell_token_address as token, + r.protocol_fee * (t.atoms_sold - r.surplus_fee) / t.atoms_bought as amount, + 'protocol_fee_correction' as transfer_type + from raw_protocol_fee_data r + join cow_protocol_ethereum.trades t + on from_hex(r.order_uid) = t.order_uid and from_hex(r.tx_hash) = t.tx_hash + where t.order_type='SELL' +) +,incoming_and_outgoing_with_internalized_imbalances_unmerged as ( + select * from ( + select * from incoming_and_outgoing_with_internalized_imbalances_temp + union all + select * from buy_token_imbalance_due_to_protocol_fee + union all + select * from sell_token_imbalance_due_to_protocol_fee + ) as _ + order by block_time +) +,incoming_and_outgoing_with_internalized_imbalances as ( + select + block_time, + tx_hash, + solver_address, + symbol, + CASE + WHEN token = 0xeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeee then 0xc02aaa39b223fe8d0a0e5c4f27ead9083c756cc2 + ELSE token + END as token, + amount, + transfer_type + from incoming_and_outgoing_with_internalized_imbalances_unmerged +) +-- These batches involve a token who do not emit standard transfer events. +-- These batches are excluded due to inaccurate prices. +,excluded_batches as ( + select tx_hash from query_3490353 +) +,final_token_balance_sheet as ( + select + solver_address, + sum(amount) token_imbalance_wei, + symbol, + token, + tx_hash, + date_trunc('hour', block_time) as hour + from + incoming_and_outgoing_with_internalized_imbalances + where tx_hash not in (select tx_hash from excluded_batches) + group by + symbol, token, solver_address, tx_hash, block_time + having + sum(amount) != cast(0 as int256) +) +,token_times as ( + select hour, token + from final_token_balance_sheet + group by hour, token +) +,precise_prices as ( + select + contract_address, + decimals, + date_trunc('hour', minute) as hour, + avg( + CASE + WHEN (price > 10 and contract_address = 0xdef1ca1fb7fbcdc777520aa7f396b4e015f497ab) then 0.26 -- dirty fix for some bogus COW prices Dune reports on July 29, 2024 + ELSE price + END + ) as price + from + prices.usd pusd + inner join token_times tt + on minute between date(hour) and date(hour) + interval '1' day -- query execution speed optimization since minute is indexed + and date_trunc('hour', minute) = hour + and contract_address = token + and blockchain = 'ethereum' + group by + contract_address, + decimals, + date_trunc('hour', minute) +) +,intrinsic_prices as ( + select + contract_address, + decimals, + hour, + AVG(price) as price + from ( + select + buy_token_address as contract_address, + ROUND(LOG(10, atoms_bought / units_bought)) as decimals, + date_trunc('hour', block_time) as hour, + usd_value / units_bought as price + FROM cow_protocol_ethereum.trades + WHERE block_number >= (select start_block from block_range) and block_number <= (select end_block from block_range) + AND units_bought > 0 + UNION + select + sell_token_address as contract_address, + ROUND(LOG(10, atoms_sold / units_sold)) as decimals, + date_trunc('hour', block_time) as hour, + usd_value / units_sold as price + FROM cow_protocol_ethereum.trades + WHERE block_number >= (select start_block from block_range) and block_number <= (select end_block from block_range) + AND units_sold > 0 + ) as combined + GROUP BY hour, contract_address, decimals + order by hour +) +-- -- Price Construction: https://dune.com/queries/1579091? +,prices as ( + select + tt.hour as hour, + tt.token as contract_address, + COALESCE( + precise.decimals, + intrinsic.decimals + ) as decimals, + COALESCE( + precise.price, + intrinsic.price + ) as price + from token_times tt + LEFT JOIN precise_prices precise + ON precise.hour = tt.hour + AND precise.contract_address = token + LEFT JOIN intrinsic_prices intrinsic + ON intrinsic.hour = tt.hour + and intrinsic.contract_address = token +) +-- -- ETH Prices: https://dune.com/queries/1578626?d=1 +,eth_prices as ( + select + date_trunc('hour', minute) as hour, + avg(price) as eth_price + from prices.usd + where blockchain = 'ethereum' + and contract_address = 0xc02aaa39b223fe8d0a0e5c4f27ead9083c756cc2 + and minute between cast('{{start_time}}' as timestamp) and cast('{{end_time}}' as timestamp) + group by date_trunc('hour', minute) +) +,results_per_tx as ( + select + ftbs.hour, + tx_hash, + solver_address, + sum(cast(token_imbalance_wei as double) * price / pow(10, p.decimals)) as usd_value, + sum(cast(token_imbalance_wei as double) * price / pow(10, p.decimals) / eth_price) * pow(10, 18) as eth_slippage_wei, + count(*) as num_entries + from + final_token_balance_sheet ftbs + left join prices p + on token = p.contract_address + and p.hour = ftbs.hour + left join eth_prices ep + on ftbs.hour = ep.hour + group by + ftbs.hour, + solver_address, + tx_hash + having + bool_and(price is not null) +) +,results as ( + select + solver_address, + concat(environment, '-', name) as solver_name, + sum(usd_value) as usd_value, + sum(eth_slippage_wei) as eth_slippage_wei, + concat( + 'link' + ) as batchwise_breakdown + from + results_per_tx rpt + join cow_protocol_ethereum.solvers + on address = solver_address + group by + solver_address, + concat(environment, '-', name) +) +select * from {{cte_name}} From c74132ec9cf3ab6243ea97a480716b36695b2bff Mon Sep 17 00:00:00 2001 From: harisang Date: Tue, 10 Sep 2024 03:19:50 +0300 Subject: [PATCH 02/12] introduce token imbalances query --- .../accounting/rewards/mainnet/.sqlfluff | 4 +- .../excluded_batches_query_3490353.sql | 153 ++++++ .../processed_token_imbalances_4057345.sql | 352 +++++++++++++ .../mainnet/slippage_query_3427730.sql | 470 +++--------------- 4 files changed, 583 insertions(+), 396 deletions(-) create mode 100644 cowprotocol/accounting/rewards/mainnet/excluded_batches_query_3490353.sql create mode 100644 cowprotocol/accounting/rewards/mainnet/processed_token_imbalances_4057345.sql diff --git a/cowprotocol/accounting/rewards/mainnet/.sqlfluff b/cowprotocol/accounting/rewards/mainnet/.sqlfluff index f064ee06..be7d3026 100644 --- a/cowprotocol/accounting/rewards/mainnet/.sqlfluff +++ b/cowprotocol/accounting/rewards/mainnet/.sqlfluff @@ -1,6 +1,6 @@ [sqlfluff:templater:jinja:context] start_time='2024-08-01 12:00' end_time='2024-08-02 12:00' -tx_hash='0xb548b6d5c99be70cc70162591e7699801f8841e59ce12aa653c9146f207f146e' -solver_address='0x008300082C3000009e63680088f8c7f4D3ff2E87' +tx_hash='0x' +solver_address='0x' cte_name = 'results' diff --git a/cowprotocol/accounting/rewards/mainnet/excluded_batches_query_3490353.sql b/cowprotocol/accounting/rewards/mainnet/excluded_batches_query_3490353.sql new file mode 100644 index 00000000..3e4db147 --- /dev/null +++ b/cowprotocol/accounting/rewards/mainnet/excluded_batches_query_3490353.sql @@ -0,0 +1,153 @@ +select distinct tx_hash +from + cow_protocol_ethereum.trades +where + 0xf5d669627376ebd411e34b98f19c868c8aba5ada in (buy_token_address, sell_token_address) -- exclude AXS (Old) + -- mixed ERC20/ERC721 tokens: + or 0xf66434c34f3644473d91f065bF35225aec9e0Cfd in (buy_token_address, sell_token_address) -- exclude 404 + or 0x9E9FbDE7C7a83c43913BddC8779158F1368F0413 in (buy_token_address, sell_token_address) -- exclude PANDORA + or 0x6C061D18D2b5bbfBe8a8D1EEB9ee27eFD544cC5D in (buy_token_address, sell_token_address) -- exclude MNRCH + or 0xbE33F57f41a20b2f00DEc91DcC1169597f36221F in (buy_token_address, sell_token_address) -- exclude Rug + or 0x938403C5427113C67b1604d3B407D995223C2B78 in (buy_token_address, sell_token_address) -- exclude OOZ + or 0x54832d8724f8581e7Cc0914b3A4e70aDC0D94872 in (buy_token_address, sell_token_address) -- exclude DN404 + -- Temporary exceptions for Feb 13..Feb20, 2024 are starting here + or 0xB5C457dDB4cE3312a6C5a2b056a1652bd542a208 in (buy_token_address, sell_token_address) -- exclude EtherRock404 + or 0xd555498a524612c67f286dF0e0a9a64a73a7Cdc7 in (buy_token_address, sell_token_address) -- exclude DeFrogs + or 0x73576A927Cd93a578a9dFD61c75671D97c779da7 in (buy_token_address, sell_token_address) -- exclude Forge + or 0x3F73EAEBA8f2b2699D6cC7581678bA631de5F183 in (buy_token_address, sell_token_address) -- exclude DEV404 + or 0x7c6314cCd4e34346Ba9C9bd9900FaafB4E3711B0 in (buy_token_address, sell_token_address) -- exclude ERC404X + or 0xe2f95ee8B72fFed59bC4D2F35b1d19b909A6e6b3 in (buy_token_address, sell_token_address) -- exclude EGGX + or 0xd5C02bB3e40494D4674778306Da43a56138A383E in (buy_token_address, sell_token_address) -- exclude OMNI404 + or 0x92715b8F93729c0B014213f769EF493baecEDACC in (buy_token_address, sell_token_address) -- exclude WIFU 404 + or 0x413530a7beB9Ff6C44e9e6C9001C93B785420C32 in (buy_token_address, sell_token_address) -- exclude PFPAsia. NEEDS TO BE REMOVED FROM THIS LIST + or 0xe7468080c033cE50Dd09A22ad1E58D1BDA69E436 in (buy_token_address, sell_token_address) -- exclude YUMYUM. NEEDS TO BE REMOVED FROM THIS LIST + or tx_hash = 0x41418cef26e608ed47a5c4997833caaa2366a0163173286140da28a32e37b25d -- temporary solution + or tx_hash = 0xdf415f3048d401c9ca7bf079722be96aaed3d2d2b5c0e12b7dc75d6eec30b3d4 -- temporary solution + or tx_hash = 0x15b9906aa2039ccbc9ae9fab0f0c7517e9c88c41b74cd8a09f202803d37f6341 -- temporary solution + or tx_hash = 0x3a71df0f6898b229c3643d4703b56d7510d455c65649cb364e5b69cadf5d1d37 -- temporary solution + or tx_hash = 0xc9bcb4c8c68d4edcb97403131d28416a418ae537c43e9feca50f11ca744c079e -- temporary solution + -- the following 2 stable-to-stable trades Otex settled. Due to inaccurate accounting, and since Otex has more of those, + -- I decided to remove 2 of those to mitigate the inaccuracies resulting from the rest + or tx_hash = 0x60157b1891dbdbcdc88c637079c4c9e37d5fe943bf3ffff14412b33bf7125ad1 + or tx_hash = 0x414e72fa7c061a1b2c5905f21e41d8cb5500ec9043b65b317cd20362f4eff757 + or tx_hash = 0x829d0583b647581cdd8f01f62e6715a7c6333b499f164995601217bde1976a09 -- internalization involving PANDORA + -- for week of Feb 27, 2024 until March 5, 2024 + or tx_hash = 0xc27463c9c6084a1067488d75732d37d85bf34f5d7882222eceba2d7f83c85dfe + or tx_hash = 0x65ae7ff7419777bb0e81ebfffc55da654c89834f23065f7e62aac5891a8e0abb + or tx_hash = 0xf82ad7fc31169a51e24f30677cf6ba5c337fd3c501551635cd94b768c9a1d5b1 + or tx_hash = 0xe3cf17ab69ff9efd72d44cd855db35c76732895a5413d13851871e2f6cbe701c + or tx_hash = 0xdcddf86f9439522158c259ad5eabc6574b4f176631b09a27f450f2c6cc420993 + or tx_hash = 0xc3e8f21faea641132927eb9e7c5f5321cb90ef50300bce896a4277ee9a2bbd1a + or tx_hash = 0x5ae92778c6d18d8391ecf87a10e4de381e558bab0eb939a69d596801d47e8b97 + -- for week of March 5, 2024 until March 12, 2024 + or tx_hash = 0x245cad3a40ab34ae6a6e79e050ec6946d80b1a501b345412bd33a8e0df6a1ea6 + or tx_hash = 0xc2e44a4abcfb719b3038ac346b89b2fd1391abcc3d9938954a6bc81495143619 + or tx_hash = 0xc7928590347245ccaa1b4794cc348c0d72b757f4376c023a8f67238c81280046 + or tx_hash = 0x3fbcf3aa9024d82e23c262a1e3c8ecbca83279e92fd0e2e147f3125762ca1bb4 + or tx_hash = 0x98d74de9f96d14f38cdabda0446d61e7a49db68f71670f1e66830bf40a0ca003 + or tx_hash = 0xaf56355b74863b9129824fbf31a182bc54bd94501b6c557778f060a2c2cd9973 + or tx_hash = 0x44daaccec0c6718b557258348b9f8736fbb94ea97d7d21336c8e0da3e309f84f + or tx_hash = 0x5ae0810874dd9f4657fced144563af501e0d43265ac1b7a2ec2c7b0291b84af8 + or tx_hash = 0x5cb533bd94ac4c3703b6fe7e52c2089ffe9dc6675b2f6b96242a8b340cbd1430 + or tx_hash = 0xcde2671c02065773ef8efee2e39acb8a78bea213fffaf692f454e7bd97711c70 + or tx_hash = 0xe1d3480b3c99b2387cf6b0724abcd936fd7f888d9a5ee70be96cdcfc94eec29b + or tx_hash = 0x0b8f6950f3f54034530bed401331172849b7e16bf964e3b92d838451a0a29d64 + or tx_hash = 0x1879438c38fae1ed205063218086cca0a600fe0263ab0f6cfad0f31bd3355b15 + or tx_hash = 0xbcfb968a772f0b68a7ecf1858925a2876e86a8d6941e7c53d0bf666aa66e02c0 + or tx_hash = 0xc06297f9a24faae8b165de7abf793dd53dfe8abd5be67ceb0964145a74e244cd + or tx_hash = 0xb6e93c1b30b2020c943dd956ba5c797cecfbbdf121b0ee7ea1c0552b22e031a4 + or tx_hash = 0xcd9fb72ab8a61b6706e8ecb79939111318e770fcd8c29e8d49826c57b48cdb6b + or tx_hash = 0x2a9a9b9c837bf8cd89dabf91825ca678fd2e2d506a0686cf3774e6c77748d319 + or tx_hash = 0xfb239a1959d1db58be3f33ab13c1aa45ea39e7b97653590b0f320b4e446ae6ab + or tx_hash = 0x7b2588fda96cb480d6a055f327c368b3e1a5638f489e1b1ede9d143361b94c65 + or tx_hash = 0x00198fdad1047b31299d8d91afa71467cc491d643e730f9ef5bb9a9e7a5cfdad + -- for week of March 12, 2024 until March 19, 2024 + or 0x382E57cA8e4c4DB9649884ca77B0a355692D14AC in (buy_token_address, sell_token_address) -- exclude XYXYX + or tx_hash = 0x46c5064ffae9d4f0132fcaf9e75b169aecd23b0834b7743bc5280770ace3a10e + or tx_hash = 0xba20e80f1e055865e594f868843f5f642b896291c91afa39cde1820e3129f543 + or tx_hash = 0xeb18483d07998f33952bba494aff9542283afcd2867b12fcfdc82672f87a97a3 + -- for week of March 19, 2024 until March 26, 2024 + or tx_hash = 0xe926b6c67228cc5ff3f44a4ea46104468d984a68316871b0b5165065f8c0feca + or tx_hash = 0xf1495b9c437e50454ff525902b700aec7a1b8d75d47798333480f6a445082064 + or tx_hash = 0x8901360b463e470f44f91511b89f97197d7d5d7ca48a39ad51098f1fe630727b + or tx_hash = 0xf04d5c32a1d1fa791a974270f7466383f2e2677fa667942bc862bfae4e84e502 + -- for week of March 26, 2024 until April 1, 2024 + or tx_hash = 0xa93c3d40f94c9feb75f6e0453d7e338666ce842b675017a01e7bd20d415dbaa1 + or tx_hash = 0x03e7a74da8a2f8318caa38da3ab83e5540e7324340552d04e9e0c4f97d763dc4 + or tx_hash = 0x844195cb1e04cc532b9595e03b86ca6481bd36e38b974d72f6ef11caf21a6875 + or tx_hash = 0x0b419b76bb53b9903bdfbcf47da50491e5a95833b0a4ac08c2cd1a12afa99cf3 + or tx_hash = 0x1a1212026760ad3d01ec678f87c6dfe3ac47ce9bcb1f7b09675462664b23f921 + or tx_hash = 0x033cf6c93b222900b6b7f41d1833efc19d5c1b3e7701e4335979716f60f7ade2 + or tx_hash = 0x862f950718b7e14225625277f6d16dfb9d48c923b936691f5149863b498535f2 + or tx_hash = 0x54ae0ccd530438de78fe7317a76abe7fffeb9bb15673b6d0885839eb0aa8184b + or tx_hash = 0x9233c85da85670a0ae0fa61404387d1fbd88319aec4fafe13eee9605cc521462 + -- for week of April 2, 2024 until April 9, 2024 + or tx_hash = 0x924a9d66594ebd8e85204ce1a9ed853d4151923519d146bf6bcbf61bd5978837 + or tx_hash = 0x491faa01f97bf667a9a014bf8ea0200db42eaaf3968746f9e7005a75d10ad624 + or tx_hash = 0x907b052adeb8ffca4948908b38628ef6af425f630dad1c054f96e577ca4ffb7b + or tx_hash = 0x70b8a208ac86b1290b8bb300dd0d2faef93fb91327da40b8bd4f55275ee4b4ab + -- for week of April 9, 2024 until April 16, 2024 + or tx_hash = 0xd00adcd9c7ae9612a10afb390fbe81409b7972c10ac582930afe7e1c23298d62 + or tx_hash = 0xe8012a6474bd9db791f4157c487a8880c06e41275272113b5fad03c04ee2cba7 + -- for week of April 16, 2024 until April 23, 2024 + or tx_hash = 0x142adfe0b863a6621579f501859733de243d4b8d673b9d50150c8e99ec7387eb + -- for week of April 30, 2024 until May 7, 2024 + or 0x730BCBe5Cdc1a3061Dfe700774b7B8dd1d4173DB in (buy_token_address, sell_token_address) -- exclude DaVinci ERC-721 + -- for week of May 7, 2024 until May 14, 2024 + or tx_hash = 0x360803f2df15d66fef4afdeb981798c988d72078c400acdb20e10d5018cb1f46 + or tx_hash = 0xca73fed6c8e0a7b44685d74884025d25bee4c1fba836e7f211331e2b2bfcdc09 + or tx_hash = 0x4c723a4e944425e85fb34ebf9943c5ddadce0b4d388259181e11134aa8fdefa3 + or tx_hash = 0xc5cc04cb47695b1a7e32341bf254054698097596420d7822760e96548a739a16 + -- for week of May 21, 2024 until May 28, 2024 + or tx_hash = 0x0531bcb0e1c6e9c743b787c6dbf8b6f9c5ff67682408f74c11a567b74f31fedc + or tx_hash = 0x03943dd6ea4bb2e1b4ff03eae70d19efb6921ecd0666c213ff20a84c31a74de5 + or tx_hash = 0xd2e723895af68036f2623d016a6d4ed7dd4cdef919220c847293b7fb49be5ed6 + or tx_hash = 0xec44a4a88420de45a02147a20dd4a25c49ac53c3c06bb840ff0b093f7db88cc1 + or tx_hash = 0x66bbee193158b5c172cc03486e91a4de086a8375e2ab421ef0d8e23a7de13dd2 + or tx_hash = 0x8af8e15f5f425ce29e05743e1586f6e39f138ac16836a2ee888fe8cf181493ad + or tx_hash = 0xb07d4ed63a4cb373d0676f7fc59d4fc0785c1a025f5f4950e5909ee44c546343 + or tx_hash = 0x73c118eedaab117c8ff88262132e75e0b9969a0ed9c789bc23cdad17f11fa159 + or tx_hash = 0x129c49166827f038101d6a5735e1c85269a1430300136471817b60995dc97de1 + or tx_hash = 0x2746c84a8c9e08d72c362ecacfc471473911b953f62f2a45899e994372a38f5c + or tx_hash = 0x3c7ec9f66b75b8e2e0d8174adf761b2f483abb0537919dcc46acbc693bda2982 + -- for week of May 28, 2024 until June 4, 2024 + or tx_hash = 0xc93f75665df1d4f62ee2447c2ffa40a628b5904878450a05e27de597bdb1470e + or tx_hash = 0x68a10171dad3d5ee4b0304926d33501cf03c77d308d52bfd43e5d0d9cd021d89 + or tx_hash = 0x4930273761cdd2fba156adc4d3556e3b7d6655089a1bb22b0b08f94edd0b21c7 + or tx_hash = 0x23638eb4c4ee00ddf855fc8daf91e9baf7c803e747dbfa26e36f58eb4576df8e + -- for week of June 11, 2024 until June 18, 2024 + or tx_hash = 0xbe34ce42dae8faae31876616d8a3359fe1f22b598a753a518065dd7e73d2b1e2 + or tx_hash = 0x6098baad61108c4db73d4fca97f0a3c97f156524f71b8d65f9fa4e4f208ae664 + or tx_hash = 0x9d93a23556cfaf7d63155ef4b317a9168bcef3e4a5642320bdc013ece70fe909 + or tx_hash = 0xddcec62f27d370edf84d4ae6787e401eaea62a47257d9c3c4295e7ac6b792dce + or tx_hash = 0xb904b88ef329cceba0ff90481dadf8fd17dc5371516808a4ae4de128eb14821c + or tx_hash = 0x883efbacc1a9331b4a15cac3f7f28ec0c9e187658bf27108f656e8275915a87a + or tx_hash = 0x357f85c50d1b8c484d4181ce300b2ab64db33832c4a765852444503f5a0f906b + or tx_hash = 0xd24b3c8aaefaa9e4f467ca7fa8156afb18f9218e0a34de45f2f524f2bb4879ef + or tx_hash = 0x7fe800c0e51970d25a3ee0e2d899c0c8fc128fdd6f5f07e11f8e7113cd6d11a5 + or tx_hash = 0xd03209f71ddd2502f73627ccb81ed54d8a2a7cd42a0920cec53a511f2d757c4b + or tx_hash = 0xf19e56beb9f2a4ff548c4f5f3d8f3a368a8fab9d65d7aa1a07f6278f0c6daa4a + -- for week of June 18, 2024 until June 25, 2024 + or tx_hash = 0x9e53bd81a1ea279403c41dc3c92ac57b70bfd75ee8fa2d30e1029050f1bc5730 + -- for week of July 2, 2024 until July 9, 2024 + or tx_hash = 0xaf40d801d03975135c539707b1ecc998730750c0f9b185a0cd144e0d461f53cd + or tx_hash = 0x7e65980f09bb8ec67f6dddd82e6a2f2a990501c3c6928b423903e2642dc5d73d + -- for week of July 9, 2024 until July 16, 2024 + or tx_hash = 0x1d9577d7c8e856a74f664b4d1be3d7488e33b730f8c190e433278d8e3cefc2cb + or tx_hash = 0x69f9ab97c687a68575ced1d57ff71e69b680746b6473ac269d3ec3a21f686b33 + or tx_hash = 0x89f921cf4d93eeba622b4b333e92c023698d32263fe29fdb93fac34656f86c06 + or tx_hash = 0xb4f58c9e7132e49fe10ea3e0ec90c37a68f11fd0454f750387ff9dbc633a811e + or tx_hash = 0xc78513b3146004bc7d3e0765c92e13c4b91adb9a16002aea2601ec4a68d1eab5 + or tx_hash = 0xd6ab356a216afca8a40e9343f4cdffe64ec5999a47a10fe7ce4427aba7b6cf96 + or tx_hash = 0x87030eb545efebe7f59718608eee475eea95f5ba77bb1c1f46d2a46ded245b13 + or tx_hash = 0x9e216f57d34e31ac61aa1316c3b9a5e460ae1eb7d6b8bf017fdd4af083566219 + -- for week of July 16, 2024 until July 23, 2024 + or tx_hash = 0x0cd1c6d5c0d01b114ab85a92cf52eabd41bc7eb48692069f8a60ca24ef284e1d + or tx_hash = 0xfc8af62481cf21f6c91d1e64afb4079d95a3c76f3d3ad6626206ca6c5e9c6126 + or tx_hash = 0x18b436c1f14b491282c453d7bc67295f95108d055001719d6ffd7110fe6513cd + or tx_hash = 0x27c9fd96c1bbcf75c521ac774f270f9502bd4ce4816e4f2c9d75e64b90fb9778 + or tx_hash = 0x9a0d7ac0eb92197e4122c56332f3bf6ee6d6ce6cd6a03f988db268e4f88a3c5d + -- for week of July 23, 2024 until July 30, 2024 + or tx_hash = 0x6f4638194282021a3ae2a80c778ff7829d4b269af6ac1cd612744a9d3dbd86fb + -- for week of August 06, 2024 until August 13, 2024 + or tx_hash = 0xbd8cf4a21ad811cc3b9e49cff5e95563c3c2651b0ea41e0f8a7987818205c984 diff --git a/cowprotocol/accounting/rewards/mainnet/processed_token_imbalances_4057345.sql b/cowprotocol/accounting/rewards/mainnet/processed_token_imbalances_4057345.sql new file mode 100644 index 00000000..b22d5b58 --- /dev/null +++ b/cowprotocol/accounting/rewards/mainnet/processed_token_imbalances_4057345.sql @@ -0,0 +1,352 @@ +with +block_range as ( + select * from "query_3333356(start_time='{{start_time}}',end_time='{{end_time}}')" +), + +batch_meta as ( + select + b.block_time, + b.block_number, + b.tx_hash, + b.num_trades, + b.solver_address, + case + when dex_swaps = 0 + -- Estimation made here: https://dune.com/queries/1646084 + then cast((b.gas_used - 73688 - (70528 * b.num_trades)) / 90000 as int) + else dex_swaps + end as dex_swaps + from cow_protocol_ethereum.batches as b + where + b.block_number >= (select start_block from block_range) and b.block_number <= (select end_block from block_range) + and (b.solver_address = from_hex('{{solver_address}}') or '{{solver_address}}' = '0x') + and (b.tx_hash = from_hex('{{tx_hash}}') or '{{tx_hash}}' = '0x') +), + +filtered_trades as ( + select + t.tx_hash, + b.block_number, + receiver as trader_out, + sell_token_address as sell_token, + buy_token_address as buy_token, + atoms_bought, + 0x9008d19f58aabd9ed0d60971565aa8510560ab41 as contract_address, + case + when trader = 0x9008d19f58aabd9ed0d60971565aa8510560ab41 + then 0x0000000000000000000000000000000000000001 + else trader + end as trader_in, + atoms_sold - coalesce(surplus_fee, cast(0 as uint256)) as atoms_sold + from cow_protocol_ethereum.trades as t + inner join cow_protocol_ethereum.batches as b + on t.tx_hash = b.tx_hash + left outer join cow_protocol_ethereum.order_rewards as f + on + t.tx_hash = f.tx_hash + and t.order_uid = f.order_uid + where + b.block_number >= (select start_block from block_range) and b.block_number <= (select end_block from block_range) + and t.block_number >= (select start_block from block_range) and t.block_number <= (select end_block from block_range) + and (b.solver_address = from_hex('{{solver_address}}') or '{{solver_address}}' = '0x') + and (t.tx_hash = from_hex('{{tx_hash}}') or '{{tx_hash}}' = '0x') +), + +batchwise_traders as ( + select + tx_hash, + block_number, + array_agg(trader_in) as traders_in, + array_agg(trader_out) as traders_out + from filtered_trades + group by tx_hash, block_number +), + +user_in as ( + select + tx_hash, + trader_in as sender, + contract_address as receiver, + sell_token as token, + cast(atoms_sold as int256) as amount_wei, + 'IN_USER' as transfer_type + from filtered_trades +), + +user_out as ( + select + tx_hash, + contract_address as sender, + trader_out as receiver, + buy_token as token, + cast(atoms_bought as int256) as amount_wei, + 'OUT_USER' as transfer_type + from filtered_trades +), + +other_transfers as ( + select + b.tx_hash, + "from" as sender, + to as receiver, + t.contract_address as token, + cast(value as int256) as amount_wei, + case + when to = 0x9008d19f58aabd9ed0d60971565aa8510560ab41 + then 'IN_AMM' + when "from" = 0x9008d19f58aabd9ed0d60971565aa8510560ab41 + then 'OUT_AMM' + end as transfer_type + from erc20_ethereum.evt_Transfer as t + inner join cow_protocol_ethereum.batches as b + on + evt_block_number = b.block_number + and evt_tx_hash = b.tx_hash + inner join batchwise_traders as bt + on evt_tx_hash = bt.tx_hash + where + b.block_number >= (select start_block from block_range) and b.block_number <= (select end_block from block_range) + and 0x9008d19f58aabd9ed0d60971565aa8510560ab41 in (to, "from") + and not contains(traders_in, "from") + and not contains(traders_out, to) + and to != "from" + and "from" not in ( -- ETH FLOW ORDERS ARE NOT AMM TRANSFERS! + select distinct contract_address + from cow_protocol_ethereum.CoWSwapEthFlow_evt_OrderPlacement + ) + and (t.evt_tx_hash = from_hex('{{tx_hash}}') or '{{tx_hash}}' = '0x') + and (solver_address = from_hex('{{solver_address}}') or '{{solver_address}}' = '0x') +), + +eth_transfers as ( + select + bt.tx_hash, + "from" as sender, + to as receiver, + 0xeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeee as token, + cast(value as int256) as amount_wei, + case + when 0x9008d19f58aabd9ed0d60971565aa8510560ab41 = to + then 'AMM_IN' + else 'AMM_OUT' + end as transfer_type + from batchwise_traders as bt + inner join ethereum.traces as et + on + bt.block_number = et.block_number + and bt.tx_hash = et.tx_hash + and value > cast(0 as uint256) + and success = true + and 0x9008d19f58aabd9ed0d60971565aa8510560ab41 in (to, "from") + -- WETH unwraps don't have cancelling WETH transfer. + and not 0xc02aaa39b223fe8d0a0e5c4f27ead9083c756cc2 in (to, "from") + -- ETH transfers to traders are already part of USER_OUT + and not contains(traders_out, to) +), + +-- sDAI emits only one transfer event for deposits and withdrawals. +-- This reconstructs the missing transfer from event logs. +sdai_deposit_withdrawal_transfers as ( + -- withdraw events result in additional AMM_IN transfer + select + tx_hash, + 0x9008d19f58aabd9ed0d60971565aa8510560ab41 as sender, + 0x0000000000000000000000000000000000000000 as receiver, + contract_address as token, + cast(shares as int256) as amount_wei, + 'AMM_IN' as transfer_type + from batch_meta as bm + inner join maker_ethereum.SavingsDai_evt_Withdraw as w + on bm.tx_hash = w.evt_tx_hash + where owner = 0x9008d19f58aabd9ed0d60971565aa8510560ab41 + union all + -- deposit events result in additional AMM_OUT transfer + select + tx_hash, + 0x0000000000000000000000000000000000000000 as sender, + 0x9008d19f58aabd9ed0d60971565aa8510560ab41 as receiver, + contract_address as token, + cast(shares as int256) as amount_wei, + 'AMM_OUT' as transfer_type + from batch_meta as bm + inner join maker_ethereum.SavingsDai_evt_Deposit as w + on bm.tx_hash = w.evt_tx_hash + where owner = 0x9008d19f58aabd9ed0d60971565aa8510560ab41 +), + +all_transfers_temp as ( + select * from user_in + union all + select * from user_out + union all + select * from other_transfers + union all + select * from eth_transfers + union all + select * from sdai_deposit_withdrawal_transfers +), + +pre_batch_transfers as ( + select * from all_transfers_temp + order by tx_hash +), + +batch_transfers as ( + select + block_time, + block_number, + pbt.tx_hash, + dex_swaps, + num_trades, + solver_address, + sender, + receiver, + token, + amount_wei, + transfer_type + from batch_meta as bm + inner join pre_batch_transfers as pbt + on bm.tx_hash = pbt.tx_hash +), + +incoming_and_outgoing_temp as ( + select + block_time, + tx_hash, + dex_swaps, + solver_address, + transfer_type, + case + when t.symbol = 'ETH' then 'WETH' + when t.symbol is not null then t.symbol + else cast(i.token as varchar) + end as symbol, + case + when token = 0xeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeee + then 0xc02aaa39b223fe8d0a0e5c4f27ead9083c756cc2 + else token + end as token, + case + when receiver = 0x9008d19f58aabd9ed0d60971565aa8510560ab41 + then amount_wei + when sender = 0x9008d19f58aabd9ed0d60971565aa8510560ab41 + then cast(-1 as int256) * amount_wei + end as amount + from batch_transfers as i + left outer join tokens.erc20 as t + on + i.token = t.contract_address + and blockchain = 'ethereum' +), + +incoming_and_outgoing as ( + select + block_time, + tx_hash, + solver_address, + symbol, + token, + amount, + transfer_type + from incoming_and_outgoing_temp + order by block_time +), + +-- add correction for protocol fees +raw_protocol_fee_data as ( + select + order_uid, + tx_hash, + cast(cast(data.protocol_fee as varchar) as int256) as protocol_fee, + data.protocol_fee_token, + cast(cast(data.surplus_fee as varchar) as int256) as surplus_fee, + solver, + symbol + from cowswap.raw_order_rewards + inner join tokens.erc20 as t + on + t.contract_address = from_hex(data.protocol_fee_token) + and blockchain = 'ethereum' + where + block_number >= (select start_block from block_range) and block_number <= (select end_block from block_range) + and data.protocol_fee_native_price > 0 +), + +buy_token_imbalance_due_to_protocol_fee as ( + select + t.block_time, + symbol, + t.buy_token_address as token, + 'protocol_fee_correction' as transfer_type, + from_hex(r.tx_hash) as tx_hash, + from_hex(r.solver) as solver_address, + (-1) * r.protocol_fee as amount + from raw_protocol_fee_data as r + inner join cow_protocol_ethereum.trades as t + on from_hex(r.order_uid) = t.order_uid and from_hex(r.tx_hash) = t.tx_hash + where t.order_type = 'SELL' +), + +sell_token_imbalance_due_to_protocol_fee as ( + select + t.block_time, + symbol, + t.sell_token_address as token, + 'protocol_fee_correction' as transfer_type, + from_hex(r.tx_hash) as tx_hash, + from_hex(r.solver) as solver_address, + r.protocol_fee * (t.atoms_sold - r.surplus_fee) / t.atoms_bought as amount + from raw_protocol_fee_data as r + inner join cow_protocol_ethereum.trades as t + on from_hex(r.order_uid) = t.order_uid and from_hex(r.tx_hash) = t.tx_hash + where t.order_type = 'SELL' +), + +incoming_and_outgoing_premerge as ( + select * from incoming_and_outgoing + union all + select * from buy_token_imbalance_due_to_protocol_fee + union all + select * from sell_token_imbalance_due_to_protocol_fee +), + +incoming_and_outgoing_final as ( + select + block_time, + tx_hash, + solver_address, + symbol, + amount, + transfer_type, + case + when token = 0xeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeee then 0xc02aaa39b223fe8d0a0e5c4f27ead9083c756cc2 + else token + end as token + from incoming_and_outgoing_premerge + order by block_time +), + +-- These batches involve a token that either does not emit standard transfer events, +-- or has some inaccurate price in Dune. +excluded_batches as ( + select tx_hash from query_3490353 +), + +final_token_balance_sheet as ( + select + solver_address, + symbol, + token, + tx_hash, + sum(amount) as token_imbalance_wei, + date_trunc('hour', block_time) as hour + from + incoming_and_outgoing_final + where tx_hash not in (select tx_hash from excluded_batches) + group by + symbol, token, solver_address, tx_hash, block_time + having + sum(amount) != cast(0 as int256) +) + +select * from final_token_balance_sheet diff --git a/cowprotocol/accounting/rewards/mainnet/slippage_query_3427730.sql b/cowprotocol/accounting/rewards/mainnet/slippage_query_3427730.sql index db5ed9b5..175a0804 100644 --- a/cowprotocol/accounting/rewards/mainnet/slippage_query_3427730.sql +++ b/cowprotocol/accounting/rewards/mainnet/slippage_query_3427730.sql @@ -1,439 +1,118 @@ -- https://github.com/cowprotocol/solver-rewards/pull/342 with block_range as ( - select - min("number") as start_block, - max("number") as end_block - from ethereum.blocks - where time >= cast('{{start_time}}' as timestamp) and time < cast('{{end_time}}' as timestamp) -) -,batch_meta as ( - select b.block_time, - b.block_number, - b.tx_hash, - case - when dex_swaps = 0 - -- Estimation made here: https://dune.com/queries/1646084 - then cast((gas_used - 73688 - (70528 * num_trades)) / 90000 as int) - else dex_swaps - end as dex_swaps, - num_trades, - b.solver_address - from cow_protocol_ethereum.batches b - where b.block_number >= (select start_block from block_range) and b.block_number <= (select end_block from block_range) - and (b.solver_address = from_hex('{{solver_address}}') or '{{solver_address}}' = '0x') - and (b.tx_hash = from_hex('{{tx_hash}}') or '{{tx_hash}}' = '0x') -) -,filtered_trades as ( - select t.tx_hash, - b.block_number, - case - when trader = 0x9008d19f58aabd9ed0d60971565aa8510560ab41 - then 0x0000000000000000000000000000000000000001 - else trader - end as trader_in, - receiver as trader_out, - sell_token_address as sell_token, - buy_token_address as buy_token, - atoms_sold - coalesce(surplus_fee, cast(0 as uint256)) as atoms_sold, - atoms_bought, - 0x9008d19f58aabd9ed0d60971565aa8510560ab41 as contract_address - from cow_protocol_ethereum.trades t - join cow_protocol_ethereum.batches b - on t.tx_hash = b.tx_hash - left outer join cow_protocol_ethereum.order_rewards f - on f.tx_hash = t.tx_hash - and f.order_uid = t.order_uid - where b.block_number >= (select start_block from block_range) and b.block_number <= (select end_block from block_range) - and t.block_number >= (select start_block from block_range) and t.block_number <= (select end_block from block_range) - and (b.solver_address = from_hex('{{solver_address}}') or '{{solver_address}}' = '0x') - and (t.tx_hash = from_hex('{{tx_hash}}') or '{{tx_hash}}' = '0x') -) -,batchwise_traders as ( - select - tx_hash, - block_number, - array_agg(trader_in) as traders_in, - array_agg(trader_out) as traders_out - from filtered_trades - group by tx_hash, block_number -) -,user_in as ( - select - tx_hash, - trader_in as sender, - contract_address as receiver, - sell_token as token, - cast(atoms_sold as int256) as amount_wei, - 'IN_USER' as transfer_type - from filtered_trades -) -,user_out as ( - select tx_hash, - contract_address as sender, - trader_out as receiver, - buy_token as token, - cast(atoms_bought as int256) as amount_wei, - 'OUT_USER' as transfer_type - from filtered_trades -) -,other_transfers as ( - select b.tx_hash, - "from" as sender, - to as receiver, - t.contract_address as token, - cast(value as int256) as amount_wei, - case - when to = 0x9008d19f58aabd9ed0d60971565aa8510560ab41 - then 'IN_AMM' - when "from" = 0x9008d19f58aabd9ed0d60971565aa8510560ab41 - then 'OUT_AMM' - end as transfer_type - from erc20_ethereum.evt_Transfer t - inner join cow_protocol_ethereum.batches b - on evt_block_number = b.block_number - and evt_tx_hash = b.tx_hash - inner join batchwise_traders bt - on evt_tx_hash = bt.tx_hash - where b.block_number >= (select start_block from block_range) and b.block_number <= (select end_block from block_range) - and 0x9008d19f58aabd9ed0d60971565aa8510560ab41 in (to, "from") - and not contains(traders_in, "from") - and not contains(traders_out, to) - and to != "from" - and "from" not in ( -- ETH FLOW ORDERS ARE NOT AMM TRANSFERS! - select distinct contract_address - from cow_protocol_ethereum.CoWSwapEthFlow_evt_OrderPlacement - ) - and (t.evt_tx_hash = from_hex('{{tx_hash}}') or '{{tx_hash}}' = '0x') - and (solver_address = from_hex('{{solver_address}}') or '{{solver_address}}' = '0x') -) -,eth_transfers as ( - select - bt.tx_hash, - "from" as sender, - to as receiver, - 0xeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeee as token, - cast(value as int256) as amount_wei, - case - when 0x9008d19f58aabd9ed0d60971565aa8510560ab41 = to - then 'AMM_IN' - else 'AMM_OUT' - end as transfer_type - from batchwise_traders bt - inner join ethereum.traces et - on bt.block_number = et.block_number - and bt.tx_hash = et.tx_hash - and value > cast(0 as uint256) - and success = true - and 0x9008d19f58aabd9ed0d60971565aa8510560ab41 in (to, "from") - -- WETH unwraps don't have cancelling WETH transfer. - and not 0xc02aaa39b223fe8d0a0e5c4f27ead9083c756cc2 in (to, "from") - -- ETH transfers to traders are already part of USER_OUT - and not contains(traders_out, to) -) --- sDAI emits only one transfer event for deposits and withdrawals. --- This reconstructs the missing transfer from event logs. -,sdai_deposit_withdrawal_transfers as ( - -- withdraw events result in additional AMM_IN transfer - select - tx_hash, - 0x9008d19f58aabd9ed0d60971565aa8510560ab41 as sender, - 0x0000000000000000000000000000000000000000 as receiver, - contract_address as token, - cast(shares as int256) as amount_wei, - 'AMM_IN' as transfer_type - from batch_meta bm - join maker_ethereum.SavingsDai_evt_Withdraw w - on w.evt_tx_hash= bm.tx_hash - where owner = 0x9008d19f58aabd9ed0d60971565aa8510560ab41 - union all - -- deposit events result in additional AMM_OUT transfer - select - tx_hash, - 0x0000000000000000000000000000000000000000 as sender, - 0x9008d19f58aabd9ed0d60971565aa8510560ab41 as receiver, - contract_address as token, - cast(shares as int256) as amount_wei, - 'AMM_OUT' as transfer_type - from batch_meta bm - join maker_ethereum.SavingsDai_evt_Deposit w - on w.evt_tx_hash= bm.tx_hash - where owner = 0x9008d19f58aabd9ed0d60971565aa8510560ab41 -) -,pre_batch_transfers as ( - select * from ( - select * from user_in - union all - select * from user_out - union all - select * from other_transfers - union all - select * from eth_transfers - union all - select * from sdai_deposit_withdrawal_transfers - ) as _ - order by tx_hash -) -,batch_transfers as ( - select - block_time, - block_number, - pbt.tx_hash, - dex_swaps, - num_trades, - solver_address, - sender, - receiver, - token, - amount_wei, - transfer_type - from batch_meta bm - join pre_batch_transfers pbt - on bm.tx_hash = pbt.tx_hash -) -,incoming_and_outgoing as ( - SELECT - block_time, - tx_hash, - dex_swaps, - solver_address, - case - when t.symbol = 'ETH' then 'WETH' - when t.symbol is not null then t.symbol - else cast(i.token as varchar) - end as symbol, - case - when token = 0xeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeee - then 0xc02aaa39b223fe8d0a0e5c4f27ead9083c756cc2 - else token - end as token, - case - when receiver = 0x9008d19f58aabd9ed0d60971565aa8510560ab41 - then amount_wei - when sender = 0x9008d19f58aabd9ed0d60971565aa8510560ab41 - then cast(-1 as int256) * amount_wei - end as amount, - transfer_type - from batch_transfers i - left outer join tokens.erc20 t - on i.token = t.contract_address - and blockchain = 'ethereum' -) + select * from "query_3333356(start_time='{{start_time}}',end_time='{{end_time}}')" +), -,internalized_imbalances as ( - select b.block_time, - b.tx_hash, - b.solver_address, - t.symbol, - from_hex(i.token) as token, - cast(cast(i.amount as varchar) as int256) as amount, - 'PHANTOM_TRANSFER' as transfer_type - from cowswap.raw_internal_imbalance i - inner join cow_protocol_ethereum.batches b - on i.block_number = b.block_number - and from_hex(i.tx_hash) = b.tx_hash - join tokens.erc20 t - on contract_address = from_hex(token) - and blockchain = 'ethereum' - where i.block_number >= (select start_block from block_range) and i.block_number <= (select end_block from block_range) - and ('{{solver_address}}' = '0x' or b.solver_address = from_hex('{{solver_address}}')) - and ('{{tx_hash}}' = '0x' or b.tx_hash = from_hex('{{tx_hash}}')) -) -,incoming_and_outgoing_with_internalized_imbalances_temp as ( - select * from ( - select block_time, - tx_hash, - solver_address, - symbol, - token, - amount, - transfer_type - from incoming_and_outgoing - union all - select * from internalized_imbalances - ) as _ - order by block_time -) --- add correction for protocol fees -,raw_protocol_fee_data as ( - select - order_uid, - tx_hash, - cast(cast(data.protocol_fee as varchar) as int256) as protocol_fee, - data.protocol_fee_token as protocol_fee_token, - cast(cast(data.surplus_fee as varchar) as int256) as surplus_fee, - solver, - symbol - from cowswap.raw_order_rewards ror - join tokens.erc20 t - on t.contract_address = from_hex(ror.data.protocol_fee_token) - and blockchain = 'ethereum' - where - block_number >= (select start_block from block_range) and block_number <= (select end_block from block_range) - and data.protocol_fee_native_price > 0 -) -,buy_token_imbalance_due_to_protocol_fee as ( - select - t.block_time as block_time, - from_hex(r.tx_hash) as tx_hash, - from_hex(r.solver) as solver_address, - symbol, - t.buy_token_address as token, - (-1) * r.protocol_fee as amount, - 'protocol_fee_correction' as transfer_type - from raw_protocol_fee_data r - join cow_protocol_ethereum.trades t - on from_hex(r.order_uid) = t.order_uid and from_hex(r.tx_hash) = t.tx_hash - where t.order_type='SELL' -) -,sell_token_imbalance_due_to_protocol_fee as ( - select - t.block_time as block_time, - from_hex(r.tx_hash) as tx_hash, - from_hex(r.solver) as solver_address, - symbol, - t.sell_token_address as token, - r.protocol_fee * (t.atoms_sold - r.surplus_fee) / t.atoms_bought as amount, - 'protocol_fee_correction' as transfer_type - from raw_protocol_fee_data r - join cow_protocol_ethereum.trades t - on from_hex(r.order_uid) = t.order_uid and from_hex(r.tx_hash) = t.tx_hash - where t.order_type='SELL' -) -,incoming_and_outgoing_with_internalized_imbalances_unmerged as ( - select * from ( - select * from incoming_and_outgoing_with_internalized_imbalances_temp - union all - select * from buy_token_imbalance_due_to_protocol_fee - union all - select * from sell_token_imbalance_due_to_protocol_fee - ) as _ - order by block_time -) -,incoming_and_outgoing_with_internalized_imbalances as ( - select - block_time, - tx_hash, - solver_address, - symbol, - CASE - WHEN token = 0xeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeee then 0xc02aaa39b223fe8d0a0e5c4f27ead9083c756cc2 - ELSE token - END as token, - amount, - transfer_type - from incoming_and_outgoing_with_internalized_imbalances_unmerged -) --- These batches involve a token who do not emit standard transfer events. --- These batches are excluded due to inaccurate prices. -,excluded_batches as ( - select tx_hash from query_3490353 -) ,final_token_balance_sheet as ( select - solver_address, - sum(amount) token_imbalance_wei, - symbol, - token, - tx_hash, - date_trunc('hour', block_time) as hour + * from - incoming_and_outgoing_with_internalized_imbalances - where tx_hash not in (select tx_hash from excluded_batches) - group by - symbol, token, solver_address, tx_hash, block_time - having - sum(amount) != cast(0 as int256) + "query_4057345(start_time='{{start_time}}',end_time='{{end_time}}',tx_hash='{{tx_hash}}',solver_address='{{solver_address}}')" ) -,token_times as ( - select hour, token + +token_times as ( + select + hour, + token from final_token_balance_sheet group by hour, token -) -,precise_prices as ( +), + +precise_prices as ( select contract_address, decimals, date_trunc('hour', minute) as hour, avg( - CASE - WHEN (price > 10 and contract_address = 0xdef1ca1fb7fbcdc777520aa7f396b4e015f497ab) then 0.26 -- dirty fix for some bogus COW prices Dune reports on July 29, 2024 - ELSE price - END + case + when (price > 10 and contract_address = 0xdef1ca1fb7fbcdc777520aa7f396b4e015f497ab) then 0.26 -- dirty fix for some bogus COW prices Dune reports on July 29, 2024 + else price + end ) as price from - prices.usd pusd - inner join token_times tt - on minute between date(hour) and date(hour) + interval '1' day -- query execution speed optimization since minute is indexed - and date_trunc('hour', minute) = hour - and contract_address = token - and blockchain = 'ethereum' + prices.usd + inner join token_times + on + minute between date(hour) and date(hour) + interval '1' day -- query execution speed optimization since minute is indexed + and date_trunc('hour', minute) = hour + and contract_address = token + and blockchain = 'ethereum' group by contract_address, decimals, date_trunc('hour', minute) -) -,intrinsic_prices as ( +), + +intrinsic_prices as ( select contract_address, decimals, hour, - AVG(price) as price + avg(price) as price from ( select buy_token_address as contract_address, - ROUND(LOG(10, atoms_bought / units_bought)) as decimals, + round(log(10, atoms_bought / units_bought)) as decimals, date_trunc('hour', block_time) as hour, usd_value / units_bought as price - FROM cow_protocol_ethereum.trades - WHERE block_number >= (select start_block from block_range) and block_number <= (select end_block from block_range) - AND units_bought > 0 - UNION + from cow_protocol_ethereum.trades + where + block_number >= (select start_block from block_range) and block_number <= (select end_block from block_range) + and units_bought > 0 + union distinct select sell_token_address as contract_address, - ROUND(LOG(10, atoms_sold / units_sold)) as decimals, + round(log(10, atoms_sold / units_sold)) as decimals, date_trunc('hour', block_time) as hour, usd_value / units_sold as price - FROM cow_protocol_ethereum.trades - WHERE block_number >= (select start_block from block_range) and block_number <= (select end_block from block_range) - AND units_sold > 0 + from cow_protocol_ethereum.trades + where + block_number >= (select start_block from block_range) and block_number <= (select end_block from block_range) + and units_sold > 0 ) as combined - GROUP BY hour, contract_address, decimals + group by hour, contract_address, decimals order by hour -) +), + -- -- Price Construction: https://dune.com/queries/1579091? -,prices as ( +prices as ( select - tt.hour as hour, + tt.hour, tt.token as contract_address, - COALESCE( + coalesce( precise.decimals, intrinsic.decimals ) as decimals, - COALESCE( + coalesce( precise.price, intrinsic.price ) as price - from token_times tt - LEFT JOIN precise_prices precise - ON precise.hour = tt.hour - AND precise.contract_address = token - LEFT JOIN intrinsic_prices intrinsic - ON intrinsic.hour = tt.hour - and intrinsic.contract_address = token -) + from token_times as tt + left join precise_prices as precise + on + tt.hour = precise.hour + and precise.contract_address = token + left join intrinsic_prices as intrinsic + on + tt.hour = intrinsic.hour + and intrinsic.contract_address = token +), + -- -- ETH Prices: https://dune.com/queries/1578626?d=1 -,eth_prices as ( +eth_prices as ( select date_trunc('hour', minute) as hour, avg(price) as eth_price from prices.usd - where blockchain = 'ethereum' - and contract_address = 0xc02aaa39b223fe8d0a0e5c4f27ead9083c756cc2 - and minute between cast('{{start_time}}' as timestamp) and cast('{{end_time}}' as timestamp) + where + blockchain = 'ethereum' + and contract_address = 0xc02aaa39b223fe8d0a0e5c4f27ead9083c756cc2 + and minute between cast('{{start_time}}' as timestamp) and cast('{{end_time}}' as timestamp) group by date_trunc('hour', minute) -) -,results_per_tx as ( +), + +results_per_tx as ( select ftbs.hour, tx_hash, @@ -442,11 +121,12 @@ block_range as ( sum(cast(token_imbalance_wei as double) * price / pow(10, p.decimals) / eth_price) * pow(10, 18) as eth_slippage_wei, count(*) as num_entries from - final_token_balance_sheet ftbs - left join prices p - on token = p.contract_address - and p.hour = ftbs.hour - left join eth_prices ep + final_token_balance_sheet as ftbs + left join prices as p + on + token = p.contract_address + and ftbs.hour = p.hour + left join eth_prices as ep on ftbs.hour = ep.hour group by ftbs.hour, @@ -454,8 +134,9 @@ block_range as ( tx_hash having bool_and(price is not null) -) -,results as ( +), + +results as ( select solver_address, concat(environment, '-', name) as solver_name, @@ -470,11 +151,12 @@ block_range as ( '" target="_blank">link' ) as batchwise_breakdown from - results_per_tx rpt - join cow_protocol_ethereum.solvers + results_per_tx + inner join cow_protocol_ethereum.solvers on address = solver_address group by solver_address, concat(environment, '-', name) ) + select * from {{cte_name}} From 688aabc610416894c4e15c43597c01fbe24e9531 Mon Sep 17 00:00:00 2001 From: harisang Date: Thu, 12 Sep 2024 03:40:53 +0300 Subject: [PATCH 03/12] clean up some comments --- .../rewards/mainnet/excluded_batches_query_3490353.sql | 7 +++---- 1 file changed, 3 insertions(+), 4 deletions(-) diff --git a/cowprotocol/accounting/rewards/mainnet/excluded_batches_query_3490353.sql b/cowprotocol/accounting/rewards/mainnet/excluded_batches_query_3490353.sql index 3e4db147..3e00ea21 100644 --- a/cowprotocol/accounting/rewards/mainnet/excluded_batches_query_3490353.sql +++ b/cowprotocol/accounting/rewards/mainnet/excluded_batches_query_3490353.sql @@ -19,15 +19,14 @@ where or 0xe2f95ee8B72fFed59bC4D2F35b1d19b909A6e6b3 in (buy_token_address, sell_token_address) -- exclude EGGX or 0xd5C02bB3e40494D4674778306Da43a56138A383E in (buy_token_address, sell_token_address) -- exclude OMNI404 or 0x92715b8F93729c0B014213f769EF493baecEDACC in (buy_token_address, sell_token_address) -- exclude WIFU 404 - or 0x413530a7beB9Ff6C44e9e6C9001C93B785420C32 in (buy_token_address, sell_token_address) -- exclude PFPAsia. NEEDS TO BE REMOVED FROM THIS LIST - or 0xe7468080c033cE50Dd09A22ad1E58D1BDA69E436 in (buy_token_address, sell_token_address) -- exclude YUMYUM. NEEDS TO BE REMOVED FROM THIS LIST + or 0x413530a7beB9Ff6C44e9e6C9001C93B785420C32 in (buy_token_address, sell_token_address) -- exclude PFPAsia. + or 0xe7468080c033cE50Dd09A22ad1E58D1BDA69E436 in (buy_token_address, sell_token_address) -- exclude YUMYUM. or tx_hash = 0x41418cef26e608ed47a5c4997833caaa2366a0163173286140da28a32e37b25d -- temporary solution or tx_hash = 0xdf415f3048d401c9ca7bf079722be96aaed3d2d2b5c0e12b7dc75d6eec30b3d4 -- temporary solution or tx_hash = 0x15b9906aa2039ccbc9ae9fab0f0c7517e9c88c41b74cd8a09f202803d37f6341 -- temporary solution or tx_hash = 0x3a71df0f6898b229c3643d4703b56d7510d455c65649cb364e5b69cadf5d1d37 -- temporary solution or tx_hash = 0xc9bcb4c8c68d4edcb97403131d28416a418ae537c43e9feca50f11ca744c079e -- temporary solution - -- the following 2 stable-to-stable trades Otex settled. Due to inaccurate accounting, and since Otex has more of those, - -- I decided to remove 2 of those to mitigate the inaccuracies resulting from the rest + -- for week of Feb 13, 2024 until Feb 20, 2024 or tx_hash = 0x60157b1891dbdbcdc88c637079c4c9e37d5fe943bf3ffff14412b33bf7125ad1 or tx_hash = 0x414e72fa7c061a1b2c5905f21e41d8cb5500ec9043b65b317cd20362f4eff757 or tx_hash = 0x829d0583b647581cdd8f01f62e6715a7c6333b499f164995601217bde1976a09 -- internalization involving PANDORA From e06bf647de66e77906463738ebf9f7633b26810f Mon Sep 17 00:00:00 2001 From: harisang Date: Thu, 12 Sep 2024 12:12:37 +0300 Subject: [PATCH 04/12] small cleanup --- .../mainnet/processed_token_imbalances_4057345.sql | 12 +----------- 1 file changed, 1 insertion(+), 11 deletions(-) diff --git a/cowprotocol/accounting/rewards/mainnet/processed_token_imbalances_4057345.sql b/cowprotocol/accounting/rewards/mainnet/processed_token_imbalances_4057345.sql index b22d5b58..87b1288a 100644 --- a/cowprotocol/accounting/rewards/mainnet/processed_token_imbalances_4057345.sql +++ b/cowprotocol/accounting/rewards/mainnet/processed_token_imbalances_4057345.sql @@ -8,14 +8,7 @@ batch_meta as ( b.block_time, b.block_number, b.tx_hash, - b.num_trades, - b.solver_address, - case - when dex_swaps = 0 - -- Estimation made here: https://dune.com/queries/1646084 - then cast((b.gas_used - 73688 - (70528 * b.num_trades)) / 90000 as int) - else dex_swaps - end as dex_swaps + b.solver_address from cow_protocol_ethereum.batches as b where b.block_number >= (select start_block from block_range) and b.block_number <= (select end_block from block_range) @@ -196,8 +189,6 @@ batch_transfers as ( block_time, block_number, pbt.tx_hash, - dex_swaps, - num_trades, solver_address, sender, receiver, @@ -213,7 +204,6 @@ incoming_and_outgoing_temp as ( select block_time, tx_hash, - dex_swaps, solver_address, transfer_type, case From af42aa4d5a73a60f7cdaac285fdacc2c923d468c Mon Sep 17 00:00:00 2001 From: harisang Date: Sat, 14 Sep 2024 00:58:48 +0300 Subject: [PATCH 05/12] simplifications --- .../processed_token_imbalances_4057345.sql | 36 +++++-------------- 1 file changed, 8 insertions(+), 28 deletions(-) diff --git a/cowprotocol/accounting/rewards/mainnet/processed_token_imbalances_4057345.sql b/cowprotocol/accounting/rewards/mainnet/processed_token_imbalances_4057345.sql index 87b1288a..35c6412e 100644 --- a/cowprotocol/accounting/rewards/mainnet/processed_token_imbalances_4057345.sql +++ b/cowprotocol/accounting/rewards/mainnet/processed_token_imbalances_4057345.sql @@ -12,8 +12,6 @@ batch_meta as ( from cow_protocol_ethereum.batches as b where b.block_number >= (select start_block from block_range) and b.block_number <= (select end_block from block_range) - and (b.solver_address = from_hex('{{solver_address}}') or '{{solver_address}}' = '0x') - and (b.tx_hash = from_hex('{{tx_hash}}') or '{{tx_hash}}' = '0x') ), filtered_trades as ( @@ -30,6 +28,9 @@ filtered_trades as ( then 0x0000000000000000000000000000000000000001 else trader end as trader_in, + -- here we aim to account for network fee. However, in case there is also a protocol fee + -- the surplus_fee accounts for that so there needs to be a correction here, that happens + -- a bit later on in this long query. atoms_sold - coalesce(surplus_fee, cast(0 as uint256)) as atoms_sold from cow_protocol_ethereum.trades as t inner join cow_protocol_ethereum.batches as b @@ -39,10 +40,7 @@ filtered_trades as ( t.tx_hash = f.tx_hash and t.order_uid = f.order_uid where - b.block_number >= (select start_block from block_range) and b.block_number <= (select end_block from block_range) - and t.block_number >= (select start_block from block_range) and t.block_number <= (select end_block from block_range) - and (b.solver_address = from_hex('{{solver_address}}') or '{{solver_address}}' = '0x') - and (t.tx_hash = from_hex('{{tx_hash}}') or '{{tx_hash}}' = '0x') + t.block_number >= (select start_block from block_range) and t.block_number <= (select end_block from block_range) ), batchwise_traders as ( @@ -107,8 +105,6 @@ other_transfers as ( select distinct contract_address from cow_protocol_ethereum.CoWSwapEthFlow_evt_OrderPlacement ) - and (t.evt_tx_hash = from_hex('{{tx_hash}}') or '{{tx_hash}}' = '0x') - and (solver_address = from_hex('{{solver_address}}') or '{{solver_address}}' = '0x') ), eth_transfers as ( @@ -179,16 +175,11 @@ all_transfers_temp as ( select * from sdai_deposit_withdrawal_transfers ), -pre_batch_transfers as ( - select * from all_transfers_temp - order by tx_hash -), - batch_transfers as ( select block_time, block_number, - pbt.tx_hash, + att.tx_hash, solver_address, sender, receiver, @@ -196,8 +187,8 @@ batch_transfers as ( amount_wei, transfer_type from batch_meta as bm - inner join pre_batch_transfers as pbt - on bm.tx_hash = pbt.tx_hash + inner join all_transfers_temp as att + on bm.tx_hash = att.tx_hash ), incoming_and_outgoing_temp as ( @@ -206,11 +197,6 @@ incoming_and_outgoing_temp as ( tx_hash, solver_address, transfer_type, - case - when t.symbol = 'ETH' then 'WETH' - when t.symbol is not null then t.symbol - else cast(i.token as varchar) - end as symbol, case when token = 0xeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeee then 0xc02aaa39b223fe8d0a0e5c4f27ead9083c756cc2 @@ -234,7 +220,6 @@ incoming_and_outgoing as ( block_time, tx_hash, solver_address, - symbol, token, amount, transfer_type @@ -251,7 +236,6 @@ raw_protocol_fee_data as ( data.protocol_fee_token, cast(cast(data.surplus_fee as varchar) as int256) as surplus_fee, solver, - symbol from cowswap.raw_order_rewards inner join tokens.erc20 as t on @@ -265,7 +249,6 @@ raw_protocol_fee_data as ( buy_token_imbalance_due_to_protocol_fee as ( select t.block_time, - symbol, t.buy_token_address as token, 'protocol_fee_correction' as transfer_type, from_hex(r.tx_hash) as tx_hash, @@ -280,7 +263,6 @@ buy_token_imbalance_due_to_protocol_fee as ( sell_token_imbalance_due_to_protocol_fee as ( select t.block_time, - symbol, t.sell_token_address as token, 'protocol_fee_correction' as transfer_type, from_hex(r.tx_hash) as tx_hash, @@ -305,7 +287,6 @@ incoming_and_outgoing_final as ( block_time, tx_hash, solver_address, - symbol, amount, transfer_type, case @@ -325,7 +306,6 @@ excluded_batches as ( final_token_balance_sheet as ( select solver_address, - symbol, token, tx_hash, sum(amount) as token_imbalance_wei, @@ -334,7 +314,7 @@ final_token_balance_sheet as ( incoming_and_outgoing_final where tx_hash not in (select tx_hash from excluded_batches) group by - symbol, token, solver_address, tx_hash, block_time + token, solver_address, tx_hash, block_time having sum(amount) != cast(0 as int256) ) From 9005e6ccb4969afaf3852a092ca8db1a39d29283 Mon Sep 17 00:00:00 2001 From: harisang Date: Sat, 14 Sep 2024 01:45:24 +0300 Subject: [PATCH 06/12] clean up and addressing review --- .../processed_token_imbalances_4057345.sql | 20 ++++++--------- .../mainnet/slippage_query_3427730.sql | 25 ++++++------------- 2 files changed, 16 insertions(+), 29 deletions(-) diff --git a/cowprotocol/accounting/rewards/mainnet/processed_token_imbalances_4057345.sql b/cowprotocol/accounting/rewards/mainnet/processed_token_imbalances_4057345.sql index 35c6412e..ae592b74 100644 --- a/cowprotocol/accounting/rewards/mainnet/processed_token_imbalances_4057345.sql +++ b/cowprotocol/accounting/rewards/mainnet/processed_token_imbalances_4057345.sql @@ -197,11 +197,7 @@ incoming_and_outgoing_temp as ( tx_hash, solver_address, transfer_type, - case - when token = 0xeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeee - then 0xc02aaa39b223fe8d0a0e5c4f27ead9083c756cc2 - else token - end as token, + token, case when receiver = 0x9008d19f58aabd9ed0d60971565aa8510560ab41 then amount_wei @@ -232,18 +228,18 @@ raw_protocol_fee_data as ( select order_uid, tx_hash, - cast(cast(data.protocol_fee as varchar) as int256) as protocol_fee, - data.protocol_fee_token, - cast(cast(data.surplus_fee as varchar) as int256) as surplus_fee, - solver, + cast(cast(data.protocol_fee as varchar) as int256) as protocol_fee, -- noqa: RF01 + data.protocol_fee_token, -- noqa: RF01 + cast(cast(data.surplus_fee as varchar) as int256) as surplus_fee, -- noqa: RF01 + solver from cowswap.raw_order_rewards inner join tokens.erc20 as t on - t.contract_address = from_hex(data.protocol_fee_token) + t.contract_address = from_hex(data.protocol_fee_token) -- noqa: RF01 and blockchain = 'ethereum' where block_number >= (select start_block from block_range) and block_number <= (select end_block from block_range) - and data.protocol_fee_native_price > 0 + and data.protocol_fee_native_price > 0 -- noqa: RF01 ), buy_token_imbalance_due_to_protocol_fee as ( @@ -309,7 +305,7 @@ final_token_balance_sheet as ( token, tx_hash, sum(amount) as token_imbalance_wei, - date_trunc('hour', block_time) as hour + date_trunc('hour', block_time) as 'hour' from incoming_and_outgoing_final where tx_hash not in (select tx_hash from excluded_batches) diff --git a/cowprotocol/accounting/rewards/mainnet/slippage_query_3427730.sql b/cowprotocol/accounting/rewards/mainnet/slippage_query_3427730.sql index 175a0804..64278653 100644 --- a/cowprotocol/accounting/rewards/mainnet/slippage_query_3427730.sql +++ b/cowprotocol/accounting/rewards/mainnet/slippage_query_3427730.sql @@ -1,15 +1,11 @@ --- https://github.com/cowprotocol/solver-rewards/pull/342 with block_range as ( select * from "query_3333356(start_time='{{start_time}}',end_time='{{end_time}}')" ), -,final_token_balance_sheet as ( - select - * - from - "query_4057345(start_time='{{start_time}}',end_time='{{end_time}}',tx_hash='{{tx_hash}}',solver_address='{{solver_address}}')" -) +final_token_balance_sheet as ( + select * from "query_4057345(start_time='{{start_time}}',end_time='{{end_time}}')" +), token_times as ( select @@ -23,13 +19,8 @@ precise_prices as ( select contract_address, decimals, - date_trunc('hour', minute) as hour, - avg( - case - when (price > 10 and contract_address = 0xdef1ca1fb7fbcdc777520aa7f396b4e015f497ab) then 0.26 -- dirty fix for some bogus COW prices Dune reports on July 29, 2024 - else price - end - ) as price + date_trunc('hour', minute) as 'hour', + avg(price) as price from prices.usd inner join token_times @@ -54,7 +45,7 @@ intrinsic_prices as ( select buy_token_address as contract_address, round(log(10, atoms_bought / units_bought)) as decimals, - date_trunc('hour', block_time) as hour, + date_trunc('hour', block_time) as 'hour', usd_value / units_bought as price from cow_protocol_ethereum.trades where @@ -64,7 +55,7 @@ intrinsic_prices as ( select sell_token_address as contract_address, round(log(10, atoms_sold / units_sold)) as decimals, - date_trunc('hour', block_time) as hour, + date_trunc('hour', block_time) as 'hour', usd_value / units_sold as price from cow_protocol_ethereum.trades where @@ -102,7 +93,7 @@ prices as ( -- -- ETH Prices: https://dune.com/queries/1578626?d=1 eth_prices as ( select - date_trunc('hour', minute) as hour, + date_trunc('hour', minute) as 'hour', avg(price) as eth_price from prices.usd where From 74eddc2fd128a66969f2c230b93cc9a93ab40bf0 Mon Sep 17 00:00:00 2001 From: harisang Date: Sat, 14 Sep 2024 02:41:35 +0300 Subject: [PATCH 07/12] clean up balances query --- .../mainnet/processed_token_imbalances_4057345.sql | 4 ++-- .../accounting/rewards/mainnet/slippage_query_3427730.sql | 8 +++++++- 2 files changed, 9 insertions(+), 3 deletions(-) diff --git a/cowprotocol/accounting/rewards/mainnet/processed_token_imbalances_4057345.sql b/cowprotocol/accounting/rewards/mainnet/processed_token_imbalances_4057345.sql index ae592b74..bd54c3c3 100644 --- a/cowprotocol/accounting/rewards/mainnet/processed_token_imbalances_4057345.sql +++ b/cowprotocol/accounting/rewards/mainnet/processed_token_imbalances_4057345.sql @@ -304,8 +304,8 @@ final_token_balance_sheet as ( solver_address, token, tx_hash, - sum(amount) as token_imbalance_wei, - date_trunc('hour', block_time) as 'hour' + block_time, + sum(amount) as token_imbalance_wei from incoming_and_outgoing_final where tx_hash not in (select tx_hash from excluded_batches) diff --git a/cowprotocol/accounting/rewards/mainnet/slippage_query_3427730.sql b/cowprotocol/accounting/rewards/mainnet/slippage_query_3427730.sql index 64278653..83665ea8 100644 --- a/cowprotocol/accounting/rewards/mainnet/slippage_query_3427730.sql +++ b/cowprotocol/accounting/rewards/mainnet/slippage_query_3427730.sql @@ -4,7 +4,13 @@ block_range as ( ), final_token_balance_sheet as ( - select * from "query_4057345(start_time='{{start_time}}',end_time='{{end_time}}')" + select + solver_address, + token, + tx_hash, + sum(amount) as token_imbalance_wei, + date_trunc('hour', block_time) as 'hour' + from "query_4057345(start_time='{{start_time}}',end_time='{{end_time}}')" ), token_times as ( From 1468c5cea6c85a224ed0a0e09456631974180879 Mon Sep 17 00:00:00 2001 From: harisang Date: Sat, 14 Sep 2024 02:42:11 +0300 Subject: [PATCH 08/12] fix copy paste error --- .../accounting/rewards/mainnet/slippage_query_3427730.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/cowprotocol/accounting/rewards/mainnet/slippage_query_3427730.sql b/cowprotocol/accounting/rewards/mainnet/slippage_query_3427730.sql index 83665ea8..2492d469 100644 --- a/cowprotocol/accounting/rewards/mainnet/slippage_query_3427730.sql +++ b/cowprotocol/accounting/rewards/mainnet/slippage_query_3427730.sql @@ -8,7 +8,7 @@ final_token_balance_sheet as ( solver_address, token, tx_hash, - sum(amount) as token_imbalance_wei, + token_imbalance_wei, date_trunc('hour', block_time) as 'hour' from "query_4057345(start_time='{{start_time}}',end_time='{{end_time}}')" ), From 4231b04fd468d40c6d44937677e1e642a8b73ebc Mon Sep 17 00:00:00 2001 From: harisang Date: Mon, 16 Sep 2024 09:33:55 +0300 Subject: [PATCH 09/12] moved excluded hashes to main slippage query --- .../rewards/mainnet/processed_token_imbalances_4057345.sql | 7 ------- .../accounting/rewards/mainnet/slippage_query_3427730.sql | 7 +++++++ 2 files changed, 7 insertions(+), 7 deletions(-) diff --git a/cowprotocol/accounting/rewards/mainnet/processed_token_imbalances_4057345.sql b/cowprotocol/accounting/rewards/mainnet/processed_token_imbalances_4057345.sql index bd54c3c3..399aa9ff 100644 --- a/cowprotocol/accounting/rewards/mainnet/processed_token_imbalances_4057345.sql +++ b/cowprotocol/accounting/rewards/mainnet/processed_token_imbalances_4057345.sql @@ -293,12 +293,6 @@ incoming_and_outgoing_final as ( order by block_time ), --- These batches involve a token that either does not emit standard transfer events, --- or has some inaccurate price in Dune. -excluded_batches as ( - select tx_hash from query_3490353 -), - final_token_balance_sheet as ( select solver_address, @@ -308,7 +302,6 @@ final_token_balance_sheet as ( sum(amount) as token_imbalance_wei from incoming_and_outgoing_final - where tx_hash not in (select tx_hash from excluded_batches) group by token, solver_address, tx_hash, block_time having diff --git a/cowprotocol/accounting/rewards/mainnet/slippage_query_3427730.sql b/cowprotocol/accounting/rewards/mainnet/slippage_query_3427730.sql index 2492d469..ca8e1cda 100644 --- a/cowprotocol/accounting/rewards/mainnet/slippage_query_3427730.sql +++ b/cowprotocol/accounting/rewards/mainnet/slippage_query_3427730.sql @@ -3,6 +3,12 @@ block_range as ( select * from "query_3333356(start_time='{{start_time}}',end_time='{{end_time}}')" ), +-- These batches involve a token that either does not emit standard transfer events, +-- or has some inaccurate price in Dune. +excluded_batches as ( + select tx_hash from query_3490353 +), + final_token_balance_sheet as ( select solver_address, @@ -11,6 +17,7 @@ final_token_balance_sheet as ( token_imbalance_wei, date_trunc('hour', block_time) as 'hour' from "query_4057345(start_time='{{start_time}}',end_time='{{end_time}}')" + where tx_hash not in (select tx_hash from excluded_batches) ), token_times as ( From b2c03da84355750bf58440e84889cfe52fc2b50b Mon Sep 17 00:00:00 2001 From: harisang Date: Mon, 16 Sep 2024 09:46:43 +0300 Subject: [PATCH 10/12] minor edits --- .../mainnet/processed_token_imbalances_4057345.sql | 6 +++--- .../rewards/mainnet/slippage_query_3427730.sql | 14 +++++++------- 2 files changed, 10 insertions(+), 10 deletions(-) diff --git a/cowprotocol/accounting/rewards/mainnet/processed_token_imbalances_4057345.sql b/cowprotocol/accounting/rewards/mainnet/processed_token_imbalances_4057345.sql index 399aa9ff..60987145 100644 --- a/cowprotocol/accounting/rewards/mainnet/processed_token_imbalances_4057345.sql +++ b/cowprotocol/accounting/rewards/mainnet/processed_token_imbalances_4057345.sql @@ -214,11 +214,11 @@ incoming_and_outgoing_temp as ( incoming_and_outgoing as ( select block_time, + token, + transfer_type, tx_hash, solver_address, - token, - amount, - transfer_type + amount from incoming_and_outgoing_temp order by block_time ), diff --git a/cowprotocol/accounting/rewards/mainnet/slippage_query_3427730.sql b/cowprotocol/accounting/rewards/mainnet/slippage_query_3427730.sql index ca8e1cda..51d7f124 100644 --- a/cowprotocol/accounting/rewards/mainnet/slippage_query_3427730.sql +++ b/cowprotocol/accounting/rewards/mainnet/slippage_query_3427730.sql @@ -15,8 +15,8 @@ final_token_balance_sheet as ( token, tx_hash, token_imbalance_wei, - date_trunc('hour', block_time) as 'hour' - from "query_4057345(start_time='{{start_time}}',end_time='{{end_time}}')" + date_trunc('hour', block_time) as hour + from "query_4073375(start_time='{{start_time}}',end_time='{{end_time}}')" where tx_hash not in (select tx_hash from excluded_batches) ), @@ -32,7 +32,7 @@ precise_prices as ( select contract_address, decimals, - date_trunc('hour', minute) as 'hour', + date_trunc('hour', minute) as hour, avg(price) as price from prices.usd @@ -58,7 +58,7 @@ intrinsic_prices as ( select buy_token_address as contract_address, round(log(10, atoms_bought / units_bought)) as decimals, - date_trunc('hour', block_time) as 'hour', + date_trunc('hour', block_time) as hour, usd_value / units_bought as price from cow_protocol_ethereum.trades where @@ -68,7 +68,7 @@ intrinsic_prices as ( select sell_token_address as contract_address, round(log(10, atoms_sold / units_sold)) as decimals, - date_trunc('hour', block_time) as 'hour', + date_trunc('hour', block_time) as hour, usd_value / units_sold as price from cow_protocol_ethereum.trades where @@ -106,7 +106,7 @@ prices as ( -- -- ETH Prices: https://dune.com/queries/1578626?d=1 eth_prices as ( select - date_trunc('hour', minute) as 'hour', + date_trunc('hour', minute) as hour, avg(price) as eth_price from prices.usd where @@ -163,4 +163,4 @@ results as ( concat(environment, '-', name) ) -select * from {{cte_name}} +select * from results From 37a36683fdb6dc61c8aaf129a659e07084ac40c7 Mon Sep 17 00:00:00 2001 From: harisang Date: Mon, 16 Sep 2024 09:47:31 +0300 Subject: [PATCH 11/12] fix final select --- .../accounting/rewards/mainnet/slippage_query_3427730.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/cowprotocol/accounting/rewards/mainnet/slippage_query_3427730.sql b/cowprotocol/accounting/rewards/mainnet/slippage_query_3427730.sql index 51d7f124..83153027 100644 --- a/cowprotocol/accounting/rewards/mainnet/slippage_query_3427730.sql +++ b/cowprotocol/accounting/rewards/mainnet/slippage_query_3427730.sql @@ -163,4 +163,4 @@ results as ( concat(environment, '-', name) ) -select * from results +select * from {{cte_name}} From d41d92be0de04cfac81b7f1c637670d6ed71ef82 Mon Sep 17 00:00:00 2001 From: harisang Date: Mon, 16 Sep 2024 09:50:15 +0300 Subject: [PATCH 12/12] bypass sqlfluff keywords rule --- .../rewards/mainnet/slippage_query_3427730.sql | 10 +++++----- 1 file changed, 5 insertions(+), 5 deletions(-) diff --git a/cowprotocol/accounting/rewards/mainnet/slippage_query_3427730.sql b/cowprotocol/accounting/rewards/mainnet/slippage_query_3427730.sql index 83153027..c82b5f50 100644 --- a/cowprotocol/accounting/rewards/mainnet/slippage_query_3427730.sql +++ b/cowprotocol/accounting/rewards/mainnet/slippage_query_3427730.sql @@ -15,7 +15,7 @@ final_token_balance_sheet as ( token, tx_hash, token_imbalance_wei, - date_trunc('hour', block_time) as hour + date_trunc('hour', block_time) as hour --noqa: RF04 from "query_4073375(start_time='{{start_time}}',end_time='{{end_time}}')" where tx_hash not in (select tx_hash from excluded_batches) ), @@ -32,7 +32,7 @@ precise_prices as ( select contract_address, decimals, - date_trunc('hour', minute) as hour, + date_trunc('hour', minute) as hour, --noqa: RF04 avg(price) as price from prices.usd @@ -58,7 +58,7 @@ intrinsic_prices as ( select buy_token_address as contract_address, round(log(10, atoms_bought / units_bought)) as decimals, - date_trunc('hour', block_time) as hour, + date_trunc('hour', block_time) as hour, --noqa: RF04 usd_value / units_bought as price from cow_protocol_ethereum.trades where @@ -68,7 +68,7 @@ intrinsic_prices as ( select sell_token_address as contract_address, round(log(10, atoms_sold / units_sold)) as decimals, - date_trunc('hour', block_time) as hour, + date_trunc('hour', block_time) as hour, --noqa: RF04 usd_value / units_sold as price from cow_protocol_ethereum.trades where @@ -106,7 +106,7 @@ prices as ( -- -- ETH Prices: https://dune.com/queries/1578626?d=1 eth_prices as ( select - date_trunc('hour', minute) as hour, + date_trunc('hour', minute) as hour, --noqa: RF04 avg(price) as eth_price from prices.usd where