diff --git a/db/db.ddl b/db/db.ddl index b20d86522fb9feecd227c592cc519bcf22335de7..8bb7cdd51ac5176e2c9dfb14d4c0825bfdb8cbfb 100644 --- a/db/db.ddl +++ b/db/db.ddl @@ -355,3 +355,23 @@ CREATE TABLE reg_requests ( user_id int DEFAULT NULL REFERENCES users(user_id) ON DELETE CASCADE, client varchar(255) NOT NULL -- kdo si registraci vyžádal ); + +-- Statistiky + +-- Pro každý region úrovně <= 2 spočítáme všechna podřízená místa +CREATE VIEW region_descendants AS + WITH RECURSIVE descendant_regions(place_id, descendant) AS ( + SELECT place_id, place_id FROM places WHERE level BETWEEN 1 AND 2 + UNION SELECT r.place_id, p.place_id + FROM descendant_regions r, places p + WHERE p.parent = r.descendant + ) SELECT place_id AS region, descendant FROM descendant_regions; + +-- Pro každou trojici (kolo, region, stav účasti) spočítáme účastníky. +-- Pokud se to ukáže být příliš pomalé, přejdeme na materializovaná views. +CREATE VIEW region_stats AS + SELECT c.round_id, rd.region, p.state, count(*) + FROM participations p + JOIN contests c USING(contest_id) + JOIN region_descendants rd ON rd.descendant = c.place_id + GROUP BY c.round_id, rd.region, p.state; diff --git a/db/upgrade-20210924.sql b/db/upgrade-20210924.sql new file mode 100644 index 0000000000000000000000000000000000000000..3aaf579de1ee506fd4eb3a8bee44a97b6382dc82 --- /dev/null +++ b/db/upgrade-20210924.sql @@ -0,0 +1,16 @@ +SET ROLE 'mo_osmo'; + +CREATE VIEW region_descendants AS + WITH RECURSIVE descendant_regions(place_id, descendant) AS ( + SELECT place_id, place_id FROM places WHERE level BETWEEN 1 AND 2 + UNION SELECT r.place_id, p.place_id + FROM descendant_regions r, places p + WHERE p.parent = r.descendant + ) SELECT place_id AS region, descendant FROM descendant_regions; + +CREATE VIEW region_stats AS + SELECT c.round_id, rd.region, p.state, count(*) + FROM participations p + JOIN contests c USING(contest_id) + JOIN region_descendants rd ON rd.descendant = c.place_id + GROUP BY c.round_id, rd.region, p.state;