From bdba81553ed16346a00eb6a3de83c4f9141115d4 Mon Sep 17 00:00:00 2001 From: ze97286 Date: Fri, 3 May 2024 12:41:00 +0100 Subject: [PATCH] fix: Ensure we dedup the game IDs --- CHANGELOG.md | 2 + datanode/networkhistory/service_test.go | 12 +- .../0107_ensure_distinct_game_id.sql | 154 ++++++++++++++++++ 3 files changed, 162 insertions(+), 6 deletions(-) create mode 100644 datanode/sqlstore/migrations/0107_ensure_distinct_game_id.sql diff --git a/CHANGELOG.md b/CHANGELOG.md index bd5209c44c..0e22eb390f 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -83,6 +83,8 @@ - [11200](https://github.com/vegaprotocol/vega/issues/11200) - Make sure a party can afford the trades before they are submitted to the book. - [11205](https://github.com/vegaprotocol/vega/issues/11205) - Evaluate transfer interval correctly. - [10374](https://github.com/vegaprotocol/vega/issues/10374) - Add transfer ID to recurring governance transfer ledger entries. +- [11221](https://github.com/vegaprotocol/vega/issues/11221) - Fix for `totalRewardsEarned` being twice the `rewardEarned`. + ## 0.75.0 diff --git a/datanode/networkhistory/service_test.go b/datanode/networkhistory/service_test.go index 8119a94649..66ce17cad3 100644 --- a/datanode/networkhistory/service_test.go +++ b/datanode/networkhistory/service_test.go @@ -379,12 +379,12 @@ func TestMain(t *testing.M) { log.Infof("%s", goldenSourceHistorySegment[4000].HistorySegmentID) log.Infof("%s", goldenSourceHistorySegment[5000].HistorySegmentID) - panicIfHistorySegmentIdsNotEqual(goldenSourceHistorySegment[1000].HistorySegmentID, "QmTnNnYP9fCqRNUdG2ojpQJBvZ4omL8LjSPYrQ7DpbE2VH", snapshots) - panicIfHistorySegmentIdsNotEqual(goldenSourceHistorySegment[2000].HistorySegmentID, "QmTv5VEoNpAyERWxASX836YPXzND7es8Rc7fzuBK38BNDi", snapshots) - panicIfHistorySegmentIdsNotEqual(goldenSourceHistorySegment[2500].HistorySegmentID, "QmWzE8bEsUwabtcAd6WohLy58widR3xqaNacZDCpbt9TWt", snapshots) - panicIfHistorySegmentIdsNotEqual(goldenSourceHistorySegment[3000].HistorySegmentID, "QmUPm6cQRNJ2B5GxRXauiAoSYWH2QZbezicVxPLGErSwy5", snapshots) - panicIfHistorySegmentIdsNotEqual(goldenSourceHistorySegment[4000].HistorySegmentID, "QmR7vN8AuQT5BPiCKjLp8JfhFQZXLG7udtdMJgcnDTUcQa", snapshots) - panicIfHistorySegmentIdsNotEqual(goldenSourceHistorySegment[5000].HistorySegmentID, "QmPJRAxy5gs3vqC6J91xx3MAo5KGHCJGbw62zqViQrHmTF", snapshots) + panicIfHistorySegmentIdsNotEqual(goldenSourceHistorySegment[1000].HistorySegmentID, "QmQqE56RWuyHEWm1rqcFNcEvCWiBpgMsSs1CAwABGfkSSh", snapshots) + panicIfHistorySegmentIdsNotEqual(goldenSourceHistorySegment[2000].HistorySegmentID, "QmNn42pXmiaxpDgLAAr2H1WTdz9YWYfyWgDBWajPb6m6Qd", snapshots) + panicIfHistorySegmentIdsNotEqual(goldenSourceHistorySegment[2500].HistorySegmentID, "QmcwwiZP3stVahfyLU4f6NjL3Spyn67JXV4RsPt2ieWL5i", snapshots) + panicIfHistorySegmentIdsNotEqual(goldenSourceHistorySegment[3000].HistorySegmentID, "QmP8LoArcevGNGoyMnfcLS82gErPfHHAukYJyax3hfvFd9", snapshots) + panicIfHistorySegmentIdsNotEqual(goldenSourceHistorySegment[4000].HistorySegmentID, "QmRJbm1dMajfEEMAzumsybuZ7hq6QcZJddT5QcNmGsFZir", snapshots) + panicIfHistorySegmentIdsNotEqual(goldenSourceHistorySegment[5000].HistorySegmentID, "QmQusPSJ5wq5gLjjCutX3hzUZ4yyY4uysyvqtq4K5disQE", snapshots) }, postgresRuntimePath, sqlFs) if exitCode != 0 { diff --git a/datanode/sqlstore/migrations/0107_ensure_distinct_game_id.sql b/datanode/sqlstore/migrations/0107_ensure_distinct_game_id.sql new file mode 100644 index 0000000000..a722bca448 --- /dev/null +++ b/datanode/sqlstore/migrations/0107_ensure_distinct_game_id.sql @@ -0,0 +1,154 @@ +-- +goose Up + +drop materialized view if exists game_stats; +drop materialized view if exists game_stats_current; +drop view if exists game_individual_rankings; + +create view game_individual_rankings as +with individual_games as ( + -- get the games where the entity scope is individuals + select distinct game_id + from transfers + where dispatch_strategy ->> 'entity_scope' = '1' + and game_id is not null), + individual_totals as ( + -- calculate the total rewards for each individual in each individual entity scoped game + select t.game_id, + t.epoch_id, + t.asset_id, + t.party_id, + sum(t.total_rewards) as total_rewards, + sum(total_rewards_quantum) as total_rewards_quantum + from game_reward_totals t + join individual_games i on t.game_id = i.game_id + group by t.game_id, t.epoch_id, t.asset_id, t.party_id), + individual_rankings as ( +-- rank the individuals for each game at each epoch + select game_id, + epoch_id, + party_id, + total_rewards_quantum, + rank() over ( + partition by game_id, epoch_id order by total_rewards_quantum desc + ) as rank + from individual_totals) +select it.game_id, + it.epoch_id, + it.party_id, + it.total_rewards, + ir.total_rewards_quantum, + ir.rank +from individual_totals it + join individual_rankings ir + on it.game_id = ir.game_id and it.epoch_id = ir.epoch_id and it.party_id = ir.party_id; + +create materialized view game_stats as +with + game_epochs as ( + select distinct + game_id, epoch_id + from rewards + where + game_id is not null + ), + dispatch_strategies AS ( + SELECT DISTINCT + ON (game_id) game_id, dispatch_strategy + FROM transfers + WHERE + transfer_type = 'Recurring' + ORDER BY game_id, vega_time DESC + ), + game_rewards as ( + select + r.*, t.dispatch_strategy, tm.team_id, tmr.rank as member_rank, tr.rank as team_rank, tmr.total_rewards, tmr.total_rewards_quantum, + tr.total_rewards as team_total_rewards, tr.total_rewards_quantum as team_total_rewards_quantum, 'ENTITY_SCOPE_TEAMS' as entity_scope + from + rewards r + join game_epochs ge on r.game_id = ge.game_id + and r.epoch_id = ge.epoch_id + JOIN dispatch_strategies t ON r.game_id = t.game_id + AND t.dispatch_strategy ->> 'entity_scope' = '2' + join team_members tm on r.party_id = tm.party_id + left join game_team_rankings tr on r.game_id = tr.game_id + and r.epoch_id = tr.epoch_id + and tm.team_id = tr.team_id + left join game_team_member_rankings tmr on r.game_id = tmr.game_id + and r.epoch_id = tmr.epoch_id + and tm.team_id = tmr.team_id + and r.party_id = tmr.party_id + union all + select + r.*, t.dispatch_strategy, null as team_id, tmr.rank as member_rank, null as team_rank, tmr.total_rewards, tmr.total_rewards_quantum, + null as team_total_rewards, null as team_total_rewards_quantum, 'ENTITY_SCOPE_INDIVIDUALS' as entity_scope + from + rewards r + join game_epochs ge on r.game_id = ge.game_id + and r.epoch_id = ge.epoch_id + JOIN dispatch_strategies t ON r.game_id = t.game_id + AND t.dispatch_strategy ->> 'entity_scope' = '1' + left join game_individual_rankings tmr on r.game_id = tmr.game_id + and r.epoch_id = tmr.epoch_id + and r.party_id = tmr.party_id + ) +select * +from game_rewards +with data; + +create materialized view game_stats_current as +with + game_epochs as ( + select game_id, max(epoch_id) as epoch_id + from rewards + where + game_id is not null + group by + game_id + ), + dispatch_strategies AS ( + SELECT DISTINCT + ON (game_id) game_id, dispatch_strategy + FROM transfers + WHERE + transfer_type = 'Recurring' + ORDER BY game_id, vega_time DESC + ), + game_rewards as ( + select + r.*, t.dispatch_strategy, tm.team_id, tmr.rank as member_rank, tr.rank as team_rank, tmr.total_rewards, tmr.total_rewards_quantum, + tr.total_rewards as team_total_rewards, tr.total_rewards_quantum as team_total_rewards_quantum, 'ENTITY_SCOPE_TEAMS' as entity_scope + from + rewards r + join game_epochs ge on r.game_id = ge.game_id + and r.epoch_id = ge.epoch_id + JOIN dispatch_strategies t ON r.game_id = t.game_id + AND t.dispatch_strategy ->> 'entity_scope' = '2' + join team_members tm on r.party_id = tm.party_id + left join game_team_rankings tr on r.game_id = tr.game_id + and r.epoch_id = tr.epoch_id + and tm.team_id = tr.team_id + left join game_team_member_rankings tmr on r.game_id = tmr.game_id + and r.epoch_id = tmr.epoch_id + and tm.team_id = tmr.team_id + and r.party_id = tmr.party_id + union all + select + r.*, t.dispatch_strategy, null as team_id, tmr.rank as member_rank, null as team_rank, tmr.total_rewards, tmr.total_rewards_quantum, + null as team_total_rewards, null as team_total_rewards_quantum, 'ENTITY_SCOPE_INDIVIDUALS' as entity_scope + from + rewards r + join game_epochs ge on r.game_id = ge.game_id + and r.epoch_id = ge.epoch_id + JOIN dispatch_strategies t ON r.game_id = t.game_id + AND t.dispatch_strategy ->> 'entity_scope' = '1' + left join game_individual_rankings tmr on r.game_id = tmr.game_id + and r.epoch_id = tmr.epoch_id + and r.party_id = tmr.party_id + ) +select * +from game_rewards +with data; + +-- +goose Down + +-- We are fixing a bug, and there is no point of reinstating a bug, we do nothing.