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

Add protocol fees to dune #64

Merged
merged 12 commits into from
Jan 22, 2024
1 change: 1 addition & 0 deletions src/fetch/orderbook.py
Original file line number Diff line number Diff line change
Expand Up @@ -97,6 +97,7 @@ def get_batch_rewards(cls, block_range: BlockRange) -> DataFrame:
open_query("orderbook/batch_rewards.sql")
.replace("{{start_block}}", str(block_range.block_from))
.replace("{{end_block}}", str(block_range.block_to))
.replace("{{EPSILON}}", "10000000000000000") # ETH cap for payment (in WEI)
harisang marked this conversation as resolved.
Show resolved Hide resolved
)
data_types = {
# According to this: https://stackoverflow.com/a/11548224
Expand Down
3 changes: 2 additions & 1 deletion src/models/batch_rewards_schema.py
Original file line number Diff line number Diff line change
Expand Up @@ -31,7 +31,8 @@ def from_pdf_to_dune_records(cls, rewards_df: DataFrame) -> list[dict[str, Any]]
"capped_payment": int(row["capped_payment"]),
"execution_cost": int(row["execution_cost"]),
"surplus": int(row["surplus"]),
"fee": int(row["fee"]),
"protocol_fee": int(row["protocol_fee"]),
harisang marked this conversation as resolved.
Show resolved Hide resolved
"fee": int(row["network_fee"]),
"winning_score": int(row["winning_score"]),
"reference_score": int(row["reference_score"]),
"participating_solvers": row["participating_solvers"],
Expand Down
5 changes: 5 additions & 0 deletions src/models/order_rewards_schema.py
Original file line number Diff line number Diff line change
Expand Up @@ -26,6 +26,11 @@ def from_pdf_to_dune_records(cls, rewards_df: DataFrame) -> list[dict[str, Any]]
"surplus_fee": str(row["surplus_fee"]),
"amount": float(row["amount"]),
"quote_solver": row["quote_solver"],
"protocol_fee": str(row["protocol_fee"]),
"protocol_fee_token": row["protocol_fee_token"],
"protocol_fee_native_price": float(
row["protocol_fee_native_price"]
),
},
}
for row in rewards_df.to_dict(orient="records")
Expand Down
159 changes: 146 additions & 13 deletions src/sql/orderbook/batch_rewards.sql
Original file line number Diff line number Diff line change
Expand Up @@ -31,13 +31,140 @@ WITH observed_settlements AS (SELECT
WHERE block_deadline > {{start_block}}
AND block_deadline <= {{end_block}}
GROUP BY ss.auction_id),
-- protocol fees:
order_surplus AS (
SELECT
ss.winner as solver,
at.auction_id,
s.tx_hash,
t.order_uid,
o.sell_token,
o.buy_token,
t.sell_amount, -- the total amount the user sends
t.buy_amount, -- the total amount the user receives
oe.surplus_fee as observed_fee, -- the total discrepancy between what the user sends and what they would have send if they traded at clearing price
o.kind,
CASE
WHEN o.kind = 'sell'
THEN t.buy_amount - t.sell_amount * o.buy_amount / (o.sell_amount + o.fee_amount)
WHEN o.kind = 'buy'
THEN t.buy_amount * (o.sell_amount + o.fee_amount) / o.buy_amount - t.sell_amount
END AS surplus,
CASE
WHEN o.kind = 'sell'
THEN o.buy_token
WHEN o.kind = 'buy'
THEN o.sell_token
END AS surplus_token
FROM settlements s -- links block_number and log_index to tx_from and tx_nonce
JOIN auction_transaction at -- links auction_id to tx_from and tx_nonce
ON s.tx_from = at.tx_from AND s.tx_nonce = at.tx_nonce
JOIN settlement_scores ss -- contains block_deadline
ON at.auction_id = ss.auction_id
JOIN trades t -- contains traded amounts
ON s.block_number = t.block_number -- log_index cannot be checked, does not work correctly with multiple auctions on the same block
JOIN orders o -- contains tokens and limit amounts
ON t.order_uid = o.uid
JOIN order_execution oe -- contains surplus fee
ON t.order_uid = oe.order_uid AND at.auction_id = oe.auction_id
WHERE ss.block_deadline > {{start_block}}
AND ss.block_deadline <= {{end_block}}
)
,order_protocol_fee AS (
SELECT
os.auction_id,
os.solver,
os.tx_hash,
os.sell_amount,
os.buy_amount,
os.sell_token,
os.observed_fee,
os.surplus,
os.surplus_token,
CASE
WHEN fp.kind = 'surplus'
THEN
CASE
WHEN os.kind = 'sell'
THEN
CASE
WHEN fp.max_volume_factor = 1 -- this is done to avoid a division by zero errors
-- We assume that the case surplus_factor != 1 always. In
-- that case reconstructing the protocol fee would be
-- impossible anyways. This query will return a division by
-- zero error in that case.
THEN fp.surplus_factor / (1 - fp.surplus_factor) * surplus
ELSE
LEAST(
fp.max_volume_factor / (1 - fp.max_volume_factor) * os.buy_amount, -- at most charge a fraction of volume
fp.surplus_factor / (1 - fp.surplus_factor) * surplus -- charge a fraction of surplus
)
END
WHEN os.kind = 'buy'
THEN
CASE
WHEN fp.max_volume_factor = 1
THEN fp.surplus_factor / (1 - fp.surplus_factor) * surplus
ELSE
LEAST(
fp.max_volume_factor / (1 - fp.max_volume_factor) * os.sell_amount, -- at most charge a fraction of volume
fp.surplus_factor / (1 - fp.surplus_factor) * surplus -- charge a fraction of surplus
)
END
END
WHEN fp.kind = 'volume'
THEN fp.volume_factor / (1 - fp.volume_factor) * os.sell_amount
END AS protocol_fee,
CASE
WHEN fp.kind = 'surplus'
THEN os.surplus_token
WHEN fp.kind = 'volume'
THEN os.sell_token
END AS protocol_fee_token
FROM order_surplus os
JOIN fee_policies fp -- contains protocol fee policy
ON os.auction_id = fp.auction_id AND os.order_uid = fp.order_uid
)
,order_protocol_fee_prices AS (
SELECT
opf.solver,
opf.tx_hash,
opf.surplus,
opf.protocol_fee,
CASE
WHEN opf.sell_token != opf.protocol_fee_token
THEN (opf.sell_amount - opf.observed_fee) / opf.buy_amount * opf.protocol_fee
ELSE opf.protocol_fee
END AS network_fee_correction,
opf.sell_token as network_fee_token,
ap_surplus.price / pow(10, 18) as surplus_token_price,
ap_protocol.price / pow(10, 18) as protocol_fee_token_price,
ap_sell.price / pow(10, 18) as network_fee_token_price
FROM order_protocol_fee opf
JOIN auction_prices ap_sell -- contains price: sell token
ON opf.auction_id = ap_sell.auction_id AND opf.sell_token = ap_sell.token
JOIN auction_prices ap_surplus -- contains price: surplus token
ON opf.auction_id = ap_surplus.auction_id AND opf.surplus_token = ap_surplus.token
JOIN auction_prices ap_protocol -- contains price: protocol fee token
ON opf.auction_id = ap_protocol.auction_id AND opf.protocol_fee_token = ap_protocol.token
),
batch_protocol_fees AS (
SELECT
solver,
tx_hash,
-- sum(surplus * surplus_token_price) as surplus,
sum(protocol_fee * protocol_fee_token_price) as protocol_fee,
sum(network_fee_correction * network_fee_token_price) as network_fee_correction
FROM order_protocol_fee_prices
group by solver, tx_hash
),
reward_data AS (SELECT
-- observations
tx_hash,
os.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,
coalesce(os.solver, winner) as solver,
block_number as settlement_block,
block_deadline,
case
Expand All @@ -53,32 +180,37 @@ WITH observed_settlements AS (SELECT
winning_score,
reference_score,
-- auction_participation
participating_solvers
participating_solvers,
-- protocol_fees
coalesce(cast(protocol_fee as numeric(78, 0)), 0) as protocol_fee,
coalesce(cast(network_fee_correction as numeric(78, 0)), 0) as network_fee_correction
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),
ON os.auction_id = ss.auction_id
LEFT OUTER JOIN batch_protocol_fees bpf
ON bpf.tx_hash = os.tx_hash),
reward_per_auction as (SELECT tx_hash,
auction_id,
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,
protocol_fee, -- the protocol fee
fee - network_fee_correction as network_fee,-- the network fee
surplus + protocol_fee + fee - network_fee_correction - reference_score as uncapped_payment_eth,
-- Uncapped Reward = CLAMP_[-E, E + exec_cost](uncapped_reward_eth)
LEAST(GREATEST(-{{EPSILON}}, surplus + protocol_fee + fee - network_fee_correction - reference_score),
{{EPSILON}} + execution_cost) as capped_payment,
winning_score,
reference_score,
participating_solvers
participating_solvers as participating_solvers
FROM reward_data)


SELECT settlement_block as block_number,
block_deadline,
case
Expand All @@ -88,7 +220,8 @@ SELECT settlement_block as block_number,
concat('0x', encode(solver, 'hex')) as solver,
execution_cost::text as execution_cost,
surplus::text as surplus,
fee::text as fee,
protocol_fee::text as protocol_fee,
network_fee::text as network_fee,
uncapped_payment_eth::text as uncapped_payment_eth,
capped_payment::text as capped_payment,
winning_score::text as winning_score,
Expand Down
117 changes: 112 additions & 5 deletions src/sql/orderbook/order_rewards.sql
Original file line number Diff line number Diff line change
Expand Up @@ -19,7 +19,107 @@ with trade_hashes as (SELECT settlement.solver,
on settlement.tx_from = auction_transaction.tx_from
and settlement.tx_nonce = auction_transaction.tx_nonce
where block_number > {{start_block}} and block_number <= {{end_block}}),

order_surplus AS (
SELECT
at.auction_id,
t.order_uid,
o.sell_token,
o.buy_token,
t.sell_amount, -- the total amount the user sends
t.buy_amount, -- the total amount the user receives
oe.surplus_fee as observed_fee, -- the total discrepancy between what the user sends and what they would have send if they traded at clearing price
o.kind,
CASE
WHEN o.kind = 'sell'
THEN t.buy_amount - t.sell_amount * o.buy_amount / (o.sell_amount + o.fee_amount)
WHEN o.kind = 'buy'
THEN t.buy_amount * (o.sell_amount + o.fee_amount) / o.buy_amount - t.sell_amount
END AS surplus,
CASE
WHEN o.kind = 'sell'
THEN o.buy_token
WHEN o.kind = 'buy'
THEN o.sell_token
END AS surplus_token
FROM settlements s -- links block_number and log_index to tx_from and tx_nonce
JOIN auction_transaction at -- links auction_id to tx_from and tx_nonce
ON s.tx_from = at.tx_from AND s.tx_nonce = at.tx_nonce
JOIN settlement_scores ss -- contains block_deadline
ON at.auction_id = ss.auction_id
JOIN trades t -- contains traded amounts
ON s.block_number = t.block_number -- log_index cannot be checked, does not work correctly with multiple auctions on the same block
JOIN orders o -- contains tokens and limit amounts
ON t.order_uid = o.uid
JOIN order_execution oe -- contains surplus fee
ON t.order_uid = oe.order_uid AND at.auction_id = oe.auction_id
WHERE s.block_number > {{start_block}}
AND s.block_number <= {{end_block}}
)
,order_protocol_fee AS (
SELECT
os.auction_id,
os.order_uid,
os.sell_amount,
os.buy_amount,
os.sell_token,
os.observed_fee,
os.surplus,
os.surplus_token,
CASE
WHEN fp.kind = 'surplus'
THEN
CASE
WHEN os.kind = 'sell'
THEN
CASE
WHEN fp.max_volume_factor = 1 -- this is done to avoid a division by zero errors
-- We assume that the case surplus_factor != 1 always. In
-- that case reconstructing the protocol fee would be
-- impossible anyways. This query will return a division by
-- zero error in that case.
THEN fp.surplus_factor / (1 - fp.surplus_factor) * surplus
ELSE
LEAST(
fp.max_volume_factor / (1 - fp.max_volume_factor) * os.buy_amount, -- at most charge a fraction of volume
fp.surplus_factor / (1 - fp.surplus_factor) * surplus -- charge a fraction of surplus
)
END
WHEN os.kind = 'buy'
THEN
CASE
WHEN fp.max_volume_factor = 1
THEN fp.surplus_factor / (1 - fp.surplus_factor) * surplus
ELSE
LEAST(
fp.max_volume_factor / (1 - fp.max_volume_factor) * os.sell_amount, -- at most charge a fraction of volume
fp.surplus_factor / (1 - fp.surplus_factor) * surplus -- charge a fraction of surplus
)
END
END
WHEN fp.kind = 'volume'
THEN fp.volume_factor / (1 - fp.volume_factor) * os.sell_amount
END AS protocol_fee,
CASE
WHEN fp.kind = 'surplus'
THEN os.surplus_token
WHEN fp.kind = 'volume'
THEN os.sell_token
END AS protocol_fee_token
FROM order_surplus os
JOIN fee_policies fp -- contains protocol fee policy
ON os.auction_id = fp.auction_id AND os.order_uid = fp.order_uid
)
,order_protocol_fee_prices AS (
SELECT
opf.order_uid,
opf.auction_id,
opf.protocol_fee,
opf.protocol_fee_token,
ap.price / pow(10, 18) as protocol_fee_native_price
FROM order_protocol_fee opf
JOIN auction_prices ap-- contains price: protocol fee token
ON opf.auction_id = ap.auction_id AND opf.protocol_fee_token = ap.token
),
winning_quotes as (SELECT concat('0x', encode(oq.solver, 'hex')) as quote_solver,
oq.order_uid
FROM trades t
Expand All @@ -31,18 +131,25 @@ with trade_hashes as (SELECT settlement.solver,
AND block_number > {{start_block}}
AND block_number <= {{end_block}}
AND oq.solver != '\x0000000000000000000000000000000000000000')

-- Most efficient column order for sorting would be having tx_hash or order_uid first
select block_number,
concat('0x', encode(trade_hashes.order_uid, 'hex')) as order_uid,
concat('0x', encode(solver, 'hex')) as solver,
quote_solver,
concat('0x', encode(tx_hash, 'hex')) as tx_hash,
coalesce(surplus_fee, 0)::text as surplus_fee,
coalesce(reward, 0.0) as amount
coalesce(reward, 0.0) as amount,
coalesce(cast(protocol_fee as numeric(78, 0)), 0)::text as protocol_fee,
CASE WHEN protocol_fee_token is not NULL
THEN concat('0x', encode(protocol_fee_token, 'hex'))
END as protocol_fee_token,
coalesce(protocol_fee_native_price, 0.0) as protocol_fee_native_price
from trade_hashes
left outer join order_execution o
on trade_hashes.order_uid = o.order_uid
and trade_hashes.auction_id = o.auction_id
left outer join winning_quotes wq
on trade_hashes.order_uid = wq.order_uid;
left outer join winning_quotes wq
on trade_hashes.order_uid = wq.order_uid
left outer join order_protocol_fee_prices opfp
on trade_hashes.order_uid = opfp.order_uid
and trade_hashes.auction_id = opfp.auction_id;
Loading
Loading