From 4182e6b418f7bc597fbc20e711007eb3cf4ad6b2 Mon Sep 17 00:00:00 2001 From: mattromano Date: Tue, 9 Jan 2024 16:25:22 -0800 Subject: [PATCH] add poly swaps --- .../hashflow/silver_dex__hashflow_pools.sql | 11 +- .../hashflow/silver_dex__hashflow_swaps.sql | 10 +- .../silver_dex__hashflow_v3_pools.sql | 55 +++++++-- .../silver_dex__hashflow_v3_swaps.sql | 104 +++++++++++++++++- .../silver_dex__hashflow_v3_swaps.yml | 5 +- .../dex/silver_dex__complete_dex_swaps.sql | 86 ++++++++------- .../dex/silver_dex__complete_dex_swaps.yml | 4 +- 7 files changed, 216 insertions(+), 59 deletions(-) diff --git a/models/silver/dex/hashflow/silver_dex__hashflow_pools.sql b/models/silver/dex/hashflow/silver_dex__hashflow_pools.sql index 049df5d..a281684 100644 --- a/models/silver/dex/hashflow/silver_dex__hashflow_pools.sql +++ b/models/silver/dex/hashflow/silver_dex__hashflow_pools.sql @@ -39,13 +39,16 @@ qualify(ROW_NUMBER() over(PARTITION BY to_address ORDER BY block_timestamp ASC)) = 1 ) - SELECT tx_hash, block_number, block_timestamp, deployer_address, - contract_address AS pool_address, + C.token_name as pool_name, + d.contract_address AS pool_address, _call_id, - _inserted_timestamp -FROM contract_deployments + d._inserted_timestamp +FROM + contract_deployments d + LEFT JOIN {{ ref('silver__contracts') }} C + ON pool_address = c.contract_address \ No newline at end of file diff --git a/models/silver/dex/hashflow/silver_dex__hashflow_swaps.sql b/models/silver/dex/hashflow/silver_dex__hashflow_swaps.sql index ce40e31..5c303cc 100644 --- a/models/silver/dex/hashflow/silver_dex__hashflow_swaps.sql +++ b/models/silver/dex/hashflow/silver_dex__hashflow_swaps.sql @@ -1,7 +1,7 @@ {{ config( materialized = 'incremental', incremental_strategy = 'delete+insert', - unique_key = 'block_number', + unique_key = "block_number", cluster_by = ['block_timestamp::DATE'], tags = ['curated','reorg'] ) }} @@ -9,7 +9,8 @@ WITH pools AS ( SELECT - pool_address + pool_address, + pool_name FROM {{ ref('silver_dex__hashflow_pools') }} ), @@ -23,6 +24,7 @@ router_swaps_base AS ( origin_to_address, l.event_index, l.contract_address, + p.pool_name, regexp_substr_all(SUBSTR(l.data, 3, len(l.data)), '.{64}') AS l_segmented_data, CONCAT( '0x', @@ -87,6 +89,7 @@ swaps_base AS ( origin_to_address, l.event_index, l.contract_address, + pool_name, regexp_substr_all(SUBSTR(l.data, 3, len(l.data)), '.{64}') AS l_segmented_data, CONCAT( '0x', @@ -151,6 +154,7 @@ FINAL AS ( origin_to_address, event_index, contract_address, + pool_name, origin_from_address AS sender, account_address AS tx_to, tokenIn AS token_in, @@ -173,6 +177,7 @@ FINAL AS ( origin_to_address, event_index, contract_address, + pool_name, origin_from_address AS sender, account_address AS tx_to, tokenIn AS token_in, @@ -195,6 +200,7 @@ SELECT origin_to_address, event_index, contract_address, + pool_name, sender, tx_to, CASE diff --git a/models/silver/dex/hashflow/silver_dex__hashflow_v3_pools.sql b/models/silver/dex/hashflow/silver_dex__hashflow_v3_pools.sql index 4c8f2dc..eae89b0 100644 --- a/models/silver/dex/hashflow/silver_dex__hashflow_v3_pools.sql +++ b/models/silver/dex/hashflow/silver_dex__hashflow_v3_pools.sql @@ -5,22 +5,28 @@ tags = ['curated'] ) }} -WITH contract_deployments AS ( +WITH logs_pull AS ( SELECT tx_hash, block_number, block_timestamp, - regexp_substr_all(SUBSTR(DATA, 3, len(DATA)), '.{64}') AS segmented_data, - origin_from_address AS deployer_address, - CONCAT('0x', SUBSTR(segmented_data [0] :: STRING, 25, 40)) AS pool_address, + DATA, + contract_address, + origin_from_address, _log_id, _inserted_timestamp FROM {{ ref('silver__logs') }} WHERE - contract_address = '0xde828fdc3f497f16416d1bb645261c7c6a62dab5' - AND topics [0] :: STRING = '0xdbd2a1ea6808362e6adbec4db4969cbc11e3b0b28fb6c74cb342defaaf1daada' + ( + contract_address = LOWER('0xdE828fdc3F497F16416D1bB645261C7C6a62DAb5') + AND topics [0] :: STRING = '0xdbd2a1ea6808362e6adbec4db4969cbc11e3b0b28fb6c74cb342defaaf1daada' + ) + OR + ( + tx_hash = '0xfaa849569efd415d8859217d2ec907ab531d932d625d8c9feeb48f4829b9fc34' + ) {% if is_incremental() %} AND _inserted_timestamp >= ( @@ -30,16 +36,51 @@ AND _inserted_timestamp >= ( {{ this }} ) {% endif %} +), +contract_deployments AS ( + SELECT + tx_hash, + block_number, + block_timestamp, + regexp_substr_all(SUBSTR(DATA, 3, len(DATA)), '.{64}') AS segmented_data, + origin_from_address AS deployer_address, + C.token_name AS pool_name, + CONCAT('0x', SUBSTR(segmented_data [0] :: STRING, 25, 40)) AS pool_address, + l._log_id, + l._inserted_timestamp + FROM + logs_pull l + LEFT JOIN {{ ref('silver__contracts') }} C + ON pool_address = c.contract_address + WHERE + l.contract_address = '0xde828fdc3f497f16416d1bb645261c7c6a62dab5' ) +SELECT + tx_hash, + block_number, + block_timestamp, + origin_from_address AS deployer_address, + 'HashflowRouter' AS pool_name, + contract_address AS pool_address, + _log_id, + _inserted_timestamp +FROM + logs_pull +WHERE + tx_hash = '0xfaa849569efd415d8859217d2ec907ab531d932d625d8c9feeb48f4829b9fc34' + AND + pool_address <> '0x0000000000000000000000000000000000001010' +UNION ALL SELECT tx_hash, block_number, block_timestamp, deployer_address, + pool_name, pool_address, _log_id, _inserted_timestamp FROM - contract_deployments qualify(ROW_NUMBER() over (PARTITION BY pool_address + contract_deployments qualify(ROW_NUMBER() over(PARTITION BY pool_address ORDER BY _inserted_timestamp DESC)) = 1 diff --git a/models/silver/dex/hashflow/silver_dex__hashflow_v3_swaps.sql b/models/silver/dex/hashflow/silver_dex__hashflow_v3_swaps.sql index 10287a1..1a5ac53 100644 --- a/models/silver/dex/hashflow/silver_dex__hashflow_v3_swaps.sql +++ b/models/silver/dex/hashflow/silver_dex__hashflow_v3_swaps.sql @@ -9,7 +9,8 @@ WITH pools AS ( SELECT - pool_address + pool_address, + pool_name FROM {{ ref('silver_dex__hashflow_v3_pools') }} ), @@ -24,6 +25,7 @@ swaps AS ( l.event_index, contract_address, regexp_substr_all(SUBSTR(DATA, 3, len(DATA)), '.{64}') AS segmented_data, + p.pool_name, CONCAT('0x', SUBSTR(segmented_data [0] :: STRING, 25, 40)) AS trader_address, CONCAT('0x', SUBSTR(segmented_data [1] :: STRING, 25, 40)) AS effective_trader_address, CONCAT( @@ -52,6 +54,75 @@ swaps AS ( WHERE l.topics [0] :: STRING = '0x34f57786fb01682fb4eec88d340387ef01a168fe345ea5b76f709d4e560c10eb' --Trade +{% if is_incremental() %} +AND _inserted_timestamp >= ( + SELECT + MAX(_inserted_timestamp) - INTERVAL '12 hours' + FROM + {{ this }} +) +{% endif %} +), +router_swaps AS ( + SELECT + l.block_number, + l.block_timestamp, + l.tx_hash, + l.origin_function_signature, + l.origin_from_address, + l.origin_to_address, + 'XChainTrade' AS event_name, + l.event_index, + contract_address, + regexp_substr_all(SUBSTR(DATA, 3, len(DATA)), '.{64}') AS segmented_data, + 'HashflowRouter' AS pool_name, + utils.udf_hex_to_int( + segmented_data [0] :: STRING + ) AS chain_id, + CASE + --ID 20 = Solana XChainTrade, address is decoded to Solana format + WHEN chain_id = '20' THEN utils.udf_hex_to_base58( + CONCAT( + '0x', + segmented_data [3] :: STRING + ) + ) + ELSE CONCAT('0x', SUBSTR(segmented_data [3] :: STRING, 27, 40)) + END AS tx_to, + --The trader wallet address that will swap with the contract. This can be a proxy contract + CONCAT('0x', SUBSTR(segmented_data [2] :: STRING, 25, 40)) AS trader_address, + --The wallet address of the actual trader + segmented_data [4] :: STRING AS txid, + CONCAT('0x', SUBSTR(segmented_data [5] :: STRING, 25, 40)) AS tokenIn, + segmented_data [6] :: STRING AS raw_token_out, + CASE + WHEN chain_id = '20' THEN utils.udf_hex_to_base58( + CONCAT( + '0x', + segmented_data [6] :: STRING + ) + ) + ELSE CONCAT('0x', SUBSTR(segmented_data [6] :: STRING, 27, 40)) + END AS tokenOut, + TRY_TO_NUMBER( + utils.udf_hex_to_int( + segmented_data [7] :: STRING + ) + ) AS amountIn, + TRY_TO_NUMBER( + utils.udf_hex_to_int( + segmented_data [8] :: STRING + ) + ) AS amountOut, + l._log_id, + l._inserted_timestamp + FROM + {{ ref('silver__logs') }} + l + WHERE + l.topics [0] :: STRING = '0x3f72b2a38919490277652bb34955c871b20e23068c243319c9fa5e27963d9e12' --Xchaintrade + AND origin_to_address = LOWER('0x55084eE0fEf03f14a305cd24286359A35D735151') --router + {% if is_incremental() %} AND _inserted_timestamp >= ( SELECT @@ -70,6 +141,7 @@ SELECT origin_to_address, event_index, contract_address, + pool_name, effective_trader_address AS sender, trader_address AS tx_to, txid, @@ -89,3 +161,33 @@ SELECT _inserted_timestamp FROM swaps +UNION ALL +SELECT + block_number, + block_timestamp, + tx_hash, + origin_function_signature, + origin_from_address, + origin_to_address, + event_index, + contract_address, + pool_name, + trader_address AS sender, + tx_to, + txid, + CASE + WHEN tokenIn = '0x0000000000000000000000000000000000000000' THEN '0x0d500b1d8e8ef31e21c99d1db9a6444d3adf1270' + ELSE tokenIn + END AS token_in, + CASE + WHEN tokenOut = '0x0000000000000000000000000000000000000000' THEN '0x0d500b1d8e8ef31e21c99d1db9a6444d3adf1270' + ELSE tokenOut + END AS token_out, + amountIn AS amount_in_unadj, + amountOut AS amount_out_unadj, + event_name, + 'hashflow-v3' AS platform, + _log_id, + _inserted_timestamp +FROM + router_swaps \ No newline at end of file diff --git a/models/silver/dex/hashflow/silver_dex__hashflow_v3_swaps.yml b/models/silver/dex/hashflow/silver_dex__hashflow_v3_swaps.yml index 2cf0d44..c3d3473 100644 --- a/models/silver/dex/hashflow/silver_dex__hashflow_v3_swaps.yml +++ b/models/silver/dex/hashflow/silver_dex__hashflow_v3_swaps.yml @@ -39,19 +39,16 @@ models: - name: TOKEN_OUT tests: - not_null - - dbt_expectations.expect_column_values_to_match_regex: - regex: 0[xX][0-9a-fA-F]+ - name: SENDER tests: - not_null: where: BLOCK_TIMESTAMP > '2021-08-01' - - dbt_expectations.expect_column_values_to_match_regex: - regex: 0[xX][0-9a-fA-F]+ - name: TX_TO tests: - not_null - dbt_expectations.expect_column_values_to_match_regex: regex: 0[xX][0-9a-fA-F]+ + where: EVENT_NAME <> 'XChainTrade' - name: PLATFORM tests: - dbt_expectations.expect_column_values_to_be_in_type_list: diff --git a/models/silver/dex/silver_dex__complete_dex_swaps.sql b/models/silver/dex/silver_dex__complete_dex_swaps.sql index e6b57b9..2f77246 100644 --- a/models/silver/dex/silver_dex__complete_dex_swaps.sql +++ b/models/silver/dex/silver_dex__complete_dex_swaps.sql @@ -498,29 +498,32 @@ hashflow_swaps AS ( 'v1' AS version, token_in, token_out, - CONCAT( - LEAST( - COALESCE( - symbol_in, - CONCAT(SUBSTRING(token_in, 1, 5), '...', SUBSTRING(token_in, 39, 42)) + CASE + WHEN pool_name IS NULL THEN CONCAT( + LEAST( + COALESCE( + symbol_in, + CONCAT(SUBSTRING(token_in, 1, 5), '...', SUBSTRING(token_in, 39, 42)) + ), + COALESCE( + symbol_out, + CONCAT(SUBSTRING(token_out, 1, 5), '...', SUBSTRING(token_out, 39, 42)) + ) ), - COALESCE( - symbol_out, - CONCAT(SUBSTRING(token_out, 1, 5), '...', SUBSTRING(token_out, 39, 42)) - ) - ), - '-', - GREATEST( - COALESCE( - symbol_in, - CONCAT(SUBSTRING(token_in, 1, 5), '...', SUBSTRING(token_in, 39, 42)) - ), - COALESCE( - symbol_out, - CONCAT(SUBSTRING(token_out, 1, 5), '...', SUBSTRING(token_out, 39, 42)) + '-', + GREATEST( + COALESCE( + symbol_in, + CONCAT(SUBSTRING(token_in, 1, 5), '...', SUBSTRING(token_in, 39, 42)) + ), + COALESCE( + symbol_out, + CONCAT(SUBSTRING(token_out, 1, 5), '...', SUBSTRING(token_out, 39, 42)) + ) ) ) - ) AS pool_name, + ELSE pool_name + END AS pool_name, _log_id, _inserted_timestamp FROM @@ -572,29 +575,32 @@ hashflow_v3_swaps AS ( 'v3' AS version, token_in, token_out, - CONCAT( - LEAST( - COALESCE( - symbol_in, - CONCAT(SUBSTRING(token_in, 1, 5), '...', SUBSTRING(token_in, 39, 42)) + CASE + WHEN pool_name IS NULL THEN CONCAT( + LEAST( + COALESCE( + symbol_in, + CONCAT(SUBSTRING(token_in, 1, 5), '...', SUBSTRING(token_in, 39, 42)) + ), + COALESCE( + symbol_out, + CONCAT(SUBSTRING(token_out, 1, 5), '...', SUBSTRING(token_out, 39, 42)) + ) ), - COALESCE( - symbol_out, - CONCAT(SUBSTRING(token_out, 1, 5), '...', SUBSTRING(token_out, 39, 42)) - ) - ), - '-', - GREATEST( - COALESCE( - symbol_in, - CONCAT(SUBSTRING(token_in, 1, 5), '...', SUBSTRING(token_in, 39, 42)) - ), - COALESCE( - symbol_out, - CONCAT(SUBSTRING(token_out, 1, 5), '...', SUBSTRING(token_out, 39, 42)) + '-', + GREATEST( + COALESCE( + symbol_in, + CONCAT(SUBSTRING(token_in, 1, 5), '...', SUBSTRING(token_in, 39, 42)) + ), + COALESCE( + symbol_out, + CONCAT(SUBSTRING(token_out, 1, 5), '...', SUBSTRING(token_out, 39, 42)) + ) ) ) - ) AS pool_name, + ELSE pool_name + END AS pool_name, _log_id, _inserted_timestamp FROM diff --git a/models/silver/dex/silver_dex__complete_dex_swaps.yml b/models/silver/dex/silver_dex__complete_dex_swaps.yml index 3a4dc88..1976abb 100644 --- a/models/silver/dex/silver_dex__complete_dex_swaps.yml +++ b/models/silver/dex/silver_dex__complete_dex_swaps.yml @@ -73,9 +73,10 @@ models: - name: TOKEN_OUT tests: - not_null: - where: PLATFORM <> 'uniswap-v3' + where: PLATFORM NOT IN ('uniswap-v3','curve') - dbt_expectations.expect_column_values_to_match_regex: regex: 0[xX][0-9a-fA-F]+ + where: EVENT_NAME <> 'XChainTrade' - name: SYMBOL_IN tests: - dbt_expectations.expect_column_values_to_be_in_type_list: @@ -99,6 +100,7 @@ models: - not_null - dbt_expectations.expect_column_values_to_match_regex: regex: 0[xX][0-9a-fA-F]+ + where: EVENT_NAME <> 'XChainTrade' enabled: False - name: PLATFORM tests: