mirror of
https://github.com/FlipsideCrypto/solana-models.git
synced 2026-02-06 11:27:00 +00:00
* intial lido model * wip * change action words, add more pools * wip' * redo deposit stake logic * initial socean model * stake pool column descriptions * wip * force dbt to 0.9.2 * fix model syntax, update test * socean tests * match output columns with other models, add tests * marinade stake pool model * update description to specify SOL * initial core view * eversol wip * eversol actions and tests * add core stake pool
150 lines
4.4 KiB
SQL
150 lines
4.4 KiB
SQL
{{ config(
|
|
materialized = 'incremental',
|
|
unique_key = "_unique_key",
|
|
incremental_strategy = 'merge',
|
|
cluster_by = ['block_timestamp::DATE','_inserted_timestamp::date']
|
|
) }}
|
|
|
|
WITH base_lido_events AS (
|
|
|
|
SELECT
|
|
*
|
|
FROM
|
|
{{ ref('silver__events') }}
|
|
WHERE
|
|
program_id = 'CrX7kMhLC3cSsXJdT7JDgqrRVWGnUpX3gfEfxxU2NVLi'
|
|
|
|
{% if is_incremental() %}
|
|
AND _inserted_timestamp >= (
|
|
SELECT
|
|
MAX(_inserted_timestamp)
|
|
FROM
|
|
{{ this }}
|
|
)
|
|
{% endif %}
|
|
),
|
|
deposit_events AS (
|
|
SELECT
|
|
*
|
|
FROM
|
|
base_lido_events
|
|
WHERE
|
|
ARRAY_SIZE(
|
|
instruction :accounts
|
|
) = 8
|
|
AND instruction :accounts [6] = 'TokenkegQfeZyiNwAJbNbGKPFXCWuBvf9Ss623VQ5DA'
|
|
AND instruction :accounts [7] = '11111111111111111111111111111111'
|
|
),
|
|
withdraw_events AS (
|
|
SELECT
|
|
*
|
|
FROM
|
|
base_lido_events
|
|
WHERE
|
|
ARRAY_SIZE(
|
|
instruction :accounts
|
|
) = 12
|
|
AND instruction :accounts [8] = 'TokenkegQfeZyiNwAJbNbGKPFXCWuBvf9Ss623VQ5DA'
|
|
AND instruction :accounts [9] = 'SysvarC1ock11111111111111111111111111111111'
|
|
AND instruction :accounts [10] = '11111111111111111111111111111111'
|
|
AND instruction :accounts [11] = 'Stake11111111111111111111111111111111111111'
|
|
)
|
|
--,
|
|
-- stake_events AS (
|
|
-- select *
|
|
-- from base_lido_events
|
|
-- where ARRAY_SIZE(instruction :accounts) = 13
|
|
-- and instruction:accounts[7] = 'SysvarC1ock11111111111111111111111111111111'
|
|
-- and instruction:accounts[8] = '11111111111111111111111111111111'
|
|
-- and instruction:accounts[9] = 'SysvarRent111111111111111111111111111111111'
|
|
-- and instruction:accounts[10] = 'Stake11111111111111111111111111111111111111'
|
|
-- and instruction:accounts[11] = 'SysvarStakeHistory1111111111111111111111111'
|
|
-- and instruction:accounts[12] = 'StakeConfig11111111111111111111111111111111'
|
|
-- ),
|
|
-- unstake_events AS (
|
|
-- SELECT
|
|
-- *
|
|
-- FROM
|
|
-- base_lido_events
|
|
-- WHERE
|
|
-- ARRAY_SIZE(
|
|
-- instruction :accounts
|
|
-- ) = 9
|
|
-- AND instruction :accounts [6] = 'SysvarC1ock11111111111111111111111111111111'
|
|
-- AND instruction :accounts [7] = '11111111111111111111111111111111'
|
|
-- AND instruction :accounts [8] = 'Stake11111111111111111111111111111111111111'
|
|
-- )
|
|
SELECT
|
|
e.tx_id,
|
|
e.block_id,
|
|
e.block_timestamp,
|
|
e.index,
|
|
e.succeeded,
|
|
'deposit' AS action,
|
|
e.instruction :accounts [0] :: STRING AS stake_pool,
|
|
NULL AS stake_pool_withdraw_authority,
|
|
NULL AS stake_pool_deposit_authority,
|
|
e.instruction :accounts [1] :: STRING AS address,
|
|
e.instruction :accounts [4] :: STRING AS reserve_stake_address,
|
|
i.value :parsed :info :lamports AS amount,
|
|
e._inserted_timestamp,
|
|
concat_ws('-',tx_id,e.index) as _unique_key
|
|
FROM
|
|
deposit_events e,
|
|
TABLE(FLATTEN(inner_instruction :instructions)) i
|
|
WHERE
|
|
i.value :parsed :info :lamports IS NOT NULL
|
|
UNION
|
|
SELECT
|
|
e.tx_id,
|
|
e.block_id,
|
|
e.block_timestamp,
|
|
e.index,
|
|
e.succeeded,
|
|
'withdraw' AS action,
|
|
e.instruction :accounts [0] :: STRING AS stake_pool,
|
|
e.instruction :accounts [7] :: STRING AS stake_pool_withdraw_authority,
|
|
NULL AS stake_pool_deposit_authority,
|
|
e.instruction :accounts [1] :: STRING AS address,
|
|
NULL AS reserve_stake_address,
|
|
i.value :parsed :info :lamports AS amount,
|
|
e._inserted_timestamp,
|
|
concat_ws('-',tx_id,e.index) as _unique_key
|
|
FROM
|
|
withdraw_events e,
|
|
TABLE(FLATTEN(inner_instruction :instructions)) i
|
|
WHERE
|
|
i.value :parsed :info :lamports IS NOT NULL
|
|
-- UNION
|
|
-- SELECT
|
|
-- e.tx_id,
|
|
-- e.block_timestamp,
|
|
-- e.index,
|
|
-- e.succeeded,
|
|
-- 'deposit_stake' AS action,
|
|
-- NULL AS delegator_address,
|
|
-- i.value :parsed :info :lamports AS amount,
|
|
-- e._inserted_timestamp,
|
|
-- concat_ws('-',tx_id,e.index) as _unique_key
|
|
-- FROM
|
|
-- stake_events e,
|
|
-- TABLE(FLATTEN(inner_instruction :instructions)) i
|
|
-- WHERE
|
|
-- i.value :parsed :info :lamports IS NOT NULL
|
|
-- UNION
|
|
-- SELECT
|
|
-- e.tx_id,
|
|
-- e.block_timestamp,
|
|
-- e.index,
|
|
-- e.succeeded,
|
|
-- 'unstake' AS action,
|
|
-- NULL AS delegator_address,
|
|
-- i.value :parsed :info :lamports AS amount,
|
|
-- e._inserted_timestamp,
|
|
-- concat_ws('-',tx_id,e.index) as _unique_key
|
|
-- FROM
|
|
-- unstake_events e,
|
|
-- TABLE(FLATTEN(inner_instruction :instructions)) i
|
|
-- WHERE
|
|
-- i.value :parsed :info :lamports IS NOT NULL
|