From 03ab43f5451b1b6852d67b236b8a3761e4b207fa Mon Sep 17 00:00:00 2001 From: Ciabas Date: Thu, 10 Jul 2025 12:49:24 +0200 Subject: [PATCH] (fix): duplications in pool_stat table in db-sync --- govtool/backend/sql/get-network-total-stake.sql | 10 +++++++++- govtool/backend/sql/list-proposals.sql | 14 +++++++++++--- 2 files changed, 20 insertions(+), 4 deletions(-) diff --git a/govtool/backend/sql/get-network-total-stake.sql b/govtool/backend/sql/get-network-total-stake.sql index 9399df5c3..afe1c0d6d 100644 --- a/govtool/backend/sql/get-network-total-stake.sql +++ b/govtool/backend/sql/get-network-total-stake.sql @@ -67,8 +67,16 @@ TotalStakeControlledByActiveDReps AS ( AND COALESCE(rd.deposit, 0) >= 0 AND ((DRepActivity.epoch_no - GREATEST(COALESCE(lve.epoch_no, 0), COALESCE(rd.epoch_no, 0))) <= DRepActivity.drep_activity) ), +-- it's a fix for duplication issue https://github.com/IntersectMBO/cardano-db-sync/issues/1986 +LatestPoolStat AS ( + SELECT DISTINCT ON (pool_hash_id) * + FROM + pool_stat + WHERE + epoch_no = (SELECT MAX(no) FROM epoch) +), TotalStakeControlledBySPOs AS ( - SELECT SUM(ps.stake)::bigint AS total FROM pool_stat ps WHERE ps.epoch_no = (SELECT no FROM CurrentEpoch) + SELECT SUM(ps.stake)::bigint AS total FROM LatestPoolStat ps WHERE ps.epoch_no = (SELECT no FROM CurrentEpoch) ), AlwaysAbstainVotingPower AS ( SELECT COALESCE((SELECT amount FROM drep_hash diff --git a/govtool/backend/sql/list-proposals.sql b/govtool/backend/sql/list-proposals.sql index dfb54e12d..0b5e47bf3 100644 --- a/govtool/backend/sql/list-proposals.sql +++ b/govtool/backend/sql/list-proposals.sql @@ -122,6 +122,14 @@ RankedPoolVotes AS ( vp.tx_id DESC, vp.id DESC ), +-- it's a fix for duplication issue https://github.com/IntersectMBO/cardano-db-sync/issues/1986 +LatestPoolStat AS ( + SELECT DISTINCT ON (pool_hash_id) * + FROM + pool_stat + WHERE + epoch_no = (SELECT MAX(no) FROM epoch) +), PoolVotes AS ( SELECT rpv.gov_action_proposal_id, @@ -132,10 +140,10 @@ PoolVotes AS ( SUM(CASE WHEN rpv.vote = 'Yes' THEN ps.voting_power ELSE 0 END) AS poolYesVotes, SUM(CASE WHEN rpv.vote = 'No' THEN ps.voting_power ELSE 0 END) AS poolNoVotes, SUM(CASE WHEN rpv.vote = 'Abstain' THEN ps.voting_power ELSE 0 END) AS poolAbstainVotes - FROM + FROM RankedPoolVotes rpv - JOIN - pool_stat ps + JOIN + LatestPoolStat ps ON rpv.pool_voter = ps.pool_hash_id WHERE ps.epoch_no = (SELECT MAX(no) FROM epoch)