Skip to content
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
119 changes: 68 additions & 51 deletions crates/orderbook/src/database/total_surplus.rs
Original file line number Diff line number Diff line change
Expand Up @@ -9,76 +9,93 @@ use {
/// and **NOT** quoted price) since march 2023.
async fn fetch_total_surplus(ex: &mut PgConnection, user: &Address) -> Result<f64, sqlx::Error> {
const TOTAL_SURPLUS_QUERY: &str = r#"
WITH regular_orders AS (
SELECT ARRAY_AGG(uid) AS ids FROM orders WHERE owner = $1
),
onchain_orders AS (
SELECT ARRAY_AGG(uid) AS ids FROM onchain_placed_orders WHERE sender = $1
),
trade_components AS (
WITH trade_components AS (
SELECT
CASE kind
-- so much was actually bought
WHEN 'sell' THEN t.buy_amount
-- so much was actually converted to buy tokens
WHEN 'buy' THEN t.sell_amount - t.fee_amount
END AS trade_amount,
CASE kind
-- so much had to be bought at least (given exeucted amount and limit price)
WHEN 'sell' THEN (t.sell_amount - t.fee_amount) * o.buy_amount / o.sell_amount
-- so much could be converted to buy_token at most (given executed amount and limit price)
WHEN 'buy' THEN t.buy_amount * o.sell_amount / o.buy_amount
END AS limit_amount,
o.kind,
CASE kind
WHEN 'sell' THEN (SELECT price FROM auction_prices ap WHERE ap.token = o.buy_token AND ap.auction_id = oe.auction_id)
WHEN 'buy' THEN (SELECT price FROM auction_prices ap WHERE ap.token = o.sell_token AND ap.auction_id = oe.auction_id)
END AS surplus_token_native_price
o.uid,
CASE o.kind
WHEN 'sell' THEN t.buy_amount
WHEN 'buy' THEN t.sell_amount - t.fee_amount
END AS trade_amount,
CASE o.kind
WHEN 'sell' THEN (t.sell_amount - t.fee_amount) * o.buy_amount / o.sell_amount
WHEN 'buy' THEN t.buy_amount * o.sell_amount / o.buy_amount
END AS limit_amount,
o.kind,
ap.price AS surplus_token_native_price
FROM orders o
JOIN trades t ON o.uid = t.order_uid
JOIN order_execution oe ON o.uid = oe.order_uid
-- use this weird construction instead of `where owner=address or sender=address` to help postgres make efficient use of indices
WHERE uid = ANY(ARRAY_CAT((SELECT ids FROM regular_orders), (SELECT ids FROM onchain_orders)))
JOIN trades t ON t.order_uid = o.uid
JOIN order_execution oe ON oe.order_uid = t.order_uid
LEFT JOIN auction_prices ap
ON ap.auction_id = oe.auction_id
AND ap.token = CASE o.kind WHEN 'sell' THEN o.buy_token ELSE o.sell_token END
WHERE o.owner = $1

UNION ALL

SELECT
o.uid,
CASE o.kind
-- so much was actually bought
WHEN 'sell' THEN t.buy_amount
-- so much was actually converted to buy tokens
WHEN 'buy' THEN t.sell_amount - t.fee_amount
END AS trade_amount,
CASE o.kind
-- so much had to be bought at least (given executed amount and limit price)
WHEN 'sell' THEN (t.sell_amount - t.fee_amount) * o.buy_amount / o.sell_amount
-- so much could be converted to buy_token at most (given executed amount and limit price)
WHEN 'buy' THEN t.buy_amount * o.sell_amount / o.buy_amount
END AS limit_amount,
o.kind,
ap.price AS surplus_token_native_price
FROM onchain_placed_orders opo
JOIN orders o ON o.uid = opo.uid AND o.owner != $1
JOIN trades t ON t.order_uid = o.uid
JOIN order_execution oe ON oe.order_uid = t.order_uid
LEFT JOIN auction_prices ap
ON ap.auction_id = oe.auction_id
AND ap.token = CASE o.kind WHEN 'sell' THEN o.buy_token ELSE o.sell_token END
WHERE opo.sender = $1

UNION ALL

-- Additional query for jit_orders
SELECT
CASE j.kind
WHEN 'sell' THEN t.buy_amount
WHEN 'buy' THEN t.sell_amount - t.fee_amount
END AS trade_amount,
CASE j.kind
WHEN 'sell' THEN (t.sell_amount - t.fee_amount) * j.buy_amount / j.sell_amount
WHEN 'buy' THEN t.buy_amount * j.sell_amount / j.buy_amount
END AS limit_amount,
j.kind,
CASE j.kind
WHEN 'sell' THEN (SELECT price FROM auction_prices ap WHERE ap.token = j.buy_token AND ap.auction_id = oe.auction_id)
WHEN 'buy' THEN (SELECT price FROM auction_prices ap WHERE ap.token = j.sell_token AND ap.auction_id = oe.auction_id)
END AS surplus_token_native_price
j.uid,
CASE j.kind
WHEN 'sell' THEN t.buy_amount
WHEN 'buy' THEN t.sell_amount - t.fee_amount
END AS trade_amount,
CASE j.kind
WHEN 'sell' THEN (t.sell_amount - t.fee_amount) * j.buy_amount / j.sell_amount
WHEN 'buy' THEN t.buy_amount * j.sell_amount / j.buy_amount
END AS limit_amount,
j.kind,
ap.price AS surplus_token_native_price
FROM jit_orders j
JOIN trades t ON j.uid = t.order_uid
JOIN order_execution oe ON j.uid = oe.order_uid
WHERE j.owner = $1 AND NOT EXISTS (
JOIN order_execution oe ON t.order_uid = oe.order_uid
LEFT JOIN auction_prices ap
ON ap.auction_id = oe.auction_id
AND ap.token = CASE j.kind WHEN 'sell' THEN j.buy_token ELSE j.sell_token END
WHERE j.owner = $1
AND NOT EXISTS (
SELECT 1
FROM orders o
WHERE o.uid = j.uid
)
),
trade_surplus AS (
)
SELECT
COALESCE(SUM(surplus_in_wei ORDER BY uid), 0) AS total_surplus_in_wei
FROM (
SELECT
uid,
CASE kind
-- amounts refer to tokens bought; more is better
WHEN 'sell' THEN (trade_amount - limit_amount) * surplus_token_native_price
-- amounts refer to tokens sold; less is better
WHEN 'buy' THEN (limit_amount - trade_amount) * surplus_token_native_price
END / POWER(10, 18) AS surplus_in_wei
FROM trade_components
)
SELECT
COALESCE(SUM(surplus_in_wei), 0) AS total_surplus_in_wei
FROM trade_surplus
) ts;
"#;

sqlx::query_scalar(TOTAL_SURPLUS_QUERY)
Expand Down
11 changes: 11 additions & 0 deletions database/README.md
Original file line number Diff line number Diff line change
Expand Up @@ -8,6 +8,7 @@ Some tables only store data emitted via smart contract events. Because we only h
[CoWSwapEthFlow](https://github.com/cowprotocol/ethflowcontract/blob/main/src/CoWSwapEthFlow.sol) we actually deployed twice so events related to the staging environment should only show up in the staging DB and likewise for production.
It's also important to note that we only index events from blocks that we are certain will not get reorged. That means specifically that events will be indexed with a block delay of at least 64.


### app\_data

Associates the 32 bytes contract app data with the corresponding full app data.
Expand Down Expand Up @@ -626,3 +627,13 @@ We support different expiration times for orders with different signing schemes.
market | Short lived order that may receive surplus. Users agree to a static fee upfront by signing it.
liquidity | These orders must be traded at their limit price and may not receive any surplus. Violating this is a slashable offence.
limit | Long lived order that may receive surplus. Users sign a static fee of 0 upfront and either the backend or the solvers compute a dynamic fee that gets taken from the surplus (while still respecting the user's limit price!).

## Notes on Migrations

Migrations that require a long running process *must* be done manually, this is due to the limitations the weekly release process imposes:
* The deployment must complete under 5 minutes
* The pod has a `processDeadlineSeconds` defaulting to 600 seconds

To avoid extending the process, we resort to manually applying complicated migrations.

The above also comes into play when dealing with indexes, as their construction with flyway may lock up rows, degrading SLI.
3 changes: 3 additions & 0 deletions database/sql/V103__create_convering_indexes_for_surplus.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,3 @@
-- covering indexes to avoid IO when calculating the total surplus for users
CREATE INDEX CONCURRENTLY IF NOT EXISTS trades_covering ON trades (order_uid) INCLUDE (buy_amount, sell_amount, fee_amount);
CREATE INDEX CONCURRENTLY IF NOT EXISTS orders_owner_covering ON orders (owner) INCLUDE (uid, kind, buy_amount, sell_amount, fee_amount, buy_token, sell_token);
Loading