From 62be777a4f80eaff993ac6aecc6f89a2cc8b2c28 Mon Sep 17 00:00:00 2001 From: Haris Angelidakis <64154020+harisang@users.noreply.github.com> Date: Thu, 21 Nov 2024 12:44:59 +0200 Subject: [PATCH] Introduce new service fee tracker query (#66) * introduce new service fee tracker query * rename service fee column * revert accidental addition of file * update column name to follow solver rewards script * update main dashboard * fix service fee join * one more fix * add start and end time parameters * Update cowprotocol/accounting/rewards/mainnet/mainnet_dashboard_query_2510345.sql Co-authored-by: Felix Henneke --------- Co-authored-by: Felix Henneke --- .../mainnet_dashboard_query_2510345.sql | 12 +- .../reduced_bonding_pools_query_4065709.sql | 57 +++++++- .../service_fee_alternative_query_4066633.sql | 123 ------------------ .../mainnet/service_fee_query_4298142.sql | 86 ++++++++++++ ... service_fee_query_DEPRECATED_4017925.sql} | 4 + 5 files changed, 147 insertions(+), 135 deletions(-) delete mode 100644 cowprotocol/accounting/rewards/mainnet/service_fee_alternative_query_4066633.sql create mode 100644 cowprotocol/accounting/rewards/mainnet/service_fee_query_4298142.sql rename cowprotocol/accounting/rewards/mainnet/{service_fee_query_4017925.sql => service_fee_query_DEPRECATED_4017925.sql} (99%) diff --git a/cowprotocol/accounting/rewards/mainnet/mainnet_dashboard_query_2510345.sql b/cowprotocol/accounting/rewards/mainnet/mainnet_dashboard_query_2510345.sql index f839925f..29796c73 100644 --- a/cowprotocol/accounting/rewards/mainnet/mainnet_dashboard_query_2510345.sql +++ b/cowprotocol/accounting/rewards/mainnet/mainnet_dashboard_query_2510345.sql @@ -133,7 +133,7 @@ service_fee_flag as ( when service_fee then 0.85 else 1 end as service_fee_factor - from "query_4017925" + from "query_4298142(start_time='{{start_time}}', end_time='{{end_time}}')" ), combined_data_after_service_fee as ( @@ -141,14 +141,14 @@ combined_data_after_service_fee as ( cd.solver, cd.network_fee_eth, cd.execution_cost_eth, - sff.service_fee_factor * cd.primary_reward_eth as primary_reward_eth, - sff.service_fee_factor * cd.primary_reward_cow as primary_reward_cow, - sff.service_fee_factor * cd.quote_reward as quote_reward, + coalesce(sff.service_fee_factor, 1) * cd.primary_reward_eth as primary_reward_eth, + coalesce(sff.service_fee_factor, 1) * cd.primary_reward_cow as primary_reward_cow, + coalesce(sff.service_fee_factor, 1) * cd.quote_reward as quote_reward, cd.slippage_eth, cd.slippage_per_tx, cd.name, - sff.service_fee as service_fee_enabled - from combined_data as cd inner join service_fee_flag as sff on cd.solver = sff.solver + coalesce(sff.service_fee, false) as service_fee_enabled + from combined_data as cd left outer join service_fee_flag as sff on cd.solver = sff.solver ), extended_payout_data as ( diff --git a/cowprotocol/accounting/rewards/mainnet/reduced_bonding_pools_query_4065709.sql b/cowprotocol/accounting/rewards/mainnet/reduced_bonding_pools_query_4065709.sql index 567adf2d..5de4c2e9 100644 --- a/cowprotocol/accounting/rewards/mainnet/reduced_bonding_pools_query_4065709.sql +++ b/cowprotocol/accounting/rewards/mainnet/reduced_bonding_pools_query_4065709.sql @@ -3,22 +3,67 @@ with reduced_bonding_pools as ( select - from_hex('0xB6113c260aD0a8A086f1E31c5C92455252A53Fb8') as pool_address, + 'prod-Barter' as solver_name, 'Reduced-CoW-DAO' as pool_name, - from_hex('0xC7899Ff6A3aC2FF59261bD960A8C880DF06E1041') as solver_address, -- prod-Barter + from_hex('0xB6113c260aD0a8A086f1E31c5C92455252A53Fb8') as pool_address, + from_hex('0xC7899Ff6A3aC2FF59261bD960A8C880DF06E1041') as solver_address, timestamp '2024-08-21 07:15:00' as creation_date union distinct select - from_hex('0xB6113c260aD0a8A086f1E31c5C92455252A53Fb8') as pool_address, + 'barn-Barter' as solver_name, 'Reduced-CoW-DAO' as pool_name, - from_hex('0xA6A871b612bCE899b1CbBad6E545e5e47Da98b87') as solver_address, -- barn-Barter + from_hex('0xB6113c260aD0a8A086f1E31c5C92455252A53Fb8') as pool_address, + from_hex('0xA6A871b612bCE899b1CbBad6E545e5e47Da98b87') as solver_address, timestamp '2024-08-21 07:15:00' as creation_date union distinct select - from_hex('0xc5Dc06423f2dB1B11611509A5814dD1b242268dd') as pool_address, + 'prod-Copium_Capital' as solver_name, 'Reduced-CoW-DAO' as pool_name, - from_hex('0x008300082C3000009e63680088f8c7f4D3ff2E87') as solver, -- prod-Copium_Capital + from_hex('0xc5Dc06423f2dB1B11611509A5814dD1b242268dd') as pool_address, + from_hex('0x008300082C3000009e63680088f8c7f4D3ff2E87') as solver_address, timestamp '2024-07-25 07:42:00' as creation_date + union distinct + select + 'prod-Rizzolver' as solver_name, + 'Reduced-CoW-DAO' as pool_name, + from_hex('0x0Deb0Ae9c4399C51289adB1f3ED83557A56dF657') as pool_address, + from_hex('0x9DFc9Bb0FfF2dc96728D2bb94eaCee6ba3592351') as solver_address, + timestamp '2024-10-10 02:03:00' as creation_date + union distinct + select + 'barn-Rizzolver' as solver_name, + 'Reduced-CoW-DAO' as pool_name, + from_hex('0x0deb0ae9c4399c51289adb1f3ed83557a56df657') as pool_address, + from_hex('0x26B5e3bF135D3Dd05A220508dD61f25BF1A47cBD') as solver_address, + timestamp '2024-10-10 02:03:00' as creation_date + union distinct + select + 'prod-Portus' as solver_name, + 'Reduced-CoW-DAO' as pool_name, + from_hex('0x3075F6aab29D92F8F062A83A0318c52c16E69a60') as pool_address, + from_hex('0x6bf97aFe2D2C790999cDEd2a8523009eB8a0823f') as solver_address, + timestamp '2024-10-21 03:33:00' as creation_date + union distinct + select + 'barn-Portus' as solver_name, + 'Reduced-CoW-DAO' as pool_name, + from_hex('0x3075F6aab29D92F8F062A83A0318c52c16E69a60') as pool_address, + from_hex('0x5131590ca2E9D3edC182581352b289dcaE83430c') as solver_address, + timestamp '2024-10-21 03:33:00' as creation_date + union distinct + select + 'prod-Fractal' as solver_name, + 'Reduced-CoW-DAO' as pool_name, + from_hex('0xDdb0a7BeBF71Fb5d3D7FB9B9B0804beDdf9C1C88') as pool_address, + from_hex('0x95480d3f27658e73b2785d30beb0c847d78294c7') as solver_address, + timestamp '2024-10-29 11:57:00' as creation_date + union distinct + select + 'barn-Fractal' as solver_name, + 'Reduced-CoW-DAO' as pool_name, + from_hex('0xDdb0a7BeBF71Fb5d3D7FB9B9B0804beDdf9C1C88') as pool_address, + from_hex('0x2a2883ade8ce179265f12fc7b48a4b50b092f1fd') as solver_address, + timestamp '2024-10-29 11:57:00' as creation_date ) select * diff --git a/cowprotocol/accounting/rewards/mainnet/service_fee_alternative_query_4066633.sql b/cowprotocol/accounting/rewards/mainnet/service_fee_alternative_query_4066633.sql deleted file mode 100644 index 9d173b57..00000000 --- a/cowprotocol/accounting/rewards/mainnet/service_fee_alternative_query_4066633.sql +++ /dev/null @@ -1,123 +0,0 @@ --- This query computes which solvers need to pay service fee --- by breaking down the calculation in small (and somewhat tedious) steps --- We stress the query is not efficient (and recomputes same things along the way) --- but we believe it is at least straightforward to check its correctness, and given --- that it's fast anyways, we decided to go with this. - --- Parameters: --- {{time}}: the date that we want to evaluate whether the service fee needs to be applied (needs to be start of accounting period) - -with --- we first compute all solvers of the CoW DAO bonding pool (this includes the ones that have their own reduced subpool) --- and only look at their names. Note that this is necessary to identify when a solver first joined the pool, as many solvers --- have changes accounts multiple times -active_cow_dao_solver_names as ( - select distinct substring(solver_name, 6, 100) as solver_name - -- here we remove the "prod-" and "barn-" prefix so as to only work with the actual solver name, - from - "query_1541516(vouch_cte_name='named_results',end_time='{{time}}')" - where - pool_address = 0x5d4020b9261f01b6f8a45db929704b0ad6f5e9e6 -- CoW DAO bonding pool address -), - --- we now take one step back and look at all solver accounts (not only the active ones) that have joined the CoW DAO bonding pool at some point, --- and we recover the date of them joining -all_cow_dao_solvers as ( - select - s.name as solver_name, - v.solver, - v.evt_block_time, - v.evt_block_number - from - cow_protocol_ethereum.VouchRegister_evt_Vouch as v - inner join cow_protocol_ethereum.solvers as s on v.solver = s.address - where - v.bondingPool = 0x5d4020b9261f01b6f8a45db929704b0ad6f5e9e6 -), - --- we now join the previous two tables so that we can associate the name of an active solver under the CoW DAO bonding pool --- with its "real" join time, i.e., the first time that it joined the pool (using potentially an account that changed on the way) -join_date_per_cow_dao_solver as ( - select - solver_name, - min(evt_block_time) as join_time - from - all_cow_dao_solvers - group by - solver_name -), - --- we now create an intermediate table to put back the "prod/barn" prefix to the solver names --- as this will make it easier to join with the rest of the tables that we want to do join -active_cow_dao_solvers_join_date as ( - select - concat('prod-', jdpcds.solver_name) as solver_name, - jdpcds.join_time - from - join_date_per_cow_dao_solver as jdpcds - inner join active_cow_dao_solver_names as acdsn on jdpcds.solver_name = acdsn.solver_name - union distinct - select - concat('barn-', jdpcds.solver_name) as solver_name, - jdpcds.join_time - from - join_date_per_cow_dao_solver as jdpcds - inner join active_cow_dao_solver_names as acdsn on jdpcds.solver_name = acdsn.solver_name -), - --- this is now the first calculation of whether a solver in the CoW DAO bonding pool needs to pay a service fee. --- note that we assume here no solver has its own subpool, and we will correct that later on. -active_cow_dao_solvers_service_fee as ( - select - solver_name, - case - when join_time > date_add('month', -6, cast('{{time}}' as timestamp)) then false - else true - end as pay_service_fee - from - active_cow_dao_solvers_join_date -), - --- we now create a table of all active solvers, not just the ones in the CoW DAO bonding pool, --- where we still pretend there are no reduced bonding pools -all_active_solvers_service_fee_prelim as ( - select - v.solver, - v.reward_target, - v.pool_address, - v.pool_name, - v.solver_name, - coalesce(acdssf.pay_service_fee, false) as pay_service_fee - from - "query_1541516(vouch_cte_name='named_results',end_time='{{time}}')" as v - left outer join active_cow_dao_solvers_service_fee as acdssf on v.solver_name = acdssf.solver_name -), - --- we now create another table that only looks at the reduced subpools and computes whether the solvers --- with subpools need to pay a service fee or not -reduced_bonding_pool_solvers_service_fee as ( - select - pool_name, - solver_address, - case - when creation_date > date_add('month', -3, cast('{{time}}' as timestamp)) then false - else true - end as pay_service_fee - from query_4065709 -), - --- finally, we join the prelim table with the above table and we define that a solver with a subpool needs to pay --- a servive fee only if it is at least 6 months in the CoW DAO bonding pool AND >= 3 months have passed since the creation --- of the subpool -all_active_solvers_service_fee_final as ( - select - p.solver, - p.reward_target, - p.pool_address, - p.solver_name, - coalesce(rbp.pool_name, p.pool_name) as pool_name, - coalesce(rbp.pay_service_fee and p.pay_service_fee, p.pay_service_fee) as pay_service_fee - from all_active_solvers_service_fee_prelim as p left outer join reduced_bonding_pool_solvers_service_fee as rbp on p.solver = rbp.solver_address -) - -select * from all_active_solvers_service_fee_final diff --git a/cowprotocol/accounting/rewards/mainnet/service_fee_query_4298142.sql b/cowprotocol/accounting/rewards/mainnet/service_fee_query_4298142.sql new file mode 100644 index 00000000..999c52c6 --- /dev/null +++ b/cowprotocol/accounting/rewards/mainnet/service_fee_query_4298142.sql @@ -0,0 +1,86 @@ +-- This query computes which solvers need to pay service fee +-- by breaking down the calculation in small (and somewhat tedious) steps +-- We stress the query is not efficient (and recomputes same things along the way) +-- but we believe it is at least straightforward to check its correctness, and given +-- that it's fast anyways, we decided to go with this. + +-- Parameters: +-- {{start_time}}: the start date of an accounting week +-- {{end_time}}: the end date of an accounting week + +with +-- we first compute all active solvers of the CoW DAO bonding pool (this includes the ones that have their own reduced subpool) +active_cow_dao_solver_names as ( + select --noqa: ST06 + case + when solver_name = 'new-Uncatalogued' then cast(solver as varchar) + else substring(solver_name, 6, 100) + end as solver_name, + case + when solver_name = 'new-Uncatalogued' then 'new' + else substring(solver_name, 1, 4) + end as environment, + solver as solver_address, + pool_name + from + "query_1541516(vouch_cte_name='named_results',end_time='{{end_time}}')" + where + pool_address = 0x5d4020b9261f01b6f8a45db929704b0ad6f5e9e6 -- CoW DAO bonding pool address +), + +-- we now take one step back and look at all solver accounts (not only the active ones) that have joined the CoW DAO bonding pool at some point, +-- and we recover the date of them joining +all_cow_dao_solvers as ( + select --noqa: ST06 + case + when s.environment = 'new' then cast(v.solver as varchar) + else s.name + end as solver_name, + s.environment, + v.evt_block_time + from + cow_protocol_ethereum.VouchRegister_evt_Vouch as v + inner join cow_protocol_ethereum.solvers as s on v.solver = s.address + where + v.bondingPool = 0x5d4020b9261f01b6f8a45db929704b0ad6f5e9e6 +), + +-- we now process the all_cow_dao_solvers table so that we can associate the name of a solver under the CoW DAO bonding pool +-- with its "real" join time, i.e., the first time that it joined the pool (using potentially an account that changed on the way) +join_date_per_cow_dao_solver as ( + select + solver_name, + environment, + min(evt_block_time) as join_time + from all_cow_dao_solvers group by solver_name, environment +), + +-- this is now the first calculation of whether a solver in the CoW DAO bonding pool needs to pay a service fee. +-- note that we assume here no solver has its own subpool, and we will correct that later on. +active_cow_dao_solvers_service_fee as ( + select + c.solver_name, + c.environment, + a.solver_address, + a.pool_name, + case + when c.join_time > date_add('month', -6, cast('{{start_time}}' as timestamp)) then false + else true + end as service_fee_flag, + c.join_time + from join_date_per_cow_dao_solver as c inner join active_cow_dao_solver_names as a on c.solver_name = a.solver_name and c.environment = a.environment +), + +reduced_bonds as ( + select * from "query_4065709" +) + +select + coalesce(e.solver_name, concat(environment, '-', d.solver_name)) as solver_name, + coalesce(e.solver_address, d.solver_address) as solver, + coalesce(e.pool_name, d.pool_name) as pool_name, + case + when e.creation_date > date_add('month', -3, cast('{{start_time}}' as timestamp)) then false + else d.service_fee_flag + end as service_fee +from active_cow_dao_solvers_service_fee as d left outer join reduced_bonds as e on d.solver_address = e.solver_address diff --git a/cowprotocol/accounting/rewards/mainnet/service_fee_query_4017925.sql b/cowprotocol/accounting/rewards/mainnet/service_fee_query_DEPRECATED_4017925.sql similarity index 99% rename from cowprotocol/accounting/rewards/mainnet/service_fee_query_4017925.sql rename to cowprotocol/accounting/rewards/mainnet/service_fee_query_DEPRECATED_4017925.sql index 155fb8ee..cfc402c4 100644 --- a/cowprotocol/accounting/rewards/mainnet/service_fee_query_4017925.sql +++ b/cowprotocol/accounting/rewards/mainnet/service_fee_query_DEPRECATED_4017925.sql @@ -1,3 +1,7 @@ +------------ DEPRECATED! +------------ +------------ +------------ with -- Add colocated solvers here