Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Adds Clipper Coves to dex.trades on Optimism #1417

Merged
Merged
Changes from 2 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
131 changes: 131 additions & 0 deletions optimism2/dex/insert_clipper_coves.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,131 @@
CREATE OR REPLACE FUNCTION dex.insert_clipper_coves(start_ts timestamptz, end_ts timestamptz=now()) RETURNS integer
LANGUAGE plpgsql AS $function$
DECLARE r integer;
BEGIN
WITH rows AS (
INSERT INTO dex.trades (
block_time,
token_a_symbol,
token_b_symbol,
token_a_amount,
token_b_amount,
project,
version,
category,
trader_a,
trader_b,
token_a_amount_raw,
token_b_amount_raw,
usd_amount,
token_a_address,
token_b_address,
exchange_contract_address,
tx_hash,
tx_from,
tx_to,
trace_address,
evt_index,
trade_id
)
SELECT
dexs.block_time,
erc20a.symbol AS token_a_symbol,
erc20b.symbol AS token_b_symbol,
token_a_amount_raw / 10 ^ erc20a.decimals AS token_a_amount,
token_b_amount_raw / 10 ^ erc20b.decimals AS token_b_amount,
project,
version,
category,
coalesce(trader_a, tx."from") as trader_a, -- subqueries rely on this COALESCE to avoid redundant joins with the transactions table
trader_b,
token_a_amount_raw,
token_b_amount_raw,
coalesce(
usd_amount,
token_a_amount_raw / 10 ^ erc20a.decimals * pa.median_price,
token_b_amount_raw / 10 ^ erc20b.decimals * pb.median_price,
0
) as usd_amount,
token_a_address,
token_b_address,
exchange_contract_address,
tx_hash,
tx."from" as tx_from,
tx."to" as tx_to,
trace_address,
evt_index,
row_number() OVER (PARTITION BY project, tx_hash, evt_index, trace_address ORDER BY version, category) AS trade_id
FROM (
-- ClipperCove Polygon
SELECT
t.evt_block_time AS block_time,
'Clipper' AS project,
'coves1' AS version,
'DEX' AS category,
t."recipient" AS trader_a,
NULL::bytea AS trader_b,
"inAmount" AS token_b_amount_raw,
"outAmount" AS token_a_amount_raw,
-- This is referenced in the coalesce above
NULL::numeric AS usd_amount,
-- Cast raw sigil as WETH for price purposes
CASE WHEN "outAsset" = '\x0000000000000000000000000000000000000000' THEN
'\x4200000000000000000000000000000000000006'::bytea ELSE "outAsset"
END AS token_a_address,
CASE WHEN "inAsset" = '\x0000000000000000000000000000000000000000' THEN
'\x4200000000000000000000000000000000000006'::bytea ELSE "inAsset"
END AS token_b_address,
t.contract_address AS exchange_contract_address,
t.evt_tx_hash AS tx_hash,
NULL::integer[] AS trace_address,
t.evt_index
FROM
clipper."ClipperCove_evt_CoveSwapped" t
WHERE t.evt_block_time >= start_ts
AND t.evt_block_time < end_ts
) dexs
INNER JOIN optimism.transactions tx
ON dexs.tx_hash = tx.hash
AND tx.block_time >= start_ts
AND tx.block_time < end_ts
LEFT JOIN erc20.tokens erc20a ON erc20a.contract_address = dexs.token_a_address
LEFT JOIN erc20.tokens erc20b ON erc20b.contract_address = dexs.token_b_address
LEFT JOIN prices.approx_prices_from_dex_data pa
ON pa.hour = date_trunc('hour', dexs.block_time)
AND pa.contract_address = dexs.token_a_address
AND pa.hour >= start_ts
AND pa.hour < end_ts
LEFT JOIN prices.approx_prices_from_dex_data pb
ON pb.hour = date_trunc('hour', dexs.block_time)
AND pb.contract_address = dexs.token_b_address
AND pb.hour >= start_ts
AND pb.hour < end_ts
ON CONFLICT DO NOTHING
RETURNING 1
)
SELECT count(*) INTO r from rows;
RETURN r;
END
$function$;

-- fill 2022
SELECT dex.insert_clipper_coves(
'2022-01-01',
now()
)
WHERE NOT EXISTS (
SELECT *
FROM dex.trades
WHERE block_time > '2022-01-01'
AND block_time <= now() - interval '20 minutes'
AND project = 'Clipper'
AND version = 'coves1'
);

INSERT INTO cron.job (schedule, command)
VALUES ('*/10 * * * *', $$
SELECT dex.insert_clipper_coves(
(SELECT max(block_time) - interval '1 days' FROM dex.trades WHERE project='Clipper' AND version='coves1'),
(SELECT now() - interval '20 minutes'));
$$)
ON CONFLICT (command) DO UPDATE SET schedule=EXCLUDED.schedule;