Skip to content

Conversation

@gregorbg
Copy link
Member

This is a precursor to / offspring of #13266. With the proper indices, it runs in ~20 seconds on my local machine. Probably the biggest advantage in terms of runtime is that we don't need to manually "batch-insert" stuff anymore...

Need approval from WRT that the query is indeed correct. It is comforting that the CI tests are passing with this on my local machine.

Comment on lines +55 to +131
WITH current_person_regions AS (
SELECT
p.wca_id AS person_id,
p.country_id AS current_country_id,
c.continent_id AS current_continent_id
FROM persons p
JOIN countries c ON p.country_id = c.id
WHERE p.sub_id = 1
),
world_stats AS (
SELECT
person_id,
event_id,
MIN(#{field}) AS world_best
FROM #{concise_table_name}
GROUP BY person_id, event_id
),
world_ranks AS (
SELECT
person_id,
event_id,
world_best,
RANK() OVER (PARTITION BY event_id ORDER BY world_best) as world_rank
FROM world_stats
),
continent_stats AS (
SELECT
person_id,
event_id,
continent_id,
MIN(#{field}) AS continent_best
FROM #{concise_table_name}
GROUP BY person_id, event_id, continent_id
),
continent_ranks AS (
SELECT
person_id,
event_id,
continent_id,
RANK() OVER (PARTITION BY continent_id, event_id ORDER BY continent_best) as continent_rank
FROM continent_stats
),
country_stats AS (
SELECT
person_id,
event_id,
country_id,
MIN(#{field}) AS country_best
FROM #{concise_table_name}
GROUP BY person_id, event_id, country_id
),
country_ranks AS (
SELECT
person_id,
event_id,
country_id,
RANK() OVER (PARTITION BY country_id, event_id ORDER BY country_best) as country_rank
FROM country_stats
)
SELECT
wr.person_id,
wr.event_id,
wr.world_best AS best,
wr.world_rank,
COALESCE(cr.continent_rank, 0) AS continent_rank,
COALESCE(cnr.country_rank, 0) AS country_rank
FROM world_ranks wr
INNER JOIN current_person_regions cps
ON wr.person_id = cps.person_id
LEFT JOIN continent_ranks cr
ON wr.person_id = cr.person_id
AND wr.event_id = cr.event_id
AND cps.current_continent_id = cr.continent_id
LEFT JOIN country_ranks cnr
ON wr.person_id = cnr.person_id
AND wr.event_id = cnr.event_id
AND cps.current_country_id = cnr.country_id
Copy link
Member

@SAuroux SAuroux Jan 30, 2026

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

@gregorbg I took a look now and...well, it works, I guess. 🙂

What deeply annoys me is that the following would just work, if people did not change regions:

Suggested change
WITH current_person_regions AS (
SELECT
p.wca_id AS person_id,
p.country_id AS current_country_id,
c.continent_id AS current_continent_id
FROM persons p
JOIN countries c ON p.country_id = c.id
WHERE p.sub_id = 1
),
world_stats AS (
SELECT
person_id,
event_id,
MIN(#{field}) AS world_best
FROM #{concise_table_name}
GROUP BY person_id, event_id
),
world_ranks AS (
SELECT
person_id,
event_id,
world_best,
RANK() OVER (PARTITION BY event_id ORDER BY world_best) as world_rank
FROM world_stats
),
continent_stats AS (
SELECT
person_id,
event_id,
continent_id,
MIN(#{field}) AS continent_best
FROM #{concise_table_name}
GROUP BY person_id, event_id, continent_id
),
continent_ranks AS (
SELECT
person_id,
event_id,
continent_id,
RANK() OVER (PARTITION BY continent_id, event_id ORDER BY continent_best) as continent_rank
FROM continent_stats
),
country_stats AS (
SELECT
person_id,
event_id,
country_id,
MIN(#{field}) AS country_best
FROM #{concise_table_name}
GROUP BY person_id, event_id, country_id
),
country_ranks AS (
SELECT
person_id,
event_id,
country_id,
RANK() OVER (PARTITION BY country_id, event_id ORDER BY country_best) as country_rank
FROM country_stats
)
SELECT
wr.person_id,
wr.event_id,
wr.world_best AS best,
wr.world_rank,
COALESCE(cr.continent_rank, 0) AS continent_rank,
COALESCE(cnr.country_rank, 0) AS country_rank
FROM world_ranks wr
INNER JOIN current_person_regions cps
ON wr.person_id = cps.person_id
LEFT JOIN continent_ranks cr
ON wr.person_id = cr.person_id
AND wr.event_id = cr.event_id
AND cps.current_continent_id = cr.continent_id
LEFT JOIN country_ranks cnr
ON wr.person_id = cnr.person_id
AND wr.event_id = cnr.event_id
AND cps.current_country_id = cnr.country_id
WITH current_person_regions AS (
SELECT
p.wca_id AS person_id,
p.country_id AS current_country_id,
c.continent_id AS current_continent_id
FROM persons p
JOIN countries c ON p.country_id = c.id
WHERE p.sub_id = 1
),
world_stats AS (
SELECT
person_id,
event_id,
MIN(#{field}) AS world_best
FROM #{concise_table_name}
GROUP BY person_id, event_id
)
SELECT
ws.person_id,
ws.event_id,
ws.world_best AS best,
RANK() OVER (PARTITION BY ws.event_id ORDER BY ws.world_best) as world_rank,
RANK() OVER (PARTITION BY ws.event_id, cps.current_continent_id ORDER BY ws.world_best) AS continent_rank,
RANK() OVER (PARTITION BY ws.event_id, cps.current_country_id ORDER BY ws.world_best) AS country_rank
FROM world_stats ws
INNER JOIN current_person_regions cps
ON ws.person_id = cps.person_id

Considering the rest are really rare edge cases, I really wonder if it should not be possible to achieve the correct outcome in a computationally much more efficient way.

Copy link
Member Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Yeah, the nationality changes are exactly what almost drove me insane. In my opinion, the logic that "results which were achieved before the nationality change still count towards the old nationality's rankings" makes it pretty much impossible to use the "triple rank" approach which you have outlined.

But I will happily be proven wrong! 😄

Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment

Labels

None yet

Projects

None yet

Development

Successfully merging this pull request may close these issues.

2 participants