mirror of
https://github.com/FlipsideCrypto/solana-models.git
synced 2026-02-06 13:56:50 +00:00
An 5709/ez liquidity pool actions (#814)
* wip * wip * update tests and models * update overview and inc * cleanup; adjust tests * add raydium stable * clean up
This commit is contained in:
parent
77d51bd5df
commit
ddd8be51a9
@ -37,6 +37,7 @@ There is more information on how to use dbt docs in the last section of this doc
|
||||
|
||||
### DeFi Tables (`Solana`.`DEFI`.`<table_name>`)
|
||||
- [ez_dex_swaps](#!/model/model.solana_models.defi__ez_dex_swaps)
|
||||
- [ez_liquidity_pool_actions](#!/model/model.solana_models.defi__ez_liquidity_pool_actions)
|
||||
- [fact_liquidity_pool_actions](#!/model/model.solana_models.defi__fact_liquidity_pool_actions)
|
||||
- [fact_stake_pool_actions](#!/model/model.solana_models.defi__fact_stake_pool_actions)
|
||||
- [fact_swaps](#!/model/model.solana_models.defi__fact_swaps)
|
||||
|
||||
180
models/gold/defi/defi__ez_liquidity_pool_actions.sql
Normal file
180
models/gold/defi/defi__ez_liquidity_pool_actions.sql
Normal file
@ -0,0 +1,180 @@
|
||||
{{
|
||||
config(
|
||||
materialized = 'incremental',
|
||||
incremental_strategy = 'merge',
|
||||
meta={'database_tags':{'table':{'PURPOSE': 'STAKING'}}},
|
||||
unique_key = ['ez_liquidity_pool_actions_id'],
|
||||
merge_exclude_columns = ['inserted_timestamp'],
|
||||
post_hook = enable_search_optimization(
|
||||
'{{this.schema}}',
|
||||
'{{this.identifier}}',
|
||||
'ON EQUALITY(ez_liquidity_pool_actions_id, pool_address, provider_address, tx_id, action_type, token_a_mint, token_b_mint)'),
|
||||
cluster_by = ['block_timestamp::DATE','action_type','program_id'],
|
||||
tags = ['scheduled_non_core'],
|
||||
)
|
||||
}}
|
||||
|
||||
{% set pool_platforms = [
|
||||
'raydiumv4',
|
||||
'raydium_cpmm',
|
||||
'raydium_clmm',
|
||||
'raydiumstable',
|
||||
'orcav1',
|
||||
'orcav2',
|
||||
'meteora_2',
|
||||
'meteora_dlmm_2',
|
||||
'orca_whirlpool',
|
||||
] %}
|
||||
|
||||
WITH
|
||||
base AS (
|
||||
{% for platform in pool_platforms %}
|
||||
SELECT
|
||||
lp.block_id,
|
||||
lp.block_timestamp,
|
||||
lp.tx_id,
|
||||
lp.index,
|
||||
lp.inner_index,
|
||||
CASE
|
||||
WHEN REGEXP_LIKE(lp.event_type, '^(increase|add|deposit|bootstrap|open).*', 'i') THEN 'deposit'
|
||||
WHEN REGEXP_LIKE(lp.event_type, '^(decrease|remove|withdraw|close).*', 'i') THEN 'withdraw'
|
||||
ELSE lp.event_type
|
||||
END AS action_type,
|
||||
lp.provider_address,
|
||||
lp.token_a_mint,
|
||||
CASE
|
||||
WHEN lp.token_a_mint = m.token_a_mint THEN m.token_a_symbol
|
||||
WHEN lp.token_a_mint = m.token_b_mint THEN m.token_b_symbol
|
||||
END AS token_a_symbol,
|
||||
lp.token_a_amount,
|
||||
lp.token_b_mint,
|
||||
CASE
|
||||
WHEN lp.token_b_mint = m.token_a_mint THEN m.token_a_symbol
|
||||
WHEN lp.token_b_mint = m.token_b_mint THEN m.token_b_symbol
|
||||
END AS token_b_symbol,
|
||||
lp.token_b_amount,
|
||||
NULL AS token_c_mint,
|
||||
NULL AS token_c_symbol,
|
||||
NULL AS token_c_amount,
|
||||
NULL AS token_d_mint,
|
||||
NULL AS token_d_symbol,
|
||||
NULL AS token_d_amount,
|
||||
lp.pool_address,
|
||||
m.pool_name,
|
||||
lp.program_id,
|
||||
m.platform,
|
||||
lp.liquidity_pool_actions_{{ platform }}_id AS ez_liquidity_pool_actions_id
|
||||
FROM
|
||||
{{ ref('silver__liquidity_pool_actions_' ~ platform) }} AS lp
|
||||
INNER JOIN
|
||||
{{ ref('silver__liquidity_pools') }} AS m
|
||||
USING(pool_address)
|
||||
{% if is_incremental() %}
|
||||
where lp.modified_timestamp > (select max(modified_timestamp) from {{ this }})
|
||||
{% endif %}
|
||||
{% if not loop.last %}
|
||||
UNION ALL
|
||||
{% endif %}
|
||||
{% endfor %}
|
||||
|
||||
UNION ALL
|
||||
-- do meteora multi separately
|
||||
SELECT
|
||||
lp.block_id,
|
||||
lp.block_timestamp,
|
||||
lp.tx_id,
|
||||
lp.index,
|
||||
lp.inner_index,
|
||||
CASE
|
||||
WHEN REGEXP_LIKE(lp.event_type, '^(increase|add|deposit|bootstrap|open).*', 'i') THEN 'deposit'
|
||||
WHEN REGEXP_LIKE(lp.event_type, '^(decrease|remove|withdraw|close).*', 'i') THEN 'withdraw'
|
||||
ELSE lp.event_type
|
||||
END AS action_type,
|
||||
lp.provider_address,
|
||||
lp.token_a_mint,
|
||||
NULL AS token_a_symbol,
|
||||
lp.token_a_amount,
|
||||
lp.token_b_mint,
|
||||
NULL AS token_b_symbol,
|
||||
lp.token_b_amount,
|
||||
token_c_mint,
|
||||
NULL AS token_c_symbol,
|
||||
token_c_amount,
|
||||
token_d_mint,
|
||||
NULL AS token_d_symbol,
|
||||
token_d_amount,
|
||||
lp.pool_address,
|
||||
NULL AS pool_name,
|
||||
lp.program_id,
|
||||
'meteora' AS platform,
|
||||
lp.liquidity_pool_actions_meteora_multi_2_id AS ez_liquidity_pool_actions_id
|
||||
FROM
|
||||
{{ ref('silver__liquidity_pool_actions_meteora_multi_2') }} AS lp
|
||||
{% if is_incremental() %}
|
||||
where lp.modified_timestamp > (select max(modified_timestamp) from {{ this }})
|
||||
{% endif %}
|
||||
),
|
||||
token_prices AS (
|
||||
SELECT
|
||||
HOUR,
|
||||
token_address,
|
||||
price
|
||||
FROM
|
||||
{{ ref('price__ez_prices_hourly') }}
|
||||
WHERE
|
||||
HOUR :: DATE IN (
|
||||
SELECT
|
||||
DISTINCT block_timestamp :: DATE
|
||||
FROM
|
||||
base
|
||||
)
|
||||
)
|
||||
SELECT
|
||||
block_id,
|
||||
block_timestamp,
|
||||
tx_id,
|
||||
index,
|
||||
inner_index,
|
||||
action_type,
|
||||
provider_address,
|
||||
token_a_mint,
|
||||
token_a_symbol,
|
||||
token_a_amount,
|
||||
(token_a_amount * tp_a.price)::numeric(22,8) AS token_a_amount_usd,
|
||||
token_b_mint,
|
||||
token_b_symbol,
|
||||
token_b_amount,
|
||||
(token_b_amount * tp_b.price)::numeric(22,8) AS token_b_amount_usd,
|
||||
token_c_mint,
|
||||
token_c_symbol,
|
||||
token_c_amount,
|
||||
(token_c_amount * tp_c.price)::numeric(22,8) AS token_c_amount_usd,
|
||||
token_d_mint,
|
||||
token_d_symbol,
|
||||
token_d_amount,
|
||||
(token_d_amount * tp_d.price)::numeric(22,8) AS token_d_amount_usd,
|
||||
pool_address,
|
||||
pool_name,
|
||||
program_id,
|
||||
platform,
|
||||
ez_liquidity_pool_actions_id,
|
||||
sysdate() AS inserted_timestamp,
|
||||
sysdate() AS modified_timestamp
|
||||
FROM
|
||||
base AS b
|
||||
LEFT JOIN
|
||||
token_prices AS tp_a
|
||||
ON date_trunc('hour', b.block_timestamp) = tp_a.HOUR
|
||||
AND b.token_a_mint = tp_a.token_address
|
||||
LEFT JOIN
|
||||
token_prices AS tp_b
|
||||
ON date_trunc('hour', b.block_timestamp) = tp_b.HOUR
|
||||
AND b.token_b_mint = tp_b.token_address
|
||||
LEFT JOIN
|
||||
token_prices AS tp_c
|
||||
ON date_trunc('hour', b.block_timestamp) = tp_c.HOUR
|
||||
AND b.token_c_mint = tp_c.token_address
|
||||
LEFT JOIN
|
||||
token_prices AS tp_d
|
||||
ON date_trunc('hour', b.block_timestamp) = tp_d.HOUR
|
||||
AND b.token_d_mint = tp_d.token_address
|
||||
112
models/gold/defi/defi__ez_liquidity_pool_actions.yml
Normal file
112
models/gold/defi/defi__ez_liquidity_pool_actions.yml
Normal file
@ -0,0 +1,112 @@
|
||||
version: 2
|
||||
models:
|
||||
- name: defi__ez_liquidity_pool_actions
|
||||
description: Convenience table capturing actions for liquidity pools in Raydium, Orca, and Meteora. This includes deposit and withdrawal events.
|
||||
recent_date_filter: &recent_date_filter
|
||||
config:
|
||||
where: >
|
||||
modified_timestamp > current_date - 7
|
||||
data_tests:
|
||||
- dbt_utils.unique_combination_of_columns:
|
||||
combination_of_columns:
|
||||
- TX_ID
|
||||
- INDEX
|
||||
- INNER_INDEX
|
||||
columns:
|
||||
- name: BLOCK_TIMESTAMP
|
||||
description: "{{ doc('block_timestamp') }}"
|
||||
data_tests:
|
||||
- not_null: *recent_date_filter
|
||||
- name: BLOCK_ID
|
||||
description: "{{ doc('block_id') }}"
|
||||
data_tests:
|
||||
- not_null: *recent_date_filter
|
||||
- name: TX_ID
|
||||
description: "{{ doc('tx_id') }}"
|
||||
data_tests:
|
||||
- not_null: *recent_date_filter
|
||||
- name: INDEX
|
||||
description: "{{ doc('event_index') }}"
|
||||
data_tests:
|
||||
- not_null: *recent_date_filter
|
||||
- name: INNER_INDEX
|
||||
description: "{{ doc('inner_index') }}"
|
||||
- name: ACTION_TYPE
|
||||
description: "{{ doc('event_type') }}"
|
||||
data_tests:
|
||||
- not_null: *recent_date_filter
|
||||
- accepted_values:
|
||||
values: ["deposit", "withdraw"]
|
||||
<<: *recent_date_filter
|
||||
- name: PROVIDER_ADDRESS
|
||||
description: "{{ doc('liquidity_provider') }}"
|
||||
data_tests:
|
||||
- not_null: *recent_date_filter
|
||||
- name: TOKEN_A_MINT
|
||||
description: "{{ doc('token_a_mint') }}"
|
||||
- name: TOKEN_A_SYMBOL
|
||||
description: "{{ doc('prices_symbol') }}"
|
||||
- name: TOKEN_A_AMOUNT
|
||||
description: "{{ doc('token_a_amount') }}"
|
||||
- name: TOKEN_A_AMOUNT_USD
|
||||
description: >
|
||||
The amount of token A in USD.
|
||||
- name: TOKEN_B_MINT
|
||||
description: "{{ doc('token_b_mint') }}"
|
||||
- name: TOKEN_B_SYMBOL
|
||||
description: "{{ doc('prices_symbol') }}"
|
||||
- name: TOKEN_B_AMOUNT
|
||||
description: "{{ doc('token_b_amount') }}"
|
||||
- name: TOKEN_B_AMOUNT_USD
|
||||
description: >
|
||||
The amount of token B in USD.
|
||||
- name: TOKEN_C_MINT
|
||||
description: >
|
||||
Address of the mint representing the third token in a liquidity pool pair.
|
||||
- name: TOKEN_C_SYMBOL
|
||||
description: "{{ doc('prices_symbol') }}"
|
||||
- name: TOKEN_C_AMOUNT
|
||||
description: >
|
||||
Amount of the third token in a liquidity pool pair transferred during a liquidity pool action.
|
||||
- name: TOKEN_C_AMOUNT_USD
|
||||
description: >
|
||||
The amount of token C in USD.
|
||||
- name: TOKEN_D_MINT
|
||||
description: >
|
||||
Address of the mint representing the fourth token in a liquidity pool pair.
|
||||
- name: TOKEN_D_SYMBOL
|
||||
description: "{{ doc('prices_symbol') }}"
|
||||
- name: TOKEN_D_AMOUNT
|
||||
description: >
|
||||
Amount of the fourth token in a liquidity pool pair transferred during a liquidity pool action.
|
||||
- name: TOKEN_D_AMOUNT_USD
|
||||
description: >
|
||||
The amount of token D in USD.
|
||||
- name: POOL_ADDRESS
|
||||
description: "{{ doc('liquidity_pool_address') }}"
|
||||
data_tests:
|
||||
- not_null: *recent_date_filter
|
||||
- name: POOL_NAME
|
||||
description: >
|
||||
Name of the liquidity pool
|
||||
- name: PROGRAM_ID
|
||||
description: "{{ doc('program_id') }}"
|
||||
data_tests:
|
||||
- not_null: *recent_date_filter
|
||||
- name: PLATFORM
|
||||
description: >
|
||||
Name of the liquidity pool protocol
|
||||
data_tests:
|
||||
- not_null
|
||||
- name: EZ_LIQUIDITY_POOL_ACTIONS_ID
|
||||
description: '{{ doc("pk") }}'
|
||||
data_tests:
|
||||
- unique
|
||||
- name: INSERTED_TIMESTAMP
|
||||
description: '{{ doc("inserted_timestamp") }}'
|
||||
data_tests:
|
||||
- not_null: *recent_date_filter
|
||||
- name: MODIFIED_TIMESTAMP
|
||||
description: '{{ doc("modified_timestamp") }}'
|
||||
data_tests:
|
||||
- not_null: *recent_date_filter
|
||||
@ -0,0 +1,95 @@
|
||||
{{
|
||||
config(
|
||||
materialized = 'incremental',
|
||||
incremental_strategy = 'merge',
|
||||
unique_key = ['pool_address'],
|
||||
merge_exclude_columns = ['inserted_timestamp'],
|
||||
post_hook = enable_search_optimization('{{this.schema}}', '{{this.identifier}}', 'ON EQUALITY(pool_address,token_a_mint,token_b_mint)'),
|
||||
tags = ['scheduled_non_core'],
|
||||
)
|
||||
}}
|
||||
|
||||
{% set pool_platforms = [
|
||||
'raydiumv4',
|
||||
'raydium_cpmm',
|
||||
'raydium_clmm',
|
||||
'raydiumstable',
|
||||
'orcav1',
|
||||
'orcav2',
|
||||
'orca_whirlpool',
|
||||
'meteora',
|
||||
'meteora_dlmm'
|
||||
] %}
|
||||
|
||||
WITH base AS (
|
||||
{% for platform in pool_platforms %}
|
||||
SELECT
|
||||
pool_address,
|
||||
pool_token_mint,
|
||||
token_a_mint,
|
||||
nullif(m.symbol,'') AS token_a_symbol,
|
||||
token_a_account,
|
||||
token_b_mint,
|
||||
nullif(m2.symbol,'') AS token_b_symbol,
|
||||
token_b_account,
|
||||
block_id AS initialized_at_block_id,
|
||||
block_timestamp AS initialized_at_block_timestamp,
|
||||
tx_id AS initialized_at_tx_id,
|
||||
index AS initialized_at_index,
|
||||
inner_index AS initialized_at_inner_index,
|
||||
program_id,
|
||||
CASE
|
||||
WHEN '{{ platform }}' ILIKE '%raydium%' THEN 'raydium'
|
||||
WHEN '{{ platform }}' ILIKE '%orca%' THEN 'orca'
|
||||
WHEN '{{ platform }}' ILIKE '%meteora%' THEN 'meteora'
|
||||
END AS platform,
|
||||
_inserted_timestamp,
|
||||
{{ 'initialization_pools_' ~ platform ~ '_id' }} AS liquidity_pools_id
|
||||
FROM
|
||||
{{ ref('silver__initialization_pools_' ~ platform) }} AS p
|
||||
LEFT JOIN
|
||||
{{ ref('price__ez_asset_metadata') }} AS m
|
||||
ON p.token_a_mint = m.token_address
|
||||
LEFT JOIN
|
||||
{{ ref('price__ez_asset_metadata') }} AS m2
|
||||
ON p.token_b_mint = m2.token_address
|
||||
{% if is_incremental() %}
|
||||
WHERE p._inserted_timestamp >= (SELECT max(_inserted_timestamp) FROM {{ this }})
|
||||
{% endif %}
|
||||
{% if not loop.last %}
|
||||
UNION ALL
|
||||
{% endif %}
|
||||
{% endfor %}
|
||||
)
|
||||
SELECT
|
||||
pool_address,
|
||||
CASE
|
||||
WHEN token_a_symbol IS NOT NULL
|
||||
AND token_b_symbol IS NOT NULL THEN
|
||||
token_a_symbol || '-' || token_b_symbol
|
||||
ELSE
|
||||
NULL
|
||||
END AS pool_name,
|
||||
pool_token_mint,
|
||||
token_a_mint,
|
||||
token_a_symbol,
|
||||
token_a_account,
|
||||
token_b_mint,
|
||||
token_b_symbol,
|
||||
token_b_account,
|
||||
initialized_at_block_id,
|
||||
initialized_at_block_timestamp,
|
||||
initialized_at_tx_id,
|
||||
initialized_at_index,
|
||||
initialized_at_inner_index,
|
||||
program_id,
|
||||
platform,
|
||||
liquidity_pools_id,
|
||||
_inserted_timestamp,
|
||||
sysdate() AS inserted_timestamp,
|
||||
sysdate() AS modified_timestamp,
|
||||
'{{ invocation_id }}' AS _invocation_id
|
||||
FROM
|
||||
base AS b
|
||||
qualify
|
||||
row_number() over(PARTITION BY pool_address ORDER BY initialized_at_block_timestamp DESC) = 1
|
||||
102
models/silver/liquidity_pool/pools/silver__liquidity_pools.yml
Normal file
102
models/silver/liquidity_pool/pools/silver__liquidity_pools.yml
Normal file
@ -0,0 +1,102 @@
|
||||
version: 2
|
||||
models:
|
||||
- name: silver__liquidity_pools
|
||||
description: Table containing information on liquidity pools
|
||||
recent_date_filter: &recent_date_filter
|
||||
config:
|
||||
where: _inserted_timestamp >= current_date - 7
|
||||
columns:
|
||||
- name: POOL_ADDRESS
|
||||
description: "{{ doc('liquidity_pool_address') }}"
|
||||
data_tests:
|
||||
- not_null
|
||||
- unique
|
||||
- name: POOL_NAME
|
||||
description: >
|
||||
Name of the liquidity pool
|
||||
data_tests:
|
||||
- not_null:
|
||||
config:
|
||||
where: >
|
||||
token_a_symbol IS NOT NULL
|
||||
AND token_b_symbol IS NOT NULL
|
||||
AND _inserted_timestamp >= current_date - 7
|
||||
- name: POOL_TOKEN_MINT
|
||||
description: "{{ doc('liquidity_pool_token_mint') }}"
|
||||
- name: TOKEN_A_MINT
|
||||
description: "{{ doc('token_a_mint') }}"
|
||||
data_tests:
|
||||
- not_null: *recent_date_filter
|
||||
- name: TOKEN_A_SYMBOL
|
||||
description: "{{ doc('prices_symbol') }}"
|
||||
- name: TOKEN_A_ACCOUNT
|
||||
description: "{{ doc('token_a_account') }}"
|
||||
data_tests:
|
||||
- not_null:
|
||||
# carried over from initialization_pools_meteora test config
|
||||
config:
|
||||
severity: error
|
||||
error_if: "> 31"
|
||||
- name: TOKEN_B_MINT
|
||||
description: "{{ doc('token_b_mint') }}"
|
||||
data_tests:
|
||||
- not_null: *recent_date_filter
|
||||
- name: TOKEN_B_SYMBOL
|
||||
description: "{{ doc('prices_symbol') }}"
|
||||
- name: TOKEN_B_ACCOUNT
|
||||
description: "{{ doc('token_b_account') }}"
|
||||
data_tests:
|
||||
- not_null:
|
||||
# carried over from initialization_pools_meteora test config
|
||||
config:
|
||||
severity: error
|
||||
error_if: "> 31"
|
||||
- name: INITIALIZED_AT_BLOCK_TIMESTAMP
|
||||
description: "{{ doc('block_timestamp') }}"
|
||||
data_tests:
|
||||
- not_null: *recent_date_filter
|
||||
- name: INITIALIZED_AT_BLOCK_ID
|
||||
description: "{{ doc('block_id') }}"
|
||||
data_tests:
|
||||
- not_null: *recent_date_filter
|
||||
- name: INITIALIZED_AT_TX_ID
|
||||
description: "{{ doc('tx_id') }}"
|
||||
data_tests:
|
||||
- not_null: *recent_date_filter
|
||||
- name: INITIALIZED_AT_INDEX
|
||||
description: "{{ doc('event_index') }}"
|
||||
data_tests:
|
||||
- not_null: *recent_date_filter
|
||||
- name: INITIALIZED_AT_INNER_INDEX
|
||||
description: "{{ doc('inner_index') }}"
|
||||
- name: PROGRAM_ID
|
||||
description: "{{ doc('program_id') }}"
|
||||
data_tests:
|
||||
- not_null: *recent_date_filter
|
||||
- name: PLATFORM
|
||||
description: >
|
||||
Name of the liquidity pool protocol
|
||||
data_tests:
|
||||
- not_null: *recent_date_filter
|
||||
- name: LIQUIDITY_POOLS_ID
|
||||
description: '{{ doc("pk") }}'
|
||||
data_tests:
|
||||
- unique
|
||||
- name: INSERTED_TIMESTAMP
|
||||
description: '{{ doc("inserted_timestamp") }}'
|
||||
data_tests:
|
||||
- not_null: *recent_date_filter
|
||||
- name: MODIFIED_TIMESTAMP
|
||||
description: '{{ doc("modified_timestamp") }}'
|
||||
data_tests:
|
||||
- not_null: *recent_date_filter
|
||||
- name: _INVOCATION_ID
|
||||
description: '{{ doc("_invocation_id") }}'
|
||||
data_tests:
|
||||
- not_null:
|
||||
name: test_silver__not_null_liquidity_pools__invocation_id
|
||||
<<: *recent_date_filter
|
||||
- name: _INSERTED_TIMESTAMP
|
||||
description: "{{ doc('_inserted_timestamp') }}"
|
||||
data_tests:
|
||||
- not_null
|
||||
@ -0,0 +1,235 @@
|
||||
-- depends_on: {{ ref('silver__decoded_instructions_combined') }}
|
||||
{{
|
||||
config(
|
||||
materialized = 'incremental',
|
||||
incremental_strategy = 'merge',
|
||||
unique_key = ['block_timestamp::date','liquidity_pool_actions_raydiumstable_id'],
|
||||
incremental_predicates = ["dynamic_range_predicate", "block_timestamp::date"],
|
||||
merge_exclude_columns = ["inserted_timestamp"],
|
||||
cluster_by = ['block_timestamp::date','modified_timestamp::date'],
|
||||
post_hook = enable_search_optimization(
|
||||
'{{this.schema}}',
|
||||
'{{this.identifier}}',
|
||||
'ON EQUALITY(tx_id, provider_address, token_a_mint, token_b_mint, liquidity_pool_actions_raydiumstable_id)'
|
||||
),
|
||||
tags = ['scheduled_non_core']
|
||||
)
|
||||
}}
|
||||
|
||||
{% if execute %}
|
||||
{% if is_incremental() %}
|
||||
{% set max_timestamp_query %}
|
||||
SELECT max(_inserted_timestamp) FROM {{ this }}
|
||||
{% endset %}
|
||||
{% set max_timestamp = run_query(max_timestamp_query)[0][0] %}
|
||||
{% endif %}
|
||||
|
||||
{% set base_query %}
|
||||
CREATE OR REPLACE TEMPORARY TABLE silver.liquidity_pool_actions_raydiumstable__intermediate_tmp AS
|
||||
SELECT
|
||||
block_id,
|
||||
block_timestamp,
|
||||
tx_id,
|
||||
index,
|
||||
inner_index,
|
||||
succeeded,
|
||||
event_type,
|
||||
decoded_instruction:accounts AS accounts,
|
||||
decoded_instruction:args AS args,
|
||||
program_id,
|
||||
_inserted_timestamp
|
||||
FROM
|
||||
{{ ref('silver__decoded_instructions_combined')}}
|
||||
WHERE
|
||||
program_id = '5quBtoiQqxF9Jv6KYKctB59NT3gtJD2Y65kdnB1Uev3h'
|
||||
AND event_type IN (
|
||||
'deposit',
|
||||
'withdraw'
|
||||
)
|
||||
AND succeeded
|
||||
{% if is_incremental() %}
|
||||
AND _inserted_timestamp > '{{ max_timestamp }}'
|
||||
{% endif %}
|
||||
{% endset %}
|
||||
{% do run_query(base_query) %}
|
||||
{% set between_stmts = fsc_utils.dynamic_range_predicate("silver.liquidity_pool_actions_raydiumstable__intermediate_tmp","block_timestamp::date") %}
|
||||
{% endif %}
|
||||
|
||||
WITH base AS (
|
||||
SELECT
|
||||
* exclude(accounts),
|
||||
silver.udf_get_account_pubkey_by_name('ammAccount', accounts) AS pool_address,
|
||||
CASE
|
||||
WHEN event_type = 'withdraw' THEN silver.udf_get_account_pubkey_by_name('userTokenPc', accounts)
|
||||
ELSE coalesce(
|
||||
silver.udf_get_account_pubkey_by_name('Remaining 0', accounts),
|
||||
silver.udf_get_account_pubkey_by_name('userOwner', accounts)
|
||||
)
|
||||
END AS provider_address,
|
||||
silver.udf_get_account_pubkey_by_name('poolTokenCoin', accounts) AS pool_token_a_account,
|
||||
silver.udf_get_account_pubkey_by_name('poolTokenPc', accounts) AS pool_token_b_account,
|
||||
CASE
|
||||
WHEN event_type = 'withdraw' THEN silver.udf_get_account_pubkey_by_name('userLpToken', accounts)
|
||||
ELSE silver.udf_get_account_pubkey_by_name('userPcToken', accounts)
|
||||
END AS token_a_account,
|
||||
CASE
|
||||
WHEN event_type = 'withdraw' THEN silver.udf_get_account_pubkey_by_name('userTokenCoin', accounts)
|
||||
ELSE silver.udf_get_account_pubkey_by_name('userLpToken', accounts)
|
||||
END AS token_b_account,
|
||||
coalesce(lead(inner_index) OVER (
|
||||
PARTITION BY tx_id, index
|
||||
ORDER BY inner_index
|
||||
), 9999) AS next_lp_action_inner_index
|
||||
FROM
|
||||
silver.liquidity_pool_actions_raydiumstable__intermediate_tmp
|
||||
),
|
||||
|
||||
transfers AS (
|
||||
SELECT
|
||||
t.* exclude(index),
|
||||
split_part(t.index,'.',1)::int AS index,
|
||||
nullif(split_part(t.index,'.',2),'')::int AS inner_index
|
||||
FROM
|
||||
{{ ref('silver__transfers') }} AS t
|
||||
INNER JOIN
|
||||
(SELECT DISTINCT block_timestamp::date AS bt, tx_id FROM base) AS b
|
||||
ON b.bt = t.block_timestamp::date
|
||||
AND b.tx_id = t.tx_id
|
||||
WHERE
|
||||
t.succeeded
|
||||
AND {{ between_stmts }}
|
||||
),
|
||||
|
||||
deposit_transfers AS (
|
||||
SELECT
|
||||
b.*,
|
||||
t.mint AS token_a_mint,
|
||||
t.amount AS token_a_amount,
|
||||
t2.mint AS token_b_mint,
|
||||
t2.amount AS token_b_amount
|
||||
FROM
|
||||
base AS b
|
||||
LEFT JOIN
|
||||
transfers AS t
|
||||
ON t.block_timestamp::date = b.block_timestamp::date
|
||||
AND t.tx_id = b.tx_id
|
||||
AND t.index = b.index
|
||||
AND coalesce(t.inner_index,0) > coalesce(b.inner_index,-1)
|
||||
AND coalesce(t.inner_index,0) < coalesce(b.next_lp_action_inner_index,9999)
|
||||
AND t.source_token_account = b.token_a_account
|
||||
AND t.dest_token_account = b.pool_token_a_account
|
||||
LEFT JOIN
|
||||
transfers AS t2
|
||||
ON t2.block_timestamp::date = b.block_timestamp::date
|
||||
AND t2.tx_id = b.tx_id
|
||||
AND t2.index = b.index
|
||||
AND coalesce(t2.inner_index,0) > coalesce(b.inner_index,-1)
|
||||
AND coalesce(t2.inner_index,0) < coalesce(b.next_lp_action_inner_index,9999)
|
||||
AND t2.source_token_account = b.token_b_account
|
||||
AND t2.dest_token_account = b.pool_token_b_account
|
||||
WHERE
|
||||
b.event_type = 'deposit'
|
||||
QUALIFY
|
||||
row_number() OVER (PARTITION BY b.tx_id, b.index, b.inner_index ORDER BY t.inner_index, t2.inner_index) = 1
|
||||
),
|
||||
|
||||
withdraw_transfers AS (
|
||||
SELECT
|
||||
b.*,
|
||||
t.mint AS token_a_mint,
|
||||
t.amount AS token_a_amount,
|
||||
t2.mint AS token_b_mint,
|
||||
t2.amount AS token_b_amount
|
||||
FROM
|
||||
base AS b
|
||||
LEFT JOIN
|
||||
transfers AS t
|
||||
ON t.block_timestamp::date = b.block_timestamp::date
|
||||
AND t.tx_id = b.tx_id
|
||||
AND t.index = b.index
|
||||
AND coalesce(t.inner_index,0) > coalesce(b.inner_index,-1)
|
||||
AND coalesce(t.inner_index,0) < coalesce(b.next_lp_action_inner_index,9999)
|
||||
AND t.dest_token_account = b.token_a_account
|
||||
AND t.source_token_account = b.pool_token_a_account
|
||||
LEFT JOIN
|
||||
transfers AS t2
|
||||
ON t2.block_timestamp::date = b.block_timestamp::date
|
||||
AND t2.tx_id = b.tx_id
|
||||
AND t2.index = b.index
|
||||
AND coalesce(t2.inner_index,0) > coalesce(b.inner_index,-1)
|
||||
AND coalesce(t2.inner_index,0) < coalesce(b.next_lp_action_inner_index,9999)
|
||||
AND t2.dest_token_account = b.token_b_account
|
||||
AND t2.source_token_account = b.pool_token_b_account
|
||||
WHERE
|
||||
b.event_type = 'withdraw'
|
||||
QUALIFY
|
||||
row_number() OVER (PARTITION BY b.tx_id, b.index, b.inner_index ORDER BY t.inner_index, t2.inner_index) = 1
|
||||
),
|
||||
|
||||
pre_final AS (
|
||||
SELECT
|
||||
block_id,
|
||||
block_timestamp,
|
||||
tx_id,
|
||||
index,
|
||||
inner_index,
|
||||
succeeded,
|
||||
event_type,
|
||||
pool_address,
|
||||
provider_address,
|
||||
token_a_mint,
|
||||
token_a_amount,
|
||||
token_b_mint,
|
||||
token_b_amount,
|
||||
program_id,
|
||||
_inserted_timestamp
|
||||
FROM
|
||||
deposit_transfers
|
||||
|
||||
UNION ALL
|
||||
|
||||
SELECT
|
||||
block_id,
|
||||
block_timestamp,
|
||||
tx_id,
|
||||
index,
|
||||
inner_index,
|
||||
succeeded,
|
||||
event_type,
|
||||
pool_address,
|
||||
provider_address,
|
||||
token_a_mint,
|
||||
token_a_amount,
|
||||
token_b_mint,
|
||||
token_b_amount,
|
||||
program_id,
|
||||
_inserted_timestamp
|
||||
FROM
|
||||
withdraw_transfers
|
||||
)
|
||||
SELECT
|
||||
block_id,
|
||||
block_timestamp,
|
||||
tx_id,
|
||||
index,
|
||||
inner_index,
|
||||
succeeded,
|
||||
event_type,
|
||||
pool_address,
|
||||
provider_address,
|
||||
/*
|
||||
mimic behavior of our other liquidity pool action models that support single token withdraws/deposits.
|
||||
Represent the single token action as token A
|
||||
*/
|
||||
iff(token_a_mint IS NULL AND token_a_amount IS NULL, token_b_mint, token_a_mint) AS token_a_mint,
|
||||
iff(token_a_mint IS NULL AND token_a_amount IS NULL, token_b_amount, token_a_amount) AS token_a_amount,
|
||||
iff(token_a_mint IS NOT NULL OR token_a_amount IS NOT NULL, token_b_mint, NULL) AS token_b_mint,
|
||||
iff(token_a_mint IS NOT NULL OR token_a_amount IS NOT NULL, token_b_amount, NULL) AS token_b_amount,
|
||||
program_id,
|
||||
_inserted_timestamp,
|
||||
{{ dbt_utils.generate_surrogate_key(['block_id', 'tx_id', 'index', 'inner_index']) }} AS liquidity_pool_actions_raydiumstable_id,
|
||||
sysdate() AS inserted_timestamp,
|
||||
sysdate() AS modified_timestamp,
|
||||
'{{ invocation_id }}' AS _invocation_id
|
||||
FROM
|
||||
pre_final
|
||||
@ -0,0 +1,90 @@
|
||||
version: 2
|
||||
models:
|
||||
- name: silver__liquidity_pool_actions_raydiumstable
|
||||
recent_date_filter: &recent_date_filter
|
||||
config:
|
||||
where: >
|
||||
_inserted_timestamp > current_date - 7
|
||||
data_tests:
|
||||
- dbt_utils.unique_combination_of_columns:
|
||||
combination_of_columns:
|
||||
- TX_ID
|
||||
- INDEX
|
||||
- INNER_INDEX
|
||||
columns:
|
||||
- name: BLOCK_TIMESTAMP
|
||||
description: "{{ doc('block_timestamp') }}"
|
||||
data_tests:
|
||||
- not_null: *recent_date_filter
|
||||
- name: BLOCK_ID
|
||||
description: "{{ doc('block_id') }}"
|
||||
data_tests:
|
||||
- not_null: *recent_date_filter
|
||||
- name: TX_ID
|
||||
description: "{{ doc('tx_id') }}"
|
||||
data_tests:
|
||||
- not_null: *recent_date_filter
|
||||
- name: INDEX
|
||||
description: "{{ doc('event_index') }}"
|
||||
data_tests:
|
||||
- not_null: *recent_date_filter
|
||||
- name: INNER_INDEX
|
||||
description: "{{ doc('inner_index') }}"
|
||||
- name: SUCCEEDED
|
||||
description: "{{ doc('tx_succeeded') }}"
|
||||
data_tests:
|
||||
- not_null: *recent_date_filter
|
||||
- name: EVENT_TYPE
|
||||
description: "{{ doc('event_type') }}"
|
||||
data_tests:
|
||||
- not_null: *recent_date_filter
|
||||
- name: POOL_ADDRESS
|
||||
description: "{{ doc('liquidity_pool_address') }}"
|
||||
data_tests:
|
||||
- not_null: *recent_date_filter
|
||||
- name: PROVIDER_ADDRESS
|
||||
description: "{{ doc('liquidity_provider') }}"
|
||||
data_tests:
|
||||
- not_null: *recent_date_filter
|
||||
- name: TOKEN_A_MINT
|
||||
description: "{{ doc('token_a_mint') }}"
|
||||
data_tests:
|
||||
- not_null: *recent_date_filter
|
||||
- name: TOKEN_A_AMOUNT
|
||||
description: "{{ doc('token_a_amount') }}"
|
||||
data_tests:
|
||||
- not_null: *recent_date_filter
|
||||
- name: TOKEN_B_MINT
|
||||
description: "{{ doc('token_b_mint') }}"
|
||||
data_tests:
|
||||
- not_null: *recent_date_filter
|
||||
- name: TOKEN_B_AMOUNT
|
||||
description: "{{ doc('token_b_amount') }}"
|
||||
data_tests:
|
||||
- not_null: *recent_date_filter
|
||||
- name: PROGRAM_ID
|
||||
description: "{{ doc('program_id') }}"
|
||||
data_tests:
|
||||
- not_null: *recent_date_filter
|
||||
- name: _INSERTED_TIMESTAMP
|
||||
description: "{{ doc('_inserted_timestamp') }}"
|
||||
data_tests:
|
||||
- not_null
|
||||
- name: LIQUIDITY_POOL_ACTIONS_RAYDIUMSTABLE_ID
|
||||
description: '{{ doc("pk") }}'
|
||||
data_tests:
|
||||
- unique
|
||||
- name: INSERTED_TIMESTAMP
|
||||
description: '{{ doc("inserted_timestamp") }}'
|
||||
data_tests:
|
||||
- not_null: *recent_date_filter
|
||||
- name: MODIFIED_TIMESTAMP
|
||||
description: '{{ doc("modified_timestamp") }}'
|
||||
data_tests:
|
||||
- not_null: *recent_date_filter
|
||||
- name: _INVOCATION_ID
|
||||
description: '{{ doc("_invocation_id") }}'
|
||||
data_tests:
|
||||
- not_null:
|
||||
name: test_silver__not_null_liquidity_pool_actions_raydiumstable_invocation_id
|
||||
<<: *recent_date_filter
|
||||
Loading…
Reference in New Issue
Block a user