Skip to content
This repository has been archived by the owner on Dec 20, 2024. It is now read-only.

Commit

Permalink
[Batch Rewards] Orderbook Query for Batch Rewards (#26)
Browse files Browse the repository at this point in the history
As part of #27 we implement the Raw Orderbook query that will be used to extract the data to be synced with Dune. The follow up to this PR will implement the python script executing this that is also responsible for transforming it into the JSON files being uploaded to Dune's AWS bucket.

Solvers are expected to change their rewards to the following

reward(txHash) = observedQuality - referenceScore

where observedQuality = Surplus + Fee

Furthermore, the reward per batch is planned to be capped by [-E, E + executionCosts]  (E = 0.01 ETH)

This query joins several tables in order to provide all terms required to evaluate the reward (namely surplus, fee, execution_cost, reference_score). winning_score is included too which is not really necessary but more for transparency.

Furthermore, it is expected that if the total allocated rewards for each accounting period are not reached, then we are to distribute the remaining funds according to the solver participation (found also as a field returned by this query).
  • Loading branch information
bh2smith authored Feb 23, 2023
1 parent 49e3e40 commit 47128c7
Showing 1 changed file with 57 additions and 0 deletions.
57 changes: 57 additions & 0 deletions src/sql/orderbook/batch_rewards.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,57 @@
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}}
),

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
)

SELECT * FROM reward_data

0 comments on commit 47128c7

Please sign in to comment.