From 9d7be1483f83904c195d7d3f47294b0a0c0f852a Mon Sep 17 00:00:00 2001 From: harisang Date: Wed, 13 Nov 2024 18:08:03 +0200 Subject: [PATCH 01/21] add multiple price feeds option --- .../unusual_slippage_query_2332678.sql | 1 + cowprotocol/accounting/slippage/.sqlfluff | 1 + .../slippage/raw_slippage_4059683.sql | 2 +- .../accounting/slippage/slippage_4070065.sql | 2 +- .../slippage/slippage_prices_4064601.sql | 70 ++++++++++++++++++- 5 files changed, 73 insertions(+), 3 deletions(-) diff --git a/cowprotocol/accounting/rewards/unusual_slippage_query_2332678.sql b/cowprotocol/accounting/rewards/unusual_slippage_query_2332678.sql index 18f86ca2..3dc1e3e3 100644 --- a/cowprotocol/accounting/rewards/unusual_slippage_query_2332678.sql +++ b/cowprotocol/accounting/rewards/unusual_slippage_query_2332678.sql @@ -24,6 +24,7 @@ select --noqa: ST06 concat( ' Date: Tue, 19 Nov 2024 00:49:02 +0200 Subject: [PATCH 02/21] address some comments --- cowprotocol/accounting/rewards/.sqlfluff | 1 + .../accounting/rewards/unusual_slippage_query_2332678.sql | 5 +++-- cowprotocol/accounting/slippage/.sqlfluff | 2 +- cowprotocol/accounting/slippage/raw_slippage_4059683.sql | 1 + cowprotocol/accounting/slippage/slippage_4070065.sql | 1 + 5 files changed, 7 insertions(+), 3 deletions(-) diff --git a/cowprotocol/accounting/rewards/.sqlfluff b/cowprotocol/accounting/rewards/.sqlfluff index b878a763..c519a917 100644 --- a/cowprotocol/accounting/rewards/.sqlfluff +++ b/cowprotocol/accounting/rewards/.sqlfluff @@ -13,3 +13,4 @@ time='2024-08-27 00:00:00' blockchain=ethereum upper_cap=0.012 lower_cap=-0.01 +price_feed=dune_price_feed,multiple_price_feeds diff --git a/cowprotocol/accounting/rewards/unusual_slippage_query_2332678.sql b/cowprotocol/accounting/rewards/unusual_slippage_query_2332678.sql index 3dc1e3e3..5f14a7a0 100644 --- a/cowprotocol/accounting/rewards/unusual_slippage_query_2332678.sql +++ b/cowprotocol/accounting/rewards/unusual_slippage_query_2332678.sql @@ -2,9 +2,10 @@ -- Parameters: -- {{start_time}} - the start date timestamp for the accounting period (inclusively) -- {{end_time}} - the end date timestamp for the accounting period (exclusively) --- {{min_absolute_slippage_tolerance}} -- the minimum absolute threshold above which a tx is may be flagged as high-slippage --- {{relative_slippage_tolerance}} -- the minimum relative threshold (wrt batch value) above which a tx may be flagged as high-slippage +-- {{min_absolute_slippage_tolerance}} -- the minimum absolute threshold above which a tx is may be flagged as high-slippage +-- {{relative_slippage_tolerance}} -- the minimum relative threshold (wrt batch value) above which a tx may be flagged as high-slippage -- {{significant_slippage_value}} -- the absolute threshold above which a tx is always flagged as high-slippage +-- {{price_feed}} -- option to user either the dune_price_feed (which has been used up till now) or the median of multiple_price_feeds with results_per_tx as ( select * from "query_4070065(blockchain='{{blockchain}}',start_time='{{start_time}}',end_time='{{end_time}}',slippage_table_name='slippage_per_transaction')" diff --git a/cowprotocol/accounting/slippage/.sqlfluff b/cowprotocol/accounting/slippage/.sqlfluff index 003ee3cd..253bcf86 100644 --- a/cowprotocol/accounting/slippage/.sqlfluff +++ b/cowprotocol/accounting/slippage/.sqlfluff @@ -4,4 +4,4 @@ end_time='2024-08-02 12:00' blockchain='ethereum' slippage_table_name=slippage_per_solver,slippage_per_transaction raw_slippage_table_name=raw_slippage_breakdown,raw_slippage_per_transaction -price_feed=dune_price_feed,multiple_price_feeds \ No newline at end of file +price_feed=dune_price_feed,multiple_price_feeds diff --git a/cowprotocol/accounting/slippage/raw_slippage_4059683.sql b/cowprotocol/accounting/slippage/raw_slippage_4059683.sql index 09b94e3a..de40b90f 100644 --- a/cowprotocol/accounting/slippage/raw_slippage_4059683.sql +++ b/cowprotocol/accounting/slippage/raw_slippage_4059683.sql @@ -6,6 +6,7 @@ -- {{blockchain}} - network to run the analysis on -- {{raw_slippage_table_name}} - raw_slippage_breakdown for a detailed per token breakdown of -- slippage; raw_slippage_per_transaction for aggregated values per transaction +-- {{price_feed}} -- option to user either the dune_price_feed (which has been used up till now) or the median of multiple_price_feeds -- -- The columns of raw_slippage_breakdown are -- - block_time: time of settlement transaction diff --git a/cowprotocol/accounting/slippage/slippage_4070065.sql b/cowprotocol/accounting/slippage/slippage_4070065.sql index a556fffc..b973fd27 100644 --- a/cowprotocol/accounting/slippage/slippage_4070065.sql +++ b/cowprotocol/accounting/slippage/slippage_4070065.sql @@ -7,6 +7,7 @@ -- {{blockchain}} - network to run the analysis on -- {{slippage_table_name}} - slippage_per_transaction for aggregated values per transaction; -- slippage_per_solver for aggregated values per transaction +-- {{price_feed}} -- option to user either the dune_price_feed (which has been used up till now) or the median of multiple_price_feeds -- -- The columns of slippage_per_transaction are -- - block_time: time of settlement transaction From 477871d80d63140be932338674424cbb0b86fc1e Mon Sep 17 00:00:00 2001 From: harisang Date: Tue, 19 Nov 2024 02:56:44 +0200 Subject: [PATCH 03/21] update median calculation --- .../slippage/slippage_prices_4064601.sql | 91 +++++++++++-------- 1 file changed, 53 insertions(+), 38 deletions(-) diff --git a/cowprotocol/accounting/slippage/slippage_prices_4064601.sql b/cowprotocol/accounting/slippage/slippage_prices_4064601.sql index d832dacf..f9b1785c 100644 --- a/cowprotocol/accounting/slippage/slippage_prices_4064601.sql +++ b/cowprotocol/accounting/slippage/slippage_prices_4064601.sql @@ -25,53 +25,56 @@ with token_times as ( group by 1, 2 ), -imported_price_feed as ( +-- Fetching all additional price feeds that are synced to Dune +imported_price_feeds_raw as ( select * from "query_4252674" where price_unit < 10000000 -- here we filter all tokens with price more than $1M, as these are probably bogus prices ), +-- The next four tables decompose the imported_price_feeds_raw table by source, in a format that can then be used for slippage acounting +-- Currently, four price feeds are used: coingecko, moralis, the auction prices provided by the backend, and dune prices. + +-- the coingecko price feed coingecko_price_feed as ( select - ipf.hour, - ipf.token_address, - ipf.decimals, - ipf.price_unit, - ipf.price_atom - from imported_price_feed as ipf inner join token_times as tt on ipf.hour = tt.hour and ipf.token_address = tt.token_address + ipfr.hour, + ipfr.token_address, + ipfr.decimals, + ipfr.price_unit + from imported_price_feeds_raw as ipfr inner join token_times as tt on ipfr.hour = tt.hour and ipfr.token_address = tt.token_address where source = 'coingecko' ), +-- the moralis price feed moralis_price_feed as ( select - ipf.hour, - ipf.token_address, - ipf.decimals, - ipf.price_unit, - ipf.price_atom - from imported_price_feed as ipf inner join token_times as tt on ipf.hour = tt.hour and ipf.token_address = tt.token_address + ipfr.hour, + ipfr.token_address, + ipfr.decimals, + ipfr.price_unit + from imported_price_feeds_raw as ipfr inner join token_times as tt on ipfr.hour = tt.hour and ipfr.token_address = tt.token_address where source = 'moralis' ), +-- the auction prices feed auction_price_feed as ( select - ipf.hour, - ipf.token_address, - ipf.decimals, - ipf.price_unit, - ipf.price_atom - from imported_price_feed as ipf inner join token_times as tt on ipf.hour = tt.hour and ipf.token_address = tt.token_address + ipfr.hour, + ipfr.token_address, + ipfr.decimals, + ipfr.price_unit + from imported_price_feeds_raw as ipfr inner join token_times as tt on ipfr.hour = tt.hour and ipfr.token_address = tt.token_address where source = 'native' ), --- Precise prices are prices from the Dune price feed. +-- the Dune price feed; note that this is computed on Dune and is not part of the imported_price_feeds_raw table. dune_price_feed as ( select -- noqa: ST06 date_trunc('hour', minute) as hour, --noqa: RF04 token_address, decimals, - avg(price) as price_unit, - avg(price) / pow(10, decimals) as price_atom + avg(price) as price_unit from prices.usd inner join token_times @@ -82,28 +85,40 @@ dune_price_feed as ( group by 1, 2, 3 ), -multiple_price_feeds_pre as ( - select * - from dune_price_feed - union all - select * - from coingecko_price_feed - union all - select * - from moralis_price_feed - union all - select * - from auction_price_feed +-- we are now ready to define a new price feed that is the median of all price feeds defined above +-- there are 2 tables for this purpose, and the code for the median is based on the No.2 section +-- of this article: https://medium.com/learning-sql/how-to-calculate-median-the-right-way-in-postgresql-f7b84e9e2df7 +intermediate_compute_median_table as ( + select + hour, + token_address, + decimals, + price_unit, + row_number() over (partition by hour, token_address, decimals order by price_unit asc) as rn_asc, + count(*) over (partition by hour, token_address, decimals) as ct + from ( + select * from dune_price_feed + union all + select * from coingecko_price_feed + union all + select * from moralis_price_feed + union all + select * from auction_price_feed + ) ), +-- this is the final table generated, that uses the median of all price feeds +-- to compute a final price. multiple_price_feeds as ( select hour, token_address, decimals, - approx_percentile(price_unit, 0.5) as price_unit, - approx_percentile(price_atom, 0.5) as price_atom - from multiple_price_feeds_pre group by 1, 2, 3 + avg(price_unit) as price_unit, + avg(price_unit) / pow(10, decimals) as price_atom + from intermediate_compute_median_table + where rn_asc between ct / 2.0 and ct / 2.0 + 1 + group by 1, 2, 3 ), precise_prices as ( @@ -187,7 +202,7 @@ wrapped_native_token as ( end as native_token_address ), --- The price of the native token is reconstructed from it chain-dependent wrapped version. +-- The price of the native token is reconstructed from its chain-dependent wrapped version. native_token_prices as ( select -- noqa: ST06 date_trunc('hour', minute) as hour, --noqa: RF04 From d649006d797a8d6473f4b96b9d37f79317bc18fa Mon Sep 17 00:00:00 2001 From: harisang Date: Tue, 19 Nov 2024 03:12:50 +0200 Subject: [PATCH 04/21] add parameter in description --- cowprotocol/accounting/slippage/slippage_prices_4064601.sql | 1 + 1 file changed, 1 insertion(+) diff --git a/cowprotocol/accounting/slippage/slippage_prices_4064601.sql b/cowprotocol/accounting/slippage/slippage_prices_4064601.sql index f9b1785c..fda1f728 100644 --- a/cowprotocol/accounting/slippage/slippage_prices_4064601.sql +++ b/cowprotocol/accounting/slippage/slippage_prices_4064601.sql @@ -6,6 +6,7 @@ -- {{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 +-- {{price_feed}} -- option to user either the dune_price_feed (which has been used up till now) or the median of multiple_price_feeds -- -- The columns of the result are -- - hour: hour for which a price is valid From 1bc0655647a91d65a35c55cc00e4a4a0094b8869 Mon Sep 17 00:00:00 2001 From: harisang Date: Tue, 19 Nov 2024 15:40:49 +0200 Subject: [PATCH 05/21] remove unecessary intermediate tables --- .../slippage/slippage_prices_4064601.sql | 52 +++---------------- 1 file changed, 8 insertions(+), 44 deletions(-) diff --git a/cowprotocol/accounting/slippage/slippage_prices_4064601.sql b/cowprotocol/accounting/slippage/slippage_prices_4064601.sql index fda1f728..3e9e04c9 100644 --- a/cowprotocol/accounting/slippage/slippage_prices_4064601.sql +++ b/cowprotocol/accounting/slippage/slippage_prices_4064601.sql @@ -27,46 +27,14 @@ with token_times as ( ), -- Fetching all additional price feeds that are synced to Dune -imported_price_feeds_raw as ( - select * - from "query_4252674" - where price_unit < 10000000 -- here we filter all tokens with price more than $1M, as these are probably bogus prices -), - --- The next four tables decompose the imported_price_feeds_raw table by source, in a format that can then be used for slippage acounting --- Currently, four price feeds are used: coingecko, moralis, the auction prices provided by the backend, and dune prices. - --- the coingecko price feed -coingecko_price_feed as ( - select - ipfr.hour, - ipfr.token_address, - ipfr.decimals, - ipfr.price_unit - from imported_price_feeds_raw as ipfr inner join token_times as tt on ipfr.hour = tt.hour and ipfr.token_address = tt.token_address - where source = 'coingecko' -), - --- the moralis price feed -moralis_price_feed as ( - select - ipfr.hour, - ipfr.token_address, - ipfr.decimals, - ipfr.price_unit - from imported_price_feeds_raw as ipfr inner join token_times as tt on ipfr.hour = tt.hour and ipfr.token_address = tt.token_address - where source = 'moralis' -), - --- the auction prices feed -auction_price_feed as ( +imported_price_feeds as ( select - ipfr.hour, - ipfr.token_address, - ipfr.decimals, - ipfr.price_unit - from imported_price_feeds_raw as ipfr inner join token_times as tt on ipfr.hour = tt.hour and ipfr.token_address = tt.token_address - where source = 'native' + a.hour, + a.token_address, + a.decimals, + a.price_unit + from "query_4252674" as a inner join token_times as tt on a.hour = tt.hour and a.token_address = tt.token_address + where a.price_unit < 10000000 -- here we filter all tokens with price more than $1M, as these are probably bogus prices ), -- the Dune price feed; note that this is computed on Dune and is not part of the imported_price_feeds_raw table. @@ -100,11 +68,7 @@ intermediate_compute_median_table as ( from ( select * from dune_price_feed union all - select * from coingecko_price_feed - union all - select * from moralis_price_feed - union all - select * from auction_price_feed + select * from imported_price_feeds ) ), From 93b85099999c53890ca26d081d7fe9be819bbf0c Mon Sep 17 00:00:00 2001 From: harisang Date: Tue, 19 Nov 2024 15:57:20 +0200 Subject: [PATCH 06/21] add comments and minor changes --- .../accounting/slippage/slippage_prices_4064601.sql | 10 +++++++--- 1 file changed, 7 insertions(+), 3 deletions(-) diff --git a/cowprotocol/accounting/slippage/slippage_prices_4064601.sql b/cowprotocol/accounting/slippage/slippage_prices_4064601.sql index 3e9e04c9..632c840d 100644 --- a/cowprotocol/accounting/slippage/slippage_prices_4064601.sql +++ b/cowprotocol/accounting/slippage/slippage_prices_4064601.sql @@ -86,6 +86,8 @@ multiple_price_feeds as ( group by 1, 2, 3 ), +-- We now define the precise_prices table, which refers to prices that +-- we have directly computed from various price feeds. precise_prices as ( select * from {{price_feed}} @@ -128,8 +130,8 @@ intrinsic_prices as ( group by 1, 2, 3 ), --- The final price is the Dune price if it exists and the intrinsic price otherwise. If both prices --- are not available, the price is null. +-- The final price is the precise price if it exists and the intrinsic price otherwise. +-- If both prices are not available, the price is null. prices as ( select tt.hour, @@ -157,6 +159,8 @@ prices as ( and tt.token_address = intrinsic.token_address ), +-- We also want to have the prices of the native token of each chain +-- so we define this intermediate table to help with that wrapped_native_token as ( select case '{{blockchain}}' @@ -184,5 +188,5 @@ native_token_prices as ( ) select * from prices -union all +union distinct select * from native_token_prices From 1fa83a6c12f513bcbabaadff07927171b808f33f Mon Sep 17 00:00:00 2001 From: harisang Date: Wed, 27 Nov 2024 09:37:31 +0200 Subject: [PATCH 07/21] revert distinct union change --- cowprotocol/accounting/slippage/slippage_prices_4064601.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/cowprotocol/accounting/slippage/slippage_prices_4064601.sql b/cowprotocol/accounting/slippage/slippage_prices_4064601.sql index 632c840d..6ee85e5c 100644 --- a/cowprotocol/accounting/slippage/slippage_prices_4064601.sql +++ b/cowprotocol/accounting/slippage/slippage_prices_4064601.sql @@ -188,5 +188,5 @@ native_token_prices as ( ) select * from prices -union distinct +union all select * from native_token_prices From d96570da8227c5fa4ffc726c2e08277338c975a1 Mon Sep 17 00:00:00 2001 From: harisang Date: Fri, 31 Jan 2025 04:08:20 +0200 Subject: [PATCH 08/21] change raw price table to be identical to prices.usd dune table --- .../raw_price_feed_query_4252674.sql | 58 ++++++++----------- 1 file changed, 24 insertions(+), 34 deletions(-) diff --git a/cowprotocol/accounting/price_feed/raw_price_feed_query_4252674.sql b/cowprotocol/accounting/price_feed/raw_price_feed_query_4252674.sql index 6117c01f..d95a8bd1 100644 --- a/cowprotocol/accounting/price_feed/raw_price_feed_query_4252674.sql +++ b/cowprotocol/accounting/price_feed/raw_price_feed_query_4252674.sql @@ -1,56 +1,46 @@ -- This query parses the raw price_feed table that we sync on Dune, --- and returns a view that is based on hourly prices, similar to --- how the Dune price feed is used for slippage accounting +-- and returns a view that is based on minute prices, quite similar to +-- how the Dune price.usd looks like -- --- Parameters: --- {{blockchain}} - network to run the analysis on; currently it only works for mainnet -- -- The columns of the result are --- - token_address: a token --- - hour: the hour for which a price is computed +-- - minute: the minute for which a price is computed +-- - blockchain: the corresponding chain +-- - contract_address: a token -- - decimals: the decimals of the token +-- - price: the price, in USD, of one unit of the token -- - source: the source from which this price was computed, --- price_unit: the price, in USD, of one unit of the token --- - price_atom: the price, in USD, of one atom of the token with imported_prices as ( select - token_address, cast(replace(time, 'T', ' ') as timestamp) as time, --noqa: RF04 - cast(price as double) as price_unit_eth, + 'ethereum' as blockchain, + token_address as contract_address, decimals, - source - from dune.cowprotocol.dataset_price_feed_{{blockchain}} + source, + cast(price as double) as price_unit_eth + from dune.cowprotocol.dataset_price_feed_ethereum ), imported_prices_per_minute as ( select -- noqa: ST06 - token_address, date_trunc('minute', time) as minute, --noqa: RF04 + blockchain, + contract_address, decimals, source, avg(price_unit_eth) as price_unit_eth - from imported_prices group by 1, 2, 3, 4 -), - -imported_prices_per_minute_with_usd_prices as ( - select -- noqa: ST06 - ippm.token_address, - ippm.minute, - ippm.decimals, - ippm.price_unit_eth, - ippm.price_unit_eth * p.price as price_unit, - ippm.price_unit_eth * p.price / pow(10, ippm.decimals) as price_atom, - source - from imported_prices_per_minute as ippm inner join prices.usd as p on ippm.minute = p.minute - where p.contract_address = 0xc02aaa39b223fe8d0a0e5c4f27ead9083c756cc2 and blockchain = 'ethereum' + from imported_prices group by 1, 2, 3, 4, 5 ) select -- noqa: ST06 - token_address, - date_trunc('hour', minute) as hour, --noqa: RF04 - decimals, - source, - avg(price_unit) as price_unit, - avg(price_atom) as price_atom -from imported_prices_per_minute_with_usd_prices group by 1, 2, 3, 4 + ippm.minute, + ippm.blockchain, + ippm.contract_address, + ippm.decimals, + ippm.source, + ippm.price_unit_eth * p.price as price +from imported_prices_per_minute as ippm +inner join prices.usd as p on ippm.minute = p.minute +where p.contract_address = 0xc02aaa39b223fe8d0a0e5c4f27ead9083c756cc2 and p.blockchain = 'ethereum' +order by ippm.minute desc --noqa: AM06 From d08b732be31889ef8757f70023846acdc7b27023 Mon Sep 17 00:00:00 2001 From: harisang Date: Fri, 31 Jan 2025 05:01:00 +0200 Subject: [PATCH 09/21] slightly change slippage_prices query --- .../slippage/slippage_prices_4064601.sql | 66 ++++++++++++------- 1 file changed, 43 insertions(+), 23 deletions(-) diff --git a/cowprotocol/accounting/slippage/slippage_prices_4064601.sql b/cowprotocol/accounting/slippage/slippage_prices_4064601.sql index 6ee85e5c..4c2ea086 100644 --- a/cowprotocol/accounting/slippage/slippage_prices_4064601.sql +++ b/cowprotocol/accounting/slippage/slippage_prices_4064601.sql @@ -28,34 +28,58 @@ with token_times as ( -- Fetching all additional price feeds that are synced to Dune imported_price_feeds as ( - select - a.hour, + select --noqa: ST06 + a.source, + date_trunc('hour', a.minute) as hour, --noqa: RF04 a.token_address, a.decimals, - a.price_unit - from "query_4252674" as a inner join token_times as tt on a.hour = tt.hour and a.token_address = tt.token_address - where a.price_unit < 10000000 -- here we filter all tokens with price more than $1M, as these are probably bogus prices + avg(a.price) as price_unit + from "query_4252674" as a inner join token_times as tt + on + date_trunc('hour', a.minute) = tt.hour + and a.contract_address = tt.token_address + and a.blockchain = '{{blockchain}}' + group by 1, 2, 3, 4 ), -- the Dune price feed; note that this is computed on Dune and is not part of the imported_price_feeds_raw table. dune_price_feed as ( select -- noqa: ST06 - date_trunc('hour', minute) as hour, --noqa: RF04 - token_address, - decimals, - avg(price) as price_unit - from - prices.usd - inner join token_times + date_trunc('hour', a.minute) as hour, --noqa: RF04 + a.token_address, + a.decimals, + avg(a.price) as price_unit, + avg(a.price) / pow(10, a.decimals) as price_atom -- this is needed later on + from prices.usd as a inner join token_times as tt on - date_trunc('hour', minute) = hour - and contract_address = token_address - and blockchain = '{{blockchain}}' + date_trunc('hour', minute) = tt.hour + and a.contract_address = tt.token_address + and a.blockchain = '{{blockchain}}' group by 1, 2, 3 ), +-- we now collect together all different price feeds that we have +all_price_feeds as ( + select + source as price_source, + hour, + token_address, + decimals, + price_unit + from imported_price_feeds + union all + select + 'dune' as price_source, + hour, + token_address, + decimals, + price_unit + from dune_price_feed +), + -- we are now ready to define a new price feed that is the median of all price feeds defined above --- there are 2 tables for this purpose, and the code for the median is based on the No.2 section +-- there is an intermediate table to help with the calculation, +-- and the code for the median is based on the No.2 section -- of this article: https://medium.com/learning-sql/how-to-calculate-median-the-right-way-in-postgresql-f7b84e9e2df7 intermediate_compute_median_table as ( select @@ -65,11 +89,7 @@ intermediate_compute_median_table as ( price_unit, row_number() over (partition by hour, token_address, decimals order by price_unit asc) as rn_asc, count(*) over (partition by hour, token_address, decimals) as ct - from ( - select * from dune_price_feed - union all - select * from imported_price_feeds - ) + from all_price_feeds ), -- this is the final table generated, that uses the median of all price feeds @@ -86,8 +106,8 @@ multiple_price_feeds as ( group by 1, 2, 3 ), --- We now define the precise_prices table, which refers to prices that --- we have directly computed from various price feeds. +-- We now define the precise_prices table, and there are 2 options to choose from, +-- either the multiple_price_feeds table or the dune_price_feed precise_prices as ( select * from {{price_feed}} From 92f7b10a424379fd27fb1e9dd1b32144b2292aa6 Mon Sep 17 00:00:00 2001 From: harisang Date: Fri, 31 Jan 2025 05:08:23 +0200 Subject: [PATCH 10/21] bug fix --- cowprotocol/accounting/slippage/slippage_prices_4064601.sql | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/cowprotocol/accounting/slippage/slippage_prices_4064601.sql b/cowprotocol/accounting/slippage/slippage_prices_4064601.sql index 4c2ea086..dec7fa2c 100644 --- a/cowprotocol/accounting/slippage/slippage_prices_4064601.sql +++ b/cowprotocol/accounting/slippage/slippage_prices_4064601.sql @@ -31,7 +31,7 @@ imported_price_feeds as ( select --noqa: ST06 a.source, date_trunc('hour', a.minute) as hour, --noqa: RF04 - a.token_address, + a.contract_address as token_address, a.decimals, avg(a.price) as price_unit from "query_4252674" as a inner join token_times as tt @@ -46,7 +46,7 @@ imported_price_feeds as ( dune_price_feed as ( select -- noqa: ST06 date_trunc('hour', a.minute) as hour, --noqa: RF04 - a.token_address, + a.contract_address as token_address, a.decimals, avg(a.price) as price_unit, avg(a.price) / pow(10, a.decimals) as price_atom -- this is needed later on From 5e4dfc062696effb87c6feee6c382ac50d34f803 Mon Sep 17 00:00:00 2001 From: harisang Date: Mon, 3 Feb 2025 12:16:32 +0200 Subject: [PATCH 11/21] remove unecessary sorting --- .../accounting/price_feed/raw_price_feed_query_4252674.sql | 1 - 1 file changed, 1 deletion(-) diff --git a/cowprotocol/accounting/price_feed/raw_price_feed_query_4252674.sql b/cowprotocol/accounting/price_feed/raw_price_feed_query_4252674.sql index d95a8bd1..e96b1955 100644 --- a/cowprotocol/accounting/price_feed/raw_price_feed_query_4252674.sql +++ b/cowprotocol/accounting/price_feed/raw_price_feed_query_4252674.sql @@ -43,4 +43,3 @@ select -- noqa: ST06 from imported_prices_per_minute as ippm inner join prices.usd as p on ippm.minute = p.minute where p.contract_address = 0xc02aaa39b223fe8d0a0e5c4f27ead9083c756cc2 and p.blockchain = 'ethereum' -order by ippm.minute desc --noqa: AM06 From cce55685d032b0f53e0582bb30d34a32421f221d Mon Sep 17 00:00:00 2001 From: harisang Date: Mon, 3 Feb 2025 12:48:34 +0200 Subject: [PATCH 12/21] minor edits to slippage_prices query --- .../slippage/slippage_prices_4064601.sql | 19 +++++-------------- 1 file changed, 5 insertions(+), 14 deletions(-) diff --git a/cowprotocol/accounting/slippage/slippage_prices_4064601.sql b/cowprotocol/accounting/slippage/slippage_prices_4064601.sql index dec7fa2c..b841c95c 100644 --- a/cowprotocol/accounting/slippage/slippage_prices_4064601.sql +++ b/cowprotocol/accounting/slippage/slippage_prices_4064601.sql @@ -29,7 +29,7 @@ with token_times as ( -- Fetching all additional price feeds that are synced to Dune imported_price_feeds as ( select --noqa: ST06 - a.source, + a.source as price_source, date_trunc('hour', a.minute) as hour, --noqa: RF04 a.contract_address as token_address, a.decimals, @@ -45,6 +45,7 @@ imported_price_feeds as ( -- the Dune price feed; note that this is computed on Dune and is not part of the imported_price_feeds_raw table. dune_price_feed as ( select -- noqa: ST06 + 'dune' as price_source, date_trunc('hour', a.minute) as hour, --noqa: RF04 a.contract_address as token_address, a.decimals, @@ -60,20 +61,10 @@ dune_price_feed as ( -- we now collect together all different price feeds that we have all_price_feeds as ( - select - source as price_source, - hour, - token_address, - decimals, - price_unit + select * from imported_price_feeds union all - select - 'dune' as price_source, - hour, - token_address, - decimals, - price_unit + select * from dune_price_feed ), @@ -208,5 +199,5 @@ native_token_prices as ( ) select * from prices -union all +union distinct -- new price feeds might already entries for the native token select * from native_token_prices From 3b5be9af307a6774a0dd36ad2e9d6e1042269cb6 Mon Sep 17 00:00:00 2001 From: harisang Date: Mon, 3 Feb 2025 14:07:27 +0200 Subject: [PATCH 13/21] rename intermediate table --- cowprotocol/accounting/slippage/.sqlfluff | 2 +- cowprotocol/accounting/slippage/slippage_prices_4064601.sql | 2 +- 2 files changed, 2 insertions(+), 2 deletions(-) diff --git a/cowprotocol/accounting/slippage/.sqlfluff b/cowprotocol/accounting/slippage/.sqlfluff index 253bcf86..9709a76c 100644 --- a/cowprotocol/accounting/slippage/.sqlfluff +++ b/cowprotocol/accounting/slippage/.sqlfluff @@ -4,4 +4,4 @@ end_time='2024-08-02 12:00' blockchain='ethereum' slippage_table_name=slippage_per_solver,slippage_per_transaction raw_slippage_table_name=raw_slippage_breakdown,raw_slippage_per_transaction -price_feed=dune_price_feed,multiple_price_feeds +price_feed=dune_price_feed,median_price_feed diff --git a/cowprotocol/accounting/slippage/slippage_prices_4064601.sql b/cowprotocol/accounting/slippage/slippage_prices_4064601.sql index b841c95c..8945f9a7 100644 --- a/cowprotocol/accounting/slippage/slippage_prices_4064601.sql +++ b/cowprotocol/accounting/slippage/slippage_prices_4064601.sql @@ -85,7 +85,7 @@ intermediate_compute_median_table as ( -- this is the final table generated, that uses the median of all price feeds -- to compute a final price. -multiple_price_feeds as ( +median_price_feed as ( select hour, token_address, From bdf4300c2c1de329f95e9f2b5acd168ddb03b981 Mon Sep 17 00:00:00 2001 From: harisang Date: Mon, 3 Feb 2025 19:04:28 +0200 Subject: [PATCH 14/21] fix comment and bug --- cowprotocol/accounting/slippage/raw_slippage_4059683.sql | 7 ++++--- 1 file changed, 4 insertions(+), 3 deletions(-) diff --git a/cowprotocol/accounting/slippage/raw_slippage_4059683.sql b/cowprotocol/accounting/slippage/raw_slippage_4059683.sql index de40b90f..c9a65288 100644 --- a/cowprotocol/accounting/slippage/raw_slippage_4059683.sql +++ b/cowprotocol/accounting/slippage/raw_slippage_4059683.sql @@ -6,7 +6,8 @@ -- {{blockchain}} - network to run the analysis on -- {{raw_slippage_table_name}} - raw_slippage_breakdown for a detailed per token breakdown of -- slippage; raw_slippage_per_transaction for aggregated values per transaction --- {{price_feed}} -- option to user either the dune_price_feed (which has been used up till now) or the median of multiple_price_feeds +-- {{price_feed}} -- option to user either the dune_price_feed (which has been used up till now) or the median_price_feed, which +-- considers the median over multiple price feeds -- -- The columns of raw_slippage_breakdown are -- - block_time: time of settlement transaction @@ -47,7 +48,7 @@ fees as ( -amount as amount, fee_type as slippage_type, date_trunc('hour', block_time) as hour --noqa: RF04 - from "query_4058574(blockchain='{{blockchain}}',price_feed='{{price_feed}}',start_time='{{start_time}}',end_time='{{end_time}}')" + from "query_4058574(blockchain='{{blockchain}}',start_time='{{start_time}}',end_time='{{end_time}}')" ), imbalances as ( @@ -57,7 +58,7 @@ imbalances as ( ), prices as ( - select * from "query_4064601(blockchain='{{blockchain}}',start_time='{{start_time}}',end_time='{{end_time}}')" + select * from "query_4064601(blockchain='{{blockchain}}',price_feed='{{price_feed}}',start_time='{{start_time}}',end_time='{{end_time}}')" ), raw_slippage_breakdown as ( From 3bd83ec4c7ba2484489ec3be7cf59f4229edc3ed Mon Sep 17 00:00:00 2001 From: harisang Date: Mon, 3 Feb 2025 19:07:28 +0200 Subject: [PATCH 15/21] fix comment --- .../accounting/rewards/unusual_slippage_query_2332678.sql | 2 +- cowprotocol/accounting/slippage/slippage_4070065.sql | 2 +- cowprotocol/accounting/slippage/slippage_prices_4064601.sql | 4 ++-- 3 files changed, 4 insertions(+), 4 deletions(-) diff --git a/cowprotocol/accounting/rewards/unusual_slippage_query_2332678.sql b/cowprotocol/accounting/rewards/unusual_slippage_query_2332678.sql index 5f14a7a0..7470c300 100644 --- a/cowprotocol/accounting/rewards/unusual_slippage_query_2332678.sql +++ b/cowprotocol/accounting/rewards/unusual_slippage_query_2332678.sql @@ -5,7 +5,7 @@ -- {{min_absolute_slippage_tolerance}} -- the minimum absolute threshold above which a tx is may be flagged as high-slippage -- {{relative_slippage_tolerance}} -- the minimum relative threshold (wrt batch value) above which a tx may be flagged as high-slippage -- {{significant_slippage_value}} -- the absolute threshold above which a tx is always flagged as high-slippage --- {{price_feed}} -- option to user either the dune_price_feed (which has been used up till now) or the median of multiple_price_feeds +-- {{price_feed}} -- option to user either the dune_price_feed (which has been used up till now) or the median_price_feed with results_per_tx as ( select * from "query_4070065(blockchain='{{blockchain}}',start_time='{{start_time}}',end_time='{{end_time}}',slippage_table_name='slippage_per_transaction')" diff --git a/cowprotocol/accounting/slippage/slippage_4070065.sql b/cowprotocol/accounting/slippage/slippage_4070065.sql index b973fd27..5284303a 100644 --- a/cowprotocol/accounting/slippage/slippage_4070065.sql +++ b/cowprotocol/accounting/slippage/slippage_4070065.sql @@ -7,7 +7,7 @@ -- {{blockchain}} - network to run the analysis on -- {{slippage_table_name}} - slippage_per_transaction for aggregated values per transaction; -- slippage_per_solver for aggregated values per transaction --- {{price_feed}} -- option to user either the dune_price_feed (which has been used up till now) or the median of multiple_price_feeds +-- {{price_feed}} -- option to user either the dune_price_feed (which has been used up till now) or the median_price_feed -- -- The columns of slippage_per_transaction are -- - block_time: time of settlement transaction diff --git a/cowprotocol/accounting/slippage/slippage_prices_4064601.sql b/cowprotocol/accounting/slippage/slippage_prices_4064601.sql index 8945f9a7..6fbc52f6 100644 --- a/cowprotocol/accounting/slippage/slippage_prices_4064601.sql +++ b/cowprotocol/accounting/slippage/slippage_prices_4064601.sql @@ -6,7 +6,7 @@ -- {{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 --- {{price_feed}} -- option to user either the dune_price_feed (which has been used up till now) or the median of multiple_price_feeds +-- {{price_feed}} -- option to user either the dune_price_feed (which has been used up till now) or the median_price_feed -- -- The columns of the result are -- - hour: hour for which a price is valid @@ -98,7 +98,7 @@ median_price_feed as ( ), -- We now define the precise_prices table, and there are 2 options to choose from, --- either the multiple_price_feeds table or the dune_price_feed +-- either the median_price_feed table or the dune_price_feed precise_prices as ( select * from {{price_feed}} From dae12f24334600f9c9d31e9a5eff67473c818fa8 Mon Sep 17 00:00:00 2001 From: harisang Date: Mon, 3 Feb 2025 19:11:07 +0200 Subject: [PATCH 16/21] use dune price feed for now --- cowprotocol/accounting/slippage/raw_slippage_4059683.sql | 2 +- cowprotocol/accounting/slippage/slippage_4070065.sql | 2 +- 2 files changed, 2 insertions(+), 2 deletions(-) diff --git a/cowprotocol/accounting/slippage/raw_slippage_4059683.sql b/cowprotocol/accounting/slippage/raw_slippage_4059683.sql index c9a65288..2f76fabb 100644 --- a/cowprotocol/accounting/slippage/raw_slippage_4059683.sql +++ b/cowprotocol/accounting/slippage/raw_slippage_4059683.sql @@ -58,7 +58,7 @@ imbalances as ( ), prices as ( - select * from "query_4064601(blockchain='{{blockchain}}',price_feed='{{price_feed}}',start_time='{{start_time}}',end_time='{{end_time}}')" + select * from "query_4064601(blockchain='{{blockchain}}',price_feed='dune_price_feed',start_time='{{start_time}}',end_time='{{end_time}}')" ), raw_slippage_breakdown as ( diff --git a/cowprotocol/accounting/slippage/slippage_4070065.sql b/cowprotocol/accounting/slippage/slippage_4070065.sql index 5284303a..1a0fb1e0 100644 --- a/cowprotocol/accounting/slippage/slippage_4070065.sql +++ b/cowprotocol/accounting/slippage/slippage_4070065.sql @@ -41,7 +41,7 @@ slippage_per_transaction as ( sum(if(slippage_type = 'raw_imbalance', slippage_usd, 0)) as imbalance_usd, sum(if(slippage_type = 'protocol_fee', -slippage_usd, 0)) as protocol_fee_usd, sum(if(slippage_type = 'network_fee', -slippage_usd, 0)) as network_fee_usd - from "query_4059683(blockchain='{{blockchain}}',price_feed='{{price_feed}}',start_time='{{start_time}}',end_time='{{end_time}}',raw_slippage_table_name='raw_slippage_breakdown')" as rs + from "query_4059683(blockchain='{{blockchain}}',price_feed='dune_price_feed',start_time='{{start_time}}',end_time='{{end_time}}',raw_slippage_table_name='raw_slippage_breakdown')" as rs inner join cow_protocol_{{blockchain}}.batches as b on rs.tx_hash = b.tx_hash where rs.tx_hash not in (select tx_hash from excluded_batches) From 84ebeef8f8a4a6e7ac528d4688ef20d88fc4b8d0 Mon Sep 17 00:00:00 2001 From: harisang Date: Mon, 3 Feb 2025 19:16:43 +0200 Subject: [PATCH 17/21] add parameter whenever needed --- .../rewards/main_rewards_dashboard_query_2510345.sql | 2 +- .../accounting/rewards/unusual_slippage_query_2332678.sql | 2 +- cowprotocol/accounting/slippage/slippage_query_3427730.sql | 3 ++- 3 files changed, 4 insertions(+), 3 deletions(-) diff --git a/cowprotocol/accounting/rewards/main_rewards_dashboard_query_2510345.sql b/cowprotocol/accounting/rewards/main_rewards_dashboard_query_2510345.sql index 9709ee68..43a1c9ff 100644 --- a/cowprotocol/accounting/rewards/main_rewards_dashboard_query_2510345.sql +++ b/cowprotocol/accounting/rewards/main_rewards_dashboard_query_2510345.sql @@ -8,7 +8,7 @@ solver_slippage as ( select solver_address as solver, slippage_wei * 1.0 / pow(10, 18) as slippage - from "query_4070065(blockchain='{{blockchain}}',start_time='{{start_time}}',end_time='{{end_time}}',slippage_table_name='slippage_per_solver')" + from "query_4070065(blockchain='{{blockchain}}',price_feed='dune_price_feed',start_time='{{start_time}}',end_time='{{end_time}}',slippage_table_name='slippage_per_solver')" ), named_results as ( diff --git a/cowprotocol/accounting/rewards/unusual_slippage_query_2332678.sql b/cowprotocol/accounting/rewards/unusual_slippage_query_2332678.sql index 7470c300..89dd64a1 100644 --- a/cowprotocol/accounting/rewards/unusual_slippage_query_2332678.sql +++ b/cowprotocol/accounting/rewards/unusual_slippage_query_2332678.sql @@ -8,7 +8,7 @@ -- {{price_feed}} -- option to user either the dune_price_feed (which has been used up till now) or the median_price_feed with results_per_tx as ( - select * from "query_4070065(blockchain='{{blockchain}}',start_time='{{start_time}}',end_time='{{end_time}}',slippage_table_name='slippage_per_transaction')" + select * from "query_4070065(blockchain='{{blockchain}}',price_feed='dune_price_feed',start_time='{{start_time}}',end_time='{{end_time}}',slippage_table_name='slippage_per_transaction')" ), url_helper as ( diff --git a/cowprotocol/accounting/slippage/slippage_query_3427730.sql b/cowprotocol/accounting/slippage/slippage_query_3427730.sql index 5108b422..5f46f8c7 100644 --- a/cowprotocol/accounting/slippage/slippage_query_3427730.sql +++ b/cowprotocol/accounting/slippage/slippage_query_3427730.sql @@ -6,11 +6,12 @@ select concat( 'link' ) as slippage_per_transaction -from "query_4070065(blockchain='{{blockchain}}',start_time='{{start_time}}',end_time='{{end_time}}',slippage_table_name='slippage_per_solver')" +from "query_4070065(blockchain='{{blockchain}}',price_feed='dune_price_feed',start_time='{{start_time}}',end_time='{{end_time}}',slippage_table_name='slippage_per_solver')" inner join cow_protocol_{{blockchain}}.solvers on solver_address = address From c1f428daa3f697e1a6619a43915534cfdbffe352 Mon Sep 17 00:00:00 2001 From: harisang Date: Tue, 4 Feb 2025 00:50:41 +0200 Subject: [PATCH 18/21] small fix --- cowprotocol/accounting/slippage/slippage_prices_4064601.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/cowprotocol/accounting/slippage/slippage_prices_4064601.sql b/cowprotocol/accounting/slippage/slippage_prices_4064601.sql index 6fbc52f6..49c9ce84 100644 --- a/cowprotocol/accounting/slippage/slippage_prices_4064601.sql +++ b/cowprotocol/accounting/slippage/slippage_prices_4064601.sql @@ -53,7 +53,7 @@ dune_price_feed as ( avg(a.price) / pow(10, a.decimals) as price_atom -- this is needed later on from prices.usd as a inner join token_times as tt on - date_trunc('hour', minute) = tt.hour + date_trunc('hour', a.minute) = tt.hour and a.contract_address = tt.token_address and a.blockchain = '{{blockchain}}' group by 1, 2, 3 From 512fe77713786f40a5ac1e0269f2985eb142cc56 Mon Sep 17 00:00:00 2001 From: harisang Date: Tue, 4 Feb 2025 01:34:49 +0200 Subject: [PATCH 19/21] clean up --- .../slippage/slippage_prices_4064601.sql | 21 +++++++------------ 1 file changed, 8 insertions(+), 13 deletions(-) diff --git a/cowprotocol/accounting/slippage/slippage_prices_4064601.sql b/cowprotocol/accounting/slippage/slippage_prices_4064601.sql index 49c9ce84..91e9dc3c 100644 --- a/cowprotocol/accounting/slippage/slippage_prices_4064601.sql +++ b/cowprotocol/accounting/slippage/slippage_prices_4064601.sql @@ -49,8 +49,7 @@ dune_price_feed as ( date_trunc('hour', a.minute) as hour, --noqa: RF04 a.contract_address as token_address, a.decimals, - avg(a.price) as price_unit, - avg(a.price) / pow(10, a.decimals) as price_atom -- this is needed later on + avg(a.price) as price_unit from prices.usd as a inner join token_times as tt on date_trunc('hour', a.minute) = tt.hour @@ -90,8 +89,7 @@ median_price_feed as ( hour, token_address, decimals, - avg(price_unit) as price_unit, - avg(price_unit) / pow(10, decimals) as price_atom + avg(price_unit) as price_unit from intermediate_compute_median_table where rn_asc between ct / 2.0 and ct / 2.0 + 1 group by 1, 2, 3 @@ -113,15 +111,13 @@ intrinsic_prices as ( hour, token_address, decimals, - avg(price_unit) as price_unit, - avg(price_atom) as price_atom + avg(price_unit) as price_unit from ( select date_trunc('hour', block_time) as hour, --noqa: RF04 buy_token_address as token_address, round(log(10, atoms_bought / units_bought)) as decimals, - usd_value / units_bought as price_unit, - usd_value / atoms_bought as price_atom + usd_value / units_bought as price_unit from cow_protocol_{{blockchain}}.trades where block_time >= cast('{{start_time}}' as timestamp) and block_time < cast('{{end_time}}' as timestamp) @@ -131,8 +127,7 @@ intrinsic_prices as ( date_trunc('hour', block_time) as hour, --noqa: RF04 sell_token_address as token_address, round(log(10, atoms_sold / units_sold)) as decimals, - usd_value / units_sold as price_unit, - usd_value / atoms_sold as price_atom + usd_value / units_sold as price_unit from cow_protocol_{{blockchain}}.trades where block_time >= cast('{{start_time}}' as timestamp) and block_time < cast('{{end_time}}' as timestamp) @@ -156,9 +151,9 @@ prices as ( intrinsic.price_unit ) as price_unit, coalesce( - precise.price_atom, - intrinsic.price_atom - ) as price_atom + precise.price_unit, + intrinsic.price_unit + ) / pow(10, coalesce(precise.decimals, intrinsic.decimals)) as price_atom from token_times as tt left join precise_prices as precise on From 98b4fd128f40f52d27b0753a86cb506b1bd41c45 Mon Sep 17 00:00:00 2001 From: harisang Date: Tue, 4 Feb 2025 01:58:25 +0200 Subject: [PATCH 20/21] another bug fix --- cowprotocol/accounting/slippage/slippage_prices_4064601.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/cowprotocol/accounting/slippage/slippage_prices_4064601.sql b/cowprotocol/accounting/slippage/slippage_prices_4064601.sql index 91e9dc3c..9dfd7273 100644 --- a/cowprotocol/accounting/slippage/slippage_prices_4064601.sql +++ b/cowprotocol/accounting/slippage/slippage_prices_4064601.sql @@ -55,7 +55,7 @@ dune_price_feed as ( date_trunc('hour', a.minute) = tt.hour and a.contract_address = tt.token_address and a.blockchain = '{{blockchain}}' - group by 1, 2, 3 + group by 1, 2, 3, 4 ), -- we now collect together all different price feeds that we have From db9a5ce05df280eb09030d1b2b461d555b03bb05 Mon Sep 17 00:00:00 2001 From: harisang Date: Wed, 5 Feb 2025 17:13:01 +0200 Subject: [PATCH 21/21] hardcode value in top-level query --- cowprotocol/accounting/slippage/raw_slippage_4059683.sql | 2 +- cowprotocol/accounting/slippage/slippage_4070065.sql | 2 +- 2 files changed, 2 insertions(+), 2 deletions(-) diff --git a/cowprotocol/accounting/slippage/raw_slippage_4059683.sql b/cowprotocol/accounting/slippage/raw_slippage_4059683.sql index 2f76fabb..c9a65288 100644 --- a/cowprotocol/accounting/slippage/raw_slippage_4059683.sql +++ b/cowprotocol/accounting/slippage/raw_slippage_4059683.sql @@ -58,7 +58,7 @@ imbalances as ( ), prices as ( - select * from "query_4064601(blockchain='{{blockchain}}',price_feed='dune_price_feed',start_time='{{start_time}}',end_time='{{end_time}}')" + select * from "query_4064601(blockchain='{{blockchain}}',price_feed='{{price_feed}}',start_time='{{start_time}}',end_time='{{end_time}}')" ), raw_slippage_breakdown as ( diff --git a/cowprotocol/accounting/slippage/slippage_4070065.sql b/cowprotocol/accounting/slippage/slippage_4070065.sql index 1a0fb1e0..5284303a 100644 --- a/cowprotocol/accounting/slippage/slippage_4070065.sql +++ b/cowprotocol/accounting/slippage/slippage_4070065.sql @@ -41,7 +41,7 @@ slippage_per_transaction as ( sum(if(slippage_type = 'raw_imbalance', slippage_usd, 0)) as imbalance_usd, sum(if(slippage_type = 'protocol_fee', -slippage_usd, 0)) as protocol_fee_usd, sum(if(slippage_type = 'network_fee', -slippage_usd, 0)) as network_fee_usd - from "query_4059683(blockchain='{{blockchain}}',price_feed='dune_price_feed',start_time='{{start_time}}',end_time='{{end_time}}',raw_slippage_table_name='raw_slippage_breakdown')" as rs + from "query_4059683(blockchain='{{blockchain}}',price_feed='{{price_feed}}',start_time='{{start_time}}',end_time='{{end_time}}',raw_slippage_table_name='raw_slippage_breakdown')" as rs inner join cow_protocol_{{blockchain}}.batches as b on rs.tx_hash = b.tx_hash where rs.tx_hash not in (select tx_hash from excluded_batches)