Skip to content

Commit

Permalink
fix: Ensure we dedup the game IDs for game_individual_rankings view…
Browse files Browse the repository at this point in the history
… before sum
  • Loading branch information
ValentinTrinque committed May 3, 2024
1 parent 346e527 commit 348e7b6
Showing 1 changed file with 84 additions and 0 deletions.
84 changes: 84 additions & 0 deletions datanode/sqlstore/migrations/0107_ensure_distinct_game_id.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,84 @@
-- +goose Up

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;


-- +goose Down

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 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;

0 comments on commit 348e7b6

Please sign in to comment.