Skip to content

Commit

Permalink
Fix network fee computation (#400)
Browse files Browse the repository at this point in the history
This PR changes the computation of network fees for solver payments.
This change is required due to a change to how the `fee` entry in the
`settlement_observations` table is computed, see
cowprotocol/services#2956.

### Network fee computation

With this PR, network fees are computed using data of executed trades.
The `surplus_fee` computed in `order_executions` is always such that
```
(sell_amount - surplus_fee) / buy_amount = buy_clearing_price / sell_clearing_price
```
with uniform clearing prices.
If it were not for protocol fees and network fees, the order would trade
at uniform clearing price.
```
(sell_amount - sell_protocol_fee - network_fee) / (buy_amount + buy_protocol_fee) = buy_clearing_price / sell_clearing_price
```
Combining it with the formula for surplus_fee gives
```
(sell_amount - sell_protocol_fee - network_fee) / (buy_amount + buy_protocol_fee) = (sell_amount - surplus_fee) / buy_amount
```
Traded amounts and surplus_fee are stored in the database. Protocol fees
can be computed independently. Thus we can rearange the formula for
`network_fee`,
```
network_fee = surplus_fee - sell_protocol_fee - (sell_amount - surplus_fee) / buy_amount * buy_protocol_fee
```
If the protocol fee is charged only in the sell token (i.e. for buy
orders), this gives
```
network_fee = surplus_fee - sell_protocol_fee
```
If the protocol fee is charged in the buy token (i.e. for sell orders),
this gives
```
network_fee = surplus_fee - (sell_amount - surplus_fee) / buy_amount * buy_protocol_fee
```
These formulas are implemented now.

### Additional changes

There were other minor changes required to make this work.
- Information on sell and buy tokens was not available for all trades in
the orders table. Now, the orders table is joined with the jit_orders
table.
- Protocol fees are not computed for all trades. There is an additional
join on order_surplus to pick up all orders for network fee computation.
Missing protocol fees are coalesced to zero.
- Not all prices need to be available for jit orders. Thus all joins on
prices were changed to left outer joins.
- The query became super slow for some reason. I added a materialized
for one of the tables (which I found to be fast during debugging) and
the query runs reasonable fast now.

I realized that there are edge cases where a jit order is supposed to
charge a fee but the price of the sell token is not available. In that
case, with this PR and the old code, the network fee of such a trad
would have been set to zero.

### Test plan

I adapted unit tests. Network fee amounts changed a bit since before the
computation depended on the settlement_observations table and not it
depends on order_executions. Those tables are not consistent in that the
fee entry does correspond to what the autopilot would compute when
observing data stored in order_executions. The order of magnitude of the
new results is easy to check as the difference of the sum of surplus
fees (converted to ETH) and the sum of protocol fees. So the new tests
seem correct.

I ran the query on the one-day period 2024-09-16--2024-09-17 and
compared old and new network fees. They were identical up to rounding
errors.

I ran the query on the one-day period 2024-09-17--2024-09-18 and
compared old and new network fees. They were different, as is to be
expected.

I looked into transaction with hash
`0xcca1897297913e58fa9fae51c9b8f93c4f6c4aebce0b7a6a5fbceaff309ef37e` in
particular since that trade had negative network fees with the old
query. The new query gives numbers consistent with our new Dune queries.

I also ran the full payment script for the accounting period
2024-09-10--2024-09-17 (commenting out slippage, which seems to have a
bug). The only difference in rewards, protocol fees, and partner fees is
that the actual payment reported a protocol fee of 27.8759 ETH while the
new run gives 27.8662 ETH. There should be no difference. So there might
be some small bug in the code somewhere, potentially ignoring some trade
or converting using a wrong price.
  • Loading branch information
fhenneke authored Sep 24, 2024
1 parent 78ce017 commit 867cae4
Show file tree
Hide file tree
Showing 5 changed files with 215 additions and 102 deletions.
145 changes: 97 additions & 48 deletions queries/orderbook/barn_batch_rewards.sql
Original file line number Diff line number Diff line change
Expand Up @@ -7,7 +7,6 @@ WITH observed_settlements AS (
-- settlement_observations
effective_gas_price * gas_used AS execution_cost,
surplus,
fee,
s.auction_id
FROM
settlement_observations so
Expand All @@ -31,30 +30,52 @@ auction_participation as (
GROUP BY
ss.auction_id
),
-- protocol fees:
-- order data
order_data AS (
SELECT
uid,
sell_token,
buy_token,
sell_amount,
buy_amount,
kind,
app_data
FROM orders
UNION ALL
SELECT
uid,
sell_token,
buy_token,
sell_amount,
buy_amount,
kind,
app_data
FROM jit_orders
),
-- additional trade data
order_surplus AS (
SELECT
ss.winner as solver,
s.auction_id,
s.tx_hash,
t.order_uid,
o.sell_token,
o.buy_token,
od.sell_token,
od.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,
od.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
WHEN od.kind = 'sell' THEN t.buy_amount - t.sell_amount * od.buy_amount / od.sell_amount
WHEN od.kind = 'buy' THEN t.buy_amount * od.sell_amount / od.buy_amount - t.sell_amount
END AS surplus,
CASE
WHEN o.kind = 'sell' THEN t.buy_amount - t.sell_amount * (oq.buy_amount - oq.buy_amount / oq.sell_amount * oq.gas_amount * oq.gas_price / oq.sell_token_price) / oq.sell_amount
WHEN o.kind = 'buy' THEN t.buy_amount * (oq.sell_amount + oq.gas_amount * oq.gas_price / oq.sell_token_price) / oq.buy_amount - t.sell_amount
WHEN od.kind = 'sell' THEN t.buy_amount - t.sell_amount * (oq.buy_amount - oq.buy_amount / oq.sell_amount * oq.gas_amount * oq.gas_price / oq.sell_token_price) / oq.sell_amount
WHEN od.kind = 'buy' THEN t.buy_amount * (oq.sell_amount + oq.gas_amount * oq.gas_price / oq.sell_token_price) / oq.buy_amount - t.sell_amount
END AS price_improvement,
CASE
WHEN o.kind = 'sell' THEN o.buy_token
WHEN o.kind = 'buy' THEN o.sell_token
WHEN od.kind = 'sell' THEN od.buy_token
WHEN od.kind = 'buy' THEN od.sell_token
END AS surplus_token,
ad.full_app_data as app_data
FROM
Expand All @@ -63,19 +84,20 @@ order_surplus AS (
ON s.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_data od -- contains tokens and limit amounts
ON t.order_uid = od.uid
JOIN order_execution oe -- contains surplus fee
ON t.order_uid = oe.order_uid
AND s.auction_id = oe.auction_id
LEFT OUTER JOIN order_quotes oq -- contains quote amounts
ON o.uid = oq.order_uid
ON od.uid = oq.order_uid
LEFT OUTER JOIN app_data ad -- contains full app data
on o.app_data = ad.contract_app_data
on od.app_data = ad.contract_app_data
WHERE
ss.block_deadline >= {{start_block}}
AND ss.block_deadline <= {{end_block}}
),
-- protocol fees:
fee_policies_first_proxy as (
select
auction_id,
Expand Down Expand Up @@ -207,7 +229,7 @@ order_surplus_intermediate as (
partner_fee_recipient
from order_protocol_fee_first
),
order_protocol_fee as (
order_protocol_fee as materialized (
SELECT
os.auction_id,
os.solver,
Expand Down Expand Up @@ -283,13 +305,33 @@ order_protocol_fee as (
ON os.auction_id = fp.auction_id
AND os.order_uid = fp.order_uid
),
order_protocol_fee_prices AS (
price_data AS (
SELECT
opf.auction_id,
opf.solver,
opf.tx_hash,
opf.order_uid,
opf.surplus,
os.auction_id,
os.order_uid,
ap_surplus.price / pow(10, 18) as surplus_token_native_price,
ap_protocol.price / pow(10, 18) as protocol_fee_token_native_price,
ap_sell.price / pow(10, 18) as network_fee_token_native_price
FROM
order_surplus AS os
LEFT OUTER JOIN auction_prices ap_sell -- contains price: sell token
ON os.auction_id = ap_sell.auction_id
AND os.sell_token = ap_sell.token
LEFT OUTER JOIN auction_prices ap_surplus -- contains price: surplus token
ON os.auction_id = ap_surplus.auction_id
AND os.surplus_token = ap_surplus.token
LEFT OUTER JOIN auction_prices ap_protocol -- contains price: protocol fee token
ON os.auction_id = ap_protocol.auction_id
AND os.surplus_token = ap_protocol.token
),
combined_order_data AS (
SELECT
os.auction_id,
os.solver,
os.tx_hash,
os.order_uid,
os.surplus,
os.surplus_token,
opf.protocol_fee,
opf.protocol_fee_token,
CASE
Expand All @@ -299,33 +341,40 @@ order_protocol_fee_prices AS (
opf.partner_fee,
opf.partner_fee_recipient,
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_native_price,
ap_protocol.price / pow(10, 18) as protocol_fee_token_native_price,
ap_sell.price / pow(10, 18) as network_fee_token_native_price
WHEN os.sell_token != os.surplus_token THEN os.observed_fee - (os.sell_amount - os.observed_fee) / os.buy_amount * coalesce(opf.protocol_fee, 0)
ELSE os.observed_fee - coalesce(opf.protocol_fee, 0)
END AS network_fee,
os.sell_token as network_fee_token,
surplus_token_native_price,
protocol_fee_token_native_price,
network_fee_token_native_price
FROM
order_protocol_fee as 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
order_surplus AS os
LEFT OUTER JOIN order_protocol_fee as opf
ON os.auction_id = opf.auction_id
AND os.order_uid = opf.order_uid
JOIN price_data pd
ON os.auction_id = pd.auction_id
AND os.order_uid = pd.order_uid
),
batch_protocol_fees AS (
SELECT
solver,
tx_hash,
sum(protocol_fee * protocol_fee_token_native_price) as protocol_fee,
sum(network_fee_correction * network_fee_token_native_price) as network_fee_correction
sum(protocol_fee * protocol_fee_token_native_price) as protocol_fee
FROM
combined_order_data
group by
solver,
tx_hash
),
batch_network_fees AS (
SELECT
solver,
tx_hash,
sum(network_fee * network_fee_token_native_price) as network_fee
FROM
order_protocol_fee_prices
combined_order_data
group by
solver,
tx_hash
Expand All @@ -342,7 +391,6 @@ reward_data AS (
block_deadline,
coalesce(execution_cost, 0) as execution_cost,
coalesce(surplus, 0) as surplus,
coalesce(fee, 0) as fee,
-- scores
winning_score,
case
Expand All @@ -356,9 +404,9 @@ reward_data AS (
-- protocol_fees
coalesce(cast(protocol_fee as numeric(78, 0)), 0) as protocol_fee,
coalesce(
cast(network_fee_correction as numeric(78, 0)),
cast(network_fee as numeric(78, 0)),
0
) as network_fee_correction
) as network_fee
FROM
settlement_scores ss
-- If there are reported scores,
Expand All @@ -367,6 +415,7 @@ reward_data AS (
-- outer joins made in order to capture non-existent settlements.
LEFT OUTER JOIN observed_settlements os ON os.auction_id = ss.auction_id
LEFT OUTER JOIN batch_protocol_fees bpf ON bpf.tx_hash = os.tx_hash
LEFT OUTER JOIN batch_network_fees bnf ON bnf.tx_hash = os.tx_hash
),
reward_per_auction as (
SELECT
Expand All @@ -378,7 +427,7 @@ reward_per_auction as (
execution_cost,
surplus,
protocol_fee, -- the protocol fee
fee - network_fee_correction as network_fee, -- the network fee
network_fee, -- the network fee
observed_score - reference_score as uncapped_payment,
-- Capped Reward = CLAMP_[-E, E + exec_cost](uncapped_reward_eth)
LEAST(
Expand Down Expand Up @@ -439,7 +488,7 @@ partner_fees_per_solver AS (
partner_fee_recipient,
sum(partner_fee * protocol_fee_token_native_price) as partner_fee
FROM
order_protocol_fee_prices
combined_order_data
WHERE partner_fee_recipient is not null
group by solver,partner_fee_recipient
),
Expand All @@ -463,7 +512,7 @@ aggregate_results as (
FROM
participation_counts pc
LEFT OUTER JOIN primary_rewards pr ON pr.solver = pc.solver
LEFT OUTER JOIN aggregate_partner_fees_per_solver aif on pr.solver = aif.solver
LEFT OUTER JOIN aggregate_partner_fees_per_solver aif on pr.solver = aif.solver
) --
select
*
Expand Down
Loading

0 comments on commit 867cae4

Please sign in to comment.