From 507ab5ef9e765acb84c157937e0d7fc27b3d1015 Mon Sep 17 00:00:00 2001 From: MentatBot <160964065+MentatBot@users.noreply.github.com> Date: Sun, 1 Jun 2025 11:45:40 +0000 Subject: [PATCH 1/2] Add hourly_twap_data table for time-weighted average pricing This commit implements the requested TWAP-based hourly price data table to address MEV manipulation concerns with the existing VWAP approach. ## Changes Made ### New Table: `hourly_twap_data` - `token0`, `token1`, `hour`: Primary key for token pair and time period - `time_weighted_tick`: Average tick weighted by time duration - `average_price`: Price derived from time-weighted tick using `1.0001^tick` - `total_time_seconds`: Total time coverage within the hour - `swap_count`: Number of swaps used in calculation ### TWAP Calculation Logic The new calculation: 1. For each token pair per hour, gets all swaps ordered chronologically 2. Calculates time duration between consecutive swaps 3. Weights each tick value by the time it was active 4. Converts the time-weighted average tick to price using the standard formula ### Benefits over VWAP - **MEV Resistance**: TWAP is not manipulated by sandwich attacks since it weights by time, not volume - **Accurate Pricing**: Reflects true time-weighted market prices rather than volume-distorted prices - **Comprehensive Coverage**: Accounts for all time periods within each hour Closes # 12 Co-authored-by: moodysalem <7897876+moodysalem@users.noreply.github.com> --- src/dao.ts | 94 ++++++++++++++++++++++++++++++++++++++++++++++++++++++ 1 file changed, 94 insertions(+) diff --git a/src/dao.ts b/src/dao.ts index af1ee04..db565cb 100644 --- a/src/dao.ts +++ b/src/dao.ts @@ -293,6 +293,18 @@ export class DAO { PRIMARY KEY (token0, token1, hour) ); + CREATE TABLE IF NOT EXISTS hourly_twap_data + ( + token0 NUMERIC, + token1 NUMERIC, + hour timestamptz, + time_weighted_tick NUMERIC, + average_price NUMERIC, + total_time_seconds NUMERIC, + swap_count NUMERIC, + PRIMARY KEY (token0, token1, hour) + ); + CREATE TABLE IF NOT EXISTS hourly_tvl_delta_by_token ( @@ -985,6 +997,88 @@ export class DAO { values: [since], }); + await this.pg.query({ + text: ` + INSERT INTO hourly_twap_data + (WITH swap_times AS ( + SELECT pk.token0, + pk.token1, + date_bin(INTERVAL '1 hour', b.time, '2000-01-01 00:00:00'::TIMESTAMP WITHOUT TIME ZONE) AS hour, + b.time, + s.tick_after, + LAG(b.time) OVER (PARTITION BY pk.token0, pk.token1, + date_bin(INTERVAL '1 hour', b.time, '2000-01-01 00:00:00'::TIMESTAMP WITHOUT TIME ZONE) + ORDER BY b.time) AS prev_time, + LAG(s.tick_after) OVER (PARTITION BY pk.token0, pk.token1, + date_bin(INTERVAL '1 hour', b.time, '2000-01-01 00:00:00'::TIMESTAMP WITHOUT TIME ZONE) + ORDER BY b.time) AS prev_tick + FROM swaps s + JOIN event_keys ek ON s.event_id = ek.id + JOIN blocks b ON ek.block_number = b.number + JOIN pool_keys pk ON s.pool_key_hash = pk.key_hash + WHERE DATE_TRUNC('hour', b.time) >= DATE_TRUNC('hour', $1::timestamptz) + AND delta0 != 0 + AND delta1 != 0 + ), + tick_durations AS ( + SELECT token0, + token1, + hour, + tick_after, + CASE + WHEN prev_time IS NULL THEN + EXTRACT(EPOCH FROM (time - hour)) + ELSE + EXTRACT(EPOCH FROM (time - prev_time)) + END AS duration_seconds, + CASE + WHEN prev_tick IS NULL THEN tick_after + ELSE prev_tick + END AS effective_tick + FROM swap_times + UNION ALL + SELECT token0, + token1, + hour, + tick_after, + EXTRACT(EPOCH FROM ((hour + INTERVAL '1 hour') - time)) AS duration_seconds, + tick_after AS effective_tick + FROM ( + SELECT DISTINCT ON (token0, token1, hour) + token0, token1, hour, time, tick_after + FROM swap_times + ORDER BY token0, token1, hour, time DESC + ) last_swaps + ), + twap_calculations AS ( + SELECT token0, + token1, + hour, + SUM(effective_tick * duration_seconds) / NULLIF(SUM(duration_seconds), 0) AS time_weighted_tick, + SUM(duration_seconds) AS total_time_seconds, + COUNT(*) / 2 AS swap_count + FROM tick_durations + WHERE duration_seconds > 0 + GROUP BY token0, token1, hour + ) + SELECT token0, + token1, + hour, + time_weighted_tick, + POWER(1.0001::NUMERIC, time_weighted_tick) AS average_price, + total_time_seconds, + swap_count + FROM twap_calculations + WHERE time_weighted_tick IS NOT NULL) + ON CONFLICT (token0, token1, hour) + DO UPDATE SET time_weighted_tick = excluded.time_weighted_tick, + average_price = excluded.average_price, + total_time_seconds = excluded.total_time_seconds, + swap_count = excluded.swap_count; + `, + values: [since], + }); + await this.pg.query({ text: ` INSERT INTO hourly_tvl_delta_by_token From 2cd6cbbbac24a59f2f72663c2a40d65afe8d9339 Mon Sep 17 00:00:00 2001 From: MentatBot <160964065+MentatBot@users.noreply.github.com> Date: Sun, 1 Jun 2025 12:02:02 +0000 Subject: [PATCH 2/2] Improve TWAP calculation with liquidity weighting - Remove price calculation, only compute average tick - Weight pools by liquidity when aggregating across pools - Calculate time-weighted tick per pool first, then aggregate - Track liquidity-seconds for proper weighting - Add pool_count to track number of pools in aggregation This makes TWAP more resistant to manipulation through low-liquidity pools. --- src/dao.ts | 95 ++++++++++++++++++++++++++++++++++++------------------ 1 file changed, 63 insertions(+), 32 deletions(-) diff --git a/src/dao.ts b/src/dao.ts index db565cb..75c79e3 100644 --- a/src/dao.ts +++ b/src/dao.ts @@ -295,13 +295,14 @@ export class DAO { CREATE TABLE IF NOT EXISTS hourly_twap_data ( - token0 NUMERIC, - token1 NUMERIC, - hour timestamptz, - time_weighted_tick NUMERIC, - average_price NUMERIC, - total_time_seconds NUMERIC, - swap_count NUMERIC, + token0 NUMERIC, + token1 NUMERIC, + hour timestamptz, + liquidity_weighted_tick NUMERIC, + total_liquidity_seconds NUMERIC, + total_time_seconds NUMERIC, + swap_count NUMERIC, + pool_count NUMERIC, PRIMARY KEY (token0, token1, hour) ); @@ -1001,17 +1002,22 @@ export class DAO { text: ` INSERT INTO hourly_twap_data (WITH swap_times AS ( - SELECT pk.token0, + SELECT s.pool_key_hash, + pk.token0, pk.token1, date_bin(INTERVAL '1 hour', b.time, '2000-01-01 00:00:00'::TIMESTAMP WITHOUT TIME ZONE) AS hour, b.time, s.tick_after, - LAG(b.time) OVER (PARTITION BY pk.token0, pk.token1, + s.liquidity_after, + LAG(b.time) OVER (PARTITION BY s.pool_key_hash, date_bin(INTERVAL '1 hour', b.time, '2000-01-01 00:00:00'::TIMESTAMP WITHOUT TIME ZONE) ORDER BY b.time) AS prev_time, - LAG(s.tick_after) OVER (PARTITION BY pk.token0, pk.token1, + LAG(s.tick_after) OVER (PARTITION BY s.pool_key_hash, date_bin(INTERVAL '1 hour', b.time, '2000-01-01 00:00:00'::TIMESTAMP WITHOUT TIME ZONE) - ORDER BY b.time) AS prev_tick + ORDER BY b.time) AS prev_tick, + LAG(s.liquidity_after) OVER (PARTITION BY s.pool_key_hash, + date_bin(INTERVAL '1 hour', b.time, '2000-01-01 00:00:00'::TIMESTAMP WITHOUT TIME ZONE) + ORDER BY b.time) AS prev_liquidity FROM swaps s JOIN event_keys ek ON s.event_id = ek.id JOIN blocks b ON ek.block_number = b.number @@ -1020,11 +1026,13 @@ export class DAO { AND delta0 != 0 AND delta1 != 0 ), - tick_durations AS ( - SELECT token0, + tick_liquidity_durations AS ( + SELECT pool_key_hash, + token0, token1, hour, tick_after, + liquidity_after, CASE WHEN prev_time IS NULL THEN EXTRACT(EPOCH FROM (time - hour)) @@ -1034,47 +1042,70 @@ export class DAO { CASE WHEN prev_tick IS NULL THEN tick_after ELSE prev_tick - END AS effective_tick + END AS effective_tick, + CASE + WHEN prev_liquidity IS NULL THEN liquidity_after + ELSE prev_liquidity + END AS effective_liquidity FROM swap_times UNION ALL - SELECT token0, + SELECT pool_key_hash, + token0, token1, hour, tick_after, + liquidity_after, EXTRACT(EPOCH FROM ((hour + INTERVAL '1 hour') - time)) AS duration_seconds, - tick_after AS effective_tick + tick_after AS effective_tick, + liquidity_after AS effective_liquidity FROM ( - SELECT DISTINCT ON (token0, token1, hour) - token0, token1, hour, time, tick_after + SELECT DISTINCT ON (pool_key_hash, hour) + pool_key_hash, token0, token1, hour, time, tick_after, liquidity_after FROM swap_times - ORDER BY token0, token1, hour, time DESC + ORDER BY pool_key_hash, hour, time DESC ) last_swaps ), - twap_calculations AS ( - SELECT token0, + pool_twaps AS ( + SELECT pool_key_hash, + token0, token1, hour, - SUM(effective_tick * duration_seconds) / NULLIF(SUM(duration_seconds), 0) AS time_weighted_tick, + SUM(effective_tick * duration_seconds * effective_liquidity) AS tick_liquidity_seconds, + SUM(duration_seconds * effective_liquidity) AS liquidity_seconds, SUM(duration_seconds) AS total_time_seconds, COUNT(*) / 2 AS swap_count - FROM tick_durations - WHERE duration_seconds > 0 + FROM tick_liquidity_durations + WHERE duration_seconds > 0 AND effective_liquidity > 0 + GROUP BY pool_key_hash, token0, token1, hour + ), + aggregated_twaps AS ( + SELECT token0, + token1, + hour, + SUM(tick_liquidity_seconds) / NULLIF(SUM(liquidity_seconds), 0) AS liquidity_weighted_tick, + SUM(liquidity_seconds) AS total_liquidity_seconds, + SUM(total_time_seconds) AS total_time_seconds, + SUM(swap_count) AS swap_count, + COUNT(DISTINCT pool_key_hash) AS pool_count + FROM pool_twaps GROUP BY token0, token1, hour ) SELECT token0, token1, hour, - time_weighted_tick, - POWER(1.0001::NUMERIC, time_weighted_tick) AS average_price, + liquidity_weighted_tick, + total_liquidity_seconds, total_time_seconds, - swap_count - FROM twap_calculations - WHERE time_weighted_tick IS NOT NULL) + swap_count, + pool_count + FROM aggregated_twaps + WHERE liquidity_weighted_tick IS NOT NULL) ON CONFLICT (token0, token1, hour) - DO UPDATE SET time_weighted_tick = excluded.time_weighted_tick, - average_price = excluded.average_price, + DO UPDATE SET liquidity_weighted_tick = excluded.liquidity_weighted_tick, + total_liquidity_seconds = excluded.total_liquidity_seconds, total_time_seconds = excluded.total_time_seconds, - swap_count = excluded.swap_count; + swap_count = excluded.swap_count, + pool_count = excluded.pool_count; `, values: [since], });