Skip to content

Commit

Permalink
Fix reward misalignment on account's rewards available
Browse files Browse the repository at this point in the history
  • Loading branch information
rdlrt committed May 15, 2024
1 parent 859b283 commit d4dfb66
Show file tree
Hide file tree
Showing 4 changed files with 67 additions and 121 deletions.
29 changes: 18 additions & 11 deletions files/grest/rpc/01_cached_tables/stake_distribution_cache.sql
Original file line number Diff line number Diff line change
Expand Up @@ -22,9 +22,9 @@ BEGIN
WHERE block_no IS NOT NULL INTO _last_accounted_block_height;
SELECT (last_value::integer - 2)::integer INTO _active_stake_epoch FROM grest.control_table
WHERE key = 'last_active_stake_validated_epoch';
SELECT MAX(eic.i_last_tx_id) INTO _last_account_tx_id
SELECT (eic.i_last_tx_id) INTO _last_account_tx_id
FROM grest.epoch_info_cache AS eic
WHERE eic.epoch_no <= _active_stake_epoch;
WHERE eic.epoch_no = _active_stake_epoch;
SELECT MAX(no) INTO _latest_epoch FROM public.epoch WHERE no IS NOT NULL;

WITH
Expand Down Expand Up @@ -114,8 +114,7 @@ BEGIN
COALESCE(SUM(reward.amount), 0) AS rewards
FROM reward
INNER JOIN accounts_with_delegated_pools AS awdp ON awdp.stake_address_id = reward.addr_id
WHERE
(reward.spendable_epoch >= (_active_stake_epoch + 2) AND reward.spendable_epoch <= _latest_epoch )
WHERE (reward.spendable_epoch >= (_active_stake_epoch + 2) AND reward.spendable_epoch <= _latest_epoch )
OR (reward.TYPE = 'refund' AND reward.spendable_epoch >= (_active_stake_epoch + 1) AND reward.spendable_epoch <= _latest_epoch )
GROUP BY awdp.stake_address_id
),
Expand Down Expand Up @@ -158,6 +157,16 @@ BEGIN
FROM withdrawal
INNER JOIN accounts_with_delegated_pools ON accounts_with_delegated_pools.stake_address_id = withdrawal.addr_id
GROUP BY accounts_with_delegated_pools.stake_address_id
),

account_total_instant_rewards AS (
SELECT
awdp.stake_address_id,
COALESCE(SUM(ir.amount), 0) AS amount
FROM instant_reward AS ir
INNER JOIN accounts_with_delegated_pools AS awdp ON awdp.stake_address_id = ir.addr_id
WHERE ir.spendable_epoch <= _latest_epoch
GROUP BY awdp.stake_address_id
)

-- INSERT QUERY START
Expand All @@ -166,18 +175,16 @@ BEGIN
awdp.stake_address,
pi.pool_id,
COALESCE(aas.amount, 0) + COALESCE(ado.amount, 0) - COALESCE(adi.amount, 0) + COALESCE(adr.rewards, 0) + COALESCE(adir.amount, 0) - COALESCE(adw.withdrawals, 0) AS total_balance,
COALESCE(aas.amount, 0) + COALESCE(ado.amount, 0) - COALESCE(adi.amount, 0) + COALESCE(adr.rewards, 0) + COALESCE(adir.amount, 0) - COALESCE(adw.withdrawals, 0) AS utxo,
COALESCE(aas.amount, 0) + COALESCE(ado.amount, 0) - COALESCE(adi.amount, 0) + COALESCE(adr.rewards, 0) + COALESCE(adir.amount, 0) - COALESCE(adw.withdrawals, 0) - COALESCE(atrew.rewards, 0) - COALESCE(atir.amount, 0) + COALESCE(atw.withdrawals, 0) AS utxo,
COALESCE(atrew.rewards, 0) AS rewards,
COALESCE(atw.withdrawals, 0) AS withdrawals,
CASE
WHEN ( COALESCE(atrew.rewards, 0) + COALESCE(adir.amount, 0) - COALESCE(atw.withdrawals, 0) ) <= 0 THEN 0
ELSE COALESCE(atrew.rewards, 0) + COALESCE(adir.amount, 0) - COALESCE(atw.withdrawals, 0)
END AS rewards_available
COALESCE(atrew.rewards, 0) + COALESCE(atir.amount, 0) - COALESCE(atw.withdrawals, 0) AS rewards_available
FROM accounts_with_delegated_pools AS awdp
INNER JOIN pool_ids AS pi ON pi.stake_address_id = awdp.stake_address_id
LEFT JOIN account_active_stake AS aas ON aas.stake_address_id = awdp.stake_address_id
LEFT JOIN account_total_rewards AS atrew ON atrew.stake_address_id = awdp.stake_address_id
LEFT JOIN account_total_withdrawals AS atw ON atw.stake_address_id = awdp.stake_address_id
LEFT JOIN account_total_instant_rewards AS atir ON atir.stake_address_id = awdp.stake_address_id
LEFT JOIN account_delta_input AS adi ON adi.stake_address_id = awdp.stake_address_id
LEFT JOIN account_delta_output AS ado ON ado.stake_address_id = awdp.stake_address_id
LEFT JOIN account_delta_rewards AS adr ON adr.stake_address_id = awdp.stake_address_id
Expand Down Expand Up @@ -280,14 +287,14 @@ BEGIN
FROM grest.control_table
WHERE key = 'last_active_stake_validated_epoch'
) OR (
SELECT ((SELECT MAX(no) FROM epoch) - COALESCE((last_value::integer - 2)::integer, 0 )) > 3
SELECT ((SELECT MAX(no) FROM epoch) - COALESCE((last_value::integer - 2)::integer, 0 )) > 2
FROM grest.control_table
WHERE key = 'last_active_stake_validated_epoch'
) THEN
RAISE EXCEPTION 'Active Stake cache too far, skipping...';
ELSIF (
SELECT
((SELECT MAX(no) FROM epoch) - (SELECT MAX(epoch_no)::integer FROM grest.epoch_info_cache))::integer > 1
((SELECT MAX(no) FROM epoch) - (SELECT MAX(epoch_no)::integer FROM grest.epoch_info_cache))::integer > 0
) THEN
RAISE EXCEPTION 'Epoch Info cache wasnt run yet, skipping...';
END IF;
Expand Down
69 changes: 23 additions & 46 deletions files/grest/rpc/account/account_info.sql
Original file line number Diff line number Diff line change
Expand Up @@ -22,24 +22,7 @@ BEGIN
WHERE stake_address.view = ANY(_stake_addresses);

RETURN QUERY
WITH latest_withdrawal_txs AS (
SELECT DISTINCT ON (addr_id)
addr_id,
tx_id
FROM withdrawal
WHERE addr_id = ANY(sa_id_list)
ORDER BY addr_id, tx_id DESC
),

latest_withdrawal_epochs AS (
SELECT
lwt.addr_id,
b.epoch_no
FROM block b
INNER JOIN tx ON tx.block_id = b.id
INNER JOIN latest_withdrawal_txs AS lwt ON tx.id = lwt.tx_id
)


SELECT
status_t.view AS stake_address,
CASE WHEN status_t.registered = TRUE THEN
Expand All @@ -48,19 +31,11 @@ BEGIN
'not registered'
END AS status,
pool_t.delegated_pool,
CASE WHEN (COALESCE(rewards_t.rewards, 0) - COALESCE(withdrawals_t.withdrawals, 0)) < 0 THEN
(COALESCE(utxo_t.utxo, 0) + COALESCE(rewards_t.rewards, 0) - COALESCE(withdrawals_t.withdrawals, 0) + COALESCE(reserves_t.reserves, 0) + COALESCE(treasury_t.treasury, 0) - (COALESCE(rewards_t.rewards, 0) - COALESCE(withdrawals_t.withdrawals, 0)))::text
ELSE
(COALESCE(utxo_t.utxo, 0) + COALESCE(rewards_t.rewards, 0) - COALESCE(withdrawals_t.withdrawals, 0) + COALESCE(reserves_t.reserves, 0) + COALESCE(treasury_t.treasury, 0))::text
END AS total_balance,
(COALESCE(utxo_t.utxo, 0) + COALESCE(rewards_t.rewards, 0) + COALESCE(reserves_t.reserves, 0) + COALESCE(treasury_t.treasury, 0) - COALESCE(withdrawals_t.withdrawals, 0))::text AS total_balance,
COALESCE(utxo_t.utxo, 0)::text AS utxo,
COALESCE(rewards_t.rewards, 0)::text AS rewards,
COALESCE(withdrawals_t.withdrawals, 0)::text AS withdrawals,
CASE WHEN (COALESCE(rewards_t.rewards, 0) - COALESCE(withdrawals_t.withdrawals, 0)) <= 0 THEN
'0'
ELSE
(COALESCE(rewards_t.rewards, 0) - COALESCE(withdrawals_t.withdrawals, 0))::text
END AS rewards_available,
(COALESCE(rewards_t.rewards, 0) + COALESCE(reserves_t.reserves, 0) + COALESCE(treasury_t.treasury, 0) - COALESCE(withdrawals_t.withdrawals, 0))::text AS rewards_available,
COALESCE(reserves_t.reserves, 0)::text AS reserves,
COALESCE(treasury_t.treasury, 0)::text AS treasury
FROM
Expand Down Expand Up @@ -137,29 +112,31 @@ BEGIN
) AS withdrawals_t ON withdrawals_t.addr_id = status_t.id
LEFT JOIN (
SELECT
reserve.addr_id,
COALESCE(SUM(reserve.amount), 0) AS reserves
FROM reserve
INNER JOIN tx ON tx.id = reserve.tx_id
INNER JOIN block ON block.id = tx.block_id
INNER JOIN latest_withdrawal_epochs AS lwe ON lwe.addr_id = reserve.addr_id
WHERE reserve.addr_id = ANY(sa_id_list)
AND block.epoch_no >= lwe.epoch_no
r.addr_id,
COALESCE(SUM(r.amount), 0) AS reserves
FROM instant_reward AS r
WHERE r.addr_id = ANY(sa_id_list)
AND r.type = 'reserves'
AND r.spendable_epoch <= (
SELECT MAX(no)
FROM epoch
)
GROUP BY
reserve.addr_id
r.addr_id
) AS reserves_t ON reserves_t.addr_id = status_t.id
LEFT JOIN (
SELECT
treasury.addr_id,
COALESCE(SUM(treasury.amount), 0) AS treasury
FROM treasury
INNER JOIN tx ON tx.id = treasury.tx_id
INNER JOIN block ON block.id = tx.block_id
INNER JOIN latest_withdrawal_epochs AS lwe ON lwe.addr_id = treasury.addr_id
WHERE treasury.addr_id = ANY(sa_id_list)
AND block.epoch_no >= lwe.epoch_no
t.addr_id,
COALESCE(SUM(t.amount), 0) AS treasury
FROM instant_reward AS t
WHERE t.addr_id = ANY(sa_id_list)
AND t.type = 'treasury'
AND t.spendable_epoch <= (
SELECT MAX(no)
FROM epoch
)
GROUP BY
treasury.addr_id
t.addr_id
) AS treasury_t ON treasury_t.addr_id = status_t.id;
END;
$$;
Expand Down
86 changes: 24 additions & 62 deletions files/grest/rpc/account/account_info_cached.sql
Original file line number Diff line number Diff line change
Expand Up @@ -24,22 +24,6 @@ BEGIN
stake_address.view = ANY(_stake_addresses);

RETURN QUERY
WITH latest_withdrawal_txs AS (
SELECT DISTINCT ON (addr_id)
addr_id,
tx_id
FROM withdrawal
WHERE addr_id = ANY(sa_id_list)
ORDER BY addr_id, tx_id DESC
),
latest_withdrawal_epochs AS (
SELECT
lwt.addr_id,
b.epoch_no
FROM block AS b
INNER JOIN tx ON tx.block_id = b.id
INNER JOIN latest_withdrawal_txs AS lwt ON tx.id = lwt.tx_id
)

SELECT
sdc.stake_address,
Expand Down Expand Up @@ -77,28 +61,31 @@ BEGIN
) AS status_t ON sdc.stake_address = status_t.view
LEFT JOIN (
SELECT
reserve.addr_id,
COALESCE(SUM(reserve.amount), 0) AS reserves
FROM reserve
INNER JOIN tx ON tx.id = reserve.tx_id
INNER JOIN block ON block.id = tx.block_id
INNER JOIN latest_withdrawal_epochs AS lwe ON lwe.addr_id = reserve.addr_id
WHERE reserve.addr_id = ANY(sa_id_list)
AND block.epoch_no >= lwe.epoch_no
GROUP BY reserve.addr_id
) AS reserves_t ON reserves_t.addr_id = status_t.id
r.addr_id,
COALESCE(SUM(r.amount), 0) AS reserves
FROM instant_reward AS r
WHERE r.addr_id = ANY(sa_id_list)
AND r.type = 'reserves'
AND r.spendable_epoch <= (
SELECT MAX(no)
FROM epoch
)
GROUP BY
r.addr_id
) AS reserves_t ON reserves_t.addr_id = status_t.id
LEFT JOIN (
SELECT
treasury.addr_id,
COALESCE(SUM(treasury.amount), 0) AS treasury
FROM treasury
INNER JOIN tx ON tx.id = treasury.tx_id
INNER JOIN block ON block.id = tx.block_id
INNER JOIN latest_withdrawal_epochs AS lwe ON lwe.addr_id = treasury.addr_id
WHERE treasury.addr_id = ANY(sa_id_list)
AND block.epoch_no >= lwe.epoch_no
t.addr_id,
COALESCE(SUM(t.amount), 0) AS treasury
FROM instant_reward AS t
WHERE t.addr_id = ANY(sa_id_list)
AND t.type = 'treasury'
AND t.spendable_epoch <= (
SELECT MAX(no)
FROM epoch
)
GROUP BY
treasury.addr_id
t.addr_id
) AS treasury_t ON treasury_t.addr_id = status_t.id
WHERE sdc.stake_address = ANY(_stake_addresses)

Expand All @@ -113,8 +100,8 @@ BEGIN
ai.rewards::text,
ai.withdrawals::text,
ai.rewards_available::text,
COALESCE(reserves_t.reserves, 0)::text AS reserves,
COALESCE(treasury_t.treasury, 0)::text AS treasury
ai.reserves,
ai.treasury
FROM
(
SELECT
Expand All @@ -124,31 +111,6 @@ BEGIN
WHERE view = ANY(_stake_addresses)
AND NOT EXISTS (SELECT null FROM grest.stake_distribution_cache AS sdc WHERE sdc.stake_address = sa.view)
) AS z
LEFT JOIN (
SELECT
reserve.addr_id,
COALESCE(SUM(reserve.amount), 0) AS reserves
FROM reserve
INNER JOIN tx ON tx.id = reserve.tx_id
INNER JOIN block ON block.id = tx.block_id
INNER JOIN latest_withdrawal_epochs AS lwe ON lwe.addr_id = reserve.addr_id
WHERE reserve.addr_id = ANY(sa_id_list)
AND block.epoch_no >= lwe.epoch_no
GROUP BY reserve.addr_id
) AS reserves_t ON reserves_t.addr_id = z.addr_id
LEFT JOIN (
SELECT
treasury.addr_id,
COALESCE(SUM(treasury.amount), 0) AS treasury
FROM treasury
INNER JOIN tx ON tx.id = treasury.tx_id
INNER JOIN block ON block.id = tx.block_id
INNER JOIN latest_withdrawal_epochs AS lwe ON lwe.addr_id = treasury.addr_id
WHERE treasury.addr_id = ANY(sa_id_list)
AND block.epoch_no >= lwe.epoch_no
GROUP BY
treasury.addr_id
) AS treasury_t ON treasury_t.addr_id = z.addr_id
, LATERAL grest.account_info(array[z.stake_address]) AS ai
;

Expand Down
4 changes: 2 additions & 2 deletions files/grest/rpc/pool/pool_delegators.sql
Original file line number Diff line number Diff line change
Expand Up @@ -31,7 +31,7 @@ BEGIN

-- combine with registered delegations not in stake-dist-cache yet
SELECT
z.stake_address_id, z.stake_address, SUM(acc_info.value::numeric) AS total_balance
z.stake_address_id, z.stake_address, SUM(acc_info.value::numeric) AS total_balance
FROM
(
SELECT
Expand All @@ -42,7 +42,7 @@ BEGIN
INNER JOIN stake_address AS sa ON d.addr_id = sa.id
AND NOT EXISTS (SELECT null FROM delegation AS d2 WHERE d2.addr_id = d.addr_id AND d2.id > d.id)
AND NOT EXISTS (SELECT null FROM stake_deregistration AS sd WHERE sd.addr_id = d.addr_id AND sd.tx_id > d.tx_id)
AND NOT grest.is_dangling_delegation(d.id)
-- AND NOT grest.is_dangling_delegation(d.id)
AND NOT EXISTS (SELECT null FROM grest.stake_distribution_cache AS sdc WHERE sdc.stake_address = sa.view)
) z,
LATERAL grest.account_utxos(array[z.stake_address], false) AS acc_info
Expand Down

0 comments on commit d4dfb66

Please sign in to comment.