diff --git a/dbt_subprojects/dex/macros/models/_project/paraswap/all-entities.sql b/dbt_subprojects/dex/macros/models/_project/paraswap/all-entities.sql new file mode 100644 index 00000000000..02f1fd3c4bc --- /dev/null +++ b/dbt_subprojects/dex/macros/models/_project/paraswap/all-entities.sql @@ -0,0 +1,44 @@ +{% macro paraswap_all_entities() %} +{% +set date_to = "timestamp '{{date_to}}'" +%} +{% +set date_from = "timestamp '{{date_from}}'" +%} +{# 0xace5ae3de4baffc4a45028659c5ee330764e4f53 is testing agent address on staging #} +{% +set delta_configs = [ + ['ethereum', 'delta-v1-single', 'paraswapdelta_ethereum.ParaswapDeltav1_call_settleSwap', 'contract_address', 'call_block_time', 'call_tx_hash', null, '0'], + ['ethereum', 'delta-v1-batch', 'paraswapdelta_ethereum.ParaswapDeltav1_call_safeSettleBatchSwap', 'contract_address', 'call_block_time', 'call_tx_hash', null, '0'], + + ['ethereum', 'delta-v2', 'paraswapdelta_ethereum.ParaswapDeltav2_evt_OrderSettled', 'contract_address', 'evt_block_time', 'evt_tx_hash', null, '0'], + ['base', 'delta-v2', 'paraswapdelta_base.ParaswapDeltav2_evt_OrderSettled', 'contract_address', 'evt_block_time', 'evt_tx_hash', 'evt_tx_from <> 0xace5ae3de4baffc4a45028659c5ee330764e4f53', '0'], + + ['ethereum', 'augustus', 'dex_aggregator.trades', 'project_contract_address', 'block_time', 'tx_hash', "project='paraswap' and blockchain='ethereum'", 'amount_usd'], + + ['polygon', 'augustus', 'dex_aggregator.trades', 'project_contract_address', 'block_time', 'tx_hash', "project='paraswap' and blockchain='polygon'", 'amount_usd'], + ['bnb', 'augustus', 'dex_aggregator.trades', 'project_contract_address', 'block_time', 'tx_hash', "project='paraswap' and blockchain='bnb'", 'amount_usd'], + ['arbitrum', 'augustus', 'dex_aggregator.trades', 'project_contract_address', 'block_time', 'tx_hash', "project='paraswap' and blockchain='arbitrum'", 'amount_usd'], + ['avalanche_c', 'augustus', 'dex_aggregator.trades', 'project_contract_address', 'block_time', 'tx_hash', "project='paraswap' and blockchain='avalanche_c'", 'amount_usd'], + ['fantom', 'augustus', 'dex_aggregator.trades', 'project_contract_address', 'block_time', 'tx_hash', "project='paraswap' and blockchain='fantom'", 'amount_usd'], + ['optimism', 'augustus', 'dex_aggregator.trades', 'project_contract_address', 'block_time', 'tx_hash', "project='paraswap' and blockchain='optimism'", 'amount_usd'], + ['base', 'augustus', 'dex_aggregator.trades', 'project_contract_address', 'block_time', 'tx_hash', "project='paraswap' and blockchain='base'", 'amount_usd'], + + + + +] + +%} +with entities as ( + {% for blockchain, entity, table, contract_field_name, time_field_name, hash_field_name, conditional, usd_value_expression in delta_configs %} + select '{{ entity }}' as entity, '{{ blockchain }}' as blockchain, {{contract_field_name}} as contract_address, {{time_field_name}} as block_time, {{hash_field_name}} as tx_hash, {{usd_value_expression}} as usd_value from {{ table }} + where + ({{time_field_name}} BETWEEN {{date_from}} AND {{date_to}}) + {% if conditional %} + AND {{ conditional }} + {% endif %} + {% if not loop.last %} union all {% endif %} + {% endfor %} +) +{% endmacro %} \ No newline at end of file diff --git a/dbt_subprojects/dex/macros/models/_project/paraswap/delta/v1/safe_settle_batch_swap.sql b/dbt_subprojects/dex/macros/models/_project/paraswap/delta/v1/safe_settle_batch_swap.sql new file mode 100644 index 00000000000..58b602a0ee6 --- /dev/null +++ b/dbt_subprojects/dex/macros/models/_project/paraswap/delta/v1/safe_settle_batch_swap.sql @@ -0,0 +1,97 @@ +-- ref dbt_subprojects/dex/macros/models/_project/paraswap/v6/paraswap_v6_trades_master.sql +{% macro delta_safe_settle_batch_swap(blockchain) %} +safe_settle_batch_swap_ExpandedOrders AS ( + SELECT + call_trace_address, + call_block_time, + call_block_number, + call_tx_hash, + output_successfulOrders, + JSON_EXTRACT(data, '$.ordersData') AS parsed_orders, + contract_address + FROM paraswapdelta_{{blockchain}}.ParaswapDeltav1_call_safeSettleBatchSwap + where call_success = true + {% if is_incremental() %} + AND {{ incremental_predicate('call_block_time') }} + {% endif %} +), safe_settle_batch_swap_parsedOrderItems AS ( + SELECT + index, + JSON_ARRAY_GET(parsed_orders, index) AS parsed_order_data, + * + FROM safe_settle_batch_swap_ExpandedOrders + CROSS JOIN UNNEST(SEQUENCE(0, CARDINALITY(output_successfulOrders) - 1)) AS t(index) + WHERE + output_successfulOrders[index + 1] +), safe_settle_batch_swap_parsedOrdersWithSig AS ( + SELECT + JSON_EXTRACT_SCALAR(parsed_order_data, '$.feeAmount') AS feeAmount, + JSON_EXTRACT(parsed_order_data, '$.orderWithSig') AS orderWithSig, + JSON_EXTRACT(parsed_order_data, '$.calldataToExecute') AS calldataToExecute, + * + FROM safe_settle_batch_swap_parsedOrderItems +), safe_settle_batch_swap_unparsedOrders AS ( + SELECT + JSON_EXTRACT(JSON_PARSE(TRY_CAST(orderWithSig AS VARCHAR)), '$.order') AS "order", + JSON_EXTRACT(JSON_PARSE(TRY_CAST(orderWithSig AS VARCHAR)), '$.signature') AS signature, + * + FROM safe_settle_batch_swap_parsedOrdersWithSig +), safe_settle_batch_swap_parsedOrders AS ( + SELECT + from_hex(JSON_EXTRACT_SCALAR(JSON_PARSE(TRY_CAST("order" AS VARCHAR)), '$.owner')) AS "order_owner", + FROM_HEX(JSON_EXTRACT_SCALAR(JSON_PARSE(TRY_CAST("order" AS VARCHAR)), '$.srcToken')) AS "src_token", + FROM_HEX(JSON_EXTRACT_SCALAR(JSON_PARSE(TRY_CAST("order" AS VARCHAR)), '$.destToken')) AS "dest_token", + JSON_EXTRACT_SCALAR(JSON_PARSE(TRY_CAST("order" AS VARCHAR)), '$.srcAmount') AS "src_amount", + JSON_EXTRACT_SCALAR(JSON_PARSE(TRY_CAST("order" AS VARCHAR)), '$.destAmount') AS "dest_amount", + * + FROM safe_settle_batch_swap_unparsedOrders +), safe_settle_batch_swap_withUSDs AS ( + SELECT + CASE + WHEN dest_token = 0xeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeee THEN 0xc02aaa39b223fe8d0a0e5c4f27ead9083c756cc2 + ELSE dest_token + END AS dest_token_for_joining, + CASE + WHEN src_token = 0xeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeee THEN 0xc02aaa39b223fe8d0a0e5c4f27ead9083c756cc2 + ELSE src_token + END AS src_token_for_joining, + * + FROM safe_settle_batch_swap_parsedOrders +), delta_v1_safe_settle_batch_swap_model as ( +SELECT + w.*, + w.dest_token AS fee_token, + CAST(s.price AS DECIMAL(38,18)) AS src_token_price_usd, + CAST(d.price AS DECIMAL(38,18)) AS dest_token_price_usd, + COALESCE( + d.price * CAST (w.feeAmount AS uint256) / POWER(10, d.decimals), + -- src cost + + (s.price * CAST (w.src_amount AS uint256) / POWER(10, s.decimals)) + * CAST (w.feeAmount AS uint256) / CAST (w.dest_amount AS uint256) + + ) AS gas_fee_usd, + s.price * CAST (w.src_amount AS uint256) / POWER(10, s.decimals) AS src_token_order_usd, + d.price * CAST (w.dest_amount AS uint256) / POWER(10, d.decimals) AS dest_token_order_usd + +FROM safe_settle_batch_swap_withUSDs w +LEFT JOIN prices.usd d + ON d.blockchain = '{{blockchain}}' + AND d.minute > TIMESTAMP '2024-06-01' + {% if is_incremental() %} + AND {{ incremental_predicate('d.minute') }} + {% endif %} + AND d.contract_address = w.dest_token_for_joining + AND d.minute = DATE_TRUNC('minute', w.call_block_time) +LEFT JOIN prices.usd s + ON s.blockchain = '{{blockchain}}' + AND s.minute > TIMESTAMP '2024-06-01' + {% if is_incremental() %} + AND {{ incremental_predicate('s.minute') }} + {% endif %} + AND s.contract_address = w.src_token_for_joining + AND s.minute = DATE_TRUNC('minute', w.call_block_time) +ORDER BY + CARDINALITY(w.output_successfulOrders) +) +{% endmacro %} \ No newline at end of file diff --git a/dbt_subprojects/dex/macros/models/_project/paraswap/delta/v1/settle_swap.sql b/dbt_subprojects/dex/macros/models/_project/paraswap/delta/v1/settle_swap.sql new file mode 100644 index 00000000000..7723f55dd89 --- /dev/null +++ b/dbt_subprojects/dex/macros/models/_project/paraswap/delta/v1/settle_swap.sql @@ -0,0 +1,95 @@ +{% +-- ref: dbt_subprojects/dex/macros/models/_project/paraswap/v6/paraswap_v6_trades_master.sql +%} +{% macro delta_settle_swap(blockchain) %} +settle_swap_withParsedOrderData AS ( + SELECT + call_trace_address, + call_block_time, + call_block_number, + call_tx_hash, + JSON_EXTRACT(data, '$.orderData') AS parsed_order_data, + contract_address + FROM + paraswapdelta_{{blockchain}}.ParaswapDeltav1_call_settleSwap + where call_success = true + {% if is_incremental() %} + AND {{ incremental_predicate('call_block_time') }} + {% endif %} +), +settle_swap_parsedOrderWithSig AS ( + SELECT + JSON_EXTRACT_SCALAR(JSON_PARSE(TRY_CAST(parsed_order_data AS VARCHAR)), '$.feeAmount') AS feeAmount, + JSON_EXTRACT(JSON_PARSE(TRY_CAST(parsed_order_data AS VARCHAR)), '$.orderWithSig') AS orderWithSig, + JSON_EXTRACT(JSON_PARSE(TRY_CAST(parsed_order_data AS VARCHAR)), '$.calldataToExecute') AS calldataToExecute, + * + FROM + settle_swap_withParsedOrderData +), +settle_swap_unparsedOrders AS ( + SELECT + JSON_EXTRACT(JSON_PARSE(TRY_CAST(orderWithSig AS VARCHAR)), '$.order') AS "order", + JSON_EXTRACT(JSON_PARSE(TRY_CAST(orderWithSig AS VARCHAR)), '$.signature') AS signature, + * + FROM settle_swap_parsedOrderWithSig +), +settle_swap_parsedOrders AS ( + SELECT + from_hex(JSON_EXTRACT_SCALAR(JSON_PARSE(TRY_CAST("order" AS VARCHAR)), '$.owner')) AS "order_owner", + FROM_HEX(JSON_EXTRACT_SCALAR(JSON_PARSE(TRY_CAST("order" AS VARCHAR)), '$.srcToken')) AS "src_token", + FROM_HEX(JSON_EXTRACT_SCALAR(JSON_PARSE(TRY_CAST("order" AS VARCHAR)), '$.destToken')) AS "dest_token", + JSON_EXTRACT_SCALAR(JSON_PARSE(TRY_CAST("order" AS VARCHAR)), '$.srcAmount') AS "src_amount", + JSON_EXTRACT_SCALAR(JSON_PARSE(TRY_CAST("order" AS VARCHAR)), '$.destAmount') AS "dest_amount", + JSON_EXTRACT_SCALAR(JSON_PARSE(TRY_CAST("order" AS VARCHAR)), '$.permit') AS "permit", + * + FROM settle_swap_unparsedOrders +), +settle_swap_withUSDs AS ( + SELECT + CASE + WHEN dest_token = 0xeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeee THEN 0xc02aaa39b223fe8d0a0e5c4f27ead9083c756cc2 + ELSE dest_token + END AS dest_token_for_joining, + CASE + WHEN src_token = 0xeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeee THEN 0xc02aaa39b223fe8d0a0e5c4f27ead9083c756cc2 + ELSE src_token + END AS src_token_for_joining, + * + FROM settle_swap_parsedOrders +), delta_v1_settle_swap_model as ( +SELECT + w.*, + w.dest_token AS fee_token, + CAST(s.price AS DECIMAL(38,18)) AS src_token_price_usd, + CAST(d.price AS DECIMAL(38,18)) AS dest_token_price_usd, + COALESCE( + d.price * CAST (w.feeAmount AS uint256) / POWER(10, d.decimals), + -- src cost + + (s.price * CAST (w.src_amount AS uint256) / POWER(10, s.decimals)) + * CAST (w.feeAmount AS uint256) / CAST (w.dest_amount AS uint256), + 0 + + ) AS gas_fee_usd, + s.price * CAST (w.src_amount AS uint256) / POWER(10, s.decimals) AS src_token_order_usd, + d.price * CAST (w.dest_amount AS uint256) / POWER(10, d.decimals) AS dest_token_order_usd + +FROM settle_swap_withUSDs w +LEFT JOIN prices.usd d + ON d.blockchain = '{{blockchain}}' + AND d.minute > TIMESTAMP '2024-06-01' + {% if is_incremental() %} + AND {{ incremental_predicate('d.minute') }} + {% endif %} + AND d.contract_address = w.dest_token_for_joining + AND d.minute = DATE_TRUNC('minute', w.call_block_time) +LEFT JOIN prices.usd s + ON s.blockchain = '{{blockchain}}' + AND s.minute > TIMESTAMP '2024-06-01' + {% if is_incremental() %} + AND {{ incremental_predicate('s.minute') }} + {% endif %} + AND s.contract_address = w.src_token_for_joining + AND s.minute = DATE_TRUNC('minute', w.call_block_time) +) +{% endmacro %} \ No newline at end of file diff --git a/dbt_subprojects/dex/models/_projects/paraswap/all-entities-aggregated.sql b/dbt_subprojects/dex/models/_projects/paraswap/all-entities-aggregated.sql new file mode 100644 index 00000000000..1c2257888e0 --- /dev/null +++ b/dbt_subprojects/dex/models/_projects/paraswap/all-entities-aggregated.sql @@ -0,0 +1,20 @@ +-- NB: this is a generated query, do not edit it directly, instead edit the template and re-generate the query +-- hydrate the generated ouput here: https://dune.com/queries/4403433 +{{ paraswap_all_entities() }} +,ordered_entities as ( + select + entity, blockchain, contract_address, block_time, tx_hash, usd_value + from entities + order by block_time, tx_hash +) +select + blockchain, + entity, + contract_address, + count(*) as qty, + sum(usd_value) as usd_volume, + -- a rubbish but tolerable way to get the checksum of the txhash. Is consistent with internal counterparty query though + sum(varbinary_to_decimal(from_hex(substring(to_hex(tx_hash),1,0+8)))) as txhash_checksum +from ordered_entities +group by 1,2,3 +order by qty desc \ No newline at end of file diff --git a/dbt_subprojects/dex/models/_projects/paraswap/all-entities-details.sql b/dbt_subprojects/dex/models/_projects/paraswap/all-entities-details.sql new file mode 100644 index 00000000000..d6493bc611c --- /dev/null +++ b/dbt_subprojects/dex/models/_projects/paraswap/all-entities-details.sql @@ -0,0 +1,10 @@ +-- NB: this is a generated query, do not edit it directly, instead edit the template and re-generate the query +-- hydrate the generated ouput here: https://dune.com/queries/4407620 +{% set blockchain_var = "{{blockchain}}" %} +{% set contract_address_var = "{{contract_address}}" %} +{{ paraswap_all_entities() }} +select + entity, blockchain, contract_address, block_time, tx_hash +from entities +where blockchain = '{{blockchain_var}}' and contract_address = {{contract_address_var}} +order by block_time desc, tx_hash diff --git a/dbt_subprojects/dex/models/_projects/paraswap/ethereum/_schema.yml b/dbt_subprojects/dex/models/_projects/paraswap/ethereum/_schema.yml index 312e8c69a76..c4b687e0ec5 100644 --- a/dbt_subprojects/dex/models/_projects/paraswap/ethereum/_schema.yml +++ b/dbt_subprojects/dex/models/_projects/paraswap/ethereum/_schema.yml @@ -234,6 +234,64 @@ models: - *trace_address - *evt_index + + - name: paraswap_delta_v1_ethereum_trades + description: "Paraswap Delta V1 trades" + tests: + - dbt_utils.unique_combination_of_columns: + combination_of_columns: + - method + - call_tx_hash + - call_trace_address + columns: + - name: method + description: "Call Method" + - name: call_trace_address + description: "Call Trace Address" + - name: call_block_number + description: "Call Block Number" + - name: call_block_time + description: "Call Block Time" + - name: call_tx_hash + description: "Call Transaction Hash" + - name: fee_amount + description: "Fee Amount" + - name: order_with_sig + description: "Order with Signature" + - name: calldata_to_execute + description: "Calldata to Execute" + - name: order + description: "Order" + - name: signature + description: "Signature" + - name: order_owner + description: "Order Owner" + - name: src_token + description: "Source Token" + - name: dest_token + description: "Destination Token" + - name: src_amount + description: "Source Amount" + - name: dest_amount + description: "Destination Amount" + - name: src_token_for_joining + description: "Source Token for Joining" + - name: dest_token_for_joining + description: "Destination Token for Joining" + - name: fee_token + description: "Fee Token" + - name: src_token_price_usd + description: "Source Token Price (USD)" + - name: dest_token_price_usd + description: "Destination Token Price (USD)" + - name: gas_fee_usd + description: "Gas Fee (USD)" + - name: src_token_order_usd + description: "Source Token Order Value (USD)" + - name: dest_token_order_usd + description: "Destination Token Order Value (USD)" + - name: contract_address + description: "Contract Address" - name: paraswap_v6_ethereum_trades_decoded description: "Paraswap V6 trades decoded" diff --git a/dbt_subprojects/dex/models/_projects/paraswap/ethereum/paraswap_delta_v1_ethereum_trades.sql b/dbt_subprojects/dex/models/_projects/paraswap/ethereum/paraswap_delta_v1_ethereum_trades.sql new file mode 100644 index 00000000000..c84f0cb2a53 --- /dev/null +++ b/dbt_subprojects/dex/models/_projects/paraswap/ethereum/paraswap_delta_v1_ethereum_trades.sql @@ -0,0 +1,172 @@ +-- ref dbt_subprojects/dex/models/_projects/paraswap/ethereum/paraswap_v6_ethereum_trades.sql +-- ref dbt_subprojects/dex/models/_projects/paraswap/ethereum/paraswap_v6_ethereum_trades_decoded.sql +{{ config( + schema = 'paraswap_delta_v1_ethereum', + alias = 'trades', + + partition_by = ['block_month'], + materialized = 'incremental', + file_format = 'delta', + incremental_strategy = 'merge', + incremental_predicates = [incremental_predicate('DBT_INTERNAL_DEST.call_block_time')], + unique_key = ['method', 'call_tx_hash', 'call_trace_address'], + post_hook='{{ expose_spells(blockchains = \'["ethereum"]\', + spell_type = "project", + spell_name = "paraswap_delta_v1", + contributors = \'["eptighte"]\') }}' + ) +}} + +{% set project_start_date = '2024-05-01' %} + +with +{{ delta_settle_swap('ethereum') }} +,{{ delta_safe_settle_batch_swap('ethereum') }} +select + 'delta_v1_settle_swap_model' as method, + call_trace_address, + call_block_number, + call_block_time, + call_tx_hash, + -- parsed_order_data, + feeAmount as fee_amount, + orderWithSig as order_with_sig, + calldataToExecute as calldata_to_execute, + "order", + signature, + order_owner, + src_token, + dest_token, + src_amount, + dest_amount, + src_token_for_joining, + dest_token_for_joining, + fee_token, + src_token_price_usd, + dest_token_price_usd, + gas_fee_usd, + src_token_order_usd, + dest_token_order_usd, + contract_address + from delta_v1_settle_swap_model +union all +select + 'delta_v1_safe_settle_batch_swap_model' as method, + call_trace_address, + call_block_number, + call_block_time, + call_tx_hash, + -- parsed_order_data, + feeAmount as fee_amount, + orderWithSig as order_with_sig, + calldataToExecute as calldata_to_execute, + "order", + signature, + order_owner, + src_token, + dest_token, + src_amount, + dest_amount, + src_token_for_joining, + dest_token_for_joining, + fee_token, + src_token_price_usd, + dest_token_price_usd, + gas_fee_usd, + src_token_order_usd, + dest_token_order_usd, + contract_address +from delta_v1_safe_settle_batch_swap_model + +-- with dexs AS ( +-- SELECT +-- blockTime AS block_time, +-- blockNumber AS block_number, +-- from_hex(beneficiary) AS taker, +-- null AS maker, -- TODO: can parse from traces +-- receivedAmount AS token_bought_amount_raw, +-- fromAmount AS token_sold_amount_raw, +-- CAST(NULL AS double) AS amount_usd, +-- method, +-- CASE +-- WHEN from_hex(destToken) = 0xeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeee +-- THEN 0xc02aaa39b223fe8d0a0e5c4f27ead9083c756cc2 -- WETH +-- ELSE from_hex(destToken) +-- END AS token_bought_address, +-- CASE +-- WHEN from_hex(srcToken) = 0xeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeee +-- THEN 0xc02aaa39b223fe8d0a0e5c4f27ead9083c756cc2 -- WETH +-- ELSE from_hex(srcToken) +-- END AS token_sold_address, +-- projectContractAddress as project_contract_address, +-- txHash AS tx_hash, +-- callTraceAddress AS trace_address, +-- CAST(-1 as integer) AS evt_index +-- FROM {{ ref('paraswap_v6_ethereum_trades_decoded') }} +-- {% if is_incremental() %} +-- WHERE {{ incremental_predicate('blockTime') }} +-- {% endif %} +-- ) +-- SELECT 'ethereum' AS blockchain, +-- 'paraswap' AS project, +-- '6' AS version, +-- cast(date_trunc('day', d.block_time) as date) as block_date, +-- cast(date_trunc('month', d.block_time) as date) as block_month, +-- d.block_time, +-- method, +-- e1.symbol AS token_bought_symbol, +-- e2.symbol AS token_sold_symbol, +-- CASE +-- WHEN lower(e1.symbol) > lower(e2.symbol) THEN concat(e2.symbol, '-', e1.symbol) +-- ELSE concat(e1.symbol, '-', e2.symbol) +-- END AS token_pair, +-- d.token_bought_amount_raw / power(10, e1.decimals) AS token_bought_amount, +-- d.token_sold_amount_raw / power(10, e2.decimals) AS token_sold_amount, +-- d.token_bought_amount_raw, +-- d.token_sold_amount_raw, +-- coalesce( +-- d.amount_usd +-- ,(d.token_bought_amount_raw / power(10, p1.decimals)) * p1.price +-- ,(d.token_sold_amount_raw / power(10, p2.decimals)) * p2.price +-- ) AS amount_usd, +-- d.token_bought_address, +-- d.token_sold_address, +-- coalesce(d.taker, tx."from") AS taker, +-- coalesce(d.maker, tx."from") as maker, +-- d.project_contract_address, +-- d.tx_hash, +-- tx."from" AS tx_from, +-- tx.to AS tx_to, +-- d.trace_address, +-- d.evt_index +-- FROM dexs d +-- INNER JOIN {{ source('ethereum', 'transactions') }} tx ON d.tx_hash = tx.hash +-- AND d.block_number = tx.block_number +-- {% if not is_incremental() %} +-- AND tx.block_time >= TIMESTAMP '{{project_start_date}}' +-- {% endif %} +-- {% if is_incremental() %} +-- AND {{ incremental_predicate('tx.block_time') }} +-- {% endif %} +-- LEFT JOIN {{ source('tokens', 'erc20') }} e1 ON e1.contract_address = d.token_bought_address +-- AND e1.blockchain = 'ethereum' +-- LEFT JOIN {{ source('tokens', 'erc20') }} e2 ON e2.contract_address = d.token_sold_address +-- AND e2.blockchain = 'ethereum' +-- LEFT JOIN {{ source('prices', 'usd') }} p1 ON p1.minute = date_trunc('minute', d.block_time) +-- AND p1.contract_address = d.token_bought_address +-- AND p1.blockchain = 'ethereum' +-- {% if not is_incremental() %} +-- AND p1.minute >= TIMESTAMP '{{project_start_date}}' +-- {% endif %} +-- {% if is_incremental() %} +-- AND {{ incremental_predicate('p1.minute') }} +-- {% endif %} +-- LEFT JOIN {{ source('prices', 'usd') }} p2 ON p2.minute = date_trunc('minute', d.block_time) +-- AND p2.contract_address = d.token_sold_address +-- AND p2.blockchain = 'ethereum' +-- {% if not is_incremental() %} +-- AND p2.minute >= TIMESTAMP '{{project_start_date}}' +-- {% endif %} +-- {% if is_incremental() %} +-- AND {{ incremental_predicate('p2.minute') }} +-- {% endif %} diff --git a/dbt_subprojects/dex/target/compiled/dex/models/_projects/paraswap/all-entities-aggregated.sql b/dbt_subprojects/dex/target/compiled/dex/models/_projects/paraswap/all-entities-aggregated.sql new file mode 100644 index 00000000000..1f1ea5dfa18 --- /dev/null +++ b/dbt_subprojects/dex/target/compiled/dex/models/_projects/paraswap/all-entities-aggregated.sql @@ -0,0 +1,118 @@ +-- NB: this is a generated query, do not edit it directly, instead edit the template and re-generate the query +-- hydrate the generated ouput here: https://dune.com/queries/4403433 + + + + + +with entities as ( + + select 'delta-v1-single' as entity, 'ethereum' as blockchain, contract_address as contract_address, call_block_time as block_time, call_tx_hash as tx_hash, 0 as usd_value from paraswapdelta_ethereum.ParaswapDeltav1_call_settleSwap + where + (call_block_time BETWEEN timestamp '{{date_from}}' AND timestamp '{{date_to}}') + + union all + + select 'delta-v1-batch' as entity, 'ethereum' as blockchain, contract_address as contract_address, call_block_time as block_time, call_tx_hash as tx_hash, 0 as usd_value from paraswapdelta_ethereum.ParaswapDeltav1_call_safeSettleBatchSwap + where + (call_block_time BETWEEN timestamp '{{date_from}}' AND timestamp '{{date_to}}') + + union all + + select 'delta-v2' as entity, 'ethereum' as blockchain, contract_address as contract_address, evt_block_time as block_time, evt_tx_hash as tx_hash, 0 as usd_value from paraswapdelta_ethereum.ParaswapDeltav2_evt_OrderSettled + where + (evt_block_time BETWEEN timestamp '{{date_from}}' AND timestamp '{{date_to}}') + + union all + + select 'delta-v2' as entity, 'base' as blockchain, contract_address as contract_address, evt_block_time as block_time, evt_tx_hash as tx_hash, 0 as usd_value from paraswapdelta_base.ParaswapDeltav2_evt_OrderSettled + where + (evt_block_time BETWEEN timestamp '{{date_from}}' AND timestamp '{{date_to}}') + + AND evt_tx_from <> 0xace5ae3de4baffc4a45028659c5ee330764e4f53 + + union all + + select 'augustus' as entity, 'ethereum' as blockchain, project_contract_address as contract_address, block_time as block_time, tx_hash as tx_hash, amount_usd as usd_value from dex_aggregator.trades + where + (block_time BETWEEN timestamp '{{date_from}}' AND timestamp '{{date_to}}') + + AND project='paraswap' and blockchain='ethereum' + + union all + + select 'augustus' as entity, 'polygon' as blockchain, project_contract_address as contract_address, block_time as block_time, tx_hash as tx_hash, amount_usd as usd_value from dex_aggregator.trades + where + (block_time BETWEEN timestamp '{{date_from}}' AND timestamp '{{date_to}}') + + AND project='paraswap' and blockchain='polygon' + + union all + + select 'augustus' as entity, 'bnb' as blockchain, project_contract_address as contract_address, block_time as block_time, tx_hash as tx_hash, amount_usd as usd_value from dex_aggregator.trades + where + (block_time BETWEEN timestamp '{{date_from}}' AND timestamp '{{date_to}}') + + AND project='paraswap' and blockchain='bnb' + + union all + + select 'augustus' as entity, 'arbitrum' as blockchain, project_contract_address as contract_address, block_time as block_time, tx_hash as tx_hash, amount_usd as usd_value from dex_aggregator.trades + where + (block_time BETWEEN timestamp '{{date_from}}' AND timestamp '{{date_to}}') + + AND project='paraswap' and blockchain='arbitrum' + + union all + + select 'augustus' as entity, 'avalanche_c' as blockchain, project_contract_address as contract_address, block_time as block_time, tx_hash as tx_hash, amount_usd as usd_value from dex_aggregator.trades + where + (block_time BETWEEN timestamp '{{date_from}}' AND timestamp '{{date_to}}') + + AND project='paraswap' and blockchain='avalanche_c' + + union all + + select 'augustus' as entity, 'fantom' as blockchain, project_contract_address as contract_address, block_time as block_time, tx_hash as tx_hash, amount_usd as usd_value from dex_aggregator.trades + where + (block_time BETWEEN timestamp '{{date_from}}' AND timestamp '{{date_to}}') + + AND project='paraswap' and blockchain='fantom' + + union all + + select 'augustus' as entity, 'optimism' as blockchain, project_contract_address as contract_address, block_time as block_time, tx_hash as tx_hash, amount_usd as usd_value from dex_aggregator.trades + where + (block_time BETWEEN timestamp '{{date_from}}' AND timestamp '{{date_to}}') + + AND project='paraswap' and blockchain='optimism' + + union all + + select 'augustus' as entity, 'base' as blockchain, project_contract_address as contract_address, block_time as block_time, tx_hash as tx_hash, amount_usd as usd_value from dex_aggregator.trades + where + (block_time BETWEEN timestamp '{{date_from}}' AND timestamp '{{date_to}}') + + AND project='paraswap' and blockchain='base' + + + +) + +,ordered_entities as ( + select + entity, blockchain, contract_address, block_time, tx_hash, usd_value + from entities + order by block_time, tx_hash +) +select + blockchain, + entity, + contract_address, + count(*) as qty, + sum(usd_value) as usd_volume, + -- a rubbish but tolerable way to get the checksum of the txhash. Is consistent with internal counterparty query though + sum(varbinary_to_decimal(from_hex(substring(to_hex(tx_hash),1,0+8)))) as txhash_checksum +from ordered_entities +group by 1,2,3 +order by qty desc \ No newline at end of file diff --git a/dbt_subprojects/dex/target/compiled/dex/models/_projects/paraswap/all-entities-details.sql b/dbt_subprojects/dex/target/compiled/dex/models/_projects/paraswap/all-entities-details.sql new file mode 100644 index 00000000000..b701b9fa2f5 --- /dev/null +++ b/dbt_subprojects/dex/target/compiled/dex/models/_projects/paraswap/all-entities-details.sql @@ -0,0 +1,108 @@ +-- NB: this is a generated query, do not edit it directly, instead edit the template and re-generate the query +-- hydrate the generated ouput here: https://dune.com/queries/4407620 + + + + + + + +with entities as ( + + select 'delta-v1-single' as entity, 'ethereum' as blockchain, contract_address as contract_address, call_block_time as block_time, call_tx_hash as tx_hash, 0 as usd_value from paraswapdelta_ethereum.ParaswapDeltav1_call_settleSwap + where + (call_block_time BETWEEN timestamp '{{date_from}}' AND timestamp '{{date_to}}') + + union all + + select 'delta-v1-batch' as entity, 'ethereum' as blockchain, contract_address as contract_address, call_block_time as block_time, call_tx_hash as tx_hash, 0 as usd_value from paraswapdelta_ethereum.ParaswapDeltav1_call_safeSettleBatchSwap + where + (call_block_time BETWEEN timestamp '{{date_from}}' AND timestamp '{{date_to}}') + + union all + + select 'delta-v2' as entity, 'ethereum' as blockchain, contract_address as contract_address, evt_block_time as block_time, evt_tx_hash as tx_hash, 0 as usd_value from paraswapdelta_ethereum.ParaswapDeltav2_evt_OrderSettled + where + (evt_block_time BETWEEN timestamp '{{date_from}}' AND timestamp '{{date_to}}') + + union all + + select 'delta-v2' as entity, 'base' as blockchain, contract_address as contract_address, evt_block_time as block_time, evt_tx_hash as tx_hash, 0 as usd_value from paraswapdelta_base.ParaswapDeltav2_evt_OrderSettled + where + (evt_block_time BETWEEN timestamp '{{date_from}}' AND timestamp '{{date_to}}') + + AND evt_tx_from <> 0xace5ae3de4baffc4a45028659c5ee330764e4f53 + + union all + + select 'augustus' as entity, 'ethereum' as blockchain, project_contract_address as contract_address, block_time as block_time, tx_hash as tx_hash, amount_usd as usd_value from dex_aggregator.trades + where + (block_time BETWEEN timestamp '{{date_from}}' AND timestamp '{{date_to}}') + + AND project='paraswap' and blockchain='ethereum' + + union all + + select 'augustus' as entity, 'polygon' as blockchain, project_contract_address as contract_address, block_time as block_time, tx_hash as tx_hash, amount_usd as usd_value from dex_aggregator.trades + where + (block_time BETWEEN timestamp '{{date_from}}' AND timestamp '{{date_to}}') + + AND project='paraswap' and blockchain='polygon' + + union all + + select 'augustus' as entity, 'bnb' as blockchain, project_contract_address as contract_address, block_time as block_time, tx_hash as tx_hash, amount_usd as usd_value from dex_aggregator.trades + where + (block_time BETWEEN timestamp '{{date_from}}' AND timestamp '{{date_to}}') + + AND project='paraswap' and blockchain='bnb' + + union all + + select 'augustus' as entity, 'arbitrum' as blockchain, project_contract_address as contract_address, block_time as block_time, tx_hash as tx_hash, amount_usd as usd_value from dex_aggregator.trades + where + (block_time BETWEEN timestamp '{{date_from}}' AND timestamp '{{date_to}}') + + AND project='paraswap' and blockchain='arbitrum' + + union all + + select 'augustus' as entity, 'avalanche_c' as blockchain, project_contract_address as contract_address, block_time as block_time, tx_hash as tx_hash, amount_usd as usd_value from dex_aggregator.trades + where + (block_time BETWEEN timestamp '{{date_from}}' AND timestamp '{{date_to}}') + + AND project='paraswap' and blockchain='avalanche_c' + + union all + + select 'augustus' as entity, 'fantom' as blockchain, project_contract_address as contract_address, block_time as block_time, tx_hash as tx_hash, amount_usd as usd_value from dex_aggregator.trades + where + (block_time BETWEEN timestamp '{{date_from}}' AND timestamp '{{date_to}}') + + AND project='paraswap' and blockchain='fantom' + + union all + + select 'augustus' as entity, 'optimism' as blockchain, project_contract_address as contract_address, block_time as block_time, tx_hash as tx_hash, amount_usd as usd_value from dex_aggregator.trades + where + (block_time BETWEEN timestamp '{{date_from}}' AND timestamp '{{date_to}}') + + AND project='paraswap' and blockchain='optimism' + + union all + + select 'augustus' as entity, 'base' as blockchain, project_contract_address as contract_address, block_time as block_time, tx_hash as tx_hash, amount_usd as usd_value from dex_aggregator.trades + where + (block_time BETWEEN timestamp '{{date_from}}' AND timestamp '{{date_to}}') + + AND project='paraswap' and blockchain='base' + + + +) + +select + entity, blockchain, contract_address, block_time, tx_hash +from entities +where blockchain = '{{blockchain}}' and contract_address = {{contract_address}} +order by block_time desc, tx_hash \ No newline at end of file diff --git a/dbt_subprojects/dex/target/compiled/dex/models/_projects/paraswap/ethereum/paraswap_delta_v1_ethereum_trades.sql b/dbt_subprojects/dex/target/compiled/dex/models/_projects/paraswap/ethereum/paraswap_delta_v1_ethereum_trades.sql new file mode 100644 index 00000000000..2cde3dfccc7 --- /dev/null +++ b/dbt_subprojects/dex/target/compiled/dex/models/_projects/paraswap/ethereum/paraswap_delta_v1_ethereum_trades.sql @@ -0,0 +1,323 @@ +-- ref dbt_subprojects/dex/models/_projects/paraswap/ethereum/paraswap_v6_ethereum_trades.sql +-- ref dbt_subprojects/dex/models/_projects/paraswap/ethereum/paraswap_v6_ethereum_trades_decoded.sql + + + + +with + +settle_swap_withParsedOrderData AS ( + SELECT + call_trace_address, + call_block_time, + call_block_number, + call_tx_hash, + JSON_EXTRACT(data, '$.orderData') AS parsed_order_data, + contract_address + FROM + paraswapdelta_ethereum.ParaswapDeltav1_call_settleSwap + where call_success = true + +), +settle_swap_parsedOrderWithSig AS ( + SELECT + JSON_EXTRACT_SCALAR(JSON_PARSE(TRY_CAST(parsed_order_data AS VARCHAR)), '$.feeAmount') AS feeAmount, + JSON_EXTRACT(JSON_PARSE(TRY_CAST(parsed_order_data AS VARCHAR)), '$.orderWithSig') AS orderWithSig, + JSON_EXTRACT(JSON_PARSE(TRY_CAST(parsed_order_data AS VARCHAR)), '$.calldataToExecute') AS calldataToExecute, + * + FROM + settle_swap_withParsedOrderData +), +settle_swap_unparsedOrders AS ( + SELECT + JSON_EXTRACT(JSON_PARSE(TRY_CAST(orderWithSig AS VARCHAR)), '$.order') AS "order", + JSON_EXTRACT(JSON_PARSE(TRY_CAST(orderWithSig AS VARCHAR)), '$.signature') AS signature, + * + FROM settle_swap_parsedOrderWithSig +), +settle_swap_parsedOrders AS ( + SELECT + from_hex(JSON_EXTRACT_SCALAR(JSON_PARSE(TRY_CAST("order" AS VARCHAR)), '$.owner')) AS "order_owner", + FROM_HEX(JSON_EXTRACT_SCALAR(JSON_PARSE(TRY_CAST("order" AS VARCHAR)), '$.srcToken')) AS "src_token", + FROM_HEX(JSON_EXTRACT_SCALAR(JSON_PARSE(TRY_CAST("order" AS VARCHAR)), '$.destToken')) AS "dest_token", + JSON_EXTRACT_SCALAR(JSON_PARSE(TRY_CAST("order" AS VARCHAR)), '$.srcAmount') AS "src_amount", + JSON_EXTRACT_SCALAR(JSON_PARSE(TRY_CAST("order" AS VARCHAR)), '$.destAmount') AS "dest_amount", + JSON_EXTRACT_SCALAR(JSON_PARSE(TRY_CAST("order" AS VARCHAR)), '$.permit') AS "permit", + * + FROM settle_swap_unparsedOrders +), +settle_swap_withUSDs AS ( + SELECT + CASE + WHEN dest_token = 0xeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeee THEN 0xc02aaa39b223fe8d0a0e5c4f27ead9083c756cc2 + ELSE dest_token + END AS dest_token_for_joining, + CASE + WHEN src_token = 0xeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeee THEN 0xc02aaa39b223fe8d0a0e5c4f27ead9083c756cc2 + ELSE src_token + END AS src_token_for_joining, + * + FROM settle_swap_parsedOrders +), delta_v1_settle_swap_model as ( +SELECT + w.*, + w.dest_token AS fee_token, + CAST(s.price AS DECIMAL(38,18)) AS src_token_price_usd, + CAST(d.price AS DECIMAL(38,18)) AS dest_token_price_usd, + COALESCE( + d.price * CAST (w.feeAmount AS uint256) / POWER(10, d.decimals), + -- src cost + + (s.price * CAST (w.src_amount AS uint256) / POWER(10, s.decimals)) + * CAST (w.feeAmount AS uint256) / CAST (w.dest_amount AS uint256), + 0 + + ) AS gas_fee_usd, + s.price * CAST (w.src_amount AS uint256) / POWER(10, s.decimals) AS src_token_order_usd, + d.price * CAST (w.dest_amount AS uint256) / POWER(10, d.decimals) AS dest_token_order_usd + +FROM settle_swap_withUSDs w +LEFT JOIN prices.usd d + ON d.blockchain = 'ethereum' + AND d.minute > TIMESTAMP '2024-06-01' + + AND d.contract_address = w.dest_token_for_joining + AND d.minute = DATE_TRUNC('minute', w.call_block_time) +LEFT JOIN prices.usd s + ON s.blockchain = 'ethereum' + AND s.minute > TIMESTAMP '2024-06-01' + + AND s.contract_address = w.src_token_for_joining + AND s.minute = DATE_TRUNC('minute', w.call_block_time) +) + +, +safe_settle_batch_swap_ExpandedOrders AS ( + SELECT + call_trace_address, + call_block_time, + call_block_number, + call_tx_hash, + output_successfulOrders, + JSON_EXTRACT(data, '$.ordersData') AS parsed_orders, + contract_address + FROM paraswapdelta_ethereum.ParaswapDeltav1_call_safeSettleBatchSwap + where call_success = true + +), safe_settle_batch_swap_parsedOrderItems AS ( + SELECT + index, + JSON_ARRAY_GET(parsed_orders, index) AS parsed_order_data, + * + FROM safe_settle_batch_swap_ExpandedOrders + CROSS JOIN UNNEST(SEQUENCE(0, CARDINALITY(output_successfulOrders) - 1)) AS t(index) + WHERE + output_successfulOrders[index + 1] +), safe_settle_batch_swap_parsedOrdersWithSig AS ( + SELECT + JSON_EXTRACT_SCALAR(parsed_order_data, '$.feeAmount') AS feeAmount, + JSON_EXTRACT(parsed_order_data, '$.orderWithSig') AS orderWithSig, + JSON_EXTRACT(parsed_order_data, '$.calldataToExecute') AS calldataToExecute, + * + FROM safe_settle_batch_swap_parsedOrderItems +), safe_settle_batch_swap_unparsedOrders AS ( + SELECT + JSON_EXTRACT(JSON_PARSE(TRY_CAST(orderWithSig AS VARCHAR)), '$.order') AS "order", + JSON_EXTRACT(JSON_PARSE(TRY_CAST(orderWithSig AS VARCHAR)), '$.signature') AS signature, + * + FROM safe_settle_batch_swap_parsedOrdersWithSig +), safe_settle_batch_swap_parsedOrders AS ( + SELECT + from_hex(JSON_EXTRACT_SCALAR(JSON_PARSE(TRY_CAST("order" AS VARCHAR)), '$.owner')) AS "order_owner", + FROM_HEX(JSON_EXTRACT_SCALAR(JSON_PARSE(TRY_CAST("order" AS VARCHAR)), '$.srcToken')) AS "src_token", + FROM_HEX(JSON_EXTRACT_SCALAR(JSON_PARSE(TRY_CAST("order" AS VARCHAR)), '$.destToken')) AS "dest_token", + JSON_EXTRACT_SCALAR(JSON_PARSE(TRY_CAST("order" AS VARCHAR)), '$.srcAmount') AS "src_amount", + JSON_EXTRACT_SCALAR(JSON_PARSE(TRY_CAST("order" AS VARCHAR)), '$.destAmount') AS "dest_amount", + * + FROM safe_settle_batch_swap_unparsedOrders +), safe_settle_batch_swap_withUSDs AS ( + SELECT + CASE + WHEN dest_token = 0xeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeee THEN 0xc02aaa39b223fe8d0a0e5c4f27ead9083c756cc2 + ELSE dest_token + END AS dest_token_for_joining, + CASE + WHEN src_token = 0xeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeee THEN 0xc02aaa39b223fe8d0a0e5c4f27ead9083c756cc2 + ELSE src_token + END AS src_token_for_joining, + * + FROM safe_settle_batch_swap_parsedOrders +), delta_v1_safe_settle_batch_swap_model as ( +SELECT + w.*, + w.dest_token AS fee_token, + CAST(s.price AS DECIMAL(38,18)) AS src_token_price_usd, + CAST(d.price AS DECIMAL(38,18)) AS dest_token_price_usd, + COALESCE( + d.price * CAST (w.feeAmount AS uint256) / POWER(10, d.decimals), + -- src cost + + (s.price * CAST (w.src_amount AS uint256) / POWER(10, s.decimals)) + * CAST (w.feeAmount AS uint256) / CAST (w.dest_amount AS uint256) + + ) AS gas_fee_usd, + s.price * CAST (w.src_amount AS uint256) / POWER(10, s.decimals) AS src_token_order_usd, + d.price * CAST (w.dest_amount AS uint256) / POWER(10, d.decimals) AS dest_token_order_usd + +FROM safe_settle_batch_swap_withUSDs w +LEFT JOIN prices.usd d + ON d.blockchain = 'ethereum' + AND d.minute > TIMESTAMP '2024-06-01' + + AND d.contract_address = w.dest_token_for_joining + AND d.minute = DATE_TRUNC('minute', w.call_block_time) +LEFT JOIN prices.usd s + ON s.blockchain = 'ethereum' + AND s.minute > TIMESTAMP '2024-06-01' + + AND s.contract_address = w.src_token_for_joining + AND s.minute = DATE_TRUNC('minute', w.call_block_time) +ORDER BY + CARDINALITY(w.output_successfulOrders) +) + +select + 'delta_v1_settle_swap_model' as method, + call_trace_address, + call_block_number, + call_block_time, + call_tx_hash, + -- parsed_order_data, + feeAmount as fee_amount, + orderWithSig as order_with_sig, + calldataToExecute as calldata_to_execute, + "order", + signature, + order_owner, + src_token, + dest_token, + src_amount, + dest_amount, + src_token_for_joining, + dest_token_for_joining, + fee_token, + src_token_price_usd, + dest_token_price_usd, + gas_fee_usd, + src_token_order_usd, + dest_token_order_usd, + contract_address + from delta_v1_settle_swap_model +union all +select + 'delta_v1_safe_settle_batch_swap_model' as method, + call_trace_address, + call_block_number, + call_block_time, + call_tx_hash, + -- parsed_order_data, + feeAmount as fee_amount, + orderWithSig as order_with_sig, + calldataToExecute as calldata_to_execute, + "order", + signature, + order_owner, + src_token, + dest_token, + src_amount, + dest_amount, + src_token_for_joining, + dest_token_for_joining, + fee_token, + src_token_price_usd, + dest_token_price_usd, + gas_fee_usd, + src_token_order_usd, + dest_token_order_usd, + contract_address +from delta_v1_safe_settle_batch_swap_model + +-- with dexs AS ( +-- SELECT +-- blockTime AS block_time, +-- blockNumber AS block_number, +-- from_hex(beneficiary) AS taker, +-- null AS maker, -- TODO: can parse from traces +-- receivedAmount AS token_bought_amount_raw, +-- fromAmount AS token_sold_amount_raw, +-- CAST(NULL AS double) AS amount_usd, +-- method, +-- CASE +-- WHEN from_hex(destToken) = 0xeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeee +-- THEN 0xc02aaa39b223fe8d0a0e5c4f27ead9083c756cc2 -- WETH +-- ELSE from_hex(destToken) +-- END AS token_bought_address, +-- CASE +-- WHEN from_hex(srcToken) = 0xeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeeee +-- THEN 0xc02aaa39b223fe8d0a0e5c4f27ead9083c756cc2 -- WETH +-- ELSE from_hex(srcToken) +-- END AS token_sold_address, +-- projectContractAddress as project_contract_address, +-- txHash AS tx_hash, +-- callTraceAddress AS trace_address, +-- CAST(-1 as integer) AS evt_index +-- FROM paraswap_v6_ethereum.trades_decoded +-- +-- ) +-- SELECT 'ethereum' AS blockchain, +-- 'paraswap' AS project, +-- '6' AS version, +-- cast(date_trunc('day', d.block_time) as date) as block_date, +-- cast(date_trunc('month', d.block_time) as date) as block_month, +-- d.block_time, +-- method, +-- e1.symbol AS token_bought_symbol, +-- e2.symbol AS token_sold_symbol, +-- CASE +-- WHEN lower(e1.symbol) > lower(e2.symbol) THEN concat(e2.symbol, '-', e1.symbol) +-- ELSE concat(e1.symbol, '-', e2.symbol) +-- END AS token_pair, +-- d.token_bought_amount_raw / power(10, e1.decimals) AS token_bought_amount, +-- d.token_sold_amount_raw / power(10, e2.decimals) AS token_sold_amount, +-- d.token_bought_amount_raw, +-- d.token_sold_amount_raw, +-- coalesce( +-- d.amount_usd +-- ,(d.token_bought_amount_raw / power(10, p1.decimals)) * p1.price +-- ,(d.token_sold_amount_raw / power(10, p2.decimals)) * p2.price +-- ) AS amount_usd, +-- d.token_bought_address, +-- d.token_sold_address, +-- coalesce(d.taker, tx."from") AS taker, +-- coalesce(d.maker, tx."from") as maker, +-- d.project_contract_address, +-- d.tx_hash, +-- tx."from" AS tx_from, +-- tx.to AS tx_to, +-- d.trace_address, +-- d.evt_index +-- FROM dexs d +-- INNER JOIN delta_prod.ethereum.transactions tx ON d.tx_hash = tx.hash +-- AND d.block_number = tx.block_number +-- +-- AND tx.block_time >= TIMESTAMP '2024-05-01' +-- +-- +-- LEFT JOIN delta_prod.tokens.erc20 e1 ON e1.contract_address = d.token_bought_address +-- AND e1.blockchain = 'ethereum' +-- LEFT JOIN delta_prod.tokens.erc20 e2 ON e2.contract_address = d.token_sold_address +-- AND e2.blockchain = 'ethereum' +-- LEFT JOIN delta_prod.prices.usd p1 ON p1.minute = date_trunc('minute', d.block_time) +-- AND p1.contract_address = d.token_bought_address +-- AND p1.blockchain = 'ethereum' +-- +-- AND p1.minute >= TIMESTAMP '2024-05-01' +-- +-- +-- LEFT JOIN delta_prod.prices.usd p2 ON p2.minute = date_trunc('minute', d.block_time) +-- AND p2.contract_address = d.token_sold_address +-- AND p2.blockchain = 'ethereum' +-- +-- AND p2.minute >= TIMESTAMP '2024-05-01' +-- +-- \ No newline at end of file