From d33da28d0435b21be15f7293a2241b23a982b6b1 Mon Sep 17 00:00:00 2001 From: Michal Zander <mzander@syncad.com> Date: Mon, 27 Jan 2025 14:44:17 +0000 Subject: [PATCH] Fix curation rewards --- backend/rewards.sql | 61 ++--------------------- db/process_rewards.sql | 108 ++++++++++++++++++++++++++++++----------- 2 files changed, 85 insertions(+), 84 deletions(-) diff --git a/backend/rewards.sql b/backend/rewards.sql index 07f6002..018158a 100644 --- a/backend/rewards.sql +++ b/backend/rewards.sql @@ -4,8 +4,8 @@ DROP TYPE IF EXISTS impacted_info_rewards_return CASCADE; CREATE TYPE impacted_info_rewards_return AS ( account_name VARCHAR, - posting_reward BIGINT, - curation_reward BIGINT + reward BIGINT, + payout_must_be_claimed BOOLEAN ); DROP TYPE IF EXISTS impacted_rewards_return CASCADE; @@ -31,9 +31,6 @@ BEGIN WHEN _op_type_id = 51 OR _op_type_id = 63 THEN process_author_or_benefactor_reward_operation(_operation_body, _source_op_block, _op_type_id) - - WHEN _op_type_id = 52 THEN - process_curation_reward_operation(_operation_body, _source_op_block) END ); @@ -41,26 +38,6 @@ END; $BODY$; -CREATE OR REPLACE FUNCTION get_impacted_info_reward_balances(IN _operation_body JSONB, IN _op_type_id INT) -RETURNS impacted_info_rewards_return -LANGUAGE plpgsql -STABLE -AS -$BODY$ -BEGIN - RETURN ( - CASE - WHEN _op_type_id = 52 THEN - process_curation_rewards(_operation_body) - - WHEN _op_type_id = 53 THEN - process_posting_rewards(_operation_body) - END - ); - -END; -$BODY$; - CREATE OR REPLACE FUNCTION process_posting_rewards(IN _operation_body JSONB) RETURNS impacted_info_rewards_return LANGUAGE 'plpgsql' STABLE @@ -70,7 +47,7 @@ BEGIN RETURN ( ((_operation_body)->'value'->>'author')::TEXT, ((_operation_body)->'value'->>'author_rewards')::BIGINT, - 0 + TRUE )::impacted_info_rewards_return; END @@ -84,9 +61,8 @@ $$ BEGIN RETURN ( ((_operation_body)->'value'->>'curator')::TEXT, - 0, - ((_operation_body)->'value'->'reward'->>'amount')::BIGINT - + ((_operation_body)->'value'->'reward'->>'amount')::BIGINT, + ((_operation_body)->'value'->>'payout_must_be_claimed')::BOOLEAN )::impacted_info_rewards_return; END @@ -133,33 +109,6 @@ RETURN ( END $$; -CREATE OR REPLACE FUNCTION process_curation_reward_operation(IN _operation_body JSONB, IN _source_op_block INT) -RETURNS impacted_rewards_return -LANGUAGE 'plpgsql' STABLE -AS -$$ -BEGIN -RETURN ( - WITH author_curation_operation AS ( - SELECT - ((_operation_body)->'value'->>'curator')::TEXT AS account_name, - 0 AS hbd_payout, - 0 AS hive_payout, - ((_operation_body)->'value'->'reward'->>'amount')::BIGINT AS vesting_payout - ) - SELECT - ( - account_name, - hbd_payout, - hive_payout, - vesting_payout - )::impacted_rewards_return - FROM author_curation_operation -); - -END -$$; - CREATE OR REPLACE FUNCTION process_claim_reward_balance_operation(IN _operation_body JSONB) RETURNS impacted_rewards_return LANGUAGE 'plpgsql' STABLE diff --git a/db/process_rewards.sql b/db/process_rewards.sql index 8fc5c5d..739d5d3 100644 --- a/db/process_rewards.sql +++ b/db/process_rewards.sql @@ -12,10 +12,7 @@ DECLARE __insert_rewards INT; __insert_info_rewards INT; BEGIN - - - -WITH process_block_range_data_b AS +WITH process_block_range_data_b AS MATERIALIZED ( SELECT ov.body, @@ -37,43 +34,84 @@ filter_reward_ops AS ( FROM process_block_range_data_b ov WHERE ov.op_type_id = 39 OR - (ov.op_type_id = ANY(ARRAY[51,63,52]) AND (ov.body->'value'->>'payout_must_be_claimed')::BOOLEAN = true) -), -filter_info_reward_ops AS -( - SELECT - ov.body, - ov.source_op, - ov.source_op_block, - ov.op_type_id - FROM process_block_range_data_b ov - WHERE - ov.op_type_id = ANY(ARRAY[52,53]) + (ov.op_type_id = ANY(ARRAY[51,63]) AND (ov.body->'value'->>'payout_must_be_claimed')::BOOLEAN = true) ), ------------------------------------------------------------------------------ --prepare info rewards data -get_impacted_info_rewards AS ( +get_impacted_posting AS ( SELECT - get_impacted_info_reward_balances(fio.body, fio.op_type_id) AS get_impacted_info_reward_balances, + process_posting_rewards(fio.body) AS get_posting, fio.op_type_id, fio.source_op, fio.source_op_block - FROM filter_info_reward_ops fio + FROM process_block_range_data_b fio + WHERE fio.op_type_id = 53 ), -convert_info_rewards_parameters AS ( +get_impacted_curation AS ( SELECT - (gi.get_impacted_info_reward_balances).account_name AS account_name, - (gi.get_impacted_info_reward_balances).posting_reward AS posting, - (gi.get_impacted_info_reward_balances).curation_reward AS curation - FROM get_impacted_info_rewards gi + process_curation_rewards(fio.body) AS get_curation, + fio.op_type_id, + fio.source_op, + fio.source_op_block + FROM process_block_range_data_b fio + 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 ( + SELECT + pc.account_name, + pc.reward, + (pc.reward * bv.total_vesting_fund_hive::NUMERIC / NULLIF(bv.total_vesting_shares, 0)::NUMERIC)::BIGINT AS curation_reward, + pc.payout_must_be_claimed, + pc.op_type_id, + pc.source_op, + pc.source_op_block + FROM prepare_curation pc + JOIN hive.blocks_view bv ON bv.num = pc.source_op_block +), +------------------------------------------------------------------------------ +get_impacted_info_rewards AS ( + SELECT + account_name, + posting_reward, + 0 AS curation_reward + FROM prepare_posting + + UNION ALL + + SELECT + account_name, + 0 AS posting_reward, + curation_reward + FROM calculate_vests_from_curation ), -- prepare info rewards data group_by_account_info AS ( SELECT account_name, - SUM(posting) AS posting, - SUM(curation) AS curation - FROM convert_info_rewards_parameters + SUM(posting_reward) AS posting, + SUM(curation_reward) AS curation + FROM get_impacted_info_rewards GROUP BY account_name ), posting_and_curations_account_id AS ( @@ -148,6 +186,20 @@ union_operations_with_vesting_balance AS ( FROM convert_params WHERE op_type_id = 39 + UNION ALL + + SELECT + account_name, + 0 AS reward_hbd, + 0 AS reward_hive, + reward AS reward_vests, + curation_reward AS reward_vest_balance, + op_type_id, + source_op, + source_op_block + FROM calculate_vests_from_curation + WHERE payout_must_be_claimed + ), ------------------------------------------------------------------------------ -- aggregate rewards for each account (CLAIMS WITH reward_vests = 0 INCLUDED) @@ -252,7 +304,7 @@ sum_prev_vests_without_current_row AS ( cp.is_claim FROM join_prev_balances cp ), -sum_vests_add_row_number AS ( +sum_vests_add_row_number AS MATERIALIZED ( SELECT cp.account_name, cp.reward_hbd, -- GitLab