From 3e4aabb07e49b05b1e49bd60de1a5d9129a5856f Mon Sep 17 00:00:00 2001 From: Shunji Zhan Date: Thu, 5 Dec 2024 15:48:28 +0800 Subject: [PATCH 1/3] new dex queries --- dune-acala-dex/queries.yml | 5 +++- .../queries/daily_token_prices___3989007.sql | 15 +++++++++++ .../queries/dex_latest_stats___4374073.sql | 20 ++++++++++++++ .../queries/dex_swaps___3751506.sql | 11 ++++---- .../queries/dex_volume___4373515.sql | 27 +++++++++++++++++++ 5 files changed, 72 insertions(+), 6 deletions(-) create mode 100644 dune-acala-dex/queries/daily_token_prices___3989007.sql create mode 100644 dune-acala-dex/queries/dex_latest_stats___4374073.sql create mode 100644 dune-acala-dex/queries/dex_volume___4373515.sql diff --git a/dune-acala-dex/queries.yml b/dune-acala-dex/queries.yml index 2c36330..50a66da 100644 --- a/dune-acala-dex/queries.yml +++ b/dune-acala-dex/queries.yml @@ -11,4 +11,7 @@ query_ids: - 3799539 - 3799558 - 3782346 - - 3784244 \ No newline at end of file + - 3784244 + - 4373515 + - 4374073 + - 3989007 \ No newline at end of file diff --git a/dune-acala-dex/queries/daily_token_prices___3989007.sql b/dune-acala-dex/queries/daily_token_prices___3989007.sql new file mode 100644 index 0000000..d1a64b6 --- /dev/null +++ b/dune-acala-dex/queries/daily_token_prices___3989007.sql @@ -0,0 +1,15 @@ +-- part of a query repo +-- query name: daily_token_prices +-- query link: https://dune.com/queries/3989007 + + +SELECT + date_trunc('day', minute) as day, + symbol, + avg(price) as price +FROM prices.usd +WHERE + symbol in ('DOT', 'JITOSOL', 'USDC') + AND date_trunc('day', minute) BETWEEN TIMESTAMP '2022-02-09' AND current_date +GROUP BY 1, 2 +ORDER BY 1, 2; \ No newline at end of file diff --git a/dune-acala-dex/queries/dex_latest_stats___4374073.sql b/dune-acala-dex/queries/dex_latest_stats___4374073.sql new file mode 100644 index 0000000..a565b39 --- /dev/null +++ b/dune-acala-dex/queries/dex_latest_stats___4374073.sql @@ -0,0 +1,20 @@ +-- part of a query repo +-- query name: dex_latest_stats +-- query link: https://dune.com/queries/4374073 + + +WITH latest_volume AS ( + SELECT + date, + volume, + total_volume + FROM query_4373515 + ORDER BY 1 DESC + LIMIT 1 +) + +SELECT + date, + volume, + total_volume +FROM latest_volume \ No newline at end of file diff --git a/dune-acala-dex/queries/dex_swaps___3751506.sql b/dune-acala-dex/queries/dex_swaps___3751506.sql index 5764ba9..e22ddd3 100644 --- a/dune-acala-dex/queries/dex_swaps___3751506.sql +++ b/dune-acala-dex/queries/dex_swaps___3751506.sql @@ -116,20 +116,21 @@ dex_swap_formatted AS ( SELECT E.block_time, E.address, - E.token_in, E.amount_in, - E.token_out, + E.token_in, E.amount_out, + E.token_out, CASE WHEN E.token_in IN ('AUSD', 'USDC') THEN E.amount_in - WHEN E.token_in = 'DOT' THEN E.amount_in * P.price + WHEN E.token_in IN ('DOT', 'lcDOT') THEN E.amount_in * P.price WHEN E.token_out IN ('AUSD', 'USDC') THEN E.amount_out - WHEN E.token_out = 'DOT' THEN E.amount_out * P.price + WHEN E.token_out IN ('DOT', 'lcDOT') THEN E.amount_out * P.price ELSE 0 END AS usd_value, E.block_number, E.tx_hash FROM dex_swap_formatted E -LEFT JOIN prices.usd_daily P +LEFT JOIN query_3989007 P -- daily token prices ON E.day = P.day AND P.symbol = 'DOT' +WHERE E.day != DATE '2022-08-14' ORDER BY 1 DESC \ No newline at end of file diff --git a/dune-acala-dex/queries/dex_volume___4373515.sql b/dune-acala-dex/queries/dex_volume___4373515.sql new file mode 100644 index 0000000..12dbb1a --- /dev/null +++ b/dune-acala-dex/queries/dex_volume___4373515.sql @@ -0,0 +1,27 @@ +-- part of a query repo +-- query name: dex_volume +-- query link: https://dune.com/queries/4373515 + + +WITH daily_volume AS ( + SELECT + date_trunc({{interval}}, block_time) as date, + SUM(usd_value) AS volume + FROM query_3751506 + GROUP BY 1 +), + +cumulative_volume AS ( + SELECT + date, + volume, + SUM(volume) OVER (ORDER BY date) AS cumulative_volume + FROM daily_volume +) + +SELECT + date, + volume, + cumulative_volume as total_volume +FROM cumulative_volume +WHERE date >= date_add('month', -1 * {{show data for how many months:}}, current_date) \ No newline at end of file From 0f1d0272dda7c56a95d26ad03eb04267978272b7 Mon Sep 17 00:00:00 2001 From: Shunji Zhan Date: Fri, 13 Dec 2024 14:02:02 +0800 Subject: [PATCH 2/3] update --- dune-acala-dex/queries.yml | 3 +- .../queries/dex_liquidity_tx___3769045.sql | 45 ++++-- .../queries/dex_swaps___3751506.sql | 36 +++-- .../queries/pol_tvl_ausd_intr___3799562.sql | 5 +- dune-acala-dex/queries/pool_tvl___3782346.sql | 132 ++++++++++++++++-- .../queries/pool_tvl_aca_ausd___3799554.sql | 5 +- .../queries/pool_tvl_aca_usdc___3799539.sql | 6 +- .../queries/pool_tvl_ausd_ibtc___3799558.sql | 5 +- .../queries/pool_tvl_ausd_lcdot___3799550.sql | 5 +- .../queries/pool_tvl_ausd_ldot___3799555.sql | 5 +- .../queries/pool_tvl_dot_lcdot___3799524.sql | 5 +- .../queries/pool_tvl_dot_unq___3799556.sql | 5 +- .../pool_tvl_ldot_jitosol___4403783.sql | 13 ++ .../queries/provision_tx___3782192.sql | 24 +++- 14 files changed, 244 insertions(+), 50 deletions(-) create mode 100644 dune-acala-dex/queries/pool_tvl_ldot_jitosol___4403783.sql diff --git a/dune-acala-dex/queries.yml b/dune-acala-dex/queries.yml index 50a66da..b4c90de 100644 --- a/dune-acala-dex/queries.yml +++ b/dune-acala-dex/queries.yml @@ -14,4 +14,5 @@ query_ids: - 3784244 - 4373515 - 4374073 - - 3989007 \ No newline at end of file + - 3989007 + - 4403783 \ No newline at end of file diff --git a/dune-acala-dex/queries/dex_liquidity_tx___3769045.sql b/dune-acala-dex/queries/dex_liquidity_tx___3769045.sql index 6196623..eac133b 100644 --- a/dune-acala-dex/queries/dex_liquidity_tx___3769045.sql +++ b/dune-acala-dex/queries/dex_liquidity_tx___3769045.sql @@ -48,7 +48,14 @@ liquidity_tx_extracted AS ( '"}' ) ) - WHEN JSON_EXTRACT_SCALAR(X.token0_json, '$.erc20') IS NOT NULL THEN '{"ForeignAsset":"14"}' + WHEN JSON_EXTRACT_SCALAR(X.token0_json, '$.erc20') IS NOT NULL THEN ( + CONCAT( + '{"Erc20":"', + JSON_EXTRACT_SCALAR(X.token0_json, '$.erc20'), + '"}' + ) + ) + ELSE '???' END AS token0_varchar, CASE @@ -73,7 +80,14 @@ liquidity_tx_extracted AS ( '"}' ) ) - WHEN JSON_EXTRACT_SCALAR(X.token1_json, '$.erc20') IS NOT NULL THEN '{"ForeignAsset":"14"}' + WHEN JSON_EXTRACT_SCALAR(X.token1_json, '$.erc20') IS NOT NULL THEN ( + CONCAT( + '{"Erc20":"', + JSON_EXTRACT_SCALAR(X.token1_json, '$.erc20'), + '"}' + ) + ) + ELSE '???' END AS token1_varchar FROM liquidity_tx_raw X ), @@ -84,23 +98,36 @@ liquidity_tx_parsed AS ( B.symbol AS token0, B.decimals AS decimals0, C.symbol AS token1, - C.decimals AS decimals1 + C.decimals AS decimals1, + CASE + WHEN starts_with(amount0_varchar, '0x') + THEN varbinary_to_uint256(FROM_HEX(amount0_varchar)) + ELSE CAST(amount0_varchar as uint256) + END AS amount0_uint256, + CASE + WHEN starts_with(amount1_varchar, '0x') + THEN varbinary_to_uint256(FROM_HEX(amount1_varchar)) + ELSE CAST(amount1_varchar as uint256) + END AS amount1_uint256 FROM liquidity_tx_extracted A - JOIN query_3670410 B ON A.token0_varchar = B.asset - JOIN query_3670410 C ON A.token1_varchar = C.asset + LEFT JOIN query_4397191 B -- acala assets + ON A.token0_varchar = B.asset + LEFT JOIN query_4397191 C -- acala assets + ON A.token1_varchar = C.asset ) SELECT D.block_time, D.method, D.address, + CONCAT(token0, '/', token1) AS pool_name, D.token0, - CAST(D.amount0_varchar AS DOUBLE) / POWER(10, D.decimals0) AS amount0, D.token1, - CAST(D.amount1_varchar AS DOUBLE) / POWER(10, D.decimals1) AS amount1, + amount0_uint256 / POWER(10, D.decimals0) AS amount0, + amount1_uint256 / POWER(10, D.decimals1) AS amount1, D.block_number, D.extrinsic_hash as tx_hash FROM liquidity_tx_parsed D -WHERE D.amount0_varchar NOT LIKE '0x%' -AND D.amount1_varchar NOT LIKE '0x%' +-- WHERE D.amount0_varchar NOT LIKE '0x%' +-- AND D.amount1_varchar NOT LIKE '0x%' ORDER BY 1 DESC \ No newline at end of file diff --git a/dune-acala-dex/queries/dex_swaps___3751506.sql b/dune-acala-dex/queries/dex_swaps___3751506.sql index e22ddd3..2612fbf 100644 --- a/dune-acala-dex/queries/dex_swaps___3751506.sql +++ b/dune-acala-dex/queries/dex_swaps___3751506.sql @@ -46,7 +46,13 @@ dex_swap_raw_extracted AS ( '"}' ) ) - WHEN JSON_EXTRACT_SCALAR(X.token_in_json, '$.erc20') IS NOT NULL THEN '{"ForeignAsset":"14"}' + WHEN JSON_EXTRACT_SCALAR(X.token_in_json, '$.erc20') IS NOT NULL THEN ( + CONCAT( + '{"Erc20":"', + JSON_EXTRACT_SCALAR(X.token_in_json, '$.erc20'), + '"}' + ) + ) END AS token_in_varchar, CASE @@ -71,7 +77,13 @@ dex_swap_raw_extracted AS ( '"}' ) ) - WHEN JSON_EXTRACT_SCALAR(X.token_out_json, '$.erc20') IS NOT NULL THEN '{"ForeignAsset":"14"}' + WHEN JSON_EXTRACT_SCALAR(X.token_out_json, '$.erc20') IS NOT NULL THEN ( + CONCAT( + '{"Erc20":"', + JSON_EXTRACT_SCALAR(X.token_out_json, '$.erc20'), + '"}' + ) + ) END AS token_out_varchar FROM dex_swap_raw X ), @@ -94,8 +106,10 @@ dex_swap_parsed AS ( C.symbol AS token_out, C.decimals AS decimals_out FROM dex_swap_raw_extracted A - JOIN query_3670410 B ON A.token_in_varchar = B.asset - JOIN query_3670410 C ON A.token_out_varchar = C.asset + LEFT JOIN query_4397191 B -- acala assets + ON A.token_in_varchar = B.asset + LEFT JOIN query_4397191 C -- acala assets + ON A.token_out_varchar = C.asset ), dex_swap_formatted AS ( @@ -121,16 +135,22 @@ SELECT E.amount_out, E.token_out, CASE + WHEN E.token_in IN ('DOT', 'lcDOT') THEN E.amount_in * dot_price.price + WHEN E.token_in IN ('JITOSOL') THEN E.amount_in * jitosol_price.price WHEN E.token_in IN ('AUSD', 'USDC') THEN E.amount_in - WHEN E.token_in IN ('DOT', 'lcDOT') THEN E.amount_in * P.price + WHEN E.token_out IN ('DOT', 'lcDOT') THEN E.amount_out * dot_price.price + WHEN E.token_out IN ('JITOSOL') THEN E.amount_out * jitosol_price.price WHEN E.token_out IN ('AUSD', 'USDC') THEN E.amount_out - WHEN E.token_out IN ('DOT', 'lcDOT') THEN E.amount_out * P.price ELSE 0 END AS usd_value, E.block_number, E.tx_hash FROM dex_swap_formatted E -LEFT JOIN query_3989007 P -- daily token prices -ON E.day = P.day AND P.symbol = 'DOT' +LEFT JOIN query_3989007 as dot_price + ON E.day = dot_price.day + AND dot_price.symbol = 'DOT' +LEFT JOIN query_3989007 as jitosol_price + ON E.day = jitosol_price.day + AND jitosol_price.symbol = 'JITOSOL' WHERE E.day != DATE '2022-08-14' ORDER BY 1 DESC \ No newline at end of file diff --git a/dune-acala-dex/queries/pol_tvl_ausd_intr___3799562.sql b/dune-acala-dex/queries/pol_tvl_ausd_intr___3799562.sql index 6e0e1f4..8f589c8 100644 --- a/dune-acala-dex/queries/pol_tvl_ausd_intr___3799562.sql +++ b/dune-acala-dex/queries/pol_tvl_ausd_intr___3799562.sql @@ -4,8 +4,9 @@ SELECT - day_timestamp, + date, token0_tvl AS aseed_tvl, token1_tvl AS intr_tvl FROM query_3782346 AS pool_tvl -WHERE pool_name = 'AUSD/INTR' \ No newline at end of file +WHERE pool_name = 'AUSD/INTR' +AND token0_tvl > 0 \ No newline at end of file diff --git a/dune-acala-dex/queries/pool_tvl___3782346.sql b/dune-acala-dex/queries/pool_tvl___3782346.sql index d3b2ab6..f26734d 100644 --- a/dune-acala-dex/queries/pool_tvl___3782346.sql +++ b/dune-acala-dex/queries/pool_tvl___3782346.sql @@ -1,5 +1,5 @@ -- part of a query repo --- query name: pool_tvl +-- query name: dex_pool_tvl -- query link: https://dune.com/queries/3782346 @@ -61,6 +61,7 @@ all_txs AS ( SELECT * FROM dex_txs UNION ALL SELECT * FROM query_3784244 AS admin_txs + ORDER BY 1 ASC ), pool_tvl AS ( @@ -73,15 +74,124 @@ pool_tvl AS ( SUM(net_amount0) OVER (PARTITION BY token0, token1 ORDER BY block_time) AS token0_tvl, SUM(net_amount1) OVER (PARTITION BY token0, token1 ORDER BY block_time) AS token1_tvl FROM all_txs +), + +pool_tvl_usd AS ( + SELECT + block_time, + block_number, + token0, + token1, + pool_name, + token0_tvl, + token1_tvl, + CASE + WHEN E.token0 IN ('DOT', 'lcDOT') THEN E.token0_tvl * dot_price.price * 2 + WHEN E.token0 IN ('JITOSOL') THEN E.token0_tvl * jitosol_price.price * 2 + WHEN E.token0 IN ('AUSD', 'USDC') THEN E.token0_tvl * 2 + WHEN E.token1 IN ('DOT', 'lcDOT') THEN E.token1_tvl * dot_price.price * 2 + WHEN E.token1 IN ('JITOSOL') THEN E.token1_tvl * jitosol_price.price * 2 + WHEN E.token1 IN ('AUSD', 'USDC') THEN E.token1_tvl * 2 + ELSE 0 + END AS usd_tvl + FROM pool_tvl E + LEFT JOIN query_3989007 as dot_price + ON DATE_TRUNC('day', E.block_time) = dot_price.day + AND dot_price.symbol = 'DOT' + LEFT JOIN query_3989007 as jitosol_price + ON DATE_TRUNC('day', E.block_time) = jitosol_price.day + AND jitosol_price.symbol = 'JITOSOL' +), + +daily_pool_tvl AS ( + SELECT + DATE_TRUNC('day', block_time) AS date, + pool_name, + AVG(token0_tvl) AS token0_tvl, + AVG(token1_tvl) AS token1_tvl, + AVG(usd_tvl) AS usd_tvl + FROM pool_tvl_usd + WHERE pool_name != 'AUSD/IBTC' + GROUP BY 1, 2 +), + +date_range AS ( + SELECT + MIN(DATE_TRUNC('day', block_time)) AS start_date, + MAX(DATE_TRUNC('day', block_time)) AS end_date + FROM pool_tvl_usd + WHERE pool_name != 'AUSD/IBTC' -- Add filter here +), + +all_dates AS ( + SELECT + DATE_TRUNC('day', DATE_ADD('day', value, start_date)) AS date + FROM date_range + CROSS JOIN UNNEST(sequence(0, date_diff('day', start_date, end_date))) AS t(value) +), + +all_pool_names AS ( + SELECT DISTINCT pool_name + FROM pool_tvl_usd + WHERE pool_name != 'AUSD/IBTC' -- Add filter here +), + +full_date_pool_combination AS ( + SELECT date, pool_name + FROM all_dates + CROSS JOIN all_pool_names + ORDER BY date ASC +), + +historical_values AS ( + SELECT + d1.date as ref_date, + d2.date as data_date, + d2.pool_name, + d2.token0_tvl, + d2.token1_tvl, + d2.usd_tvl, + ROW_NUMBER() OVER ( + PARTITION BY d1.date, d2.pool_name + ORDER BY d2.date DESC + ) as rn + FROM (SELECT DISTINCT date FROM full_date_pool_combination) d1 + CROSS JOIN daily_pool_tvl d2 + WHERE d2.date <= d1.date +), + +latest_historical AS ( + SELECT + ref_date as date, + pool_name, + token0_tvl as historical_token0_tvl, + token1_tvl as historical_token1_tvl, + usd_tvl as historical_usd_tvl + FROM historical_values + WHERE rn = 1 +), + +daily_pool_tvl_complete AS ( + SELECT + f.date, + f.pool_name, + COALESCE(d.token0_tvl, h.historical_token0_tvl, 0) AS token0_tvl, + COALESCE(d.token1_tvl, h.historical_token1_tvl, 0) AS token1_tvl, + COALESCE(d.usd_tvl, h.historical_usd_tvl, 0) AS usd_tvl + FROM full_date_pool_combination f + LEFT JOIN daily_pool_tvl d + ON f.date = d.date + AND f.pool_name = d.pool_name + LEFT JOIN latest_historical h + ON f.date = h.date + AND f.pool_name = h.pool_name ) -SELECT - DATE_TRUNC('day', block_time) AS day_timestamp, - pool_name, - AVG(token0_tvl) AS token0_tvl, - AVG(token1_tvl) AS token1_tvl - -- AVG(usd_value) AS usd_tvl -FROM pool_tvl --- WHERE pool_name = {{pool_name}} -GROUP BY 1, pool_name -ORDER BY 1 +SELECT + date, + pool_name, + token0_tvl, + token1_tvl, + usd_tvl +FROM daily_pool_tvl_complete +ORDER BY date DESC, pool_name; \ No newline at end of file diff --git a/dune-acala-dex/queries/pool_tvl_aca_ausd___3799554.sql b/dune-acala-dex/queries/pool_tvl_aca_ausd___3799554.sql index 766b7e5..2a63429 100644 --- a/dune-acala-dex/queries/pool_tvl_aca_ausd___3799554.sql +++ b/dune-acala-dex/queries/pool_tvl_aca_ausd___3799554.sql @@ -4,8 +4,9 @@ SELECT - day_timestamp, + date, token0_tvl AS aca_tvl, token1_tvl AS aseed_tvl FROM query_3782346 AS pool_tvl -WHERE pool_name = 'ACA/AUSD' \ No newline at end of file +WHERE pool_name = 'ACA/AUSD' +AND token0_tvl > 0 \ No newline at end of file diff --git a/dune-acala-dex/queries/pool_tvl_aca_usdc___3799539.sql b/dune-acala-dex/queries/pool_tvl_aca_usdc___3799539.sql index f1c1878..04e60f4 100644 --- a/dune-acala-dex/queries/pool_tvl_aca_usdc___3799539.sql +++ b/dune-acala-dex/queries/pool_tvl_aca_usdc___3799539.sql @@ -4,9 +4,9 @@ SELECT - day_timestamp, + date, token0_tvl AS aca_tvl, token1_tvl AS usdc_tvl - -- usd_value AS usd_tvl FROM query_3782346 AS pool_tvl -WHERE pool_name = 'ACA/USDC' \ No newline at end of file +WHERE pool_name = 'ACA/USDC' +AND token0_tvl > 0 \ No newline at end of file diff --git a/dune-acala-dex/queries/pool_tvl_ausd_ibtc___3799558.sql b/dune-acala-dex/queries/pool_tvl_ausd_ibtc___3799558.sql index 31f4f72..327fc55 100644 --- a/dune-acala-dex/queries/pool_tvl_ausd_ibtc___3799558.sql +++ b/dune-acala-dex/queries/pool_tvl_ausd_ibtc___3799558.sql @@ -4,8 +4,9 @@ SELECT - day_timestamp, + date, token0_tvl AS aseed_tvl, token1_tvl AS ibtc_tvl FROM query_3782346 AS pool_tvl -WHERE pool_name = 'AUSD/IBTC' \ No newline at end of file +WHERE pool_name = 'AUSD/IBTC' +AND token0_tvl > 0 \ No newline at end of file diff --git a/dune-acala-dex/queries/pool_tvl_ausd_lcdot___3799550.sql b/dune-acala-dex/queries/pool_tvl_ausd_lcdot___3799550.sql index 0e7f466..c0efda8 100644 --- a/dune-acala-dex/queries/pool_tvl_ausd_lcdot___3799550.sql +++ b/dune-acala-dex/queries/pool_tvl_ausd_lcdot___3799550.sql @@ -4,8 +4,9 @@ SELECT - day_timestamp, + date, token0_tvl AS aseed_tvl, token1_tvl AS lcdot_tvl FROM query_3782346 AS pool_tvl -WHERE pool_name = 'AUSD/lcDOT' \ No newline at end of file +WHERE pool_name = 'AUSD/lcDOT' +AND token0_tvl > 0 \ No newline at end of file diff --git a/dune-acala-dex/queries/pool_tvl_ausd_ldot___3799555.sql b/dune-acala-dex/queries/pool_tvl_ausd_ldot___3799555.sql index 2ecc082..2f675d3 100644 --- a/dune-acala-dex/queries/pool_tvl_ausd_ldot___3799555.sql +++ b/dune-acala-dex/queries/pool_tvl_ausd_ldot___3799555.sql @@ -4,8 +4,9 @@ SELECT - day_timestamp, + date, token0_tvl AS aseed_tvl, token1_tvl AS ldot_tvl FROM query_3782346 AS pool_tvl -WHERE pool_name = 'AUSD/LDOT' \ No newline at end of file +WHERE pool_name = 'AUSD/LDOT' +AND token0_tvl > 0 \ No newline at end of file diff --git a/dune-acala-dex/queries/pool_tvl_dot_lcdot___3799524.sql b/dune-acala-dex/queries/pool_tvl_dot_lcdot___3799524.sql index b8677c2..7d61da7 100644 --- a/dune-acala-dex/queries/pool_tvl_dot_lcdot___3799524.sql +++ b/dune-acala-dex/queries/pool_tvl_dot_lcdot___3799524.sql @@ -4,8 +4,9 @@ SELECT - day_timestamp, + date, token0_tvl AS dot_tvl, token1_tvl AS lcdot_tvl FROM query_3782346 AS pool_tvl -WHERE pool_name = 'DOT/lcDOT' \ No newline at end of file +WHERE pool_name = 'DOT/lcDOT' +AND token0_tvl > 0 \ No newline at end of file diff --git a/dune-acala-dex/queries/pool_tvl_dot_unq___3799556.sql b/dune-acala-dex/queries/pool_tvl_dot_unq___3799556.sql index 663e2c5..790b7d4 100644 --- a/dune-acala-dex/queries/pool_tvl_dot_unq___3799556.sql +++ b/dune-acala-dex/queries/pool_tvl_dot_unq___3799556.sql @@ -4,8 +4,9 @@ SELECT - day_timestamp, + date, token0_tvl AS dot_tvl, token1_tvl AS unq_tvl FROM query_3782346 AS pool_tvl -WHERE pool_name = 'DOT/UNQ' \ No newline at end of file +WHERE pool_name = 'DOT/UNQ' +AND token0_tvl > 0 \ No newline at end of file diff --git a/dune-acala-dex/queries/pool_tvl_ldot_jitosol___4403783.sql b/dune-acala-dex/queries/pool_tvl_ldot_jitosol___4403783.sql new file mode 100644 index 0000000..b4b836a --- /dev/null +++ b/dune-acala-dex/queries/pool_tvl_ldot_jitosol___4403783.sql @@ -0,0 +1,13 @@ +-- part of a query repo +-- query name: pool_tvl_ldot_jitosol +-- query link: https://dune.com/queries/4403783 + + +SELECT + date, + token0_tvl AS ldot_tvl, + token1_tvl AS jitosol_tvl, + usd_tvl +FROM query_3782346 AS pool_tvl +WHERE pool_name = 'LDOT/JITOSOL' +AND token0_tvl > 0 \ No newline at end of file diff --git a/dune-acala-dex/queries/provision_tx___3782192.sql b/dune-acala-dex/queries/provision_tx___3782192.sql index 676a764..10faa3e 100644 --- a/dune-acala-dex/queries/provision_tx___3782192.sql +++ b/dune-acala-dex/queries/provision_tx___3782192.sql @@ -54,7 +54,14 @@ provision_tx_extracted AS ( '"}' ) ) - WHEN JSON_EXTRACT_SCALAR(X.token0_json, '$.erc20') IS NOT NULL THEN '{"ForeignAsset":"14"}' + WHEN JSON_EXTRACT_SCALAR(X.token0_json, '$.erc20') IS NOT NULL THEN ( + CONCAT( + '{"Erc20":"', + JSON_EXTRACT_SCALAR(X.token0_json, '$.erc20'), + '"}' + ) + ) + ELSE '???' END AS token0_varchar, CASE @@ -86,7 +93,14 @@ provision_tx_extracted AS ( '"}' ) ) - WHEN JSON_EXTRACT_SCALAR(X.token1_json, '$.erc20') IS NOT NULL THEN '{"ForeignAsset":"14"}' + WHEN JSON_EXTRACT_SCALAR(X.token1_json, '$.erc20') IS NOT NULL THEN ( + CONCAT( + '{"Erc20":"', + JSON_EXTRACT_SCALAR(X.token1_json, '$.erc20'), + '"}' + ) + ) + ELSE '???' END AS token1_varchar FROM provision_tx_raw X ), @@ -109,8 +123,10 @@ provision_tx_parsed AS ( C.symbol AS token1, C.decimals AS decimals1 FROM provision_tx_extracted A - JOIN query_3670410 B ON A.token0_varchar = B.asset - JOIN query_3670410 C ON A.token1_varchar = C.asset + LEFT JOIN query_4397191 B -- acala assets + ON A.token0_varchar = B.asset + LEFT JOIN query_4397191 C -- acala assets + ON A.token1_varchar = C.asset ) SELECT From df0e697d4ce5a01868079a55a6e3b83663cad73b Mon Sep 17 00:00:00 2001 From: Shunji Zhan Date: Fri, 13 Dec 2024 17:04:53 +0800 Subject: [PATCH 3/3] update --- .../queries/dex_latest_stats___4374073.sql | 28 +++++++++++++++---- dune-acala-dex/queries/pool_tvl___3782346.sql | 1 + 2 files changed, 23 insertions(+), 6 deletions(-) diff --git a/dune-acala-dex/queries/dex_latest_stats___4374073.sql b/dune-acala-dex/queries/dex_latest_stats___4374073.sql index a565b39..f72be03 100644 --- a/dune-acala-dex/queries/dex_latest_stats___4374073.sql +++ b/dune-acala-dex/queries/dex_latest_stats___4374073.sql @@ -9,12 +9,28 @@ WITH latest_volume AS ( volume, total_volume FROM query_4373515 - ORDER BY 1 DESC + ORDER BY date DESC LIMIT 1 +), + +latest_tvl AS ( + SELECT + date AS tvl_date, + SUM(usd_tvl) AS usd_tvl + FROM query_3782346 + WHERE date = (SELECT MAX(date) FROM query_3782346) + GROUP BY date +), + +latest_stats AS ( + SELECT + A.date, + A.volume, + A.total_volume, + B.usd_tvl + FROM latest_volume A + CROSS JOIN latest_tvl B ) -SELECT - date, - volume, - total_volume -FROM latest_volume \ No newline at end of file +SELECT * +FROM latest_stats \ No newline at end of file diff --git a/dune-acala-dex/queries/pool_tvl___3782346.sql b/dune-acala-dex/queries/pool_tvl___3782346.sql index f26734d..dfa5942 100644 --- a/dune-acala-dex/queries/pool_tvl___3782346.sql +++ b/dune-acala-dex/queries/pool_tvl___3782346.sql @@ -194,4 +194,5 @@ SELECT token1_tvl, usd_tvl FROM daily_pool_tvl_complete +WHERE date >= date_add('month', -1 * {{show data for how many months:}}, current_date) ORDER BY date DESC, pool_name; \ No newline at end of file