From 41f0417890d25b36b35ca2fa220585112c438dfa Mon Sep 17 00:00:00 2001 From: tarikceric <46071768+tarikceric@users.noreply.github.com> Date: Mon, 19 Feb 2024 09:13:11 -0800 Subject: [PATCH] An 4449/staking tables update (#487) * update jito staking * update token --- data/testing__stake_pool_actions_generic.csv | 4 - data/testing__stake_pool_actions_jito.csv | 7 + .../defi/defi__fact_stake_pool_actions.sql | 21 +- .../silver__stake_pool_actions_generic.sql | 3 - .../silver__stake_pool_actions_generic.yml | 2 - .../silver__stake_pool_actions_jito.sql | 426 ++++++++++++++++++ .../silver__stake_pool_actions_jito.yml | 87 ++++ 7 files changed, 540 insertions(+), 10 deletions(-) create mode 100644 data/testing__stake_pool_actions_jito.csv create mode 100644 models/silver/staking/silver__stake_pool_actions_jito.sql create mode 100644 models/silver/staking/silver__stake_pool_actions_jito.yml diff --git a/data/testing__stake_pool_actions_generic.csv b/data/testing__stake_pool_actions_generic.csv index fc3c4766..bd451e78 100644 --- a/data/testing__stake_pool_actions_generic.csv +++ b/data/testing__stake_pool_actions_generic.csv @@ -13,9 +13,5 @@ PLaj4us6K5nR3wzvy78CKdChUwTBXVnwuuq2AEMje92YkAzfBnkbiZ6JAnDWenbfrCRnnGmpyk8YFhss PLaj4us6K5nR3wzvy78CKdChUwTBXVnwuuq2AEMje92YkAzfBnkbiZ6JAnDWenbfrCRnnGmpyk8YFhssDEZgAGb,4,-1,withdraw_stake,CtMyWsrUtAwXWiGr9WjHT5fC3p3fgV8cyGpLTo2LJzG1,HbJTxftxnXgpePCshA8FubsRj9MW4kfPscfuUfn44fnt,,YoUqcx1VdF4d5othDYbJhfFLvorBQGTKcFUKkRHH9ue,,107125913 HMFzzGrNy684rDDrwJR2vDFGSfLY4LBeZ7pXi3e2LNLDNtA54tW1V11FaUMxQ6xaHtpDCV6vdd5cDM3zJCecAV5,3,12,deposit_stake,CtMyWsrUtAwXWiGr9WjHT5fC3p3fgV8cyGpLTo2LJzG1,HbJTxftxnXgpePCshA8FubsRj9MW4kfPscfuUfn44fnt,GCjhUMwq9TxMDG6omiWq2qmjikSDE6jEqU7M6HQA16nT,71WDyyCsZwyEYDV91Qrb212rdg6woCHYQhFnmZUBxiJ6,AXu3DTw9AFq9FDTzX4vqA3XiT7LjrS5DpbsZaPpEx6qR,27670038 HMFzzGrNy684rDDrwJR2vDFGSfLY4LBeZ7pXi3e2LNLDNtA54tW1V11FaUMxQ6xaHtpDCV6vdd5cDM3zJCecAV5,3,4,withdraw_stake,stk9ApL5HeVAwPLr3TLhDXdZS8ptVu7zp6ov8HFDuMi,6WecYymEARvjG5ZyqkrVQ6YkhPfujNzWpSPwNKXHCbV2,,6U91aKa8pmMxkJwBCfPTmUEfZi6dHe7DcFq2ALvB2tbB,,27670038 -fn3s4BFL4tYwCWm7qVpeiMaoufr2yW3BdvS7w75RCY6mKhamEwJKtq6LcJdvJqbNro4EnyKW52uBmkNwmCsFkft,1,-1,deposit,Jito4APyf642JPZPx3hGc6WWJ8zPKtRbRs4P815Awbb,6iQKfEyhr3bZMotVkW6beNZz5CPAkiwvgV2CTje9pVSS,,F4j4un3cSHwwhNW9USgrvaHUVwjgY45mhvh75cGEAdDa,BgKUXdS29YcHCFrPm5M8oLHiTzZaMDjsebggjoaQ6KFL,2000000000 -2ZUtEGM3QUcQCR11nh8VVCRTEpXtgfrsbDMz7eymk4WShUDeRPrFE7Ja39ZkjioacJ7x6wJ2fbfmJybVM89pgEVJ,0,9,withdraw,Jito4APyf642JPZPx3hGc6WWJ8zPKtRbRs4P815Awbb,6iQKfEyhr3bZMotVkW6beNZz5CPAkiwvgV2CTje9pVSS,,AYZVGXdsXrdi2S2E2Ka3EiLYxC6Ra3jNeXqqnaRR9eSD,BgKUXdS29YcHCFrPm5M8oLHiTzZaMDjsebggjoaQ6KFL,707732780 3N3iRkkzC5NydgGLHHLxUH1krUjYpp7mDhQnMnuiHNk33r728MjYDm5SZCdhJAUuVcq7gpNxTrefYKwHVpfGGB9B,6,13,withdraw_stake,CtMyWsrUtAwXWiGr9WjHT5fC3p3fgV8cyGpLTo2LJzG1,HbJTxftxnXgpePCshA8FubsRj9MW4kfPscfuUfn44fnt,,9nnLbotNTcUhvbrsA6Mdkx45Sm82G35zo28AqUvjExn8,,22844333 -3N3iRkkzC5NydgGLHHLxUH1krUjYpp7mDhQnMnuiHNk33r728MjYDm5SZCdhJAUuVcq7gpNxTrefYKwHVpfGGB9B,6,21,deposit_stake,Jito4APyf642JPZPx3hGc6WWJ8zPKtRbRs4P815Awbb,6iQKfEyhr3bZMotVkW6beNZz5CPAkiwvgV2CTje9pVSS,74opVa3v51hUmTrsZn8YusZw4fXB16vGQY4WYHt9UegR,71WDyyCsZwyEYDV91Qrb212rdg6woCHYQhFnmZUBxiJ6,BgKUXdS29YcHCFrPm5M8oLHiTzZaMDjsebggjoaQ6KFL,22844333 -TuJHZeAy2czF3LJyNtgcHyr6ngcX692cnQzNj2wvV38JJr3mGJ3N6tBq27w4S94pKNj9tNnCbtvTModwf9MpNgj,4,4,withdraw_stake,Jito4APyf642JPZPx3hGc6WWJ8zPKtRbRs4P815Awbb,6iQKfEyhr3bZMotVkW6beNZz5CPAkiwvgV2CTje9pVSS,,9nnLbotNTcUhvbrsA6Mdkx45Sm82G35zo28AqUvjExn8,,27854876 TuJHZeAy2czF3LJyNtgcHyr6ngcX692cnQzNj2wvV38JJr3mGJ3N6tBq27w4S94pKNj9tNnCbtvTModwf9MpNgj,4,12,deposit_stake,CtMyWsrUtAwXWiGr9WjHT5fC3p3fgV8cyGpLTo2LJzG1,HbJTxftxnXgpePCshA8FubsRj9MW4kfPscfuUfn44fnt,GCjhUMwq9TxMDG6omiWq2qmjikSDE6jEqU7M6HQA16nT,71WDyyCsZwyEYDV91Qrb212rdg6woCHYQhFnmZUBxiJ6,AXu3DTw9AFq9FDTzX4vqA3XiT7LjrS5DpbsZaPpEx6qR,27854876 \ No newline at end of file diff --git a/data/testing__stake_pool_actions_jito.csv b/data/testing__stake_pool_actions_jito.csv new file mode 100644 index 00000000..43c16879 --- /dev/null +++ b/data/testing__stake_pool_actions_jito.csv @@ -0,0 +1,7 @@ +tx_id,index,inner_index,action,stake_pool,stake_pool_withdraw_authority,stake_pool_deposit_authority,address,reserve_stake_address,amount +fn3s4BFL4tYwCWm7qVpeiMaoufr2yW3BdvS7w75RCY6mKhamEwJKtq6LcJdvJqbNro4EnyKW52uBmkNwmCsFkft,1,-1,deposit,Jito4APyf642JPZPx3hGc6WWJ8zPKtRbRs4P815Awbb,6iQKfEyhr3bZMotVkW6beNZz5CPAkiwvgV2CTje9pVSS,,F4j4un3cSHwwhNW9USgrvaHUVwjgY45mhvh75cGEAdDa,BgKUXdS29YcHCFrPm5M8oLHiTzZaMDjsebggjoaQ6KFL,2000000000 +2ZUtEGM3QUcQCR11nh8VVCRTEpXtgfrsbDMz7eymk4WShUDeRPrFE7Ja39ZkjioacJ7x6wJ2fbfmJybVM89pgEVJ,0,9,withdraw,Jito4APyf642JPZPx3hGc6WWJ8zPKtRbRs4P815Awbb,6iQKfEyhr3bZMotVkW6beNZz5CPAkiwvgV2CTje9pVSS,,AYZVGXdsXrdi2S2E2Ka3EiLYxC6Ra3jNeXqqnaRR9eSD,BgKUXdS29YcHCFrPm5M8oLHiTzZaMDjsebggjoaQ6KFL,707732780 +3N3iRkkzC5NydgGLHHLxUH1krUjYpp7mDhQnMnuiHNk33r728MjYDm5SZCdhJAUuVcq7gpNxTrefYKwHVpfGGB9B,6,21,deposit_stake,Jito4APyf642JPZPx3hGc6WWJ8zPKtRbRs4P815Awbb,6iQKfEyhr3bZMotVkW6beNZz5CPAkiwvgV2CTje9pVSS,74opVa3v51hUmTrsZn8YusZw4fXB16vGQY4WYHt9UegR,71WDyyCsZwyEYDV91Qrb212rdg6woCHYQhFnmZUBxiJ6,BgKUXdS29YcHCFrPm5M8oLHiTzZaMDjsebggjoaQ6KFL,22844333 +TuJHZeAy2czF3LJyNtgcHyr6ngcX692cnQzNj2wvV38JJr3mGJ3N6tBq27w4S94pKNj9tNnCbtvTModwf9MpNgj,4,4,withdraw_stake,Jito4APyf642JPZPx3hGc6WWJ8zPKtRbRs4P815Awbb,6iQKfEyhr3bZMotVkW6beNZz5CPAkiwvgV2CTje9pVSS,,9nnLbotNTcUhvbrsA6Mdkx45Sm82G35zo28AqUvjExn8,,27854876 +2onuSzNrK1oNKTbS2AED5F4PTRdk1qLgPhAHYjUv1AMzWYTLDdRR43jgreb8ZQjeRDBYy4HmctJEfpxMxgHiPPCw,2,5,deposit,Jito4APyf642JPZPx3hGc6WWJ8zPKtRbRs4P815Awbb,6iQKfEyhr3bZMotVkW6beNZz5CPAkiwvgV2CTje9pVSS,,JASXSsdGAeraHAm6sKu6RSGBZiQYeujS7vejyC2wqAgx,BgKUXdS29YcHCFrPm5M8oLHiTzZaMDjsebggjoaQ6KFL,10000000 +L7RwAzBZ1Dd7NbiKGbj7xf9mfFtkDoEgbbKN3HyyfKj3gLhHYWuxHSazvxePJG6aXqw5Ard1MBZpk8ZPeLC4EuX,5,4,deposit,Jito4APyf642JPZPx3hGc6WWJ8zPKtRbRs4P815Awbb,6iQKfEyhr3bZMotVkW6beNZz5CPAkiwvgV2CTje9pVSS,,FsAHYVSL4EYJ5KWtakT9uyUMMp7jtdQVpT9Kboxjuexh,BgKUXdS29YcHCFrPm5M8oLHiTzZaMDjsebggjoaQ6KFL,1000000000 diff --git a/models/gold/defi/defi__fact_stake_pool_actions.sql b/models/gold/defi/defi__fact_stake_pool_actions.sql index f040432a..111bf3b7 100644 --- a/models/gold/defi/defi__fact_stake_pool_actions.sql +++ b/models/gold/defi/defi__fact_stake_pool_actions.sql @@ -69,7 +69,6 @@ SELECT WHEN stake_pool = '7ge2xKsZXmqPxa3YmXxXmzCp9Hc2ezrTxh6PECaxCwrL' THEN 'daopool' WHEN stake_pool = 'CtMyWsrUtAwXWiGr9WjHT5fC3p3fgV8cyGpLTo2LJzG1' THEN 'jpool' WHEN stake_pool = 'stk9ApL5HeVAwPLr3TLhDXdZS8ptVu7zp6ov8HFDuMi' THEN 'blazestake' - WHEN stake_pool = 'Jito4APyf642JPZPx3hGc6WWJ8zPKtRbRs4P815Awbb' THEN 'jito' WHEN stake_pool = 'CgnTSoL3DgY9SFHxcLj6CgCgKKoTBr6tp4CPAEWy25DE' THEN 'cogent' WHEN stake_pool = 'LAinEtNLgpmCP9Rvsf5Hn8W6EhNiKLZQti1xfWMLy6X' THEN 'laine' END AS stake_pool_name, @@ -132,3 +131,23 @@ FROM {{ ref( 'silver__stake_pool_actions_marinade' ) }} +UNION ALL +SELECT + 'jito' AS stake_pool_name, + tx_id, + block_id, + block_timestamp, + INDEX, + succeeded, + action, + address, + stake_pool, + amount, + 'SOL' AS token, + stake_pool_actions_jito_id AS fact_stake_pool_actions_id, + inserted_timestamp, + modified_timestamp +FROM + {{ ref( + 'silver__stake_pool_actions_jito' + ) }} diff --git a/models/silver/staking/silver__stake_pool_actions_generic.sql b/models/silver/staking/silver__stake_pool_actions_generic.sql index 4dc83437..2ea22db3 100644 --- a/models/silver/staking/silver__stake_pool_actions_generic.sql +++ b/models/silver/staking/silver__stake_pool_actions_generic.sql @@ -59,8 +59,6 @@ base_stake_pool_events AS ( 'stk9ApL5HeVAwPLr3TLhDXdZS8ptVu7zp6ov8HFDuMi', -- jpool stake pool 'CtMyWsrUtAwXWiGr9WjHT5fC3p3fgV8cyGpLTo2LJzG1', - -- jito stake pool - 'Jito4APyf642JPZPx3hGc6WWJ8zPKtRbRs4P815Awbb', -- cogent stake pool 'CgnTSoL3DgY9SFHxcLj6CgCgKKoTBr6tp4CPAEWy25DE', -- laine stake pool @@ -90,7 +88,6 @@ base_stake_pool_events AS ( '7ge2xKsZXmqPxa3YmXxXmzCp9Hc2ezrTxh6PECaxCwrL', 'stk9ApL5HeVAwPLr3TLhDXdZS8ptVu7zp6ov8HFDuMi', 'CtMyWsrUtAwXWiGr9WjHT5fC3p3fgV8cyGpLTo2LJzG1', - 'Jito4APyf642JPZPx3hGc6WWJ8zPKtRbRs4P815Awbb', 'CgnTSoL3DgY9SFHxcLj6CgCgKKoTBr6tp4CPAEWy25DE', 'LAinEtNLgpmCP9Rvsf5Hn8W6EhNiKLZQti1xfWMLy6X' ) diff --git a/models/silver/staking/silver__stake_pool_actions_generic.yml b/models/silver/staking/silver__stake_pool_actions_generic.yml index 2aaa8a4c..c32f4c64 100644 --- a/models/silver/staking/silver__stake_pool_actions_generic.yml +++ b/models/silver/staking/silver__stake_pool_actions_generic.yml @@ -30,8 +30,6 @@ models: '34vDDmQMPuupNKSgVRQyXrrBsMpJpQGZXagPN4xcQmMa1ebJLkfzYuXu5AsKhy6HiKN1vtfUQGLxgkqPumGxCNLz', 'PLaj4us6K5nR3wzvy78CKdChUwTBXVnwuuq2AEMje92YkAzfBnkbiZ6JAnDWenbfrCRnnGmpyk8YFhssDEZgAGb', 'HMFzzGrNy684rDDrwJR2vDFGSfLY4LBeZ7pXi3e2LNLDNtA54tW1V11FaUMxQ6xaHtpDCV6vdd5cDM3zJCecAV5', - 'fn3s4BFL4tYwCWm7qVpeiMaoufr2yW3BdvS7w75RCY6mKhamEwJKtq6LcJdvJqbNro4EnyKW52uBmkNwmCsFkft', - '2ZUtEGM3QUcQCR11nh8VVCRTEpXtgfrsbDMz7eymk4WShUDeRPrFE7Ja39ZkjioacJ7x6wJ2fbfmJybVM89pgEVJ', '3N3iRkkzC5NydgGLHHLxUH1krUjYpp7mDhQnMnuiHNk33r728MjYDm5SZCdhJAUuVcq7gpNxTrefYKwHVpfGGB9B', 'TuJHZeAy2czF3LJyNtgcHyr6ngcX692cnQzNj2wvV38JJr3mGJ3N6tBq27w4S94pKNj9tNnCbtvTModwf9MpNgj')" columns: diff --git a/models/silver/staking/silver__stake_pool_actions_jito.sql b/models/silver/staking/silver__stake_pool_actions_jito.sql new file mode 100644 index 00000000..6737a540 --- /dev/null +++ b/models/silver/staking/silver__stake_pool_actions_jito.sql @@ -0,0 +1,426 @@ +{{ config( + materialized = 'incremental', + unique_key = "stake_pool_actions_jito_id", + incremental_strategy = 'merge', + cluster_by = ['block_timestamp::DATE','_inserted_timestamp::date'], + merge_exclude_columns = ["inserted_timestamp"], + tags = ['scheduled_non_core'] +) }} + +WITH base_events AS ( + + SELECT + * + FROM + {{ ref('silver__events') }} + WHERE + ( + program_id = 'SPoo1Ku8WFXoNDMHPsrGSTSG1Y47rzgn41SLUNakuHy' + OR ARRAY_CONTAINS( + 'SPoo1Ku8WFXoNDMHPsrGSTSG1Y47rzgn41SLUNakuHy' :: variant, + inner_instruction_program_ids + ) + ) + +{% if is_incremental() %} +AND _inserted_timestamp >= ( + SELECT + MAX(_inserted_timestamp) + FROM + {{ this }} +) +{% else %} + -- and block_timestamp :: DATE between '2024-02-01' and '2024-02-10' + AND block_timestamp :: DATE >= '2022-10-30' +{% endif %} +), +base_stake_pool_events AS ( + SELECT + block_timestamp, + block_id, + tx_id, + succeeded, + INDEX, + -1 AS inner_index, + program_id, + instruction AS instruction_temp, + inner_instruction, + instruction :accounts AS accounts, + ARRAY_SIZE(accounts) AS num_accounts, + _inserted_timestamp, + signers + FROM + base_events + WHERE + program_id = 'SPoo1Ku8WFXoNDMHPsrGSTSG1Y47rzgn41SLUNakuHy' + AND instruction :accounts [0] :: STRING = 'Jito4APyf642JPZPx3hGc6WWJ8zPKtRbRs4P815Awbb' + UNION ALL + SELECT + e.block_timestamp, + e.block_id, + e.tx_id, + e.succeeded, + e.index, + i.index AS inner_index, + i.value :programId :: STRING AS program_id, + i.value AS instruction_temp, + NULL AS inner_instruction, + i.value :accounts AS accounts, + ARRAY_SIZE(accounts) AS num_accounts, + e._inserted_timestamp, + e.signers + FROM + base_events e, + TABLE(FLATTEN(e.inner_instruction :instructions)) i + WHERE + i.value :programId :: STRING = 'SPoo1Ku8WFXoNDMHPsrGSTSG1Y47rzgn41SLUNakuHy' + AND i.value :accounts [0] :: STRING = 'Jito4APyf642JPZPx3hGc6WWJ8zPKtRbRs4P815Awbb' +), +deposit_events AS ( + SELECT + * + FROM + base_stake_pool_events + WHERE + num_accounts IN ( + 10, + 11 + ) + AND accounts [8] :: STRING = '11111111111111111111111111111111' + AND accounts [9] :: STRING = 'TokenkegQfeZyiNwAJbNbGKPFXCWuBvf9Ss623VQ5DA' +), +deposit_stake_events AS ( + SELECT + * + FROM + base_stake_pool_events + WHERE + num_accounts = 15 + AND accounts [11] :: STRING = 'SysvarC1ock11111111111111111111111111111111' + AND accounts [12] :: STRING = 'SysvarStakeHistory1111111111111111111111111' + AND accounts [13] :: STRING = 'TokenkegQfeZyiNwAJbNbGKPFXCWuBvf9Ss623VQ5DA' + AND accounts [14] :: STRING = 'Stake11111111111111111111111111111111111111' +), +inner_deposit_transfers AS ( + SELECT + t.block_id, + t.block_timestamp, + t.tx_id, + COALESCE(SPLIT_PART(t.index :: text, '.', 1) :: INT, t.index :: INT) AS INDEX, + NULLIF(SPLIT_PART(t.index :: text, '.', 2), '') :: INT AS inner_index, + t.tx_from, + t.tx_to, + t.amount + FROM + {{ ref('silver__transfers') }} t + INNER JOIN ( + SELECT + DISTINCT tx_id, + block_timestamp :: DATE AS b_date, + inner_index + FROM + deposit_events + WHERE + inner_index <> -1 + ) e + ON e.b_date = t.block_timestamp :: DATE + AND e.tx_id = t.tx_id + AND t.program_id = '11111111111111111111111111111111' + AND mint = 'So11111111111111111111111111111111111111112' + +{% if is_incremental() %} +WHERE + t._inserted_timestamp >= ( + SELECT + MAX(_inserted_timestamp) + FROM + {{ this }} + ) +{% else %} +WHERE + -- t.block_timestamp :: DATE between '2024-02-01' and '2024-02-10' + t.block_timestamp :: DATE >= '2022-10-30' +{% endif %} +), +withdraw_events AS ( + SELECT + * + FROM + base_stake_pool_events + WHERE + num_accounts IN ( + 12, + 13 + ) + AND accounts [8] :: STRING = 'SysvarC1ock11111111111111111111111111111111' + AND accounts [9] :: STRING = 'SysvarStakeHistory1111111111111111111111111' + AND accounts [10] :: STRING = 'Stake11111111111111111111111111111111111111' + AND accounts [11] :: STRING = 'TokenkegQfeZyiNwAJbNbGKPFXCWuBvf9Ss623VQ5DA' +), +-- multiple withdraws in inner_instruction can be exactly the same so get the range to relate to correct Spoo1... event +withdraw_events_inner_program_range AS ( + SELECT + *, + CASE + WHEN inner_index <> -1 THEN inner_index + END AS start_inner_program, + CASE + WHEN inner_index = -1 THEN NULL + ELSE ( + COALESCE(LEAD(inner_index) over (PARTITION BY tx_id, INDEX + ORDER BY + inner_index) -1, 999999) + ) + END AS end_inner_program + FROM + withdraw_events +), +withdraw_stake_events AS ( + SELECT + * + FROM + base_stake_pool_events + WHERE + ARRAY_SIZE( + accounts + ) = 13 + AND accounts [10] :: STRING = 'SysvarC1ock11111111111111111111111111111111' + AND accounts [11] :: STRING = 'TokenkegQfeZyiNwAJbNbGKPFXCWuBvf9Ss623VQ5DA' + AND accounts [12] :: STRING = 'Stake11111111111111111111111111111111111111' +), +base_balances AS ( + SELECT + t.tx_id, + signers, + pre_balances, + post_balances, + account_keys + FROM + {{ ref('silver__transactions') }} + t + INNER JOIN ( + SELECT + DISTINCT tx_id, + block_timestamp :: DATE AS b_date + FROM + deposit_stake_events + ) e + ON e.b_date = t.block_timestamp :: DATE + AND e.tx_id = t.tx_id + +{% if is_incremental() %} +WHERE + _inserted_timestamp >= ( + SELECT + MAX(_inserted_timestamp) + FROM + {{ this }} + ) +{% else %} +WHERE + -- t.block_timestamp :: DATE between '2024-02-01' and '2024-02-10' + t.block_timestamp :: DATE >= '2022-10-30' +{% endif %} +), +merge_events AS ( + SELECT + b.tx_id, + b.index, + i.index AS inner_index, + i.value :parsed :info :destination :: STRING AS merge_destination, + i.value :parsed :info :stakeAuthority :: STRING AS temp_stake_authority + FROM + base_events b, + TABLE(FLATTEN(inner_instruction :instructions)) i + WHERE + i.value :parsed :type = 'merge' + AND i.value :programId = 'Stake11111111111111111111111111111111111111' + AND b.tx_id IN ( + SELECT + tx_id + FROM + deposit_stake_events + ) +), +deposit_stake_merge AS ( + SELECT + e.tx_id, + e.block_id, + e.block_timestamp, + e.index, + e.inner_index, + e.succeeded, + e.accounts [0] :: STRING AS stake_pool, + e.accounts [3] :: STRING AS stake_pool_withdraw_authority, + e.accounts [2] :: STRING AS stake_pool_deposit_authority, + b.signers [0] :: STRING AS address, + e.accounts [6] :: STRING AS reserve_stake_address, + i.merge_destination, + silver.udf_get_account_balances_index( + merge_destination, + b.account_keys + ) AS merge_destination_balances_index, + silver.udf_get_account_balances_index( + reserve_stake_address, + b.account_keys + ) AS reserve_stake_balances_index, + b.post_balances [merge_destination_balances_index] - b.pre_balances [merge_destination_balances_index] + b.post_balances [reserve_stake_balances_index] - b.pre_balances [reserve_stake_balances_index] AS amount, + e._inserted_timestamp + FROM + deposit_stake_events e + LEFT OUTER JOIN base_balances b + ON b.tx_id = e.tx_id + LEFT OUTER JOIN merge_events i + ON e.tx_id = i.tx_id + AND e.index = i.index + WHERE + amount IS NOT NULL + AND i.temp_stake_authority = stake_pool_withdraw_authority + AND i.merge_destination = e.accounts [5] :: STRING +), +pre_final AS ( + SELECT + e.tx_id, + e.block_id, + e.block_timestamp, + e.index, + e.inner_index, + e.succeeded, + 'deposit' AS action, + e.accounts [0] :: STRING AS stake_pool, + e.accounts [1] :: STRING AS stake_pool_withdraw_authority, + NULL AS stake_pool_deposit_authority, + e.signers [0] :: STRING AS address, + e.accounts [2] :: STRING AS reserve_stake_address, + (t.amount * pow(10, 9)) :: INT AS amount, + e._inserted_timestamp + FROM + deposit_events e + LEFT JOIN inner_deposit_transfers t + ON e.tx_id = t.tx_id + AND e.accounts [3] :: STRING = t.tx_from + and e.index = t.index + and e.inner_index = (t.inner_index - 1) + where + e.inner_index <> -1 + UNION + SELECT + e.tx_id, + e.block_id, + e.block_timestamp, + e.index, + e.inner_index, + e.succeeded, + 'deposit' AS action, + e.accounts [0] :: STRING AS stake_pool, + e.accounts [1] :: STRING AS stake_pool_withdraw_authority, + NULL AS stake_pool_deposit_authority, + e.signers [0] :: STRING AS address, + -- use signers instead of instruction account because of "passthrough" wallets + e.accounts [2] :: STRING AS reserve_stake_address, + i.value :parsed :info :lamports AS amount, + e._inserted_timestamp + FROM + deposit_events e + LEFT OUTER JOIN 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.inner_index, + e.succeeded, + 'withdraw' AS action, + e.accounts [0] :: STRING AS stake_pool, + e.accounts [1] :: STRING AS stake_pool_withdraw_authority, + NULL AS stake_pool_deposit_authority, + e.accounts [5] :: STRING AS address, + e.accounts [4] :: STRING AS reserve_stake_address, + i.value :parsed :info :lamports AS amount, + e._inserted_timestamp + FROM + withdraw_events_inner_program_range e + LEFT OUTER JOIN base_events b + ON e.tx_id = b.tx_id + AND e.index = b.index + LEFT OUTER JOIN TABLE(FLATTEN(b.inner_instruction :instructions)) i + WHERE + i.value :parsed :type = 'withdraw' + AND i.value :parsed :info :withdrawAuthority = stake_pool_withdraw_authority + AND i.value :parsed :info :lamports IS NOT NULL + AND ( + e.start_inner_program IS NULL + OR i.index BETWEEN e.start_inner_program + AND e.end_inner_program + ) + UNION + SELECT + e.tx_id, + e.block_id, + e.block_timestamp, + e.index, + e.inner_index, + e.succeeded, + 'deposit_stake' AS action, + e.stake_pool, + e.stake_pool_withdraw_authority, + e.stake_pool_deposit_authority, + e.address, + e.reserve_stake_address, + e.amount :: NUMBER AS amount, + e._inserted_timestamp + FROM + deposit_stake_merge e + UNION + SELECT + e.tx_id, + e.block_id, + e.block_timestamp, + e.index, + e.inner_index, + e.succeeded, + 'withdraw_stake' AS action, + e.accounts [0] :: STRING AS stake_pool, + e.accounts [2] :: STRING AS stake_pool_withdraw_authority, + NULL AS stake_pool_deposit_authority, + e.accounts [5] :: STRING AS address, + NULL AS reserve_stake_address, + i.value :parsed :info :lamports AS amount, + e._inserted_timestamp + FROM + withdraw_stake_events e + LEFT OUTER JOIN base_events b + ON e.tx_id = b.tx_id + AND e.index = b.index + LEFT OUTER JOIN TABLE(FLATTEN(b.inner_instruction :instructions)) i + WHERE + i.value :parsed :info :lamports IS NOT NULL + AND i.value :parsed :type :: STRING = 'split' + AND i.value :parsed :info :newSplitAccount = e.accounts [4] +) +SELECT + tx_id, + block_id, + block_timestamp, + INDEX, + inner_index, + succeeded, + action, + stake_pool, + stake_pool_withdraw_authority, + stake_pool_deposit_authority, + address, + reserve_stake_address, + amount, + _inserted_timestamp, + {{ dbt_utils.generate_surrogate_key( + ['tx_id', 'index', 'inner_index'] + ) }} AS stake_pool_actions_jito_id, + SYSDATE() AS inserted_timestamp, + SYSDATE() AS modified_timestamp, + '{{ invocation_id }}' AS _invocation_id +FROM + pre_final diff --git a/models/silver/staking/silver__stake_pool_actions_jito.yml b/models/silver/staking/silver__stake_pool_actions_jito.yml new file mode 100644 index 00000000..cc6da866 --- /dev/null +++ b/models/silver/staking/silver__stake_pool_actions_jito.yml @@ -0,0 +1,87 @@ +version: 2 +models: + - name: silver__stake_pool_actions_jito + tests: + - dbt_utils.unique_combination_of_columns: + combination_of_columns: + - stake_pool_actions_jito_id + - compare_model_subset: + name: silver__stake_pool_actions_jito_business_logic_test + compare_model: ref('testing__stake_pool_actions_jito') + compare_columns: + - tx_id + - index + - inner_index + - action + - stake_pool + - stake_pool_withdraw_authority + - stake_pool_deposit_authority + - address + - reserve_stake_address + - amount + model_condition: "where tx_id in ('fn3s4BFL4tYwCWm7qVpeiMaoufr2yW3BdvS7w75RCY6mKhamEwJKtq6LcJdvJqbNro4EnyKW52uBmkNwmCsFkft', + '2ZUtEGM3QUcQCR11nh8VVCRTEpXtgfrsbDMz7eymk4WShUDeRPrFE7Ja39ZkjioacJ7x6wJ2fbfmJybVM89pgEVJ', + '3N3iRkkzC5NydgGLHHLxUH1krUjYpp7mDhQnMnuiHNk33r728MjYDm5SZCdhJAUuVcq7gpNxTrefYKwHVpfGGB9B', + 'TuJHZeAy2czF3LJyNtgcHyr6ngcX692cnQzNj2wvV38JJr3mGJ3N6tBq27w4S94pKNj9tNnCbtvTModwf9MpNgj', + '2onuSzNrK1oNKTbS2AED5F4PTRdk1qLgPhAHYjUv1AMzWYTLDdRR43jgreb8ZQjeRDBYy4HmctJEfpxMxgHiPPCw', + 'L7RwAzBZ1Dd7NbiKGbj7xf9mfFtkDoEgbbKN3HyyfKj3gLhHYWuxHSazvxePJG6aXqw5Ard1MBZpk8ZPeLC4EuX')" + columns: + - name: BLOCK_TIMESTAMP + description: "{{ doc('block_timestamp') }}" + tests: + - not_null + - dbt_expectations.expect_row_values_to_have_recent_data: + datepart: day + interval: 2 + - name: BLOCK_ID + description: "{{ doc('block_id') }}" + tests: + - not_null + - name: TX_ID + description: "{{ doc('tx_id') }}" + tests: + - not_null + - name: INDEX + description: Location of the stake pool action within a transaction + tests: + - not_null + - name: INNER_INDEX + description: Location of the stake pool action within the inner instructions of a transaction + tests: + - not_null + - name: SUCCEEDED + description: "{{ doc('tx_succeeded') }}" + tests: + - not_null + - name: ACTION + description: "{{ doc('stake_pool_action') }}" + tests: + - not_null + - name: STAKE_POOL + description: "{{ doc('stake_pool') }}" + tests: + - not_null + - name: STAKE_POOL_WITHDRAW_AUTHORITY + description: "{{ doc('stake_pool_withdraw_authority') }}" + tests: + - not_null + - name: STAKE_POOL_DEPOSIT_AUTHORITY + description: "{{ doc('stake_pool_deposit_authority') }}" + - name: ADDRESS + description: "{{ doc('stake_pool_address') }}" + tests: + - not_null + - name: RESERVE_STAKE_ADDRESS + description: "{{ doc('stake_pool_reserve_stake_address') }}" + tests: + - not_null: + where: action <> 'withdraw_stake' + - name: AMOUNT + description: "{{ doc('stake_pool_amount') }}" + tests: + - not_null: + where: succeeded = true + - name: _INSERTED_TIMESTAMP + description: "{{ doc('_inserted_timestamp') }}" + tests: + - not_null \ No newline at end of file