Skip to content

Commit

Permalink
Introduce second layer of best-only aggregation via ROW_NUMBER
Browse files Browse the repository at this point in the history
  • Loading branch information
gregorbg committed Dec 31, 2024
1 parent c3431aa commit 78e9f54
Showing 1 changed file with 6 additions and 2 deletions.
8 changes: 6 additions & 2 deletions lib/auxiliary_data_computation.rb
Original file line number Diff line number Diff line change
Expand Up @@ -52,17 +52,21 @@ def self.compute_rank_tables
DbHelper.with_temp_table(table_name) do |temp_table_name|
ActiveRecord::Base.connection.execute <<-SQL
INSERT INTO #{temp_table_name} (personId, eventId, best, worldRank, continentRank, countryRank)
WITH personal_best AS (
WITH best_per_region AS (
SELECT eventId, personId, countryId, continentId, min(#{field}) `value`
FROM #{concise_table_name}
GROUP BY personId, countryId, continentId, eventId
), personal_bests AS (
SELECT *, ROW_NUMBER() OVER (PARTITION BY eventId, personId ORDER BY value) AS really_best
FROM best_per_region
)
SELECT
personId, eventId, `value`,
RANK() OVER(PARTITION BY eventId ORDER BY `value`) AS worldRank,
RANK() OVER(PARTITION BY eventId, continentId ORDER BY `value`) AS continentRank,
RANK() OVER(PARTITION BY eventId, countryId ORDER BY `value`) AS countryRank
FROM personal_best
FROM personal_bests
WHERE really_best = 1
ORDER BY eventId, `value`
SQL
end
Expand Down

0 comments on commit 78e9f54

Please sign in to comment.