From bdc9a44b38507257cfac06386ca283a2e78ad29a Mon Sep 17 00:00:00 2001 From: Michal Zander <mzander@syncad.com> Date: Fri, 31 Jan 2025 14:59:39 +0000 Subject: [PATCH] Add new processing function for withdrawals and delayed vests --- backend/delayed_vests.sql | 58 ----- backend/delays.sql | 89 +++++++ backend/hardforks.sql | 60 ----- backend/withdrawals.sql | 119 +++++++++ backend/withdraws.sql | 197 -------------- db/btracker_app.sql | 13 +- db/process_withdrawals.sql | 512 +++++++++++++++++++++++++++++++++---- scripts/install_app.sh | 4 +- 8 files changed, 685 insertions(+), 367 deletions(-) delete mode 100644 backend/delayed_vests.sql create mode 100644 backend/delays.sql create mode 100644 backend/withdrawals.sql delete mode 100644 backend/withdraws.sql diff --git a/backend/delayed_vests.sql b/backend/delayed_vests.sql deleted file mode 100644 index 7f09be7..0000000 --- a/backend/delayed_vests.sql +++ /dev/null @@ -1,58 +0,0 @@ -SET ROLE btracker_owner; - -CREATE OR REPLACE FUNCTION process_transfer_to_vesting_completed_operation(body jsonb) -RETURNS void -LANGUAGE 'plpgsql' VOLATILE -AS -$$ -BEGIN -WITH transfer_to_vesting_completed_operation AS ( - SELECT - (SELECT id FROM accounts_view WHERE name = body->'value'->>'to_account') AS _account, - (body->'value'->'vesting_shares_received'->>'amount')::BIGINT AS _delayed_vests -) - INSERT INTO account_withdraws - ( - account, - delayed_vests - ) - SELECT - _account, - _delayed_vests - FROM transfer_to_vesting_completed_operation - - ON CONFLICT ON CONSTRAINT pk_account_withdraws - DO UPDATE SET - delayed_vests = account_withdraws.delayed_vests + EXCLUDED.delayed_vests; - -END -$$; - -CREATE OR REPLACE FUNCTION process_delayed_voting_operation(body jsonb) -RETURNS void -LANGUAGE 'plpgsql' VOLATILE -AS -$$ -BEGIN -WITH delayed_voting_operation AS ( - SELECT - (SELECT id FROM accounts_view WHERE name = body->'value'->>'voter') AS _account, - (body->'value'->>'votes')::BIGINT AS _delayed_vests -) - INSERT INTO account_withdraws - ( - account, - delayed_vests - ) - SELECT - _account, - _delayed_vests - FROM delayed_voting_operation - - ON CONFLICT ON CONSTRAINT pk_account_withdraws - DO UPDATE SET - delayed_vests = GREATEST(account_withdraws.delayed_vests - EXCLUDED.delayed_vests, 0); -END -$$; - -RESET ROLE; diff --git a/backend/delays.sql b/backend/delays.sql new file mode 100644 index 0000000..2206794 --- /dev/null +++ b/backend/delays.sql @@ -0,0 +1,89 @@ +SET ROLE btracker_owner; + +DROP TYPE IF EXISTS impacted_delays_return CASCADE; +CREATE TYPE impacted_delays_return AS +( + from_account VARCHAR, + withdrawn BIGINT, + to_account VARCHAR, + deposited BIGINT +); + +CREATE OR REPLACE FUNCTION get_impacted_delayed_balances(IN _operation_body JSONB, IN _op_type_id INT) +RETURNS impacted_delays_return +LANGUAGE plpgsql +STABLE +AS +$BODY$ +BEGIN + RETURN ( + CASE + WHEN _op_type_id = 56 THEN + process_fill_vesting_withdraw_operation(_operation_body) + + WHEN _op_type_id = 77 THEN + process_transfer_to_vesting_completed_operation(_operation_body) + + WHEN _op_type_id = 70 THEN + process_delayed_voting_operation(_operation_body) + END + ); + +END; +$BODY$; + +CREATE OR REPLACE FUNCTION process_fill_vesting_withdraw_operation(IN _operation_body JSONB) +RETURNS impacted_delays_return +LANGUAGE 'plpgsql' STABLE +AS +$$ +BEGIN + IF ((_operation_body)->'value'->'deposited'->>'precision')::INT = 6 THEN + RETURN ( + ((_operation_body)->'value'->>'from_account')::TEXT, + - ((_operation_body)->'value'->'withdrawn'->>'amount')::BIGINT, + ((_operation_body)->'value'->>'to_account')::TEXT, + ((_operation_body)->'value'->'deposited'->>'amount')::BIGINT + )::impacted_delays_return; + ELSE + RETURN ( + ((_operation_body)->'value'->>'from_account')::TEXT, + - ((_operation_body)->'value'->'withdrawn'->>'amount')::BIGINT, + NULL, + NULL + )::impacted_delays_return; + END IF; +END +$$; + +CREATE OR REPLACE FUNCTION process_transfer_to_vesting_completed_operation(IN _operation_body JSONB) +RETURNS impacted_delays_return +LANGUAGE 'plpgsql' STABLE +AS +$$ +BEGIN + RETURN ( + ((_operation_body)->'value'->>'to_account')::TEXT, + ((_operation_body)->'value'->'vesting_shares_received'->>'amount')::BIGINT, + NULL, + NULL + )::impacted_delays_return; +END +$$; + +CREATE OR REPLACE FUNCTION process_delayed_voting_operation(IN _operation_body JSONB) +RETURNS impacted_delays_return +LANGUAGE 'plpgsql' STABLE +AS +$$ +BEGIN + RETURN ( + ((_operation_body)->'value'->>'voter')::TEXT, + - ((_operation_body)->'value'->'votes')::BIGINT, + NULL, + NULL + )::impacted_delays_return; +END +$$; + +RESET ROLE; diff --git a/backend/hardforks.sql b/backend/hardforks.sql index 97981bc..87585f1 100644 --- a/backend/hardforks.sql +++ b/backend/hardforks.sql @@ -1,27 +1,5 @@ SET ROLE btracker_owner; -CREATE OR REPLACE FUNCTION process_hardfork_hive_operation(body JSONB) -RETURNS VOID -LANGUAGE 'plpgsql' VOLATILE -AS -$$ -BEGIN -WITH hardfork_hive_operation AS MATERIALIZED -( - SELECT - (SELECT id FROM accounts_view WHERE name = (body)->'value'->>'account') AS _account -) - UPDATE account_withdraws SET - vesting_withdraw_rate = 0, - to_withdraw = 0, - withdrawn = 0, - delayed_vests = 0 - FROM hardfork_hive_operation - WHERE account = _account; - -END -$$; - --this function won't be necessary after changes in hardfork_hive_operation CREATE OR REPLACE FUNCTION process_hf_23(__hardfork_23_block INT) RETURNS VOID @@ -70,42 +48,4 @@ BEGIN END $$; -CREATE OR REPLACE FUNCTION process_hardfork(_hardfork_id INT) -RETURNS VOID -LANGUAGE 'plpgsql' VOLATILE -AS -$$ -BEGIN - - CASE - - WHEN _hardfork_id = 1 THEN - WITH account_withdraws AS MATERIALIZED - ( - SELECT - account as account_id, - (to_withdraw * 1000000) AS _to_withdraw, - ((to_withdraw * 1000000)/ 104) AS _vesting_withdraw_rate, - (withdrawn * 1000000) AS _withdrawn - FROM account_withdraws - ) - UPDATE account_withdraws SET - vesting_withdraw_rate = ad._vesting_withdraw_rate, - to_withdraw = ad._to_withdraw, - withdrawn = ad._withdrawn - FROM account_withdraws ad - WHERE account = ad.account_id; - - WHEN _hardfork_id = 16 THEN - UPDATE btracker_app_status SET withdraw_rate = 13; - - WHEN _hardfork_id = 24 THEN - UPDATE btracker_app_status SET start_delayed_vests = TRUE; - - ELSE - END CASE; - -END -$$; - RESET ROLE; diff --git a/backend/withdrawals.sql b/backend/withdrawals.sql new file mode 100644 index 0000000..5cc5f25 --- /dev/null +++ b/backend/withdrawals.sql @@ -0,0 +1,119 @@ +SET ROLE btracker_owner; + +DROP TYPE IF EXISTS impacted_withdraws_return CASCADE; +CREATE TYPE impacted_withdraws_return AS +( + account_name VARCHAR, + withdrawn BIGINT, + vesting_withdraw_rate BIGINT, + to_withdraw BIGINT +); + +DROP TYPE IF EXISTS impacted_fill_withdraw_return CASCADE; +CREATE TYPE impacted_fill_withdraw_return AS +( + account_name VARCHAR, + withdrawn BIGINT +); + +DROP TYPE IF EXISTS impacted_withdraw_routes_return CASCADE; +CREATE TYPE impacted_withdraw_routes_return AS +( + from_account VARCHAR, + to_account VARCHAR, + percent BIGINT +); + + +CREATE OR REPLACE FUNCTION get_impacted_withdraws(IN _operation_body JSONB, IN _op_type_id INT, IN _source_op_block INT) +RETURNS impacted_withdraws_return +LANGUAGE plpgsql +STABLE +AS +$BODY$ +BEGIN + RETURN ( + CASE + WHEN _op_type_id = 4 THEN + process_withdraw_vesting_operation( + _operation_body, + (SELECT (block_num < _source_op_block) FROM hafd.applied_hardforks WHERE hardfork_num = 1), + (SELECT (block_num < _source_op_block) FROM hafd.applied_hardforks WHERE hardfork_num = 16) + ) + + WHEN _op_type_id = 68 THEN + process_reset_withdraw_hf23(_operation_body) + END + ); + +END; +$BODY$; + +CREATE OR REPLACE FUNCTION process_withdraw_vesting_operation(IN _operation_body JSONB, IN _is_hf01 BOOLEAN, IN _is_hf16 BOOLEAN) +RETURNS impacted_withdraws_return +LANGUAGE 'plpgsql' STABLE +AS +$$ +DECLARE + _pre_hf1 INT := (CASE WHEN _is_hf01 THEN 1 ELSE 1000000 END); + _rate INT := (CASE WHEN _is_hf16 THEN 13 ELSE 104 END); + _withdraw BIGINT := GREATEST(((_operation_body)->'value'->'vesting_shares'->>'amount')::BIGINT, 0); +BEGIN + RETURN ( + ((_operation_body)->'value'->>'account')::TEXT, + 0, -- resets withdrawn + ((_withdraw * _pre_hf1) / _rate)::BIGINT, + (_withdraw * _pre_hf1)::BIGINT + )::impacted_withdraws_return; + +END +$$; + +CREATE OR REPLACE FUNCTION process_fill_vesting_withdraw_operation(IN _operation_body JSONB, IN _is_hf01 BOOLEAN) +RETURNS impacted_fill_withdraw_return +LANGUAGE 'plpgsql' STABLE +AS +$$ +DECLARE + _pre_hf1 INT := (CASE WHEN _is_hf01 THEN 1 ELSE 1000000 END); +BEGIN + RETURN ( + ((_operation_body)->'value'->>'from_account')::TEXT, + (((_operation_body)->'value'->'withdrawn'->>'amount')::BIGINT * _pre_hf1) + )::impacted_fill_withdraw_return; + +END +$$; + +CREATE OR REPLACE FUNCTION process_set_withdraw_vesting_route_operation(IN _operation_body JSONB) +RETURNS impacted_withdraw_routes_return +LANGUAGE 'plpgsql' STABLE +AS +$$ +BEGIN + RETURN ( + ((_operation_body)->'value'->>'from_account')::TEXT, + ((_operation_body)->'value'->>'to_account')::TEXT, + ((_operation_body)->'value'->>'percent')::INT + )::impacted_withdraw_routes_return; + +END +$$; + +CREATE OR REPLACE FUNCTION process_reset_withdraw_hf23(IN _operation_body JSONB) +RETURNS impacted_withdraws_return +LANGUAGE 'plpgsql' STABLE +AS +$$ +BEGIN + RETURN ( + ((_operation_body)->'value'->>'account')::TEXT, + 0, -- resets withdrawn + 0, + 0 + )::impacted_withdraws_return; + +END +$$; + +RESET ROLE; diff --git a/backend/withdraws.sql b/backend/withdraws.sql deleted file mode 100644 index 7ab0731..0000000 --- a/backend/withdraws.sql +++ /dev/null @@ -1,197 +0,0 @@ -SET ROLE btracker_owner; - -CREATE OR REPLACE FUNCTION process_withdraw_vesting_operation( - body jsonb, _withdraw_rate int -) -RETURNS void -LANGUAGE 'plpgsql' VOLATILE -AS -$$ -BEGIN -WITH withdraw_vesting_operation AS -( - SELECT - (SELECT id FROM accounts_view WHERE name = (body)->'value'->>'account') AS _account, - GREATEST(((body)->'value'->'vesting_shares'->>'amount')::BIGINT, 0) AS _vesting_withdraw -) -INSERT INTO account_withdraws - ( - account, - vesting_withdraw_rate, - to_withdraw - ) - SELECT - _account, - _vesting_withdraw / _withdraw_rate, - _vesting_withdraw - FROM withdraw_vesting_operation - - ON CONFLICT ON CONSTRAINT pk_account_withdraws - DO UPDATE SET - withdrawn = 0, - vesting_withdraw_rate = EXCLUDED.vesting_withdraw_rate, - to_withdraw = EXCLUDED.to_withdraw; -END -$$; - -CREATE OR REPLACE FUNCTION process_set_withdraw_vesting_route_operation( - body jsonb -) -RETURNS void -LANGUAGE 'plpgsql' VOLATILE -AS -$$ -DECLARE - _account INT; - _to_account INT; - _percent INT; - _current_balance INT; -BEGIN - -SELECT (SELECT id FROM accounts_view WHERE name = (body)->'value'->>'from_account'), - (SELECT id FROM accounts_view WHERE name = (body)->'value'->>'to_account'), - ((body)->'value'->>'percent')::INT -INTO _account, _to_account, _percent; - - SELECT cawr.percent INTO _current_balance - FROM account_routes cawr - WHERE cawr.account= _account - AND cawr.to_account= _to_account; - -IF _current_balance IS NULL THEN - - INSERT INTO account_routes - ( - account, - to_account, - percent - ) - SELECT - _account, - _to_account, - _percent; - - INSERT INTO account_withdraws - ( - account, - withdraw_routes - ) - SELECT - _account, - 1 - - ON CONFLICT ON CONSTRAINT pk_account_withdraws - DO UPDATE SET - withdraw_routes = account_withdraws.withdraw_routes + EXCLUDED.withdraw_routes; -ELSE - IF _percent = 0 THEN - - INSERT INTO account_withdraws - ( - account, - withdraw_routes - ) - SELECT - _account, - 1 - - ON CONFLICT ON CONSTRAINT pk_account_withdraws - DO UPDATE SET - withdraw_routes = account_withdraws.withdraw_routes - EXCLUDED.withdraw_routes; - - DELETE FROM account_routes - WHERE account = _account - AND to_account = _to_account; - - ELSE - - UPDATE account_routes SET - percent = _percent - WHERE account = _account - AND to_account = _to_account; - - END IF; -END IF; -END -$$; - -CREATE OR REPLACE FUNCTION process_fill_vesting_withdraw_operation( - body jsonb, - _start_delayed_vests boolean -) -RETURNS void -LANGUAGE 'plpgsql' VOLATILE -AS -$$ -DECLARE -_vesting_withdraw BIGINT; -_account INT; -_vesting_deposit BIGINT; -_precision INT; -_to_account INT; -BEGIN - - SELECT (SELECT id FROM accounts_view WHERE name = (body)->'value'->>'from_account'), - (SELECT id FROM accounts_view WHERE name = (body)->'value'->>'to_account'), - ((body)->'value'->'withdrawn'->>'amount')::BIGINT, - ((body)->'value'->'deposited'->>'amount')::BIGINT, - ((body)->'value'->'deposited'->>'precision')::INT - INTO _account, _to_account, _vesting_withdraw, _vesting_deposit, _precision; - - INSERT INTO account_withdraws - ( - account, - withdrawn - ) - SELECT - _account, - _vesting_withdraw - - ON CONFLICT ON CONSTRAINT pk_account_withdraws - DO UPDATE SET - withdrawn = account_withdraws.withdrawn + EXCLUDED.withdrawn; - - IF _start_delayed_vests = TRUE THEN - - INSERT INTO account_withdraws - ( - account, - delayed_vests - ) - SELECT - _account, - _vesting_withdraw - - ON CONFLICT ON CONSTRAINT pk_account_withdraws - DO UPDATE SET - delayed_vests = GREATEST(account_withdraws.delayed_vests - EXCLUDED.delayed_vests, 0); - - IF _precision = 6 THEN - - INSERT INTO account_withdraws - ( - account, - delayed_vests - ) - SELECT - _to_account, - _vesting_deposit - - ON CONFLICT ON CONSTRAINT pk_account_withdraws - DO UPDATE SET - delayed_vests = account_withdraws.delayed_vests + EXCLUDED.delayed_vests; - - END IF; - - END IF; - - UPDATE account_withdraws SET - vesting_withdraw_rate = 0, - to_withdraw = 0, - withdrawn = 0 - WHERE account_withdraws.account = _account - AND account_withdraws.to_withdraw = account_withdraws.withdrawn; -END -$$; - -RESET ROLE; diff --git a/db/btracker_app.sql b/db/btracker_app.sql index 4c6c8b2..b5085ed 100644 --- a/db/btracker_app.sql +++ b/db/btracker_app.sql @@ -33,15 +33,13 @@ RAISE NOTICE 'Attempting to create an application schema tables...'; CREATE TABLE IF NOT EXISTS btracker_app_status ( continue_processing BOOLEAN NOT NULL, - withdraw_rate INT NOT NULL, - start_delayed_vests BOOLEAN NOT NULL, is_indexes_created BOOLEAN NOT NULL ); INSERT INTO btracker_app_status -(continue_processing, withdraw_rate, start_delayed_vests, is_indexes_created) +(continue_processing, is_indexes_created) VALUES -(True, 104, False, False) +(True, False) ; --ACCOUNT BALANCES @@ -135,7 +133,8 @@ CREATE TABLE IF NOT EXISTS account_withdraws to_withdraw BIGINT DEFAULT 0, withdrawn BIGINT DEFAULT 0, withdraw_routes BIGINT DEFAULT 0, - delayed_vests BIGINT DEFAULT 0, + delayed_vests BIGINT DEFAULT 0, + source_op BIGINT, CONSTRAINT pk_account_withdraws PRIMARY KEY (account) ); @@ -146,6 +145,7 @@ CREATE TABLE IF NOT EXISTS account_routes account INT NOT NULL, to_account INT NOT NULL, percent INT NOT NULL, + source_op BIGINT NOT NULL, CONSTRAINT pk_account_routes PRIMARY KEY (account, to_account) ); @@ -223,7 +223,7 @@ BEGIN RETURN EXISTS( SELECT true FROM pg_index WHERE indexrelid = ( - SELECT oid FROM pg_class WHERE relname = 'idx_account_balance_history_account_source_op_idx' + SELECT oid FROM pg_class WHERE relname = 'idx_account_balance_history_account_source_op_idx' LIMIT 1 ) ); END @@ -288,7 +288,6 @@ BEGIN PERFORM process_block_range_rewards(_from, __hardfork_23_block); PERFORM process_block_range_delegations(_from, __hardfork_23_block); - -- Manually process hardfork_hive_operation for balance, rewards, savings PERFORM process_hf_23(__hardfork_23_block); RAISE NOTICE 'Btracker processed hardfork 23 successfully'; diff --git a/db/process_withdrawals.sql b/db/process_withdrawals.sql index 12cfef2..45bb65d 100644 --- a/db/process_withdrawals.sql +++ b/db/process_withdrawals.sql @@ -9,60 +9,486 @@ SET jit = OFF AS $$ DECLARE - _result INT; + __insert_routes INT; + __delete_routes INT; + __insert_sum_of_routes INT; + __delete_hf23_routes_count INT; + __delete_hf23_routes INT; + __insert_not_yet_filled_withdrawals INT; + __reset_filled_withdrawals INT; BEGIN ---RAISE NOTICE 'Processing delegations, rewards, savings, withdraws';) ---delegations (40,41,62) ---savings (32,33,34,59,55) ---rewards (39,51,52,63,53) ---withdraws (4,20,56) ---hardforks (60) - -WITH process_block_range_data_b AS MATERIALIZED +-----------------------------------------WITHDRAWALS--------------------------------------------- +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 + FROM operations_view ov + 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 +), +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 +) +INSERT INTO account_withdraws + (account, vesting_withdraw_rate, to_withdraw, withdrawn, source_op) SELECT - ov.body_binary::jsonb AS body, - ov.id AS source_op, - ov.block_num as source_op_block, - ov.op_type_id -FROM operations_view ov -WHERE - ov.op_type_id IN (4,20,56,60,77,70,68) AND - ov.block_num BETWEEN _from AND _to -), -insert_balance AS MATERIALIZED + jlw.account_id, + jlw.vesting_withdraw_rate, + jlw.to_withdraw, + jlw.withdrawn, + jlw.source_op +FROM join_latest_withdraw jlw +ON CONFLICT ON CONSTRAINT pk_account_withdraws +DO UPDATE SET + vesting_withdraw_rate = EXCLUDED.vesting_withdraw_rate, + to_withdraw = EXCLUDED.to_withdraw, + withdrawn = EXCLUDED.withdrawn, + source_op = EXCLUDED.source_op; + +-----------------------------------------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 + FROM operations_view ov + 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 +), +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 +), +join_prev_route AS ( + SELECT + cp.from_account, + cp.to_account, + cp.percent, + cr.percent AS prev_percent, + cp.source_op + FROM join_latest_withdraw_routes cp + LEFT JOIN account_routes cr ON cr.account = cp.from_account AND cr.to_account = cp.to_account +), +add_routes AS MATERIALIZED ( + SELECT + from_account, + to_account, + percent, + ( + CASE + WHEN prev_percent IS NULL AND percent != 0 THEN + 1 + WHEN prev_percent IS NOT NULL AND percent != 0 THEN + 0 + WHEN prev_percent IS NOT NULL AND percent = 0 THEN + -1 + ELSE + 0 + END + ) AS withdraw_routes, + source_op + FROM join_prev_route +), +sum_routes AS ( + SELECT + from_account, + SUM(withdraw_routes) AS withdraw_routes + FROM add_routes + GROUP BY from_account +), +insert_routes AS ( + INSERT INTO account_routes + (account, to_account, percent, source_op) + SELECT + ar.from_account, + ar.to_account, + ar.percent, + ar.source_op + FROM add_routes ar + WHERE ar.percent != 0 + ON CONFLICT ON CONSTRAINT pk_account_routes + DO UPDATE SET + percent = EXCLUDED.percent, + source_op = EXCLUDED.source_op + RETURNING account +), +delete_routes AS ( + DELETE FROM account_routes ar + USING add_routes ar2 + WHERE + ar.account = ar2.from_account AND + ar.to_account = ar2.to_account AND + ar2.percent = 0 + RETURNING ar.account +), +insert_sum_of_routes AS ( + INSERT INTO account_withdraws + (account, withdraw_routes) + SELECT + sr.from_account, + sr.withdraw_routes + FROM sum_routes sr + ON CONFLICT ON CONSTRAINT pk_account_withdraws + DO UPDATE SET + withdraw_routes = account_withdraws.withdraw_routes + EXCLUDED.withdraw_routes + RETURNING account +) +SELECT + (SELECT count(*) FROM insert_routes) AS insert_routes, + (SELECT count(*) FROM delete_routes) AS delete_routes, + (SELECT count(*) FROM insert_sum_of_routes) AS insert_sum_of_routes +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 + 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 + WHERE gi.source_op > ar.source_op +), +count_deleted_routes AS ( + SELECT + account, + COUNT(*) AS count + FROM join_current_routes_for_hf23_accounts + GROUP BY account +), +delete_hf23_routes_count AS ( + INSERT INTO account_withdraws + (account, withdraw_routes) + SELECT + cd.account, + cd.count + FROM count_deleted_routes cd + ON CONFLICT ON CONSTRAINT pk_account_withdraws + DO UPDATE SET + withdraw_routes = account_withdraws.withdraw_routes - EXCLUDED.withdraw_routes + RETURNING account +), +delete_hf23_routes AS ( + DELETE FROM account_routes ar + USING join_current_routes_for_hf23_accounts jcr + WHERE + ar.account = jcr.account AND + ar.to_account = jcr.to_account + RETURNING ar.account +) +SELECT + (SELECT count(*) FROM delete_hf23_routes_count) AS delete_hf23_routes_count, + (SELECT count(*) FROM delete_hf23_routes) AS delete_hf23_routes +INTO __delete_hf23_routes_count, __delete_hf23_routes; + +-----------------------------------------FILL WITHDRAWS--------------------------------------------- + +WITH process_block_range_data_b AS ( -SELECT - pbr.source_op, - pbr.source_op_block, - (CASE - WHEN pbr.op_type_id = 4 THEN - process_withdraw_vesting_operation(pbr.body, (SELECT withdraw_rate FROM btracker_app_status)) + SELECT + ov.body_binary::jsonb AS body, + ov.id AS source_op, + ov.block_num as source_op_block, + ov.op_type_id + FROM operations_view ov + 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 +), +join_current_withdraw AS ( + SELECT + aw.account, + aw.withdrawn, + aw.to_withdraw, + aw.source_op + FROM account_withdraws aw + JOIN group_by_account gba ON aw.account = gba.account_id +), +-------------------------------------------------------------------------------------- +get_fills_conserning_current_withdrawal AS MATERIALIZED ( + SELECT + cp.account_id, + SUM(cp.withdrawn) + aw.withdrawn AS withdrawn, + MAX(aw.to_withdraw) AS to_withdraw + FROM convert_parameters_for_delegations 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 +), +insert_not_yet_filled_withdrawals AS ( + INSERT INTO account_withdraws + (account, withdrawn) + SELECT + gf.account_id, + gf.withdrawn + FROM get_fills_conserning_current_withdrawal gf + WHERE gf.to_withdraw > gf.withdrawn + ON CONFLICT ON CONSTRAINT pk_account_withdraws + DO UPDATE SET + withdrawn = EXCLUDED.withdrawn + RETURNING account +), +reset_filled_withdrawals AS ( + INSERT INTO account_withdraws + (account, vesting_withdraw_rate, to_withdraw, withdrawn) + SELECT + gf.account_id, + 0, + 0, + 0 + FROM get_fills_conserning_current_withdrawal gf + WHERE gf.to_withdraw <= gf.withdrawn + ON CONFLICT ON CONSTRAINT pk_account_withdraws + DO UPDATE SET + vesting_withdraw_rate = EXCLUDED.vesting_withdraw_rate, + to_withdraw = EXCLUDED.to_withdraw, + withdrawn = EXCLUDED.withdrawn + RETURNING account +) +SELECT + (SELECT count(*) FROM insert_not_yet_filled_withdrawals) AS insert_not_yet_filled_withdrawals, + (SELECT count(*) FROM reset_filled_withdrawals) AS reset_filled_withdrawals +INTO __insert_not_yet_filled_withdrawals, __reset_filled_withdrawals; - WHEN pbr.op_type_id = 20 THEN - process_set_withdraw_vesting_route_operation(pbr.body) +-----------------------------------------DELAYS--------------------------------------------- - WHEN pbr.op_type_id = 56 THEN - process_fill_vesting_withdraw_operation(pbr.body, (SELECT start_delayed_vests FROM btracker_app_status)) +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 + 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 + WHERE + ov.op_type_id IN (56,77,70) AND + ov.block_num BETWEEN _from AND _to +), - WHEN pbr.op_type_id = 77 AND (SELECT start_delayed_vests FROM btracker_app_status) = TRUE THEN - process_transfer_to_vesting_completed_operation(pbr.body) +-------------------------------------------------------------------------------------- +-- 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 ( + SELECT + from_account AS account_id, + withdrawn AS balance, + source_op + FROM convert_parameters + + UNION ALL - WHEN pbr.op_type_id = 70 AND (SELECT start_delayed_vests FROM btracker_app_status) = TRUE THEN - process_delayed_voting_operation(pbr.body) + SELECT + to_account AS account_id, + deposited AS balance, + source_op + FROM convert_parameters + WHERE to_account IS NOT NULL +), +group_by_account AS ( + SELECT + account_id + FROM union_delays + GROUP BY account_id +), +join_prev_delays AS ( + SELECT + gb.account_id, + COALESCE(aw.delayed_vests,0) AS balance, + 0 AS source_op + FROM group_by_account gb + LEFT JOIN account_withdraws aw ON aw.account = gb.account_id +), +union_prev_delays AS ( + SELECT + account_id, + balance, + source_op + FROM join_prev_delays - WHEN pbr.op_type_id = 68 THEN - process_hardfork_hive_operation(pbr.body) + UNION ALL - WHEN pbr.op_type_id = 60 THEN - process_hardfork(((pbr.body)->'value'->>'hardfork_id')::INT) - END) -FROM process_block_range_data_b pbr -ORDER BY pbr.source_op_block, pbr.source_op -) + SELECT + account_id, + balance, + source_op + FROM union_delays +), +add_row_number AS ( + SELECT + account_id, + balance, + source_op, + ROW_NUMBER() OVER (PARTITION BY account_id ORDER BY source_op) AS row_num + FROM union_prev_delays +), +recursive_delays AS MATERIALIZED ( + WITH RECURSIVE calculated_delays AS ( + SELECT + cp.account_id, + cp.balance, + cp.source_op, + cp.row_num + FROM add_row_number cp + WHERE cp.row_num = 1 + + UNION ALL -SELECT COUNT(*) INTO _result -FROM insert_balance; + SELECT + next_cp.account_id, + GREATEST(next_cp.balance + prev.balance, 0) AS balance, + next_cp.source_op, + next_cp.row_num + FROM calculated_delays prev + JOIN add_row_number next_cp ON prev.account_id = next_cp.account_id AND next_cp.row_num = prev.row_num + 1 + ) + SELECT * FROM calculated_delays +), +latest_rows AS ( + SELECT + account_id, + balance, + ROW_NUMBER() OVER (PARTITION BY account_id ORDER BY source_op DESC) AS rn + FROM + recursive_delays +) +-------------------------------------------------------------------------------------- +INSERT INTO account_withdraws + (account, delayed_vests) +SELECT + account_id, + balance +FROM latest_rows +WHERE rn = 1 +ON CONFLICT ON CONSTRAINT pk_account_withdraws +DO UPDATE SET + delayed_vests = EXCLUDED.delayed_vests; END $$; diff --git a/scripts/install_app.sh b/scripts/install_app.sh index c411884..3fcecc7 100755 --- a/scripts/install_app.sh +++ b/scripts/install_app.sh @@ -77,12 +77,12 @@ psql "$POSTGRES_ACCESS" -v ON_ERROR_STOP=on -c "SET SEARCH_PATH TO ${BTRACKER_S psql "$POSTGRES_ACCESS" -v ON_ERROR_STOP=on -c "SET SEARCH_PATH TO ${BTRACKER_SCHEMA};" -f "$SCRIPTPATH/../db/process_delegations.sql" psql "$POSTGRES_ACCESS" -v ON_ERROR_STOP=on -c "SET SEARCH_PATH TO ${BTRACKER_SCHEMA};" -f "$SCRIPTPATH/../db/process_withdrawals.sql" -psql "$POSTGRES_ACCESS" -v ON_ERROR_STOP=on -c "SET SEARCH_PATH TO ${BTRACKER_SCHEMA};" -f "$SCRIPTPATH/../backend/delayed_vests.sql" +psql "$POSTGRES_ACCESS" -v ON_ERROR_STOP=on -c "SET SEARCH_PATH TO ${BTRACKER_SCHEMA};" -f "$SCRIPTPATH/../backend/delays.sql" psql "$POSTGRES_ACCESS" -v ON_ERROR_STOP=on -c "SET SEARCH_PATH TO ${BTRACKER_SCHEMA};" -f "$SCRIPTPATH/../backend/delegations.sql" psql "$POSTGRES_ACCESS" -v ON_ERROR_STOP=on -c "SET SEARCH_PATH TO ${BTRACKER_SCHEMA};" -f "$SCRIPTPATH/../backend/hardforks.sql" psql "$POSTGRES_ACCESS" -v ON_ERROR_STOP=on -c "SET SEARCH_PATH TO ${BTRACKER_SCHEMA};" -f "$SCRIPTPATH/../backend/rewards.sql" psql "$POSTGRES_ACCESS" -v ON_ERROR_STOP=on -c "SET SEARCH_PATH TO ${BTRACKER_SCHEMA};" -f "$SCRIPTPATH/../backend/savings.sql" -psql "$POSTGRES_ACCESS" -v ON_ERROR_STOP=on -c "SET SEARCH_PATH TO ${BTRACKER_SCHEMA};" -f "$SCRIPTPATH/../backend/withdraws.sql" +psql "$POSTGRES_ACCESS" -v ON_ERROR_STOP=on -c "SET SEARCH_PATH TO ${BTRACKER_SCHEMA};" -f "$SCRIPTPATH/../backend/withdrawals.sql" psql "$POSTGRES_ACCESS" -v ON_ERROR_STOP=on -c "SET custom.swagger_url = '$SWAGGER_URL'; SET SEARCH_PATH TO ${BTRACKER_SCHEMA};" -f "$SCRIPTPATH/../endpoints/endpoint_schema.sql" psql "$POSTGRES_ACCESS" -v ON_ERROR_STOP=on -c "SET SEARCH_PATH TO ${BTRACKER_SCHEMA};" -f "$SCRIPTPATH/../endpoints/types/coin_type.sql" -- GitLab