X-Git-Url: https://git.sesse.net/?a=blobdiff_plain;f=sql%2Fccbs.sql;h=d48fbeb04c33385c27929a10defee15003bd842d;hb=23a9b9ce42cd6a8c5752b217bccb581425267fdb;hp=c13c666774d872d199351fe59b01ba43fa468f3d;hpb=c73f95e10416d77bea35c2e409f3d6cd4b81143a;p=ccbs diff --git a/sql/ccbs.sql b/sql/ccbs.sql index c13c666..d48fbeb 100644 --- a/sql/ccbs.sql +++ b/sql/ccbs.sql @@ -10,8 +10,19 @@ CREATE TABLE machines ( CREATE TABLE countries ( country SERIAL PRIMARY KEY, countryname VARCHAR NOT NULL, + countrycode CHAR(3) NOT NULL, -- IOC country code - UNIQUE ( countryname ) + UNIQUE ( countryname ), + UNIQUE ( countrycode ) +); + +CREATE TABLE clubs ( + club SERIAL PRIMARY KEY, + clubname VARCHAR NOT NULL, + clubcode CHAR(3) NOT NULL, + + UNIQUE ( clubname ), + UNIQUE ( clubcode ) ); CREATE TABLE songs ( @@ -24,7 +35,20 @@ CREATE TABLE songs ( UNIQUE ( title ) ); --- CREATE TABLE machinesongs etc. +CREATE TABLE songshorttitles ( + song INTEGER NOT NULL REFERENCES songs, + shorttitle VARCHAR NOT NULL, + + PRIMARY KEY ( song, shorttitle ), + UNIQUE ( shorttitle ) +); + +CREATE TABLE machinesongs ( + song INTEGER NOT NULL REFERENCES songs, + machine INTEGER NOT NULL REFERENCES machines, + + PRIMARY KEY ( song, machine ) +); CREATE TABLE scoringsystems ( scoringsystem SERIAL PRIMARY KEY, @@ -34,17 +58,23 @@ CREATE TABLE scoringsystems ( ); CREATE TABLE songratings ( - song INTEGER NOT NULL REFERENCES songs, -- strictly song+machine + song INTEGER NOT NULL REFERENCES songs, + machine INTEGER NOT NULL REFERENCES machines, playmode VARCHAR NOT NULL CHECK (playmode IN ('single','double')), difficulty VARCHAR NOT NULL CHECK (difficulty IN ('beginner','standard','difficult','expert','challenge')), feetrating INTEGER NOT NULL CHECK (feetrating >= 0 AND feetrating <= 10), - PRIMARY KEY (song, playmode, difficulty) + PRIMARY KEY (song, machine, playmode, difficulty) ); +CREATE INDEX songratings_feetrating ON songratings ( feetrating ); + +CREATE VIEW max_single_feetrating AS SELECT machine,song,MAX(feetrating) AS feetrating FROM songratings WHERE playmode='single' GROUP BY machine,song; CREATE TABLE players ( player SERIAL PRIMARY KEY, nick VARCHAR NOT NULL, + country INTEGER NOT NULL REFERENCES countries, + club INTEGER REFERENCES clubs, UNIQUE ( nick ) ); @@ -83,8 +113,7 @@ CREATE TABLE tournamentrankings ( player INTEGER NOT NULL REFERENCES players, points INTEGER, - UNIQUE (tournament, player), - PRIMARY KEY (tournament, ranking) + PRIMARY KEY (tournament, player) ); CREATE TABLE rounds ( @@ -136,16 +165,94 @@ CREATE TABLE scores ( player INTEGER NOT NULL REFERENCES players, songnumber INTEGER NOT NULL, - song INTEGER NOT NULL REFERENCES songs, + song INTEGER REFERENCES songs, playmode VARCHAR CHECK (playmode IS NULL OR playmode IN ('single','double')), difficulty VARCHAR CHECK (difficulty IS NULL OR difficulty IN ('beginner','standard','difficult','expert','challenge')), - chosen BOOLEAN NOT NULL, - score INTEGER NOT NULL CHECK (score >= 0 AND score <= 10000), + chosen BOOLEAN, + score INTEGER CHECK (score IS NULL OR (score >= 0 AND score <= 10000)), - FOREIGN KEY (song) REFERENCES songs (song), - FOREIGN KEY (song, playmode, difficulty) REFERENCES songratings (song, playmode, difficulty), + -- FOREIGN KEY (song, playmode, difficulty) REFERENCES songratings (song, playmode, difficulty), FOREIGN KEY (tournament, round, parallel, player) REFERENCES roundparticipation (tournament, round, parallel, player), - UNIQUE (tournament, round, parallel, player, songnumber), - PRIMARY KEY (tournament, round, parallel, player, song) + PRIMARY KEY (tournament, round, parallel, player, songnumber) ); + +CREATE TABLE randomsongsused ( + song INTEGER NOT NULL PRIMARY KEY REFERENCES songs +); + +CREATE SCHEMA bigscreen; + +CREATE TABLE bigscreen.active_tournament ( + tournament INTEGER NOT NULL PRIMARY KEY REFERENCES tournaments +); +CREATE TABLE bigscreen.active_groups ( + tournament INTEGER NOT NULL REFERENCES bigscreen.active_tournament, + round INTEGER NOT NULL, + parallel INTEGER NOT NULL, + num_machines INTEGER NOT NULL, + players_per_machine INTEGER NOT NULL CHECK ( players_per_machine IN (1, 2) ), + last_updated TIMESTAMP NOT NULL, + + PRIMARY KEY ( tournament, round, parallel ), + FOREIGN KEY ( tournament, round, parallel ) REFERENCES groups +); +CREATE TABLE bigscreen.active_screens ( + id VARCHAR NOT NULL PRIMARY KEY +); + +-- get_max_score_for_songs(tournament, playmode) +CREATE TYPE max_score AS ( + song INTEGER, + max_score INTEGER +); + +CREATE FUNCTION get_max_score_for_songs(integer, varchar) RETURNS SETOF max_score + AS $$ + SELECT + song, + MAX(feetrating)*1000 AS max_score + FROM songratings + WHERE + machine=( + SELECT machine FROM tournaments WHERE tournament=$1 + ) + AND playmode=$2 + GROUP BY song + ; +$$ + LANGUAGE SQL + STABLE + RETURNS NULL ON NULL INPUT; + +-- get_max_score_for_players(tournament, round, playmode) +CREATE FUNCTION get_max_score_for_players(integer, integer, varchar) RETURNS SETOF max_score + AS $$ + SELECT player, + ( + SELECT feetrating + FROM songratings + WHERE machine=( -- only find songs on the machine we use + SELECT machine FROM tournaments WHERE tournament=$1 + ) + AND song NOT IN ( -- not a song that has been in elimination or seeding + SELECT song FROM scores + WHERE tournament=$1 + AND song IS NOT NULL + AND parallel=0 + AND chosen='f' + ) + AND (player,song) NOT IN ( -- not a song the player has chosen before, or is a random song in this round + SELECT player,song FROM scores + WHERE tournament=$1 + AND song IS NOT NULL + AND ( chosen='t' OR round=$2 ) + ) + AND playmode=$3 + ORDER BY feetrating DESC LIMIT 1 + ) * 1000 AS max_score FROM tournamentparticipation; +$$ + LANGUAGE SQL + STABLE + RETURNS NULL ON NULL INPUT; +