From 234b24e982eb964bdd2a0c63417f14e4d0f665ca Mon Sep 17 00:00:00 2001 From: harisang Date: Tue, 3 Sep 2024 12:25:55 +0300 Subject: [PATCH] sqlfluff fixes --- .../mainnet/service_fee_query_4017925.sql | 431 +++++++++--------- 1 file changed, 213 insertions(+), 218 deletions(-) diff --git a/cowprotocol/accounting/rewards/mainnet/service_fee_query_4017925.sql b/cowprotocol/accounting/rewards/mainnet/service_fee_query_4017925.sql index 8a465eda..80e7dfd9 100644 --- a/cowprotocol/accounting/rewards/mainnet/service_fee_query_4017925.sql +++ b/cowprotocol/accounting/rewards/mainnet/service_fee_query_4017925.sql @@ -1,5 +1,6 @@ WITH -bonding_pools (pool, name, initial_funder) AS ( + +bonding_pools (name, pool, initial_funder) AS ( SELECT name, from_hex(pool), @@ -7,250 +8,244 @@ bonding_pools (pool, name, initial_funder) AS ( FROM ( VALUES {{BondingPoolData}} ) AS _ (name, pool,funder) - ), +), first_event_after_timestamp AS ( - SELECT - MAX(number) + SELECT MAX(number) FROM - ethereum.blocks + ethereum.blocks WHERE - time > CAST('2024-08-20 00:00:00' AS timestamp) -- CIP-48 starts bonding pool timer at midnight UTC on 20/08/24 - ), - initial_vouches AS ( + time > CAST('2024-08-20 00:00:00' AS timestamp) -- CIP-48 starts bonding pool timer at midnight UTC on 20/08/24 +), + +initial_vouches AS ( SELECT - RANK() OVER ( - PARTITION BY - solver, - bondingPool, - sender - ORDER BY - evt_block_number ASC, - evt_index ASC - ) AS rk, - evt_block_number, - evt_index, - solver, - cowRewardTarget, - bondingPool, - sender, - True AS active + evt_block_number, + evt_index, + solver, + cowRewardTarget, + bondingPool, + sender, + True AS active, + RANK() OVER ( + PARTITION BY + solver, + bondingPool, + sender + ORDER BY + evt_block_number ASC, + evt_index ASC + ) AS rk FROM - cow_protocol_ethereum.VouchRegister_evt_Vouch + cow_protocol_ethereum.VouchRegister_evt_Vouch WHERE - evt_block_number <= ( - SELECT - * - FROM - first_event_after_timestamp - ) - AND bondingPool IN ( - SELECT - pool - FROM - bonding_pools - ) - AND sender IN ( - SELECT - initial_funder - FROM - bonding_pools - ) - ), - joined_on_data AS ( + evt_block_number <= ( + SELECT * + FROM + first_event_after_timestamp + ) + AND bondingPool IN ( + SELECT pool + FROM + bonding_pools + ) + AND sender IN ( + SELECT initial_funder + FROM + bonding_pools + ) +), + +joined_on_data AS ( SELECT - iv.solver, - iv.cowRewardTarget AS reward_target, - iv.bondingPool AS pool, - iv.evt_block_number, - iv.evt_index, - iv.rk, - True AS active + iv.solver, + iv.cowRewardTarget AS reward_target, + iv.bondingPool AS pool, + iv.evt_block_number, + iv.evt_index, + iv.rk, + True AS active FROM - initial_vouches iv + initial_vouches AS iv WHERE - iv.rk = 1 - ), - latest_vouches AS ( + iv.rk = 1 +), + +latest_vouches AS ( SELECT - RANK() OVER ( - PARTITION BY - solver, - bondingPool, - sender - ORDER BY - evt_block_number DESC, - evt_index DESC - ) AS rk, - evt_block_number, - evt_index, - solver, - cowRewardTarget, - bondingPool, - sender, - CASE - WHEN event_type = 'Vouch' THEN True - ELSE False - END AS active + evt_block_number, + evt_index, + solver, + cowRewardTarget, + bondingPool, + sender, + RANK() OVER ( + PARTITION BY + solver, + bondingPool, + sender + ORDER BY + evt_block_number DESC, + evt_index DESC + ) AS rk, + COALESCE (event_type = 'Vouch', FALSE) AS active FROM - ( - SELECT - evt_block_number, - evt_index, - solver, - cowRewardTarget, - bondingPool, - sender, - 'Vouch' AS event_type - FROM - cow_protocol_ethereum.VouchRegister_evt_Vouch - WHERE - evt_block_number <= ( - SELECT - * - FROM - first_event_after_timestamp - ) - AND bondingPool IN ( + ( SELECT - pool + evt_block_number, + evt_index, + solver, + cowRewardTarget, + bondingPool, + sender, + 'Vouch' AS event_type FROM - bonding_pools - ) - AND sender IN ( + cow_protocol_ethereum.VouchRegister_evt_Vouch + WHERE + evt_block_number <= ( + SELECT * + FROM + first_event_after_timestamp + ) + AND bondingPool IN ( + SELECT pool + FROM + bonding_pools + ) + AND sender IN ( + SELECT initial_funder + FROM + bonding_pools + ) + UNION DISTINCT SELECT - initial_funder + evt_block_number, + evt_index, + solver, + Null AS cowRewardTarget, -- Invalidation does not have a reward target + bondingPool, + sender, + 'InvalidateVouch' AS event_type FROM - bonding_pools - ) - UNION - SELECT - evt_block_number, - evt_index, - solver, - NULL AS cowRewardTarget, -- Invalidation does not have a reward target - bondingPool, - sender, - 'InvalidateVouch' AS event_type - FROM - cow_protocol_ethereum.VouchRegister_evt_InvalidateVouch - WHERE - evt_block_number <= ( - SELECT - * - FROM - first_event_after_timestamp - ) - AND bondingPool IN ( - SELECT - pool - FROM - bonding_pools - ) - AND sender IN ( - SELECT - initial_funder - FROM - bonding_pools - ) - ) AS unioned_events - ), - valid_vouches AS ( + cow_protocol_ethereum.VouchRegister_evt_InvalidateVouch + WHERE + evt_block_number <= ( + SELECT * + FROM + first_event_after_timestamp + ) + AND bondingPool IN ( + SELECT pool + FROM + bonding_pools + ) + AND sender IN ( + SELECT initial_funder + FROM + bonding_pools + ) + ) AS unioned_events +), + +valid_vouches AS ( SELECT - lv.solver, - lv.cowRewardTarget AS reward_target, - lv.bondingPool AS pool + lv.solver, + lv.cowRewardTarget AS reward_target, + lv.bondingPool AS pool FROM - latest_vouches lv + latest_vouches AS lv WHERE - lv.rk = 1 - AND lv.active = TRUE - ), - joined_on AS ( + lv.rk = 1 + AND lv.active = True +), + +joined_on AS ( SELECT - jd.solver, - jd.reward_target, - jd.pool, - bp.name AS pool_name, - b.time AS joined_on + jd.solver, + jd.reward_target, + jd.pool, + bp.name AS pool_name, + b.time AS joined_on FROM - joined_on_data jd - JOIN ethereum.blocks b ON b.number = jd.evt_block_number - JOIN bonding_pools bp ON jd.pool = bp.pool - ), - named_results AS ( + joined_on_data AS jd + INNER JOIN ethereum.blocks AS b ON jd.evt_block_number = b.number + INNER JOIN bonding_pools AS bp ON jd.pool = bp.pool +), + +named_results AS ( SELECT - jd.solver, - CONCAT(environment, '-', s.name) AS solver_name, - jd.pool_name, - jd.pool, - jd.joined_on, - date_diff('day', date(jd.joined_on), date(NOW())) AS days_in_pool + jd.solver, + jd.pool_name, + jd.pool, + jd.joined_on, + CONCAT(environment, '-', s.name) AS solver_name, + DATE_DIFF('day', DATE(jd.joined_on), DATE(NOW())) AS days_in_pool FROM - joined_on jd - JOIN cow_protocol_ethereum.solvers s ON s.address = jd.solver - JOIN valid_vouches vv ON vv.solver = jd.solver - AND vv.pool = jd.pool - ), - ranked_named_results AS ( + joined_on AS jd + INNER JOIN cow_protocol_ethereum.solvers AS s ON jd.solver = s.address + INNER JOIN valid_vouches + AS vv ON jd.solver = vv.solver + AND jd.pool = vv.pool +), + +ranked_named_results AS ( SELECT - nr.solver, - nr.solver_name, - nr.pool_name, - nr.pool, - nr.joined_on, - nr.days_in_pool, - ROW_NUMBER() OVER ( - PARTITION BY - nr.solver_name - ORDER BY - nr.joined_on DESC - ) AS rn, - COUNT(*) OVER ( - PARTITION BY - nr.solver_name - ) AS solver_name_count + nr.solver, + nr.solver_name, + nr.pool_name, + nr.pool, + nr.joined_on, + nr.days_in_pool, + ROW_NUMBER() OVER ( + PARTITION BY + nr.solver_name + ORDER BY + nr.joined_on DESC + ) AS rn, + COUNT(*) OVER ( + PARTITION BY + nr.solver_name + ) AS solver_name_count FROM - named_results nr - ), - filtered_named_results AS ( + named_results AS nr +), + +filtered_named_results AS ( SELECT - rnr.solver, - rnr.solver_name, - CASE - WHEN rnr.solver_name_count > 1 THEN 'Colocation' - ELSE rnr.pool_name - END AS pool_name, - rnr.pool, - rnr.joined_on, - rnr.days_in_pool, - CASE - WHEN rnr.solver_name_count > 1 THEN DATE_ADD('month', 3, rnr.joined_on) -- Add 3 month grace period for colocated solvers - ELSE GREATEST( - DATE_ADD('month', 6, rnr.joined_on), -- Add 6 month grace period to joined_on for non colocated solvers - TIMESTAMP '2024-08-20 00:00:00' -- Introduction of CIP-48 - ) - END AS expires + rnr.solver, + rnr.solver_name, + rnr.pool, + rnr.joined_on, + rnr.days_in_pool, + CASE + WHEN rnr.solver_name_count > 1 THEN 'Colocation' + ELSE rnr.pool_name + END AS pool_name, + CASE + WHEN rnr.solver_name_count > 1 THEN DATE_ADD('month', 3, rnr.joined_on) -- Add 3 month grace period for colocated solvers + ELSE GREATEST( + DATE_ADD('month', 6, rnr.joined_on), -- Add 6 month grace period to joined_on for non colocated solvers + TIMESTAMP '2024-08-20 00:00:00' -- Introduction of CIP-48 + ) + END AS expires FROM - ranked_named_results rnr + ranked_named_results AS rnr WHERE - rnr.rn = 1 - ) + rnr.rn = 1 +) + SELECT - fnr.solver, - fnr.solver_name, - fnr.pool_name, - fnr.pool, - fnr.joined_on, - fnr.days_in_pool, - CASE - WHEN fnr.pool_name = 'Gnosis' THEN TIMESTAMP '2028-10-08 00:00:00' - ELSE fnr.expires - END AS expires, - CASE - WHEN NOW() > fnr.expires - AND fnr.pool_name != 'Gnosis' THEN TRUE - ELSE FALSE - END AS service_fee + fnr.solver, + fnr.solver_name, + fnr.pool_name, + fnr.pool, + fnr.joined_on, + fnr.days_in_pool, + CASE + WHEN fnr.pool_name = 'Gnosis' THEN TIMESTAMP '2028-10-08 00:00:00' + ELSE fnr.expires + END AS expires, + COALESCE (NOW() > fnr.expires + AND fnr.pool_name != 'Gnosis', FALSE) AS service_fee FROM - filtered_named_results fnr; \ No newline at end of file + filtered_named_results AS fnr;