This repository has been archived by the owner on Dec 20, 2024. It is now read-only.
-
Notifications
You must be signed in to change notification settings - Fork 1
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
This PR finalizes the DB query based on the progress made in [rewards script](https://github.com/cowprotocol/solver-rewards) -- specifically that query which was finalized [here](cowprotocol/solver-rewards#203) Its a bit gross that the orderbook query lives in two places (for the time being). At some point we will want to expose this as an API endpoint (on a constrained `block_range`) directly via the orderbook. However, until we have landed on the correct query (sufficient to reproduce solver rewards) we will maintain this externally - in two places. The tests introduced here are both for the DB extraction result and then the transformation phase to JSON before upload. Closes #31
- Loading branch information
Showing
6 changed files
with
309 additions
and
74 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -1,68 +1,97 @@ | ||
WITH observed_settlements AS ( | ||
SELECT | ||
-- settlement | ||
tx_hash, | ||
solver, | ||
-- settlement_observations | ||
block_number, | ||
effective_gas_price * gas_used AS execution_cost, | ||
surplus, | ||
fee, | ||
-- auction_transaction | ||
auction_id | ||
FROM settlement_observations so | ||
JOIN settlements s | ||
ON s.block_number = so.block_number | ||
AND s.log_index = so.log_index | ||
JOIN auction_transaction at | ||
ON s.tx_from = at.tx_from | ||
AND s.tx_nonce = at.tx_nonce | ||
WHERE block_number > {{start_block}} AND block_number <= {{end_block}} | ||
), | ||
WITH observed_settlements AS (SELECT | ||
-- settlement | ||
tx_hash, | ||
solver, | ||
s.block_number, | ||
-- settlement_observations | ||
effective_gas_price * gas_used AS execution_cost, | ||
surplus, | ||
fee, | ||
-- auction_transaction | ||
at.auction_id | ||
FROM settlement_observations so | ||
JOIN settlements s | ||
ON s.block_number = so.block_number | ||
AND s.log_index = so.log_index | ||
JOIN auction_transaction at | ||
ON s.tx_from = at.tx_from | ||
AND s.tx_nonce = at.tx_nonce | ||
JOIN settlement_scores ss | ||
ON at.auction_id = ss.auction_id | ||
WHERE ss.block_deadline > {{start_block}} | ||
AND ss.block_deadline <= {{end_block}}), | ||
|
||
reward_data AS ( | ||
SELECT | ||
-- observations | ||
tx_hash, | ||
coalesce( | ||
solver, | ||
-- This is the winning solver (i.e. last entry of participants array) | ||
participants[array_length(participants, 1)] | ||
) as solver, | ||
-- Right-hand terms in coalesces below represent the case when settlement | ||
-- observations are unavailable (i.e. no settlement corresponds to reported scores). | ||
-- In particular, this means that surplus, fee and execution cost are all zero. | ||
-- When there is an absence of settlement block number, we fall back | ||
-- on the block_deadline from the settlement_scores table. | ||
coalesce(block_number, block_deadline) as block_number, | ||
coalesce(execution_cost, 0) as execution_cost, | ||
coalesce(surplus, 0) as surplus, | ||
coalesce(fee, 0) as fee, | ||
surplus + fee - reference_score AS payment, | ||
-- scores | ||
winning_score, | ||
reference_score, | ||
-- participation | ||
participants | ||
FROM settlement_scores ss | ||
-- If there are reported scores, | ||
-- there will always be a record of auction participants | ||
JOIN auction_participants ap | ||
ON os.auction_id = ap.auction_id | ||
-- outer joins made in order to capture non-existent settlements. | ||
LEFT OUTER JOIN observed_settlements os | ||
ON os.auction_id = ss.auction_id | ||
) | ||
auction_participation as (SELECT ss.auction_id, | ||
array_agg( | ||
concat('0x', encode(participant, 'hex')) ORDER BY participant | ||
) as participating_solvers | ||
FROM auction_participants | ||
JOIN settlement_scores ss | ||
ON auction_participants.auction_id = ss.auction_id | ||
WHERE block_deadline > {{start_block}} | ||
AND block_deadline <= {{end_block}} | ||
GROUP BY ss.auction_id), | ||
reward_data AS (SELECT | ||
-- observations | ||
tx_hash, | ||
ss.auction_id, | ||
-- TODO - Assuming that `solver == winner` when both not null | ||
-- We will need to monitor that `solver == winner`! | ||
coalesce(solver, winner) as solver, | ||
block_number as settlement_block, | ||
block_deadline, | ||
case | ||
when block_number is not null and block_number > block_deadline then 0 | ||
else coalesce(execution_cost, 0) end as execution_cost, | ||
case | ||
when block_number is not null and block_number > block_deadline then 0 | ||
else coalesce(surplus, 0) end as surplus, | ||
case | ||
when block_number is not null and block_number > block_deadline then 0 | ||
else coalesce(fee, 0) end as fee, | ||
-- scores | ||
winning_score, | ||
reference_score, | ||
-- auction_participation | ||
participating_solvers | ||
FROM settlement_scores ss | ||
-- If there are reported scores, | ||
-- there will always be a record of auction participants | ||
JOIN auction_participation ap | ||
ON ss.auction_id = ap.auction_id | ||
-- outer joins made in order to capture non-existent settlements. | ||
LEFT OUTER JOIN observed_settlements os | ||
ON os.auction_id = ss.auction_id), | ||
reward_per_auction as (SELECT tx_hash, | ||
settlement_block, | ||
block_deadline, | ||
solver, | ||
execution_cost, | ||
surplus, | ||
fee, | ||
surplus + fee - reference_score as uncapped_payment_eth, | ||
-- Uncapped Reward = CLAMP_[-E, E + exec_cost](uncapped_payment_eth) | ||
LEAST(GREATEST(-10000000000000000, surplus + fee - reference_score), | ||
10000000000000000 + execution_cost) as capped_payment, | ||
winning_score, | ||
reference_score, | ||
participating_solvers | ||
FROM reward_data) | ||
|
||
SELECT | ||
block_number, | ||
concat('0x', encode(tx_hash, 'hex')) as tx_hash, | ||
concat('0x', encode(solver, 'hex')) as solver, | ||
execution_cost, | ||
surplus, | ||
fee, | ||
surplus + fee - reference_score as reward_eth, | ||
winning_score, | ||
reference_score, | ||
participants as participating_solvers | ||
FROM reward_data | ||
|
||
SELECT settlement_block as block_number, | ||
block_deadline, | ||
case | ||
when tx_hash is NULL then NULL | ||
else concat('0x', encode(tx_hash, 'hex')) | ||
end as tx_hash, | ||
concat('0x', encode(solver, 'hex')) as solver, | ||
execution_cost, | ||
surplus, | ||
fee, | ||
uncapped_payment_eth, | ||
capped_payment, | ||
winning_score, | ||
reference_score, | ||
participating_solvers | ||
FROM reward_per_auction |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Oops, something went wrong.