Skip to content
Snippets Groups Projects
Commit 74b95e60 authored by Martin Mareš's avatar Martin Mareš
Browse files

DB: Statistiky

parent cf9dbac3
No related branches found
No related tags found
No related merge requests found
......@@ -355,3 +355,42 @@ 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 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
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 dvojici (kolo, region) spočítáme soutěže.
CREATE VIEW region_contest_stats AS
SELECT c.round_id, rd.region, count(*) AS count
FROM contests c
JOIN region_descendants rd ON rd.descendant = c.place_id
WHERE rd.region <> c.place_id
GROUP BY c.round_id, rd.region;
-- 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_participant_stats AS
SELECT c.round_id, rd.region, p.state, count(*) AS 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;
-- Pro každou trojici (kolo, region, úloha) spočítáme řešení.
CREATE VIEW region_task_stats AS
SELECT r.round_id, rd.region, t.task_id, count(*) AS count
FROM rounds r
JOIN contests c USING(round_id)
JOIN participations p USING(contest_id)
JOIN tasks t USING(round_id)
JOIN solutions s USING(user_id, task_id)
JOIN region_descendants rd ON rd.descendant = c.place_id
GROUP BY r.round_id, rd.region, t.task_id;
SET ROLE 'mo_osmo';
-- Pro každý region 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
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 dvojici (kolo, region) spočítáme soutěže.
CREATE VIEW region_contest_stats AS
SELECT c.round_id, rd.region, count(*) AS count
FROM contests c
JOIN region_descendants rd ON rd.descendant = c.place_id
WHERE rd.region <> c.place_id
GROUP BY c.round_id, rd.region;
-- 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_participant_stats AS
SELECT c.round_id, rd.region, p.state, count(*) AS 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;
-- Pro každou trojici (kolo, region, úloha) spočítáme řešení.
CREATE VIEW region_task_stats AS
SELECT r.round_id, rd.region, t.task_id, count(*) AS count
FROM rounds r
JOIN contests c USING(round_id)
JOIN participations p USING(contest_id)
JOIN tasks t USING(round_id)
JOIN solutions s USING(user_id, task_id)
JOIN region_descendants rd ON rd.descendant = c.place_id
GROUP BY r.round_id, rd.region, t.task_id;
......@@ -705,6 +705,49 @@ class RegRequest(Base):
user = relationship('User')
class RegionDescendant(Base):
__tablename__ = 'region_descendants'
region = Column(Integer, ForeignKey('places.place_id'), primary_key=True)
descendant = Column(Integer, ForeignKey('places.place_id'), primary_key=True)
class RegionContestStat(Base):
__tablename__ = 'region_contest_stats'
round_id = Column(Integer, ForeignKey('rounds.round_id'), primary_key=True)
region = Column(Integer, ForeignKey('places.place_id'), primary_key=True)
count = Column(Integer, nullable=False)
round = relationship('Round')
region_place = relationship('Place', primaryjoin='RegionContestStat.region == Place.place_id', remote_side='Place.place_id')
class RegionParticipantStat(Base):
__tablename__ = 'region_participant_stats'
round_id = Column(Integer, ForeignKey('rounds.round_id'), primary_key=True)
region = Column(Integer, ForeignKey('places.place_id'), primary_key=True)
state = Column(Enum(PartState, name='part_state'), primary_key=True)
count = Column(Integer, nullable=False)
round = relationship('Round')
region_place = relationship('Place', primaryjoin='RegionParticipantStat.region == Place.place_id', remote_side='Place.place_id')
class RegionTaskStat(Base):
__tablename__ = 'region_task_stats'
round_id = Column(Integer, ForeignKey('rounds.round_id'), primary_key=True)
region = Column(Integer, ForeignKey('places.place_id'), primary_key=True)
task_id = Column(Integer, ForeignKey('tasks.task_id'), primary_key=True)
count = Column(Integer, nullable=False)
round = relationship('Round')
region_place = relationship('Place', primaryjoin='RegionTaskStat.region == Place.place_id', remote_side='Place.place_id')
task = relationship('Task')
_engine: Optional[Engine] = None
_session: Optional[Session] = None
flask_db: Any = None
......
0% Loading or .
You are about to add 0 people to the discussion. Proceed with caution.
Please register or to comment