forked from aptos-labs/aptos-indexer-processors
-
Notifications
You must be signed in to change notification settings - Fork 2
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
[ECO-2498] Drop
price_feed
function and replace it with `price_feed…
…` view that returns market data as well (#66) * Change `price_feed` function to `price_feed` view with all market data * Change view name in down.sql * Update down.sql * Update the price feed query to be correct and use the most performant view
- Loading branch information
Showing
2 changed files
with
89 additions
and
0 deletions.
There are no files selected for viewing
51 changes: 51 additions & 0 deletions
51
...essor/src/db/postgres/migrations/2024-11-26-050428_add_market_data_to_price_feed/down.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,51 @@ | ||
-- This file should undo anything in `up.sql` | ||
DROP VIEW price_feed; | ||
ALTER INDEX price_feed_idx RENAME TO price_feed; | ||
|
||
CREATE OR REPLACE FUNCTION price_feed() RETURNS TABLE( | ||
market_id BIGINT, | ||
symbol_bytes BYTEA, | ||
symbol_emojis TEXT[], | ||
market_address VARCHAR(66), | ||
open_price_q64 NUMERIC, | ||
close_price_q64 NUMERIC | ||
) | ||
AS $$ | ||
WITH markets AS ( | ||
SELECT market_id | ||
FROM market_daily_volume | ||
ORDER BY daily_volume DESC | ||
LIMIT 25 | ||
), | ||
swap24 AS ( | ||
SELECT DISTINCT ON (market_id) | ||
market_id, | ||
avg_execution_price_q64 | ||
FROM swap_events | ||
WHERE transaction_timestamp <= CURRENT_TIMESTAMP - interval '1 day' | ||
ORDER BY | ||
market_id, | ||
transaction_timestamp DESC | ||
), | ||
first_swap AS ( | ||
SELECT DISTINCT ON (market_id) | ||
market_id, | ||
avg_execution_price_q64 | ||
FROM swap_events | ||
ORDER BY | ||
market_id, | ||
transaction_timestamp ASC | ||
) | ||
SELECT | ||
swap_close.market_id, | ||
swap_close.symbol_bytes, | ||
swap_close.symbol_emojis, | ||
swap_close.market_address, | ||
COALESCE(swap_open.avg_execution_price_q64, first_swap.avg_execution_price_q64) AS open_price_q64, | ||
swap_close.last_swap_avg_execution_price_q64 AS close_price_q64 | ||
FROM markets | ||
INNER JOIN market_latest_state_event AS swap_close ON markets.market_id = swap_close.market_id | ||
INNER JOIN first_swap ON markets.market_id = first_swap.market_id | ||
LEFT JOIN swap24 AS swap_open ON markets.market_id = swap_open.market_id | ||
WHERE swap_close.transaction_timestamp > CURRENT_TIMESTAMP - interval '1 day' | ||
$$ LANGUAGE SQL; |
38 changes: 38 additions & 0 deletions
38
...ocessor/src/db/postgres/migrations/2024-11-26-050428_add_market_data_to_price_feed/up.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,38 @@ | ||
-- Your SQL goes here | ||
DROP FUNCTION price_feed; | ||
ALTER INDEX price_feed RENAME TO price_feed_idx; | ||
|
||
CREATE OR REPLACE VIEW price_feed AS | ||
WITH markets AS ( | ||
SELECT market_id | ||
FROM market_state | ||
ORDER BY daily_volume DESC | ||
), | ||
swap24 AS ( | ||
SELECT DISTINCT ON (market_id) | ||
market_id, | ||
avg_execution_price_q64 | ||
FROM swap_events | ||
WHERE transaction_timestamp <= CURRENT_TIMESTAMP - interval '1 day' | ||
ORDER BY | ||
market_id, | ||
transaction_timestamp DESC | ||
), | ||
first_swap AS ( | ||
SELECT DISTINCT ON (market_id) | ||
market_id, | ||
avg_execution_price_q64 | ||
FROM swap_events | ||
ORDER BY | ||
market_id, | ||
transaction_timestamp ASC | ||
) | ||
SELECT | ||
latest_swap.*, | ||
COALESCE(swap_open.avg_execution_price_q64, first_swap.avg_execution_price_q64) AS open_price_q64, | ||
latest_swap.last_swap_avg_execution_price_q64 AS close_price_q64 | ||
FROM markets | ||
INNER JOIN market_state AS latest_swap ON markets.market_id = latest_swap.market_id | ||
INNER JOIN first_swap ON markets.market_id = first_swap.market_id | ||
LEFT JOIN swap24 AS swap_open ON markets.market_id = swap_open.market_id | ||
WHERE latest_swap.transaction_timestamp > CURRENT_TIMESTAMP - interval '1 day'; |