From e5931a0023995c07a57e34b9bb79b7604d1d9966 Mon Sep 17 00:00:00 2001 From: tarikceric Date: Mon, 27 Oct 2025 08:53:57 -0700 Subject: [PATCH] update staking withdraw authority --- .../silver__staking_lp_actions_labeled_2.sql | 78 +++++++++++++++++-- 1 file changed, 72 insertions(+), 6 deletions(-) diff --git a/models/silver/non_core/silver__staking_lp_actions_labeled_2.sql b/models/silver/non_core/silver__staking_lp_actions_labeled_2.sql index fb14932c..714e1900 100644 --- a/models/silver/non_core/silver__staking_lp_actions_labeled_2.sql +++ b/models/silver/non_core/silver__staking_lp_actions_labeled_2.sql @@ -209,14 +209,13 @@ tx_base AS ( CASE WHEN event_type = 'initialize' THEN instruction:parsed:info:authorized:staker::string WHEN event_type = 'initializeChecked' THEN instruction:parsed:info:staker::string - WHEN event_type = 'authorize' AND instruction:parsed:info:authorityType = 'Staker' THEN instruction:parsed:info:newAuthority::string + WHEN event_type in ('authorize','authorizeChecked') AND instruction:parsed:info:authorityType = 'Staker' THEN instruction:parsed:info:newAuthority::string ELSE instruction:parsed:info:stakeAuthority::string END AS stake_authority, CASE WHEN event_type = 'initialize' THEN instruction:parsed:info:authorized:withdrawer::string WHEN event_type = 'initializeChecked' THEN instruction:parsed:info:withdrawer::string - WHEN event_type = 'authorize' AND instruction:parsed:info:authorityType = 'Withdrawer' THEN instruction:parsed:info:newAuthority::string - WHEN event_type = 'split_destination' THEN stake_authority + WHEN event_type in ('authorize','authorizeChecked') AND instruction:parsed:info:authorityType = 'Withdrawer' THEN instruction:parsed:info:newAuthority::string ELSE NULL END AS withdraw_authority, stake_account, @@ -290,7 +289,7 @@ fill_vote_acct AS ( tx_base.withdraw_authority, last_value(tx_base.withdraw_authority) IGNORE NULLS OVER ( PARTITION BY tx_base.stake_account - ORDER BY block_id, index, inner_index + ORDER BY block_id, index, COALESCE(inner_index, -1) ROWS UNBOUNDED PRECEDING ), latest_state.withdraw_authority @@ -329,6 +328,7 @@ fill_vote_acct AS ( ON latest_state.stake_account = tx_base.stake_account ), + temp AS ( SELECT b.block_id, @@ -339,7 +339,12 @@ temp AS ( b.inner_index, b.event_type, b.signers, - b.stake_authority, + -- For split_destination, inherit stake_authority from split_source if available + CASE + WHEN b.event_type = 'split_destination' AND A.stake_authority IS NOT NULL + THEN A.stake_authority + ELSE b.stake_authority + END AS stake_authority, b.withdraw_authority, b.stake_account, b.parent_stake_account, @@ -363,6 +368,67 @@ temp AS ( AND A.event_type = 'split_source' ), +-- Step 1: Add parent withdraw_authority for split inheritance using window functions +temp_with_parent_authority AS ( + SELECT + *, + -- For split_destination events, get the withdraw_authority from the parent account + -- Use a window function to find the most recent withdraw_authority for the parent + CASE + WHEN event_type = 'split_destination' AND parent_stake_account IS NOT NULL THEN + LAST_VALUE( + CASE WHEN stake_account = parent_stake_account THEN withdraw_authority END + ) IGNORE NULLS OVER ( + PARTITION BY tx_id + ORDER BY index, COALESCE(inner_index, -1) + ROWS UNBOUNDED PRECEDING + ) + ELSE NULL + END AS parent_withdraw_authority + FROM temp +), + +-- Step 2: Apply inheritance logic +temp_with_inheritance AS ( + SELECT + block_id, + block_timestamp, + tx_id, + succeeded, + index, + inner_index, + event_type, + signers, + stake_authority, + -- Apply the three inheritance rules + COALESCE( + -- 1. Use explicit withdraw_authority if set by the event + withdraw_authority, + -- 2. For split_destination, inherit from parent + parent_withdraw_authority, + -- 3. Use temporal inheritance within same stake_account + LAST_VALUE(withdraw_authority) IGNORE NULLS OVER ( + PARTITION BY stake_account + ORDER BY block_id, index, COALESCE(inner_index, -1) + ROWS UNBOUNDED PRECEDING + ), + -- 4. Fallback for completely new accounts + signers[0]::string + ) AS withdraw_authority, + stake_account, + parent_stake_account, + stake_active, + pre_tx_staked_balance, + post_tx_staked_balance, + withdraw_amount, + withdraw_destination, + move_amount, + move_destination, + vote_account, + _inserted_timestamp + FROM temp_with_parent_authority +), + temp2 AS ( SELECT block_id, @@ -395,7 +461,7 @@ temp2 AS ( END AS vote_account, _inserted_timestamp FROM - temp + temp_with_inheritance ) SELECT