diff --git a/db/process_delegations.sql b/db/process_delegations.sql index 41880c2ce70741451feedf0688df0adb4eac5ae5..d491e8789b0ee56cdc34daa22558244ef6313d06 100644 --- a/db/process_delegations.sql +++ b/db/process_delegations.sql @@ -13,39 +13,22 @@ DECLARE __delete_canceled_delegations INT; __insert_delegations INT; BEGIN -WITH process_block_range_data_b AS +WITH process_block_range_data_b AS MATERIALIZED ( SELECT - ov.body_binary::jsonb AS body, + (SELECT av.id FROM accounts_view av WHERE av.name = get_impacted_delegation_balances.delegator) AS delegator, + (SELECT av.id FROM accounts_view av WHERE av.name = get_impacted_delegation_balances.delegatee) AS delegatee, + get_impacted_delegation_balances.amount AS balance, ov.id AS source_op, ov.block_num as source_op_block, ov.op_type_id FROM operations_view ov + CROSS JOIN get_impacted_delegation_balances(ov.body, ov.op_type_id) AS get_impacted_delegation_balances WHERE ov.op_type_id IN (40,41,62,68) AND ov.block_num BETWEEN _from AND _to ), --------------------------------------------------------------------------------------- --- convert balances depending on operation type -get_impacted_delegations AS ( - SELECT - get_impacted_delegation_balances(fio.body, fio.op_type_id) AS get_impacted_delegation_balances, - fio.op_type_id, - fio.source_op, - fio.source_op_block - FROM process_block_range_data_b fio -), -convert_parameters_for_delegations AS MATERIALIZED ( - SELECT - (SELECT av.id FROM accounts_view av WHERE av.name = (gi.get_impacted_delegation_balances).delegator) AS delegator, - (SELECT av.id FROM accounts_view av WHERE av.name = (gi.get_impacted_delegation_balances).delegatee) AS delegatee, - (gi.get_impacted_delegation_balances).amount AS balance, - gi.op_type_id, - gi.source_op, - gi.source_op_block - FROM get_impacted_delegations gi -), ---------------------------------------------------------------------------------------- -- prepare hf23 data -- contains all delegation RESETS that were made by hf23 (already in the db) join_prev_balance_to_hf23_accounts AS MATERIALIZED ( @@ -56,7 +39,7 @@ join_prev_balance_to_hf23_accounts AS MATERIALIZED ( cpfd.source_op, cpfd.source_op_block FROM current_accounts_delegations prev - JOIN convert_parameters_for_delegations cpfd ON prev.delegator = cpfd.delegator AND cpfd.op_type_id = 68 + JOIN process_block_range_data_b cpfd ON prev.delegator = cpfd.delegator AND cpfd.op_type_id = 68 ), -- contains all delegation RESETS that were made by hf23 (in query) @@ -68,8 +51,8 @@ find_delegations_of_hf23_account_in_query AS ( 0 AS balance, MAX(cpfd.source_op) as source_op, MAX(cpfd.source_op_block) as source_op_block - FROM convert_parameters_for_delegations cp - JOIN convert_parameters_for_delegations cpfd ON cp.delegator = cpfd.delegator AND cpfd.op_type_id = 68 AND cp.source_op < cpfd.source_op + FROM process_block_range_data_b cp + JOIN process_block_range_data_b cpfd ON cp.delegator = cpfd.delegator AND cpfd.op_type_id = 68 AND cp.source_op < cpfd.source_op WHERE cp.op_type_id IN (40,41) AND --exclude already reset delegations @@ -107,7 +90,7 @@ delegations_in_query AS MATERIALIZED ( balance, source_op, source_op_block - FROM convert_parameters_for_delegations + FROM process_block_range_data_b WHERE op_type_id IN (40,41) UNION ALL @@ -187,7 +170,7 @@ union_delegations AS ( -- for every account found in hf23 - we need to lower its delegation by the amount that was delegated before hf23 (normally there is return operation for returned delegation) ( CASE - WHEN NOT EXISTS (SELECT 1 FROM convert_parameters_for_delegations gl WHERE gl.delegator = dd.delegator AND gl.op_type_id = 68 AND gl.source_op = dd.source_op) THEN + WHEN NOT EXISTS (SELECT 1 FROM process_block_range_data_b gl WHERE gl.delegator = dd.delegator AND gl.op_type_id = 68 AND gl.source_op = dd.source_op) THEN GREATEST(dd.balance_delta, 0) ELSE dd.balance_delta @@ -211,7 +194,7 @@ union_delegations AS ( delegator, 0 AS received_vests, balance - FROM convert_parameters_for_delegations + FROM process_block_range_data_b WHERE op_type_id = 62 ), sum_delegations AS ( diff --git a/db/process_rewards.sql b/db/process_rewards.sql index 739d5d3f6eb50f921dc6454561bf077112673a15..f2e5c979fba700e34a4e25bc214ea72148fb2ad7 100644 --- a/db/process_rewards.sql +++ b/db/process_rewards.sql @@ -24,57 +24,46 @@ WITH process_block_range_data_b AS MATERIALIZED ov.op_type_id = ANY(ARRAY[39,51,52,63,53]) AND ov.block_num BETWEEN _from AND _to ), -filter_reward_ops AS ( - +get_impacted_bal AS ( SELECT - ov.body, - ov.source_op, - ov.source_op_block, - ov.op_type_id - FROM process_block_range_data_b ov + get_impacted_reward_balances.account_name, + get_impacted_reward_balances.hbd_payout AS reward_hbd, + get_impacted_reward_balances.hive_payout AS reward_hive, + get_impacted_reward_balances.vesting_payout AS reward_vests, + fio.op_type_id, + fio.source_op, + fio.source_op_block + FROM process_block_range_data_b fio + CROSS JOIN get_impacted_reward_balances(fio.body, fio.source_op_block, fio.op_type_id) AS get_impacted_reward_balances WHERE - ov.op_type_id = 39 OR - (ov.op_type_id = ANY(ARRAY[51,63]) AND (ov.body->'value'->>'payout_must_be_claimed')::BOOLEAN = true) + fio.op_type_id = 39 OR + (fio.op_type_id IN (51,63) AND (fio.body->'value'->>'payout_must_be_claimed')::BOOLEAN = true) ), ------------------------------------------------------------------------------ --prepare info rewards data get_impacted_posting AS ( SELECT - process_posting_rewards(fio.body) AS get_posting, + get_posting.account_name, + get_posting.reward AS posting_reward, fio.op_type_id, fio.source_op, fio.source_op_block FROM process_block_range_data_b fio + CROSS JOIN process_posting_rewards(fio.body) AS get_posting WHERE fio.op_type_id = 53 ), get_impacted_curation AS ( SELECT - process_curation_rewards(fio.body) AS get_curation, + get_curation.account_name, + get_curation.reward, + get_curation.payout_must_be_claimed, fio.op_type_id, fio.source_op, fio.source_op_block FROM process_block_range_data_b fio + CROSS JOIN process_curation_rewards(fio.body) AS get_curation WHERE fio.op_type_id = 52 ), -prepare_curation AS ( - SELECT - (gi.get_curation).account_name AS account_name, - (gi.get_curation).reward AS reward, - (gi.get_curation).payout_must_be_claimed AS payout_must_be_claimed, - gi.op_type_id, - gi.source_op, - gi.source_op_block - FROM get_impacted_curation gi -), -prepare_posting AS ( - SELECT - (gi.get_posting).account_name AS account_name, - (gi.get_posting).reward AS posting_reward, - gi.op_type_id, - gi.source_op, - gi.source_op_block - FROM get_impacted_posting gi -), ------------------------------------------------------------------------------ -- calculate curation_reward into hive calculate_vests_from_curation AS MATERIALIZED ( @@ -86,7 +75,7 @@ calculate_vests_from_curation AS MATERIALIZED ( pc.op_type_id, pc.source_op, pc.source_op_block - FROM prepare_curation pc + FROM get_impacted_curation pc JOIN hive.blocks_view bv ON bv.num = pc.source_op_block ), ------------------------------------------------------------------------------ @@ -95,7 +84,7 @@ get_impacted_info_rewards AS ( account_name, posting_reward, 0 AS curation_reward - FROM prepare_posting + FROM get_impacted_posting UNION ALL @@ -122,27 +111,6 @@ posting_and_curations_account_id AS ( FROM group_by_account_info ), ------------------------------------------------------------------------------ --- prepare rewards data -get_impacted_bal AS ( - SELECT - get_impacted_reward_balances(fio.body, fio.source_op_block, fio.op_type_id) AS get_impacted_reward_balances, - fio.op_type_id, - fio.source_op, - fio.source_op_block - FROM filter_reward_ops fio -), -convert_params AS ( - SELECT - (gi.get_impacted_reward_balances).account_name AS account_name, - (gi.get_impacted_reward_balances).hbd_payout AS reward_hbd, - (gi.get_impacted_reward_balances).hive_payout AS reward_hive, - (gi.get_impacted_reward_balances).vesting_payout AS reward_vests, - gi.op_type_id, - gi.source_op, - gi.source_op_block - FROM get_impacted_bal gi -), ------------------------------------------------------------------------------- --vesting balance must be calculated for all operations except claim operation (can't be aggregated) calculate_vesting_balance AS ( SELECT @@ -154,7 +122,7 @@ calculate_vesting_balance AS ( op_type_id, source_op, source_op_block - FROM convert_params + FROM get_impacted_bal -- we use hive view because of performance issues during live sync JOIN hive.blocks_view bv ON bv.num = source_op_block WHERE op_type_id != 39 @@ -183,7 +151,7 @@ union_operations_with_vesting_balance AS ( op_type_id, source_op, source_op_block - FROM convert_params + FROM get_impacted_bal WHERE op_type_id = 39 UNION ALL diff --git a/db/process_savings.sql b/db/process_savings.sql index ea3cc57853ecf3ec6edc05c11d2e1b061d4b94d2..0972d1c9d78da9a0a047800ecd3d792fea907cdb 100644 --- a/db/process_savings.sql +++ b/db/process_savings.sql @@ -16,7 +16,7 @@ BEGIN WITH process_block_range_data_b AS ( SELECT - ov.body_binary::jsonb AS body, + ov.body, ov.id AS source_op, ov.block_num as source_op_block, ov.op_type_id @@ -28,37 +28,19 @@ WITH process_block_range_data_b AS filter_interest_ops AS ( SELECT - ov.body, + (SELECT av.id FROM accounts_view av WHERE av.name = get_impacted_saving_balances.account_name) AS account_id, + get_impacted_saving_balances.asset_symbol_nai AS nai, + get_impacted_saving_balances.amount AS balance, + get_impacted_saving_balances.savings_withdraw_request, + get_impacted_saving_balances.request_id, ov.source_op, ov.source_op_block, ov.op_type_id FROM process_block_range_data_b ov + CROSS JOIN get_impacted_saving_balances(ov.body, ov.op_type_id) AS get_impacted_saving_balances WHERE ov.op_type_id IN (32,33,34,59) OR (ov.op_type_id = 55 AND (ov.body->'value'->>'is_saved_into_hbd_balance')::BOOLEAN = false) - -), --- convert balances depending on operation type -get_impacted_bal AS ( - SELECT - get_impacted_saving_balances(fio.body, fio.op_type_id) AS get_impacted_saving_balances, - fio.op_type_id, - fio.source_op, - fio.source_op_block - FROM filter_interest_ops fio -), -convert_parameters AS ( - SELECT - (SELECT av.id FROM accounts_view av WHERE av.name = (gi.get_impacted_saving_balances).account_name) AS account_id, - (gi.get_impacted_saving_balances).asset_symbol_nai AS nai, - (gi.get_impacted_saving_balances).amount AS balance, - (gi.get_impacted_saving_balances).savings_withdraw_request AS savings_withdraw_request, - (gi.get_impacted_saving_balances).request_id AS request_id, - gi.op_type_id, - gi.source_op, - gi.source_op_block - FROM get_impacted_bal gi - order by source_op ), --------------------------------------------------------------------------------------- -- views for specific operation types @@ -72,7 +54,7 @@ cancel_and_fill_transfers AS ( op_type_id, source_op, source_op_block - FROM convert_parameters + FROM filter_interest_ops WHERE op_type_id in (34,59) ), transfers_from AS ( @@ -85,7 +67,7 @@ transfers_from AS ( op_type_id, source_op, source_op_block - FROM convert_parameters + FROM filter_interest_ops WHERE op_type_id = 33 ), income_transfers AS ( @@ -98,7 +80,7 @@ income_transfers AS ( op_type_id, source_op, source_op_block - FROM convert_parameters + FROM filter_interest_ops WHERE op_type_id IN (32,55) ), --------------------------------------------------------------------------------------- diff --git a/db/process_withdrawals.sql b/db/process_withdrawals.sql index 45bb65d240f16e12577beced56315dd0fc1ba082..f4e927d82aa80119b0202f93c1379f0cf7dfa174 100644 --- a/db/process_withdrawals.sql +++ b/db/process_withdrawals.sql @@ -18,53 +18,39 @@ DECLARE __reset_filled_withdrawals INT; BEGIN -----------------------------------------WITHDRAWALS--------------------------------------------- -WITH process_block_range_data_b AS +WITH process_block_range_data_b AS MATERIALIZED ( SELECT - ov.body_binary::jsonb AS body, - ov.id AS source_op, - ov.block_num as source_op_block, - ov.op_type_id + impacted_withdraws.account_name, + impacted_withdraws.withdrawn, + impacted_withdraws.vesting_withdraw_rate, + impacted_withdraws.to_withdraw, + ov.id AS source_op FROM operations_view ov + CROSS JOIN get_impacted_withdraws(ov.body, ov.op_type_id, ov.block_num) AS impacted_withdraws WHERE ov.op_type_id IN (4,68) AND ov.block_num BETWEEN _from AND _to ), --- convert withdraws depending on operation type -get_impacted_withdraw_balances AS ( - SELECT - get_impacted_withdraws(fio.body, fio.op_type_id, fio.source_op_block) AS impacted_withdraws, - fio.op_type_id, - fio.source_op, - fio.source_op_block - FROM process_block_range_data_b fio -), -convert_parameters_withdraws AS MATERIALIZED ( - SELECT - (gi.impacted_withdraws).account_name AS account_name, - (gi.impacted_withdraws).withdrawn AS withdrawn, - (gi.impacted_withdraws).vesting_withdraw_rate AS vesting_withdraw_rate, - (gi.impacted_withdraws).to_withdraw AS to_withdraw, - gi.source_op, - gi.source_op_block - FROM get_impacted_withdraw_balances gi -), group_by_account AS ( SELECT account_name, - MAX(source_op) AS source_op - FROM convert_parameters_withdraws - GROUP BY account_name + withdrawn, + vesting_withdraw_rate, + to_withdraw, + source_op, + ROW_NUMBER() OVER (PARTITION BY account_name ORDER BY source_op DESC) AS row_num + FROM process_block_range_data_b ), join_latest_withdraw AS ( SELECT - (SELECT av.id FROM accounts_view av WHERE av.name = cpfd.account_name) AS account_id, - cpfd.withdrawn, - cpfd.vesting_withdraw_rate, - cpfd.to_withdraw, - cpfd.source_op - FROM convert_parameters_withdraws cpfd - JOIN group_by_account gba ON cpfd.source_op = gba.source_op + (SELECT av.id FROM accounts_view av WHERE av.name = account_name) AS account_id, + withdrawn, + vesting_withdraw_rate, + to_withdraw, + source_op + FROM group_by_account + WHERE row_num = 1 ) INSERT INTO account_withdraws (account, vesting_withdraw_rate, to_withdraw, withdrawn, source_op) @@ -85,46 +71,33 @@ DO UPDATE SET -----------------------------------------WITHDRAWAL ROUTES--------------------------------------------- WITH process_block_range_data_b AS ( SELECT - ov.body_binary::jsonb AS body, - ov.id AS source_op, - ov.block_num as source_op_block, - ov.op_type_id + withdraw_vesting_route.from_account, + withdraw_vesting_route.to_account, + withdraw_vesting_route.percent, + ov.id AS source_op FROM operations_view ov + CROSS JOIN process_set_withdraw_vesting_route_operation(ov.body) AS withdraw_vesting_route WHERE ov.op_type_id = 20 AND ov.block_num BETWEEN _from AND _to ), --- convert vesting_route -get_impacted_vesting_route AS ( - SELECT - process_set_withdraw_vesting_route_operation(fio.body) AS withdraw_vesting_route, - fio.source_op - FROM process_block_range_data_b fio -), -convert_parameters_withdraw_routes AS MATERIALIZED ( - SELECT - (gi.withdraw_vesting_route).from_account AS from_account, - (gi.withdraw_vesting_route).to_account AS to_account, - (gi.withdraw_vesting_route).percent AS percent, - gi.source_op - FROM get_impacted_vesting_route gi -), group_by_account AS ( SELECT from_account, to_account, - MAX(source_op) AS source_op - FROM convert_parameters_withdraw_routes - GROUP BY from_account, to_account + percent, + source_op, + ROW_NUMBER() OVER (PARTITION BY from_account, to_account ORDER BY source_op DESC) AS row_num + FROM process_block_range_data_b ), join_latest_withdraw_routes AS ( SELECT - (SELECT av.id FROM accounts_view av WHERE av.name = cpfd.from_account) AS from_account, - (SELECT av.id FROM accounts_view av WHERE av.name = cpfd.to_account) AS to_account, - cpfd.percent, - cpfd.source_op - FROM convert_parameters_withdraw_routes cpfd - JOIN group_by_account gba ON cpfd.source_op = gba.source_op + (SELECT av.id FROM accounts_view av WHERE av.name = from_account) AS from_account, + (SELECT av.id FROM accounts_view av WHERE av.name = to_account) AS to_account, + percent, + source_op + FROM group_by_account + WHERE row_num = 1 ), join_prev_route AS ( SELECT @@ -210,28 +183,19 @@ INTO __insert_routes, __delete_routes, __insert_sum_of_routes; -- delete routes for hf23 accounts (it will be triggered only once - in hf23 block range) WITH process_block_range_data_b AS ( SELECT - ov.body_binary::jsonb AS body, - ov.id AS source_op, - ov.block_num as source_op_block, - ov.op_type_id + (SELECT av.id FROM accounts_view av WHERE av.name = (ov.body->'value'->>'account')) AS account_id, + ov.id AS source_op FROM operations_view ov WHERE ov.op_type_id = 68 AND ov.block_num BETWEEN _from AND _to ), --- convert vesting_route -get_impacted_vesting_route AS ( - SELECT - (SELECT av.id FROM accounts_view av WHERE av.name = (fio.body->'value'->>'account')) AS account_id, - fio.source_op - FROM process_block_range_data_b fio -), join_current_routes_for_hf23_accounts AS MATERIALIZED ( SELECT ar.account, ar.to_account FROM account_routes ar - JOIN get_impacted_vesting_route gi ON ar.account = gi.account_id + JOIN process_block_range_data_b gi ON ar.account = gi.account_id WHERE gi.source_op > ar.source_op ), count_deleted_routes AS ( @@ -268,42 +232,23 @@ INTO __delete_hf23_routes_count, __delete_hf23_routes; -----------------------------------------FILL WITHDRAWS--------------------------------------------- -WITH process_block_range_data_b AS +WITH process_block_range_data_b AS MATERIALIZED ( SELECT - ov.body_binary::jsonb AS body, - ov.id AS source_op, - ov.block_num as source_op_block, - ov.op_type_id + (SELECT av.id FROM accounts_view av WHERE av.name = fill_vesting_withdraw_operation.account_name) AS account_id, + fill_vesting_withdraw_operation.withdrawn, + ov.id AS source_op FROM operations_view ov + JOIN hafd.applied_hardforks ah ON ah.hardfork_num = 1 + CROSS JOIN process_fill_vesting_withdraw_operation(ov.body, ov.block_num > ah.block_num) AS fill_vesting_withdraw_operation WHERE ov.op_type_id IN (56) AND ov.block_num BETWEEN _from AND _to ), -------------------------------------------------------------------------------------- --- convert withdraws -get_impacted_fills AS ( - SELECT - process_fill_vesting_withdraw_operation( - fio.body, - (SELECT (ah.block_num < fio.source_op_block) FROM hafd.applied_hardforks ah WHERE ah.hardfork_num = 1) - ) AS fill_vesting_withdraw_operation, - fio.source_op - FROM process_block_range_data_b fio -), -convert_parameters_for_delegations AS MATERIALIZED ( - SELECT - (SELECT av.id FROM accounts_view av WHERE av.name = (gi.fill_vesting_withdraw_operation).account_name) AS account_id, - (gi.fill_vesting_withdraw_operation).withdrawn AS withdrawn, - gi.source_op - FROM get_impacted_fills gi -), --------------------------------------------------------------------------------------- group_by_account AS ( - SELECT - account_id - FROM convert_parameters_for_delegations - GROUP BY account_id + SELECT DISTINCT account_id + FROM process_block_range_data_b ), join_current_withdraw AS ( SELECT @@ -320,7 +265,7 @@ get_fills_conserning_current_withdrawal AS MATERIALIZED ( cp.account_id, SUM(cp.withdrawn) + aw.withdrawn AS withdrawn, MAX(aw.to_withdraw) AS to_withdraw - FROM convert_parameters_for_delegations cp + FROM process_block_range_data_b cp JOIN join_current_withdraw aw ON aw.account = cp.account_id WHERE cp.source_op > aw.source_op GROUP BY cp.account_id, aw.withdrawn @@ -362,37 +307,22 @@ INTO __insert_not_yet_filled_withdrawals, __reset_filled_withdrawals; -----------------------------------------DELAYS--------------------------------------------- -WITH process_block_range_data_b AS +WITH process_block_range_data_b AS MATERIALIZED ( SELECT - ov.body_binary::jsonb AS body, - ov.id AS source_op, - ov.block_num as source_op_block, - ov.op_type_id + (SELECT av.id FROM accounts_view av WHERE av.name = get_impacted_delayed_balances.from_account) AS from_account, + (SELECT av.id FROM accounts_view av WHERE av.name = get_impacted_delayed_balances.to_account) AS to_account, + get_impacted_delayed_balances.withdrawn, + get_impacted_delayed_balances.deposited, + ov.id AS source_op FROM operations_view ov -- start calculations from the first block after the 24 hardfork JOIN hafd.applied_hardforks ah ON ah.hardfork_num = 24 AND ah.block_num < ov.block_num + CROSS JOIN get_impacted_delayed_balances(ov.body, ov.op_type_id) AS get_impacted_delayed_balances WHERE ov.op_type_id IN (56,77,70) AND ov.block_num BETWEEN _from AND _to ), - --------------------------------------------------------------------------------------- --- convert balances depending on operation type -get_impacted_delays AS ( - SELECT get_impacted_delayed_balances(fio.body, fio.op_type_id) AS get_impacted_delayed_balances, - fio.source_op - FROM process_block_range_data_b fio -), -convert_parameters AS MATERIALIZED ( - SELECT - (SELECT av.id FROM accounts_view av WHERE av.name = (gi.get_impacted_delayed_balances).from_account) AS from_account, - (SELECT av.id FROM accounts_view av WHERE av.name = (gi.get_impacted_delayed_balances).to_account) AS to_account, - (gi.get_impacted_delayed_balances).withdrawn AS withdrawn, - (gi.get_impacted_delayed_balances).deposited AS deposited, - gi.source_op - FROM get_impacted_delays gi -), -------------------------------------------------------------------------------------- -- prepare and sum all delayed vests union_delays AS MATERIALIZED ( @@ -400,7 +330,7 @@ union_delays AS MATERIALIZED ( from_account AS account_id, withdrawn AS balance, source_op - FROM convert_parameters + FROM process_block_range_data_b UNION ALL @@ -408,14 +338,12 @@ union_delays AS MATERIALIZED ( to_account AS account_id, deposited AS balance, source_op - FROM convert_parameters + FROM process_block_range_data_b WHERE to_account IS NOT NULL ), group_by_account AS ( - SELECT - account_id + SELECT DISTINCT account_id FROM union_delays - GROUP BY account_id ), join_prev_delays AS ( SELECT