Skip to content
Snippets Groups Projects
Commit 42839583 authored by Michal Zander's avatar Michal Zander
Browse files

New rewards processing function

parent 59798ab1
No related branches found
No related tags found
2 merge requests!168Update return types: VEST balances should be returned as strings to address JSON limitations,!146Rewrite other balance calculating loops
SET ROLE btracker_owner;
CREATE OR REPLACE FUNCTION process_claim_reward_balance_operation(
body jsonb, _source_op bigint, _source_op_block int
)
RETURNS void
LANGUAGE 'plpgsql' VOLATILE
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
);
DROP TYPE IF EXISTS impacted_rewards_return CASCADE;
CREATE TYPE impacted_rewards_return AS
(
account_name VARCHAR,
hbd_payout BIGINT,
hive_payout BIGINT,
vesting_payout BIGINT
);
CREATE OR REPLACE FUNCTION get_impacted_reward_balances(IN _operation_body JSONB, IN _source_op_block INT, IN _op_type_id INT)
RETURNS impacted_rewards_return
LANGUAGE plpgsql
STABLE
AS
$$
$BODY$
BEGIN
WITH claim_reward_balance_operation AS
(
SELECT
(SELECT id FROM accounts_view WHERE name = (body)->'value'->>'account') AS _account,
((body)->'value'->'reward_hive'->>'amount')::BIGINT AS _hive_payout,
((body)->'value'->'reward_hbd'->>'amount')::BIGINT AS _hbd_payout,
((body)->'value'->'reward_vests'->>'amount')::numeric AS _vesting_payout
)
INSERT INTO account_rewards
(
account,
nai,
balance,
source_op,
source_op_block
)
SELECT
_account,
13,
_hbd_payout,
_source_op,
_source_op_block
FROM claim_reward_balance_operation
WHERE _hbd_payout > 0
UNION ALL
SELECT
_account,
21,
_hive_payout,
_source_op,
_source_op_block
FROM claim_reward_balance_operation
WHERE _hive_payout > 0
UNION ALL
SELECT
_account,
37,
_vesting_payout,
_source_op,
_source_op_block
FROM claim_reward_balance_operation
WHERE _vesting_payout > 0
UNION ALL
SELECT
crbo._account,
38,
(SELECT ROUND(caar.balance * crbo._vesting_payout / car.balance, 3)
FROM account_rewards car
JOIN account_rewards caar ON caar.nai = 38 AND caar.account = car.account
WHERE car.nai = 37 and car.account = crbo._account),
_source_op,
_source_op_block
FROM claim_reward_balance_operation crbo
WHERE crbo._vesting_payout > 0
ON CONFLICT ON CONSTRAINT pk_account_rewards
DO UPDATE SET
balance = account_rewards.balance - EXCLUDED.balance,
source_op = EXCLUDED.source_op,
source_op_block = EXCLUDED.source_op_block;
RETURN (
CASE
WHEN _op_type_id = 39 THEN
process_claim_reward_balance_operation(_operation_body)
END
$$;
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
);
END;
$BODY$;
CREATE OR REPLACE FUNCTION process_author_reward_operation(
body jsonb,
_source_op bigint,
_source_op_block int
)
RETURNS void
LANGUAGE 'plpgsql' VOLATILE
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
AS
$$
BEGIN
WITH author_reward_operation AS
(
SELECT
(SELECT id FROM accounts_view WHERE name = (body)->'value'->>'author') AS _account,
((body)->'value'->'hbd_payout'->>'amount')::BIGINT AS _hbd_payout,
((body)->'value'->'hive_payout'->>'amount')::BIGINT AS _hive_payout,
((body)->'value'->'vesting_payout'->>'amount')::BIGINT AS _vesting_payout
)
INSERT INTO account_rewards (
account,
nai,
balance,
source_op,
source_op_block
)
SELECT
_account,
13,
_hbd_payout,
_source_op,
_source_op_block
FROM author_reward_operation
WHERE _hbd_payout > 0
UNION ALL
SELECT
_account,
21,
_hive_payout,
_source_op,
_source_op_block
FROM author_reward_operation
WHERE _hive_payout > 0
UNION ALL
SELECT
_account,
37,
_vesting_payout,
_source_op,
_source_op_block
FROM author_reward_operation
WHERE _vesting_payout > 0
UNION ALL
SELECT
_account,
38,
(SELECT hive.get_vesting_balance(_source_op_block, _vesting_payout)),
_source_op,
_source_op_block
FROM author_reward_operation
WHERE _vesting_payout > 0
ON CONFLICT ON CONSTRAINT pk_account_rewards
DO UPDATE SET
balance = account_rewards.balance + EXCLUDED.balance,
source_op = EXCLUDED.source_op,
source_op_block = EXCLUDED.source_op_block;
RETURN (
((_operation_body)->'value'->>'author')::TEXT,
((_operation_body)->'value'->>'author_rewards')::BIGINT,
0
)::impacted_info_rewards_return;
END
$$;
CREATE OR REPLACE FUNCTION process_curation_reward_operation(
body jsonb,
_source_op bigint,
_source_op_block int
)
RETURNS void
LANGUAGE 'plpgsql' VOLATILE
CREATE OR REPLACE FUNCTION process_curation_rewards(IN _operation_body JSONB)
RETURNS impacted_info_rewards_return
LANGUAGE 'plpgsql' STABLE
AS
$$
BEGIN
WITH curation_reward_operation AS
(
SELECT
(SELECT id FROM accounts_view WHERE name = (body)->'value'->>'curator') AS _account,
((body)->'value'->'reward'->>'amount')::BIGINT AS _reward,
(SELECT hive.get_vesting_balance(_source_op_block, ((body)->'value'->'reward'->>'amount')::BIGINT)) AS _reward_hive,
((body)->'value'->>'payout_must_be_claimed')::BOOLEAN AS _payout_must_be_claimed
),
insert_balance AS
(
INSERT INTO account_rewards (
account,
nai,
balance,
source_op,
source_op_block
)
SELECT
_account,
37,
_reward,
_source_op,
_source_op_block
FROM curation_reward_operation
WHERE _payout_must_be_claimed = TRUE
UNION ALL
SELECT
_account,
38,
_reward_hive,
_source_op,
_source_op_block
FROM curation_reward_operation
WHERE _payout_must_be_claimed = TRUE
RETURN (
((_operation_body)->'value'->>'curator')::TEXT,
0,
((_operation_body)->'value'->'reward'->>'amount')::BIGINT
ON CONFLICT ON CONSTRAINT pk_account_rewards
DO UPDATE SET
balance = account_rewards.balance + EXCLUDED.balance,
source_op = EXCLUDED.source_op,
source_op_block = EXCLUDED.source_op_block
)
)::impacted_info_rewards_return;
END
$$;
INSERT INTO account_info_rewards (
account,
curation_rewards
CREATE OR REPLACE FUNCTION process_author_or_benefactor_reward_operation(IN _operation_body JSONB, IN _source_op_block INT, IN _op_type_id INT)
RETURNS impacted_rewards_return
LANGUAGE 'plpgsql' STABLE
AS
$$
BEGIN
RETURN (
WITH author_reward_operation AS (
SELECT
(CASE
WHEN _op_type_id = 51 THEN
(_operation_body)->'value'->>'author'
ELSE
(_operation_body)->'value'->>'benefactor'
END
)::TEXT AS account_name,
((_operation_body)->'value'->'hbd_payout'->>'amount')::BIGINT AS hbd_payout,
((_operation_body)->'value'->'hive_payout'->>'amount')::BIGINT AS hive_payout,
((_operation_body)->'value'->'vesting_payout'->>'amount')::BIGINT AS vesting_payout
),
add_vesting_balance AS (
SELECT
account_name,
hbd_payout,
hive_payout,
vesting_payout
FROM author_reward_operation
)
SELECT
_account,
_reward_hive
FROM curation_reward_operation
SELECT
(
account_name,
hbd_payout,
hive_payout,
vesting_payout
)::impacted_rewards_return
FROM add_vesting_balance
);
ON CONFLICT ON CONSTRAINT pk_account_info_rewards
DO UPDATE SET
curation_rewards = account_info_rewards.curation_rewards + EXCLUDED.curation_rewards;
END
$$;
CREATE OR REPLACE FUNCTION process_comment_benefactor_reward_operation(
body jsonb, _source_op bigint, _source_op_block int
)
RETURNS void
LANGUAGE 'plpgsql' VOLATILE
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
WITH comment_benefactor_reward_operation AS
(
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
(SELECT id FROM accounts_view WHERE name = (body)->'value'->>'benefactor') AS _account,
((body)->'value'->'hbd_payout'->>'amount')::BIGINT AS _hbd_payout,
((body)->'value'->'hive_payout'->>'amount')::BIGINT AS _hive_payout,
((body)->'value'->'vesting_payout'->>'amount')::BIGINT AS _vesting_payout
)
INSERT INTO account_rewards (
account,
nai,
balance,
source_op,
source_op_block
)
SELECT
_account,
13,
_hbd_payout,
_source_op,
_source_op_block
FROM comment_benefactor_reward_operation
WHERE _hbd_payout > 0
UNION ALL
SELECT
_account,
21,
_hive_payout,
_source_op,
_source_op_block
FROM comment_benefactor_reward_operation
WHERE _hive_payout > 0
UNION ALL
SELECT
_account,
37,
_vesting_payout,
_source_op,
_source_op_block
FROM comment_benefactor_reward_operation
WHERE _vesting_payout > 0
UNION ALL
SELECT
_account,
38,
(SELECT hive.get_vesting_balance(_source_op_block, _vesting_payout)),
_source_op,
_source_op_block
FROM comment_benefactor_reward_operation
WHERE _vesting_payout > 0
ON CONFLICT ON CONSTRAINT pk_account_rewards
DO UPDATE SET
balance = account_rewards.balance + EXCLUDED.balance,
source_op = EXCLUDED.source_op,
source_op_block = EXCLUDED.source_op_block;
(
account_name,
hbd_payout,
hive_payout,
vesting_payout
)::impacted_rewards_return
FROM author_curation_operation
);
END
$$;
CREATE OR REPLACE FUNCTION process_comment_reward_operation(
body jsonb
)
RETURNS void
LANGUAGE 'plpgsql' VOLATILE
CREATE OR REPLACE FUNCTION process_claim_reward_balance_operation(IN _operation_body JSONB)
RETURNS impacted_rewards_return
LANGUAGE 'plpgsql' STABLE
AS
$$
BEGIN
WITH comment_reward_operation AS
(
SELECT
(SELECT id FROM accounts_view WHERE name = (body)->'value'->>'author') AS _account,
((body)->'value'->>'author_rewards')::BIGINT AS _author_rewards
)
INSERT INTO account_info_rewards (
account,
posting_rewards
RETURN (
WITH author_claim_reward_operation AS (
SELECT
((_operation_body)->'value'->>'account')::TEXT AS account_name,
- ((_operation_body)->'value'->'reward_hbd'->>'amount')::BIGINT AS claim_hbd,
- ((_operation_body)->'value'->'reward_hive'->>'amount')::BIGINT AS claim_hive,
- ((_operation_body)->'value'->'reward_vests'->>'amount')::BIGINT AS claim_vests
)
SELECT
_account,
_author_rewards
FROM comment_reward_operation
ON CONFLICT ON CONSTRAINT pk_account_info_rewards
DO UPDATE SET
posting_rewards = account_info_rewards.posting_rewards + EXCLUDED.posting_rewards;
SELECT
(
account_name,
claim_hbd,
claim_hive,
claim_vests
)::impacted_rewards_return
FROM author_claim_reward_operation
);
END
$$;
......
......@@ -14,7 +14,7 @@ CREATE TYPE impacted_savings_return AS
CREATE OR REPLACE FUNCTION get_impacted_saving_balances(IN _operation_body JSONB, IN _op_type_id INT)
RETURNS impacted_savings_return
LANGUAGE plpgsql
VOLATILE
STABLE
AS
$BODY$
BEGIN
......@@ -42,7 +42,7 @@ $BODY$;
CREATE OR REPLACE FUNCTION process_transfer_to_savings_operation(IN _operation_body JSONB)
RETURNS impacted_savings_return
LANGUAGE 'plpgsql' VOLATILE
LANGUAGE 'plpgsql' STABLE
AS
$$
BEGIN
......@@ -59,7 +59,7 @@ $$;
CREATE OR REPLACE FUNCTION process_transfer_from_savings_operation(IN _operation_body JSONB)
RETURNS impacted_savings_return
LANGUAGE 'plpgsql' VOLATILE
LANGUAGE 'plpgsql' STABLE
AS
$$
BEGIN
......@@ -76,7 +76,7 @@ $$;
CREATE OR REPLACE FUNCTION process_fill_transfer_from_savings_operation(IN _operation_body JSONB)
RETURNS impacted_savings_return
LANGUAGE 'plpgsql' VOLATILE
LANGUAGE 'plpgsql' STABLE
AS
$$
BEGIN
......@@ -93,7 +93,7 @@ $$;
CREATE OR REPLACE FUNCTION process_interest_operation(IN _operation_body JSONB)
RETURNS impacted_savings_return
LANGUAGE 'plpgsql' VOLATILE
LANGUAGE 'plpgsql' STABLE
AS
$$
BEGIN
......@@ -110,7 +110,7 @@ $$;
CREATE OR REPLACE FUNCTION process_cancel_transfer_from_savings_operation(IN _operation_body JSONB)
RETURNS impacted_savings_return
LANGUAGE 'plpgsql' VOLATILE
LANGUAGE 'plpgsql' STABLE
AS
$$
BEGIN
......
......@@ -275,7 +275,7 @@ BEGIN
PERFORM process_block_range_balances(_from, _to);
PERFORM process_block_range_data(_from, _to);
PERFORM process_block_range_savings(_from, _to);
PERFORM process_block_range_rewards(_from, _to);
IF _logs THEN
__end_ts := clock_timestamp();
......@@ -306,6 +306,7 @@ BEGIN
PERFORM process_block_range_balances(_block, _block);
PERFORM process_block_range_data(_block, _block);
PERFORM process_block_range_savings(_block, _block);
PERFORM process_block_range_rewards(_block, _block);
IF _logs THEN
__end_ts := clock_timestamp();
......
......@@ -217,21 +217,9 @@ SELECT
ov.op_type_id
FROM operations_view ov
WHERE
ov.op_type_id IN (40,41,62,39,4,20,56,60,52,53,77,70,68,51,63) AND
ov.op_type_id IN (40,41,62,4,20,56,60,77,70,68) AND
ov.block_num BETWEEN _from AND _to
),
filter_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 IN (40,41,62,39,4,20,56,60,52,53,77,70,68) or
(ov.op_type_id IN (51,63) and (ov.body->'value'->>'payout_must_be_claimed')::BOOLEAN = true))
),
insert_balance AS MATERIALIZED
(
SELECT
......@@ -247,18 +235,6 @@ SELECT
WHEN pbr.op_type_id = 62 THEN
process_return_vesting_delegation_operation(pbr.body, pbr.source_op, pbr.source_op_block)
WHEN pbr.op_type_id = 39 THEN
process_claim_reward_balance_operation(pbr.body, pbr.source_op, pbr.source_op_block)
WHEN pbr.op_type_id = 51 THEN
process_author_reward_operation(pbr.body, pbr.source_op, pbr.source_op_block)
WHEN pbr.op_type_id = 52 THEN
process_curation_reward_operation(pbr.body, pbr.source_op, pbr.source_op_block)
WHEN pbr.op_type_id = 63 THEN
process_comment_benefactor_reward_operation(pbr.body, pbr.source_op, pbr.source_op_block)
WHEN pbr.op_type_id = 4 THEN
process_withdraw_vesting_operation(pbr.body, (SELECT withdraw_rate FROM btracker_app_status))
......@@ -268,9 +244,6 @@ SELECT
WHEN pbr.op_type_id = 56 THEN
process_fill_vesting_withdraw_operation(pbr.body, (SELECT start_delayed_vests FROM btracker_app_status))
WHEN pbr.op_type_id = 53 THEN
process_comment_reward_operation(pbr.body)
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)
......@@ -283,7 +256,7 @@ SELECT
WHEN pbr.op_type_id = 60 THEN
process_hardfork(((pbr.body)->'value'->>'hardfork_id')::INT)
END)
FROM filter_ops pbr
FROM process_block_range_data_b pbr
ORDER BY pbr.source_op_block, pbr.source_op
)
......
SET ROLE btracker_owner;
CREATE OR REPLACE FUNCTION process_block_range_rewards(IN _from INT, IN _to INT, IN _report_step INT = 1000)
RETURNS VOID
LANGUAGE 'plpgsql' VOLATILE
SET from_collapse_limit = 16
SET join_collapse_limit = 16
SET jit = OFF
AS
$$
DECLARE
__insert_rewards INT;
__insert_info_rewards INT;
BEGIN
WITH process_block_range_data_b AS
(
SELECT
ov.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 = ANY(ARRAY[39,51,52,63,53]) AND
ov.block_num BETWEEN _from AND _to
),
filter_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 = 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])
),
------------------------------------------------------------------------------
--prepare info rewards data
get_impacted_info_rewards AS (
SELECT
get_impacted_info_reward_balances(fio.body, fio.op_type_id) AS get_impacted_info_reward_balances,
fio.op_type_id,
fio.source_op,
fio.source_op_block
FROM filter_info_reward_ops fio
),
convert_info_rewards_parameters 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
),
-- 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
GROUP BY account_name
),
posting_and_curations_account_id AS (
SELECT
(SELECT av.id FROM accounts_view av WHERE av.name = account_name) AS account_id,
posting,
curation
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
account_name,
reward_hbd,
reward_hive,
reward_vests,
(reward_vests * bv.total_vesting_fund_hive::NUMERIC / NULLIF(bv.total_vesting_shares, 0)::NUMERIC)::BIGINT AS reward_vest_balance,
op_type_id,
source_op,
source_op_block
FROM convert_params
-- 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
),
union_operations_with_vesting_balance AS (
SELECT
account_name,
reward_hbd,
reward_hive,
reward_vests,
reward_vest_balance,
op_type_id,
source_op,
source_op_block
FROM calculate_vesting_balance
UNION ALL
SELECT
account_name,
reward_hbd,
reward_hive,
reward_vests,
0 AS reward_vest_balance,
op_type_id,
source_op,
source_op_block
FROM convert_params
WHERE op_type_id = 39
),
------------------------------------------------------------------------------
-- aggregate rewards for each account (CLAIMS WITH reward_vests = 0 INCLUDED)
-- Identify segments between op_type_id = 39
segmented_rows AS (
SELECT
*,
SUM(CASE WHEN op_type_id = 39 AND reward_vests != 0 THEN 1 ELSE 0 END) OVER (PARTITION BY account_name ORDER BY source_op) AS segment
FROM union_operations_with_vesting_balance
),
-- Aggregate balances for segments ending with op_type_id = 39
aggregated_rows AS (
SELECT
account_name,
SUM(CASE WHEN op_type_id = 39 AND reward_vests != 0 THEN 0 ELSE reward_hbd END) AS reward_hbd,
SUM(CASE WHEN op_type_id = 39 AND reward_vests != 0 THEN 0 ELSE reward_hive END) AS reward_hive,
SUM(CASE WHEN op_type_id = 39 AND reward_vests != 0 THEN 0 ELSE reward_vests END) AS reward_vests,
SUM(CASE WHEN op_type_id = 39 AND reward_vests != 0 THEN 0 ELSE reward_vest_balance END) AS reward_vest_balance,
MAX(source_op) AS source_op,
MAX(source_op_block) AS source_op_block
FROM segmented_rows
GROUP BY account_name, segment
),
-- Select the results including the op_type_id = 39 records
union_aggregated_and_segmented_rows AS (
SELECT
account_name,
reward_hbd,
reward_hive,
reward_vests,
reward_vest_balance,
source_op,
source_op_block,
FALSE AS is_claim
FROM aggregated_rows
WHERE NOT (reward_hbd = 0 AND reward_hive = 0 AND reward_vests = 0 AND reward_vest_balance = 0)
-- Include 39 operations in the results
UNION ALL
SELECT
account_name,
reward_hbd,
reward_hive,
reward_vests,
reward_vest_balance,
source_op,
source_op_block,
TRUE AS is_claim
FROM segmented_rows
WHERE op_type_id = 39 AND reward_vests != 0
ORDER BY source_op
),
------------------------------------------------------------------------------
-- prepare previous balances for each account
find_accounts_using_claim AS (
SELECT
account_name,
(SELECT av.id FROM accounts_view av WHERE av.name = account_name) AS account_id
FROM union_aggregated_and_segmented_rows
WHERE is_claim
GROUP BY account_name
),
prepare_prev_balances AS (
SELECT
fa.account_name,
ar.account AS account_id,
ar.nai,
ar.balance
FROM account_rewards ar
JOIN find_accounts_using_claim fa ON fa.account_id = ar.account
WHERE nai IN (38,37)
),
join_prev_balances AS (
SELECT
cp.account_name,
cp.reward_hbd,
cp.reward_hive,
cp.reward_vests,
cp.reward_vest_balance,
COALESCE(ppb.balance, 0) AS prev_vests,
COALESCE(ppbs.balance, 0)::NUMERIC AS prev_hive_vests,
cp.source_op,
cp.source_op_block,
cp.is_claim
FROM union_aggregated_and_segmented_rows cp
LEFT JOIN prepare_prev_balances ppb ON ppb.account_name = cp.account_name AND cp.is_claim AND ppb.nai = 37
LEFT JOIN prepare_prev_balances ppbs ON ppbs.account_name = cp.account_name AND ppbs.nai = 38
),
------------------------------------------------------------------------------
sum_prev_vests_without_current_row AS (
SELECT
cp.account_name,
cp.reward_hbd,
cp.reward_hive,
cp.reward_vests,
cp.reward_vest_balance,
SUM(cp.reward_vests) OVER (PARTITION BY cp.account_name ORDER BY cp.source_op ROWS BETWEEN UNBOUNDED PRECEDING AND 1 PRECEDING) AS sum_prev_vests,
cp.prev_vests,
cp.prev_hive_vests,
cp.source_op,
cp.source_op_block,
cp.is_claim
FROM join_prev_balances cp
),
sum_vests_add_row_number AS (
SELECT
cp.account_name,
cp.reward_hbd,
cp.reward_hive,
cp.reward_vests,
cp.reward_vest_balance,
COALESCE(cp.sum_prev_vests,0) + cp.prev_vests AS prev_vests,
cp.prev_hive_vests,
cp.source_op,
cp.source_op_block,
cp.is_claim,
ROW_NUMBER() OVER (PARTITION BY cp.account_name ORDER BY cp.source_op) AS row_num
FROM sum_prev_vests_without_current_row cp
),
------------------------------------------------------------------------------
recursive_vests AS (
WITH RECURSIVE calculated_vests AS (
SELECT
cp.account_name,
cp.reward_hbd,
cp.reward_hive,
cp.reward_vests,
CASE
WHEN cp.is_claim THEN
- ROUND((cp.prev_hive_vests) * (- cp.reward_vests) / cp.prev_vests, 3)
ELSE
cp.reward_vest_balance
END AS reward_vest_balance,
cp.prev_vests,
cp.prev_hive_vests,
cp.source_op,
cp.source_op_block,
cp.row_num,
cp.is_claim
FROM sum_vests_add_row_number cp
WHERE cp.row_num = 1
UNION ALL
SELECT
next_cp.account_name,
next_cp.reward_hbd,
next_cp.reward_hive,
next_cp.reward_vests,
CASE
WHEN next_cp.is_claim THEN
- ROUND((prev.reward_vest_balance + prev.prev_hive_vests) * (- next_cp.reward_vests) / next_cp.prev_vests, 3)
ELSE
next_cp.reward_vest_balance
END AS reward_vest_balance,
next_cp.prev_vests,
(prev.reward_vest_balance + prev.prev_hive_vests) AS prev_hive_vests,
next_cp.source_op,
next_cp.source_op_block,
next_cp.row_num,
next_cp.is_claim
FROM calculated_vests prev
JOIN sum_vests_add_row_number next_cp ON prev.account_name = next_cp.account_name AND next_cp.row_num = prev.row_num + 1
)
SELECT * FROM calculated_vests
),
------------------------------------------------------------------------------
sum_operations AS (
SELECT
(SELECT av.id FROM accounts_view av WHERE av.name = account_name) AS account_id,
SUM(reward_hbd)::BIGINT AS reward_hbd,
SUM(reward_hive)::BIGINT AS reward_hive,
SUM(reward_vests)::BIGINT AS reward_vests,
SUM(reward_vest_balance)::BIGINT AS reward_vest_balance,
MAX(source_op_block)::INT AS source_op_block,
MAX(source_op)::BIGINT AS source_op
FROM recursive_vests
GROUP BY account_name
),
convert_rewards AS (
SELECT
account_id,
unnest(ARRAY[13, 21, 37, 38]) AS nai,
unnest(ARRAY[reward_hbd, reward_hive, reward_vests, reward_vest_balance]) AS balance,
source_op,
source_op_block
FROM sum_operations
),
prepare_ops_before_insert AS (
SELECT
account_id,
nai,
balance,
source_op,
source_op_block
FROM convert_rewards
WHERE balance != 0
),
------------------------------------------------------------------------------
insert_sum_of_rewards AS (
INSERT INTO account_rewards
(account, nai, balance, source_op, source_op_block)
SELECT
po.account_id,
po.nai,
po.balance,
po.source_op,
po.source_op_block
FROM prepare_ops_before_insert po
ON CONFLICT ON CONSTRAINT pk_account_rewards
DO UPDATE SET
balance = account_rewards.balance + EXCLUDED.balance,
source_op = EXCLUDED.source_op,
source_op_block = EXCLUDED.source_op_block
RETURNING account AS new_updated_acccounts
),
insert_sum_of_info_rewards AS (
INSERT INTO account_info_rewards
(account, posting_rewards, curation_rewards)
SELECT
gb.account_id,
gb.posting,
gb.curation
FROM posting_and_curations_account_id gb
ON CONFLICT ON CONSTRAINT pk_account_info_rewards
DO UPDATE SET
posting_rewards = account_info_rewards.posting_rewards + EXCLUDED.posting_rewards,
curation_rewards = account_info_rewards.curation_rewards + EXCLUDED.curation_rewards
RETURNING account AS new_updated_acccounts
)
------------------------------------------------------------------------------
SELECT
(SELECT count(*) FROM insert_sum_of_rewards) AS rewards,
(SELECT count(*) FROM insert_sum_of_info_rewards) AS info_rewards
INTO __insert_rewards, __insert_info_rewards;
END
$$;
RESET ROLE;
......@@ -73,6 +73,7 @@ psql "$POSTGRES_ACCESS" -v ON_ERROR_STOP=on -c "SET ROLE btracker_owner;CREATE
psql "$POSTGRES_ACCESS" -v ON_ERROR_STOP=on -c "SET SEARCH_PATH TO ${BTRACKER_SCHEMA};" -f "$SCRIPTPATH/../db/btracker_app.sql"
psql "$POSTGRES_ACCESS" -v ON_ERROR_STOP=on -c "SET SEARCH_PATH TO ${BTRACKER_SCHEMA};" -f "$SCRIPTPATH/../db/process_block_range.sql"
psql "$POSTGRES_ACCESS" -v ON_ERROR_STOP=on -c "SET SEARCH_PATH TO ${BTRACKER_SCHEMA};" -f "$SCRIPTPATH/../db/process_savings.sql"
psql "$POSTGRES_ACCESS" -v ON_ERROR_STOP=on -c "SET SEARCH_PATH TO ${BTRACKER_SCHEMA};" -f "$SCRIPTPATH/../db/process_rewards.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/delegations.sql"
......
0% Loading or .
You are about to add 0 people to the discussion. Proceed with caution.
Please register or to comment