From 9aa870f4f4e1e8b9407be728e11af42b7e0f634e Mon Sep 17 00:00:00 2001
From: Martin Mares <mj@ucw.cz>
Date: Fri, 24 Sep 2021 17:52:00 +0200
Subject: [PATCH] tmp

---
 db/db.ddl               | 20 ++++++++++++++++++++
 db/upgrade-20210924.sql | 16 ++++++++++++++++
 2 files changed, 36 insertions(+)
 create mode 100644 db/upgrade-20210924.sql

diff --git a/db/db.ddl b/db/db.ddl
index b20d8652..8bb7cdd5 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 00000000..3aaf579d
--- /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;
-- 
GitLab