Skip to content

Commit

Permalink
deduplication
Browse files Browse the repository at this point in the history
  • Loading branch information
fleupold committed Aug 21, 2024
1 parent 9f68a28 commit 0265837
Showing 1 changed file with 58 additions and 19 deletions.
77 changes: 58 additions & 19 deletions mevblocker/fees/value_per_block_3999838.sql
Original file line number Diff line number Diff line change
Expand Up @@ -6,14 +6,14 @@
WITH block_range AS (
SELECT
MIN(number) AS start_block,
MAX(number) AS end_block
MAX(number) + 1 AS end_block -- range is exclusive
FROM ethereum.blocks
WHERE
time >= TIMESTAMP '{{start}}'
AND time < TIMESTAMP '{{end}}'
),

-- all mempool tx according to flashbots
-- perfomance optimisation: all mempool tx according to flashbots during that timeframe
mempool AS (
SELECT DISTINCT hash
FROM dune.flashbots.dataset_mempool_dumpster
Expand All @@ -23,7 +23,7 @@ mempool AS (

),

-- relevant mev blocker bundles during that timeframe
-- perfomance optimisation: relevant mev blocker bundles during that timeframe
mev_blocker_filtered AS (
SELECT *
FROM mevblocker.raw_bundles
Expand All @@ -32,6 +32,15 @@ mev_blocker_filtered AS (
AND blocknumber < (SELECT end_block FROM block_range)
),

-- perfomance optimisation: relevant ethereum transactions during that timeframe
ethereum_transactions_filtered AS (
SELECT *
FROM ethereum.transactions
WHERE
block_number >= (SELECT start_block FROM block_range)
AND block_number < (SELECT end_block FROM block_range)
),

-- all mev blocker tx that made it on chain
mev_blocker_tx AS (
SELECT
Expand All @@ -55,11 +64,13 @@ mev_blocker_tx AS (
hash VARCHAR(255) PATH 'lax $.hash'
)
) AS jt
INNER JOIN ethereum.transactions AS et
INNER JOIN ethereum_transactions_filtered AS et
ON FROM_HEX(jt.hash) = et.hash
WHERE
block_number >= (SELECT start_block FROM block_range)
AND block_number < (SELECT end_block FROM block_range)
-- remove duplicates
GROUP BY 1, 2, 3, 4, 5, 6, 7, 8, 9, 10
),

-- find last tx in mev blocker bundle
Expand Down Expand Up @@ -91,14 +102,17 @@ searcher_txs AS (
WHERE tx_from != tx_from_1
),

kickbacks AS (
kickback_txs AS (
SELECT
et.block_time,
et.block_number,
et.hash,
st.search_tx,
st.tx_1 AS target_tx,
value AS backrun_value_wei,
CAST(et.gas_used AS UINT256) * (et.gas_price - COALESCE(b.base_fee_per_gas, 0)) AS backrun_tip_wei
FROM searcher_txs AS st
INNER JOIN ethereum.transactions AS et
INNER JOIN ethereum_transactions_filtered AS et
ON
st.block_number = et.block_number
AND st.index + 1 = et.index
Expand All @@ -113,7 +127,7 @@ kickbacks AS (

-- all original (user) transactions, calculating the tip of these transactions
-- excluding transactions that were in the public mempool
user_tx AS (
user_txs AS (
SELECT
tx.block_time,
tx.block_number,
Expand All @@ -124,20 +138,45 @@ user_tx AS (
WHERE
tx.hash NOT IN (SELECT search_tx FROM searcher_txs)
AND CAST(tx.hash AS VARCHAR) NOT IN (SELECT hash FROM mempool)
-- deduplicate approve txs that appear in bundles and individually
GROUP BY 1, 2, 3, 4
),

user_txs_per_block AS (
SELECT
b.time AS block_time,
b.number AS block_number,
SUM(user_tip_wei) AS user_tip_wei,
ARRAY_AGG(ut.hash) AS user_txs
FROM ethereum.blocks AS b
INNER JOIN user_txs AS ut ON b.number = ut.block_number
GROUP BY 1, 2
),

kickback_txs_per_block AS (
SELECT
b.time AS block_time,
b.number AS block_number,
SUM(COALESCE(k.backrun_value_wei, 0)) AS backrun_value_wei,
SUM(COALESCE(k.backrun_tip_wei, 0)) AS backrun_tip_wei,
ARRAY_AGG(k.search_tx) AS searcher_txs,
ARRAY_AGG(k.hash) AS kickback_txs
FROM ethereum.blocks AS b
INNER JOIN kickback_txs AS k ON b.number = k.block_number
GROUP BY 1, 2
)

-- final calculation of the fee per block
-- the calculation: 20% of (original_tx_tip + 1/9 of backrun value)
SELECT
b.time AS block_time,
b.number AS block_number,
SUM(user_tip_wei) AS user_tip_wei,
SUM(COALESCE(k.backrun_value_wei, 0)) AS backrun_value_wei,
SUM(COALESCE(k.backrun_tip_wei, 0)) AS backrun_tip_wei,
SUM(CAST(0.2 * (user_tip_wei + (COALESCE(k.backrun_tip_wei + k.backrun_value_wei, 0) / 9)) AS UINT256))
AS block_fee_wei,
ARRAY_AGG(ut.hash) AS txs
FROM ethereum.blocks AS b
INNER JOIN user_tx AS ut ON b.number = ut.block_number
LEFT JOIN kickbacks AS k ON b.number = k.block_number
GROUP BY 1, 2
ut.block_time,
ut.block_number,
user_tip_wei,
backrun_value_wei,
backrun_tip_wei,
user_txs,
searcher_txs,
kickback_txs,
CAST(0.2 * (user_tip_wei + (COALESCE(k.backrun_tip_wei + k.backrun_value_wei, 0) / 9)) AS UINT256) AS block_fee_wei
FROM user_txs_per_block AS ut
LEFT JOIN kickback_txs_per_block AS k ON ut.block_number = k.block_number

0 comments on commit 0265837

Please sign in to comment.