add meteora bonding swaps (#842)

* add meteora bonding swaps

* add swap models to ref test

* update swap program
This commit is contained in:
tarikceric 2025-05-08 14:49:20 -07:00 committed by GitHub
parent d24c881c58
commit 21cb4f149e
No known key found for this signature in database
GPG Key ID: B5690EEEBB952194
4 changed files with 323 additions and 8 deletions

View File

@ -34,6 +34,7 @@ SELECT
to_amt AS swap_to_amount,
to_mint AS swap_to_mint,
program_id,
'bonkswap' as swap_program,
swap_index,
swaps_intermediate_bonkswap_id as fact_swaps_id,
inserted_timestamp,
@ -58,6 +59,9 @@ SELECT
to_amt AS swap_to_amount,
to_mint AS swap_to_mint,
program_id,
case when program_id = 'LBUZKhRxPF3XUpBCjp4YzTKgLccjZhTSDM9YuVaPwxo' then 'meteora dlmm pools program'
else 'meteora pools program'
end as swap_program,
swap_index,
swaps_intermediate_meteora_id as fact_swaps_id,
inserted_timestamp,
@ -82,6 +86,7 @@ SELECT
to_amt AS swap_to_amount,
to_mint AS swap_to_mint,
program_id,
'stepn swap' as swap_program,
swap_index,
swaps_intermediate_dooar_id as fact_swaps_id,
inserted_timestamp,
@ -106,6 +111,7 @@ SELECT
to_amt AS swap_to_amount,
to_mint AS swap_to_mint,
program_id,
'phoenix' as swap_program,
swap_index,
swaps_intermediate_phoenix_id as fact_swaps_id,
inserted_timestamp,
@ -130,6 +136,7 @@ SELECT
to_amt AS swap_to_amount,
to_mint AS swap_to_mint,
program_id,
'raydium concentrated liquidity' as swap_program,
swap_index,
swaps_intermediate_raydium_clmm_id as fact_swaps_id,
inserted_timestamp,
@ -154,6 +161,7 @@ SELECT
to_amt AS swap_to_amount,
to_mint AS swap_to_mint,
program_id,
'raydium liquidity pool program id v5' as swap_program,
swap_index,
swaps_intermediate_raydium_stable_id as fact_swaps_id,
inserted_timestamp,
@ -178,6 +186,7 @@ SELECT
to_amt AS swap_to_amount,
to_mint AS swap_to_mint,
program_id,
'Raydium Liquidity Pool V4' as swap_program,
swap_index,
swaps_intermediate_raydium_v4_amm_id as fact_swaps_id,
inserted_timestamp,
@ -202,6 +211,7 @@ SELECT
to_amount AS swap_to_amount,
to_mint AS swap_to_mint,
program_id,
'pump.fun' as swap_program,
swap_index,
swaps_pumpfun_id as fact_swaps_id,
inserted_timestamp,
@ -224,6 +234,7 @@ SELECT
swap_to_amount,
swap_to_mint,
program_id,
'raydium constant product market maker' as swap_program,
swap_index,
swaps_intermediate_raydium_cpmm_id as fact_swaps_id,
inserted_timestamp,
@ -246,6 +257,7 @@ SELECT
swap_to_amount,
swap_to_mint,
program_id,
'pumpswap' as swap_program,
swap_index,
swaps_pumpswap_id as fact_swaps_id,
inserted_timestamp,
@ -268,6 +280,7 @@ SELECT
to_amt AS swap_to_amount,
to_mint AS swap_to_mint,
program_id,
'lifinity swap v2' as swap_program,
swap_index,
swaps_intermediate_lifinity_id as fact_swaps_id,
inserted_timestamp,
@ -289,6 +302,7 @@ SELECT
to_amt AS swap_to_amount,
to_mint AS swap_to_mint,
program_id,
'orca whirlpool program' as swap_program,
swap_index,
swaps_intermediate_orca_whirlpool_id as fact_swaps_id,
inserted_timestamp,
@ -310,6 +324,9 @@ SELECT
to_amt AS swap_to_amount,
to_mint AS swap_to_mint,
program_id,
case when program_id = 'DjVE6JNiYqPL2QXyCUUh8rNjHrbz9hXHNYt99MQ59qw1' then 'orca token swap'
else 'ORCA Token Swap V2'
end as swap_program,
swap_index,
swaps_intermediate_orca_token_swap_id as fact_swaps_id,
inserted_timestamp,
@ -331,6 +348,7 @@ SELECT
swap_to_amount,
swap_to_mint,
program_id,
'Saber Stable Swap' as swap_program,
swap_index,
swaps_intermediate_saber_id as fact_swaps_id,
inserted_timestamp,
@ -340,6 +358,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,
'meteora bonding' as swap_program,
swap_index,
swaps_intermediate_meteora_bonding_id as fact_swaps_id,
inserted_timestamp,
modified_timestamp
FROM
{{ ref('silver__swaps_intermediate_meteora_bonding') }}
{% if is_incremental() %}
WHERE modified_timestamp >= '{{ max_modified_timestamp }}'
{% endif %}
)
{% if not is_incremental() %}
@ -403,14 +443,10 @@ select
swap_to_amount,
swap_to_mint,
program_id,
l.address_name AS swap_program,
swap_program,
concat_ws('-',tx_id,swap_index,swap_program) as _log_id,
fact_swaps_id,
s.inserted_timestamp,
s.modified_timestamp
inserted_timestamp,
modified_timestamp
FROM
swaps_individual
s
LEFT OUTER JOIN {{ ref('core__dim_labels') }}
l
ON s.program_id = l.address
swaps_individual

View File

@ -21,6 +21,12 @@ models:
- 'silver__swaps_pumpfun'
- 'silver__swaps_intermediate_raydium_cpmm'
- 'silver__swaps_pumpswap'
- 'silver__swaps_intermediate_saber'
- 'silver__swaps_intermediate_lifinity'
- 'silver__swaps_intermediate_orca_whirlpool'
- 'silver__swaps_intermediate_orca_token_swap'
- 'silver__swaps_intermediate_meteora_bonding'
id_column: 'tx_id'
columns:
- name: BLOCK_TIMESTAMP

View File

@ -0,0 +1,202 @@
-- depends_on: {{ ref('silver__decoded_instructions_combined') }}
{{ config(
materialized = 'incremental',
unique_key = "swaps_intermediate_meteora_bonding_id",
incremental_predicates = ["dynamic_range_predicate", "block_timestamp::date"],
merge_exclude_columns = ["inserted_timestamp"],
cluster_by = ['block_timestamp::DATE','modified_timestamp::DATE'],
tags = ['scheduled_non_core','scheduled_non_core_hourly'],
) }}
{% if execute %}
{% set base_query %}
CREATE OR REPLACE TEMPORARY TABLE silver.swaps_intermediate_meteora_bonding__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 = 'dbcij3LWUppWqq96dh6gJWwBifmcGfLSB5D4DuSMaqN'
AND event_type = 'swap'
AND succeeded
{% if is_incremental() %}
AND _inserted_timestamp >= (
SELECT
MAX(_inserted_timestamp) - INTERVAL '1 hour'
FROM
{{ this }}
)
{% else %}
AND _inserted_timestamp::DATE >= '2025-05-01'
{% endif %}
{% endset %}
{% do run_query(base_query) %}
{% set between_stmts = fsc_utils.dynamic_range_predicate(
"silver.swaps_intermediate_meteora_bonding__intermediate_tmp",
"block_timestamp::date"
) %}
{% endif %}
with base AS (
SELECT
*
FROM
silver.swaps_intermediate_meteora_bonding__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,
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,
silver.udf_get_account_pubkey_by_name('quote_vault', decoded_instruction:accounts) as program_destination_token_account,
silver.udf_get_account_pubkey_by_name('base_vault', decoded_instruction:accounts) as program_source_token_account,
_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,
COALESCE (
b.succeeded,
d.succeeded
) AS succeeded,
A.swapper,
COALESCE (
b.amount,
d.amount
) AS swap_from_amount,
COALESCE(
b.mint,
d.mint
) AS swap_from_mint,
COALESCE(
C.amount,
e.amount
) AS swap_to_amount,
COALESCE(
C.mint,
e.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
)
-- do a separate set of joins mirroring above because destination/source accounts are occasionaly flipped in a swap tx
LEFT JOIN transfers d
ON A.tx_id = d.tx_id
AND A.source_token_account = d.source_token_account
AND A.program_destination_token_account = d.dest_token_account
AND A.index = d.index_1
AND (
(d.inner_index_1 BETWEEN A.inner_index AND A.inner_index_end)
OR A.inner_index IS NULL
)
LEFT JOIN transfers e
ON A.tx_id = e.tx_id
AND A.destination_token_account = e.dest_token_account
AND A.program_source_token_account = e.source_token_account
AND A.index = e.index_1
AND (
(e.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_intermediate_meteora_bonding_id,
SYSDATE() AS inserted_timestamp,
SYSDATE() AS modified_timestamp,
'{{ invocation_id }}' AS _invocation_id
FROM
pre_final

View File

@ -0,0 +1,71 @@
version: 2
models:
- name: silver__swaps_intermediate_meteora_bonding
tests:
- dbt_utils.unique_combination_of_columns:
combination_of_columns:
- TX_ID
- SWAP_INDEX
- PROGRAM_ID
where: block_timestamp::date > current_date - 30
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('index') }}"
tests:
- not_null: *recent_date_filter
- name: INNER_INDEX
description: "{{ doc('inner_index') }}"
- 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: *recent_date_filter
- 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: SWAP_INDEX
description: "{{ doc('swaps_swap_index') }}"
tests:
- not_null: *recent_date_filter
- name: _INSERTED_TIMESTAMP
description: "{{ doc('_inserted_timestamp') }}"
tests:
- not_null