From 4ceeb9349c126d6a9319807013d23b0e921abbbd Mon Sep 17 00:00:00 2001 From: Haris Angelidakis <64154020+harisang@users.noreply.github.com> Date: Fri, 20 Dec 2024 15:29:49 +0200 Subject: [PATCH] Extend protocol fees per order class query to all chains (#99) * extend query to all chains * bug fixing * rename columns * add missing parameter in query description * switch to closed interval --- .../protocol_fees_by_order_class_3703312.sql | 71 +++++++++++-------- 1 file changed, 42 insertions(+), 29 deletions(-) diff --git a/cowprotocol/accounting/fees/protocol_fees_by_order_class_3703312.sql b/cowprotocol/accounting/fees/protocol_fees_by_order_class_3703312.sql index 0a77223..69bb432 100644 --- a/cowprotocol/accounting/fees/protocol_fees_by_order_class_3703312.sql +++ b/cowprotocol/accounting/fees/protocol_fees_by_order_class_3703312.sql @@ -1,51 +1,64 @@ -- This query computes protocol fees collected by the DAO, -- and breaks down the revenue based on order class. +-- Native token is ETH, with the exception of Gnosis Chain, where it is xDAI -- -- Parameters: -- {{start_time}} - the timestamp for which the analysis should start (inclusively) -- {{end_time}} - the timestamp for which the analysis should end (exclusively) +-- {{blockchain}}: the corresponding network with +block_range as ( + select * from "query_3333356(blockchain='{{blockchain}}',start_time='{{start_time}}',end_time='{{end_time}}')" +), + +-- context: CoW DAO enabled protocol fees after mainnet block 19068880; there were no protocol fees collected up till that block. +initial_block as ( + select + case + when '{{blockchain}}' = 'ethereum' then 19068880 + else 1 + end as initial_block +), + protocol_fees_collected as ( select --noqa: ST06 - order_uid, --noqa: RF03 - cast(cast(data.protocol_fee as varchar) as int256) * data.protocol_fee_native_price / pow(10, 18) as protocol_fee_in_eth, --noqa: RF01, RF03 - cast(cast(data.protocol_fee as varchar) as int256) as protocol_fee_in_surplus_token, --noqa: RF01 + order_uid, + protocol_fee * protocol_fee_native_price / pow(10, 18) as protocol_fee_in_native_token, + protocol_fee as protocol_fee_in_surplus_token, case - when data.partner_fee_recipient is not null then cast(data.partner_fee as int256) * data.protocol_fee_native_price / pow(10, 18) --noqa: RF01 - end as partner_fee_eth, - cast(cast(data.protocol_fee as varchar) as int256) * data.protocol_fee_native_price / pow(10, 18) - coalesce(case when data.partner_fee_recipient is not null then cast(data.partner_fee as int256) * data.protocol_fee_native_price / pow(10, 18) end, 0) as net_protocol_fee_in_eth, --noqa: RF01 - data.protocol_fee_token as surplus_token, --noqa: RF01 - data.quote_gas_cost, --noqa: RF01 - data.quote_sell_token_price, --noqa: RF01 - data.quote_sell_amount, --noqa: RF01 - data.quote_buy_amount, --noqa: RF01 - tx_hash, --noqa: RF03 - data.protocol_fee_kind --noqa: RF01 - from cowswap.raw_order_rewards - where block_number > 19068880 and order_uid not in (select cast(order_uid as varchar) from query_3639473) --noqa: RF03 - -- context: CoW DAO enabled protocol fees after mainnet block 19068880; there were no protocol fees collected up till that block. + when partner_fee_recipient is not null then partner_fee * protocol_fee_native_price / pow(10, 18) + end as partner_fee_native_token, + protocol_fee * protocol_fee_native_price / pow(10, 18) - coalesce(case when partner_fee_recipient is not null then cast(partner_fee as int256) * protocol_fee_native_price / pow(10, 18) end, 0) as net_protocol_fee_in_native_token, + protocol_fee_token as surplus_token, + quote_gas_cost, + quote_sell_token_price, + quote_sell_amount, + quote_buy_amount, + tx_hash + from "query_4364122(blockchain='{{blockchain}}')" + where block_number > (select initial_block from initial_block) and cast(order_uid as varchar) not in (select order_uid from query_3639473) ) + select order_class, - sum(protocol_fee_in_eth) as total_fee_in_eth, - sum(net_protocol_fee_in_eth) as net_protocol_fee_in_eth, - sum(partner_fee_eth) as total_partner_fee, + sum(protocol_fee_in_native_token) as total_fee_in_native_token, + sum(net_protocol_fee_in_native_token) as net_protocol_fee_in_native_token, + sum(partner_fee_native_token) as total_partner_fee, sum(case - when partner_recipient = '0x63695Eee2c3141BDE314C5a6f89B98E62808d716' then partner_fee_eth * 0.90 - when partner_recipient is not null then partner_fee_eth * 0.85 + when partner_recipient = '0x63695Eee2c3141BDE314C5a6f89B98E62808d716' then partner_fee_native_token * 0.90 + when partner_recipient is not null then partner_fee_native_token * 0.85 end) as partner_fee_part, sum(case - when partner_recipient = '0x63695Eee2c3141BDE314C5a6f89B98E62808d716' then partner_fee_eth * 0.10 - when partner_recipient is not null then partner_fee_eth * 0.15 + when partner_recipient = '0x63695Eee2c3141BDE314C5a6f89B98E62808d716' then partner_fee_native_token * 0.10 + when partner_recipient is not null then partner_fee_native_token * 0.15 end) as cow_dao_partner_fee_part from protocol_fees_collected as f -inner join cow_protocol_ethereum.trades as t - on f.order_uid = cast(t.order_uid as varchar) and f.tx_hash = cast(t.tx_hash as varchar) -left join dune.cowprotocol.result_cow_protocol_ethereum_app_data as a on t.app_data = a.app_hash +inner join cow_protocol_{{blockchain}}.trades as t + on f.order_uid = t.order_uid and f.tx_hash = t.tx_hash +left join dune.cowprotocol.result_cow_protocol_{{blockchain}}_app_data as a on t.app_data = a.app_hash where - block_date >= date '2024-01-23' - and block_date >= timestamp'{{start_time}}' - and block_date < timestamp'{{end_time}}' + block_number >= (select start_block from block_range) + and block_number <= (select end_block from block_range) group by 1 order by 1 desc