diff --git a/cowprotocol/accounting/rewards/solver_rewards_per_auction_5703026.sql b/cowprotocol/accounting/rewards/solver_rewards_per_auction_5703026.sql new file mode 100644 index 00000000..b3d003fd --- /dev/null +++ b/cowprotocol/accounting/rewards/solver_rewards_per_auction_5703026.sql @@ -0,0 +1,212 @@ +-- This query returns a detailed breakdown on the different types of reward or reimbursement solvers get, on a auction basis +-- The timestamp associated to each auction is the block deadline's one + +-- params: +-- start and end_time: period to consider (usually Tuesday 00:00 UTC to Tuesday 00:00 UTC to consider the payout cycle) +-- blockchain: specific chain + +-- columns: +-- quote rewards = reward for offering the winning quote +-- primary rewards = performance reward / reward for solving +-- network fee = amounts the solvers should be reimbursed due to their gas spend +-- slippage = imbalance generated in the settlement contract during a given auction +-- execution costs = actual solver's gas cost of a given batch + +--noqa: disable=all +with +auction_range as ( + select + environment, + min(auction_id) as min_auction_id, + max(auction_id) as max_auction_id + from "query_5270914(blockchain='{{blockchain}}', start_time='{{start_time}}', end_time='{{end_time}}')" + group by environment +) +, vouch_registry as ( + select * from "query_1541516(blockchain='{{blockchain}}', end_time='{{end_time}}', vouch_cte_name='named_results')" +) +, quote_cap_mapping as ( + select * + from + (values + -- Pre CIP 72 + (timestamp '2010-01-01 00:00', timestamp '2025-08-12 00:00', 0.0006, 6, 'ethereum'), + (timestamp '2010-01-01 00:00', timestamp '2025-08-12 00:00', 0.15, 6, 'gnosis'), + (timestamp '2010-01-01 00:00', timestamp '2025-08-12 00:00', 0.0002, 6, 'base'), + (timestamp '2010-01-01 00:00', timestamp '2025-08-12 00:00', 0.0002, 6, 'arbitrum'), + (timestamp '2010-01-01 00:00', timestamp '2025-08-12 00:00', 0.0005, 6, 'avalanche_c'), + (timestamp '2010-01-01 00:00', timestamp '2025-08-12 00:00', 0.5, 6, 'polygon'), + -- Post CIP 72 + (timestamp '2025-08-12 00:00', timestamp '2099-01-01 00:00', 0.0007, 6, 'ethereum'), + (timestamp '2025-08-12 00:00', timestamp '2099-01-01 00:00', 0.15, 6, 'gnosis'), + (timestamp '2025-08-12 00:00', timestamp '2099-01-01 00:00', 0.00024, 6, 'base'), + (timestamp '2025-08-12 00:00', timestamp '2099-01-01 00:00', 0.00024, 6, 'arbitrum'), + (timestamp '2025-08-12 00:00', timestamp '2099-01-01 00:00', 0.0006, 6, 'avalanche_c'), + (timestamp '2025-08-12 00:00', timestamp '2099-01-01 00:00', 0.6, 6, 'polygon') + + ) as t(from_ts, until_ts, quote_cap_native, quote_cap_cow, blockchain) +) +, conv_native_to_cow as ( + select + end_time as date, + native_token_price / nullif(cow_price, 0) as native_to_cow_rate + from dune.cowprotocol.result_accounting_cow_and_native_prices_per_chain + where + blockchain = '{{blockchain}}' + and end_time > date_add('day', -1, cast('{{end_time}}' as timestamp)) + and end_time < date_add('day', +1, cast('{{end_time}}' as timestamp)) +) +-------------------------------------------------------------------------------- +-- PERFORMANCE REWARDS + NETWORK FEES + EXECUTION COSTS +, auction_data_prep as ( + select + ad.environment, + ad.auction_id, + ad.block_deadline, + b.time as block_time, + ad.solver, + ad.total_network_fee, + ad.total_execution_cost, + ad.capped_payment + from "query_5270914(blockchain='{{blockchain}}',start_time='{{start_time}}',end_time='{{end_time}}')" as ad + inner join auction_range as ar + on ad.environment = ar.environment + and ad.auction_id between ar.min_auction_id and ar.max_auction_id + left join {{blockchain}}.blocks b + on ad.block_deadline = b.number +) +, auction_data_in_native as ( + select + solver, + auction_id, + block_deadline, + block_time, + coalesce( cast(sum(capped_payment) as double), 0) / pow(10, 18) as primary_reward_native, + coalesce( cast(sum(total_network_fee) as double), 0) / pow(10, 18) as network_fee_native, + coalesce( cast(sum(total_execution_cost) as double), 0) / pow(10, 18) as execution_cost_native + from auction_data_prep + group by 1,2,3,4 +) +, auction_data as ( + select + solver, + auction_id, + block_deadline, + block_time, + + primary_reward_native, + network_fee_native, + execution_cost_native, + + primary_reward_native * p.native_to_cow_rate as primary_reward_cow, + network_fee_native * p.native_to_cow_rate as network_fee_cow, + execution_cost_native * p.native_to_cow_rate as execution_cost_cow + from auction_data_in_native ad + left join conv_native_to_cow as p + on date_trunc('week', ad.block_time - interval '1' day) + interval '8' day = p.date +) +-------------------------------------------------------------------------------- +-- QUOTE REWARDS +, winning_quotes as ( + select + od.auction_id, + t.block_time, + od.quote_solver as solver + from "query_4364122(blockchain='{{blockchain}}')" as od + inner join auction_range as ar + on od.environment = ar.environment + and od.auction_id between ar.min_auction_id and ar.max_auction_id + inner join cow_protocol_{{blockchain}}.trades as t + on od.order_uid = t.order_uid + and od.quote_solver != 0x0000000000000000000000000000000000000000 +) +, quote_rewards as ( + select + wq.solver, + wq.auction_id, + wq.block_time, + least(cap.quote_cap_cow, cap.quote_cap_native * p.native_to_cow_rate) as quote_reward_cow, + least(cap.quote_cap_cow, cap.quote_cap_native * p.native_to_cow_rate) / p.native_to_cow_rate as quote_reward_native + from winning_quotes as wq + left join quote_cap_mapping as cap + on wq.block_time > cap.from_ts + and wq.block_time <= cap.until_ts + and cap.blockchain = '{{blockchain}}' + left join conv_native_to_cow as p + on date_trunc('week', wq.block_time - interval '1' day) + interval '8' day = p.date +) +-------------------------------------------------------------------------------- +-- SLIPPAGE +, solver_slippage_in_native as ( + select + solver_address as solver, + block_time, + cast(sum(slippage_wei) as double) / pow(10, 18) as slippage_native + from "query_4070065(blockchain='{{blockchain}}', start_time='{{start_time}}', end_time='{{end_time}}', slippage_table_name='slippage_per_transaction')" s + group by 1,2 +) +, solver_slippage as ( + select + solver, + block_time, + slippage_native, + slippage_native * p.native_to_cow_rate as slippage_cow + from solver_slippage_in_native s + left join conv_native_to_cow as p + on date_trunc('week', s.block_time - interval '1' day) + interval '8' day = p.date +) +-------------------------------------------------------------------------------- +, combined_data as ( + select + coalesce(ad.block_time, sl.block_time, qr.block_time) as block_time, + coalesce(ad.solver, sl.solver, qr.solver) as solver, + concat(s.environment, '-', s.name) as name, + + ad.primary_reward_native, + ad.network_fee_native, + ad.execution_cost_native, + ad.primary_reward_cow, + ad.network_fee_cow, + ad.execution_cost_cow, + + coalesce(qr.quote_reward_native, 0) as quote_reward_native, + coalesce(qr.quote_reward_cow, 0) as quote_reward_cow, + + coalesce(sl.slippage_native, 0) as slippage_native, + coalesce(sl.slippage_cow, 0) as slippage_cow + + from auction_data as ad + full outer join quote_rewards as qr + on ad.solver = qr.solver + and ad.block_time = qr.block_time + full outer join solver_slippage as sl + on ad.solver = sl.solver + and ad.block_time = sl.block_time + left join cow_protocol_{{blockchain}}.solvers as s + on coalesce(ad.solver, sl.solver, qr.solver) = s.address +) +select --noqa: ST06 + block_time, + (date_trunc('week', block_time - interval '1' day) + interval '8' day) as payout_date, --tuesday + name as solver, + cd.solver as solver_address, + vr.reward_target as reward_address, + + quote_reward_native, + quote_reward_cow, + + primary_reward_native, + primary_reward_cow, + + network_fee_native, + network_fee_cow, + + slippage_native, + slippage_cow, + + execution_cost_native, + execution_cost_cow + +from combined_data as cd +left join vouch_registry as vr + on cd.solver = vr.solver diff --git a/cowprotocol/accounting/rewards/solver_rewards_per_payout_week_5687609.sql b/cowprotocol/accounting/rewards/solver_rewards_per_payout_week_5687609.sql new file mode 100644 index 00000000..9daca121 --- /dev/null +++ b/cowprotocol/accounting/rewards/solver_rewards_per_payout_week_5687609.sql @@ -0,0 +1,116 @@ +-- This query returns a detailed breakdown on the different types of reward or reimbursement solvers get, on a block_time basis + +-- params: +-- quote_cap_native_token and quote_reward: chain-specific limits for rewards on a batch basis, more details in https://docs.cow.fi/cow-protocol/reference/core/auctions/rewards#price-estimation-competition-rewards-cips-27-57 +-- start and end_time: period to consider (usually Tuesday 00:00 UTC to Tuesday 00:00 UTC to consider the payout cycle) + +-- columns: +-- quote rewards = reward for offering the winning quote +-- primary rewards = performance reward / reward for solving +-- network fee = amounts the solvers should be reimbursed due to their gas spend +-- execution costs = actual gas cost of that batch for the solver +-- slippage = imbalance generated in the settlement contract during a given auction +-- reimbursement = slippage + network fees +-- overdraft = when the sum of primary_reward + slippage + network_fee is negative +-- native_token_transfer = amount due to the solver in native token, depends on specific logic that can be seen in the end of this code +-- cow_transfer = amount due to the solver in COW token, depends on specific logic that can be seen in the end of this code (does not including quote rewards) + +--noqa: disable=all + +with +week_agg as ( + select + payout_date + , solver + , solver_address + , reward_address + + , sum(quote_reward_native) as quote_reward_native + , sum(quote_reward_cow) as quote_reward_cow + + , sum(primary_reward_native) as primary_reward_native + , sum(primary_reward_cow) as primary_reward_cow + + , sum(slippage_native) as slippage_native + , sum(slippage_cow) as slippage_cow + + , sum(network_fee_native) as network_fee_native + , sum(network_fee_cow) as network_fee_cow + + , sum(execution_cost_native) as execution_cost_native + , sum(execution_cost_cow) as execution_cost_cow + + from "query_5703026(blockchain='ethereum', start_time='{{start_time}}', end_time='{{end_time}}')" + group by 1,2,3,4 +) +, service_fee_flag as ( + select + solver as solver_address, + service_fee, + case when service_fee then 0.85 else 1 end as service_fee_factor + from "query_4298142(blockchain='{{blockchain}}', start_time='{{start_time}}', end_time='{{end_time}}')" +) +, service_fee_correction as ( + select + payout_date + , solver + , wa.solver_address + , reward_address + , coalesce(sff.service_fee, false) as service_fee_enabled + + , coalesce(sff.service_fee_factor, 1) * quote_reward_native as quote_reward_native + , coalesce(sff.service_fee_factor, 1) * quote_reward_cow as quote_reward_cow + + , case + when primary_reward_native < 0 then primary_reward_native + else coalesce(sff.service_fee_factor, 1) * primary_reward_native + end as primary_reward_native + , case + when primary_reward_cow < 0 then primary_reward_cow + else coalesce(sff.service_fee_factor, 1) * primary_reward_cow + end as primary_reward_cow + + , slippage_native + , slippage_cow + + , network_fee_native + , network_fee_cow + + , execution_cost_native + , execution_cost_cow + + from week_agg as wa + left join service_fee_flag as sff + on wa.solver_address = sff.solver_address +) +, payout_logic_prep as ( + select * + , slippage_native + network_fee_native as reimbursement_native + , slippage_cow + network_fee_cow as reimbursement_cow + , coalesce(primary_reward_native + slippage_native + network_fee_native < 0, false) as is_overdraft + from week_agg +) +select + *, + case + when is_overdraft then null + when reimbursement_native > 0 and primary_reward_cow < 0 + then reimbursement_native + primary_reward_native + when reimbursement_native < 0 and primary_reward_cow > 0 + then 0 + else reimbursement_native + end as native_token_transfer, + + case + when is_overdraft then null + when reimbursement_native > 0 and primary_reward_cow < 0 + then 0 + when reimbursement_native < 0 and primary_reward_cow > 0 + then reimbursement_cow + primary_reward_cow + else primary_reward_cow + end as cow_transfer, + + if(is_overdraft, primary_reward_native + slippage_native + network_fee_native) as overdraft_native + +from payout_logic_prep +order by 1,2