diff --git a/models/gold/defi/defi__fact_swaps.sql b/models/gold/defi/defi__fact_swaps.sql index 56bc9a49..7edc7ade 100644 --- a/models/gold/defi/defi__fact_swaps.sql +++ b/models/gold/defi/defi__fact_swaps.sql @@ -382,6 +382,28 @@ FROM {% if is_incremental() %} WHERE modified_timestamp >= '{{ max_modified_timestamp }}' {% endif %} +UNION ALL +SELECT + block_timestamp, + block_id, + tx_id, + succeeded, + swapper, + swap_from_amount, + swap_from_mint, + swap_to_amount, + swap_to_mint, + program_id, + 'pancakeswap' as swap_program, + swap_index, + swaps_pancakeswap_id as fact_swaps_id, + inserted_timestamp, + modified_timestamp +FROM + {{ ref('silver__swaps_pancakeswap') }} +{% if is_incremental() %} +WHERE modified_timestamp >= '{{ max_modified_timestamp }}' +{% endif %} ) {% if not is_incremental() %} diff --git a/models/gold/defi/defi__fact_swaps.yml b/models/gold/defi/defi__fact_swaps.yml index ee16309f..ed75c2e8 100644 --- a/models/gold/defi/defi__fact_swaps.yml +++ b/models/gold/defi/defi__fact_swaps.yml @@ -26,7 +26,7 @@ models: - 'silver__swaps_intermediate_orca_whirlpool' - 'silver__swaps_intermediate_orca_token_swap' - 'silver__swaps_intermediate_meteora_bonding' - + - 'silver__swaps_pancakeswap' id_column: 'tx_id' columns: - name: BLOCK_TIMESTAMP diff --git a/models/silver/swaps/pancakeswap/silver__swaps_pancakeswap.sql b/models/silver/swaps/pancakeswap/silver__swaps_pancakeswap.sql new file mode 100644 index 00000000..9eb89677 --- /dev/null +++ b/models/silver/swaps/pancakeswap/silver__swaps_pancakeswap.sql @@ -0,0 +1,168 @@ +-- depends_on: {{ ref('silver__decoded_instructions_combined') }} + +{{ config( + materialized = 'incremental', + unique_key = "swaps_pancakeswap_id", + incremental_predicates = ["dynamic_range_predicate", "block_timestamp::date"], + merge_exclude_columns = ["inserted_timestamp"], + cluster_by = ['modified_timestamp::DATE'], + tags = ['scheduled_non_core','scheduled_non_core_hourly'], +) }} + +{% if execute %} + {% set base_query %} + CREATE OR REPLACE TEMPORARY TABLE silver.swaps_pancakeswap__intermediate_tmp AS + SELECT + block_timestamp, + block_id, + tx_id, + succeeded, + INDEX, + inner_index, + program_id, + event_type, + decoded_instruction, + _inserted_timestamp + FROM + {{ ref('silver__decoded_instructions_combined') }} + WHERE + program_id = 'HpNfyc2Saw7RKkQd8nEL4khUcuPhQ7WwY1B2qjx8jxFq' + AND event_type in ('swap','swap_v2') + AND succeeded + + {% if is_incremental() %} + AND _inserted_timestamp >= ( + SELECT + MAX(_inserted_timestamp) - INTERVAL '1 hour' + FROM + {{ this }} + ) + {% else %} + AND _inserted_timestamp::DATE >= '2025-08-05' + {% endif %} + {% endset %} + + {% do run_query(base_query) %} + {% set between_stmts = fsc_utils.dynamic_range_predicate( + "silver.swaps_pancakeswap__intermediate_tmp", + "block_timestamp::date" + ) %} +{% endif %} + +with base AS ( + SELECT + * + FROM + silver.swaps_pancakeswap__intermediate_tmp +), +decoded AS ( + SELECT + block_timestamp, + block_id, + tx_id, + INDEX, + inner_index, + COALESCE( + LEAD(inner_index) OVER ( + PARTITION BY tx_id, index + ORDER BY inner_index + ) - 1, + 999999 + ) AS inner_index_end, + program_id, + silver.udf_get_account_pubkey_by_name('payer', decoded_instruction:accounts) AS swapper, + silver.udf_get_account_pubkey_by_name('input_token_account', decoded_instruction:accounts) AS source_token_account, -- 1 txfer source + NULL AS source_mint, + NULL AS destination_mint, + silver.udf_get_account_pubkey_by_name('output_token_account', decoded_instruction:accounts) AS destination_token_account, -- 2 txfer dest + silver.udf_get_account_pubkey_by_name('output_vault', decoded_instruction:accounts) AS program_destination_token_account, -- 2 source + silver.udf_get_account_pubkey_by_name('input_vault', decoded_instruction:accounts) AS program_source_token_account, -- 1 dest + _inserted_timestamp + FROM + base +) +, +transfers AS ( + SELECT + A.*, + COALESCE(SPLIT_PART(INDEX :: text, '.', 1) :: INT, INDEX :: INT) AS index_1, + NULLIF(SPLIT_PART(INDEX :: text, '.', 2), '') :: INT AS inner_index_1 + FROM + {{ ref('silver__transfers') }} A + INNER JOIN ( + SELECT + DISTINCT tx_id, + block_timestamp::DATE AS block_date + FROM + decoded + ) d + ON d.block_date = A.block_timestamp::DATE + AND d.tx_id = A.tx_id + WHERE + A.succeeded + and {{ between_stmts }} +), +pre_final AS ( + SELECT + A.block_id, + A.block_timestamp, + A.program_id, + A.tx_id, + A.index, + A.inner_index, + A.inner_index_end, + C.succeeded, + A.swapper, + b.amount AS swap_from_amount, + b.mint AS swap_from_mint, + C.amount AS swap_to_amount, + C.mint AS swap_to_mint, + A._inserted_timestamp + FROM + decoded A + LEFT JOIN transfers b + ON A.tx_id = b.tx_id + AND A.source_token_account = b.source_token_account + AND A.program_source_token_account = b.dest_token_account + AND A.index = b.index_1 + AND ( + (b.inner_index_1 BETWEEN A.inner_index AND A.inner_index_end) + OR A.inner_index IS NULL + ) + LEFT JOIN transfers C + ON A.tx_id = C.tx_id + AND A.destination_token_account = C.dest_token_account + AND A.program_destination_token_account = C.source_token_account + AND A.index = C.index_1 + AND ( + (C.inner_index_1 BETWEEN A.inner_index AND A.inner_index_end) + OR A.inner_index IS NULL + ) + QUALIFY ROW_NUMBER() over (PARTITION BY A.tx_id, A.index, A.inner_INDEX ORDER BY inner_index) = 1 +) +SELECT + block_id, + block_timestamp, + program_id, + tx_id, + succeeded, + ROW_NUMBER() over ( + PARTITION BY tx_id + ORDER BY + INDEX, + inner_index + ) AS swap_index, + index, + inner_index, + swapper, + swap_from_amount, + swap_from_mint, + swap_to_amount, + swap_to_mint, + _inserted_timestamp, + {{ dbt_utils.generate_surrogate_key(['tx_id','index','inner_index']) }} AS swaps_pancakeswap_id, + SYSDATE() AS inserted_timestamp, + SYSDATE() AS modified_timestamp, + '{{ invocation_id }}' AS _invocation_id +FROM + pre_final \ No newline at end of file diff --git a/models/silver/swaps/pancakeswap/silver__swaps_pancakeswap.yml b/models/silver/swaps/pancakeswap/silver__swaps_pancakeswap.yml new file mode 100644 index 00000000..d2e43a0c --- /dev/null +++ b/models/silver/swaps/pancakeswap/silver__swaps_pancakeswap.yml @@ -0,0 +1,84 @@ +version: 2 +models: + - name: silver__swaps_pancakeswap + tests: + - dbt_utils.unique_combination_of_columns: + combination_of_columns: + - TX_ID + - INDEX + - INNER_INDEX + where: block_timestamp::date > current_date - 7 + recent_date_filter: &recent_date_filter + config: + where: _inserted_timestamp >= current_date - 7 + columns: + - name: BLOCK_TIMESTAMP + description: "{{ doc('block_timestamp') }}" + tests: + - not_null: *recent_date_filter + - dbt_expectations.expect_row_values_to_have_recent_data: + datepart: day + interval: 2 + - name: BLOCK_ID + description: "{{ doc('block_id') }}" + tests: + - not_null: *recent_date_filter + - name: TX_ID + description: "{{ doc('tx_id') }}" + tests: + - not_null: *recent_date_filter + - name: INDEX + description: "{{ doc('event_index') }}" + tests: + - not_null: *recent_date_filter + - name: INNER_INDEX + description: "{{ doc('inner_index') }}. This is the inner index of the log event listing the inner swap" + - name: SUCCEEDED + description: "{{ doc('tx_succeeded') }}" + tests: + - not_null: *recent_date_filter + - name: PROGRAM_ID + description: "{{ doc('program_id') }}" + tests: + - not_null: *recent_date_filter + - name: SWAPPER + description: "{{ doc('swaps_swapper') }}" + tests: + - not_null: + where: _inserted_timestamp between current_date - 7 and current_date - 2 # allow it to be null during lookback buffer + - name: SWAP_FROM_AMOUNT + description: "{{ doc('swaps_from_amt') }}" + tests: + - not_null: *recent_date_filter + - name: SWAP_FROM_MINT + description: "{{ doc('swaps_from_mint') }}" + tests: + - not_null: *recent_date_filter + - name: SWAP_TO_AMOUNT + description: "{{ doc('swaps_to_amt') }}" + tests: + - not_null: *recent_date_filter + - name: SWAP_TO_MINT + description: "{{ doc('swaps_to_mint') }}" + tests: + - not_null: *recent_date_filter + - name: _INSERTED_TIMESTAMP + description: "{{ doc('_inserted_timestamp') }}" + - name: SWAPS_PANCAKESWAP_ID + description: '{{ doc("pk") }}' + tests: + - unique: *recent_date_filter + - name: INSERTED_TIMESTAMP + description: '{{ doc("inserted_timestamp") }}' + tests: + - not_null: *recent_date_filter + - name: MODIFIED_TIMESTAMP + description: '{{ doc("modified_timestamp") }}' + tests: + - not_null: *recent_date_filter + - name: _INVOCATION_ID + description: '{{ doc("_invocation_id") }}' + tests: + - not_null: + name: test_silver__not_null_swaps_pancakeswap__invocation_id + <<: *recent_date_filter \ No newline at end of file