-- vim:set tw=0: CREATE TABLE machines ( machine SERIAL PRIMARY KEY, machinename VARCHAR NOT NULL, UNIQUE ( machinename ) ); CREATE TABLE countries ( country SERIAL PRIMARY KEY, countryname VARCHAR NOT NULL, countrycode CHAR(3) NOT NULL, -- IOC country code 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 ( song SERIAL PRIMARY KEY, title VARCHAR NOT NULL, artist VARCHAR NOT NULL, minbpm INTEGER NOT NULL, maxbpm INTEGER NOT NULL, UNIQUE ( title ) ); 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, scoringsystemname VARCHAR NOT NULL, UNIQUE ( scoringsystemname ) ); CREATE TABLE songratings ( 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, 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 ) ); CREATE TABLE seasons ( season SERIAL PRIMARY KEY, seasonname VARCHAR NOT NULL, UNIQUE ( seasonname ) ); CREATE TABLE tournaments ( tournament SERIAL PRIMARY KEY, season INTEGER NOT NULL REFERENCES seasons, tournamentname VARCHAR NOT NULL, country INTEGER NOT NULL REFERENCES countries, location VARCHAR NOT NULL, "date" DATE NOT NULL, machine INTEGER NOT NULL REFERENCES machines, scoringsystem INTEGER NOT NULL REFERENCES scoringsystems, UNIQUE ( season, tournamentname ) ); CREATE TABLE tournamentparticipation ( tournament INTEGER NOT NULL REFERENCES tournaments, player INTEGER NOT NULL REFERENCES players, paid BOOLEAN NOT NULL, PRIMARY KEY ( tournament, player ) ); CREATE TABLE tournamentrankings ( tournament INTEGER NOT NULL REFERENCES tournaments, ranking INTEGER NOT NULL, player INTEGER NOT NULL REFERENCES players, points INTEGER, PRIMARY KEY (tournament, player) ); CREATE TABLE rounds ( tournament INTEGER NOT NULL REFERENCES tournaments, round INTEGER NOT NULL, randomsongs INTEGER NOT NULL, chosensongs INTEGER NOT NULL, numqualifying INTEGER, PRIMARY KEY (tournament, round) ); CREATE TABLE groups ( tournament INTEGER NOT NULL REFERENCES tournaments, round INTEGER NOT NULL, parallel INTEGER NOT NULL, FOREIGN KEY (tournament, round) REFERENCES rounds (tournament, round), PRIMARY KEY (tournament, round, parallel) ); CREATE TABLE roundrandomsongs ( tournament INTEGER NOT NULL, round INTEGER NOT NULL, parallel INTEGER NOT NULL, song INTEGER NOT NULL REFERENCES songs, FOREIGN KEY (tournament, round, parallel) REFERENCES groups (tournament, round, parallel), PRIMARY KEY (tournament, round, parallel, song) ); CREATE TABLE roundparticipation ( tournament INTEGER NOT NULL, round INTEGER NOT NULL, parallel INTEGER NOT NULL, player INTEGER NOT NULL REFERENCES players, position INTEGER NOT NULL, UNIQUE (tournament, round, player), UNIQUE (tournament, round, parallel, position), FOREIGN KEY (tournament, round, parallel) REFERENCES groups (tournament, round, parallel), PRIMARY KEY (tournament, round, parallel, player) ); CREATE TABLE scores ( tournament INTEGER NOT NULL, round INTEGER NOT NULL, parallel INTEGER NOT NULL, player INTEGER NOT NULL REFERENCES players, songnumber INTEGER NOT NULL, 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, score INTEGER CHECK (score IS NULL OR (score >= 0 AND score <= 10000)), -- FOREIGN KEY (song, playmode, difficulty) REFERENCES songratings (song, playmode, difficulty), FOREIGN KEY (tournament, round, parallel, player) REFERENCES roundparticipation (tournament, round, parallel, player), 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; -- Find out, for each player in the group, what the maximum remaining score -- possibly can be, using get_max_score_for_{songs,players} (the first for -- selected but not played songs, the second for random songs that have not -- been chosen yet). -- -- This doesn't solve problems we'd face with more than one chosen song, but it -- should be good enough. CREATE TYPE minmax_score AS ( player INTEGER, min_score INTEGER, max_score INTEGER ); -- get_minmax_score_for_players(tournament, round, playmode) CREATE FUNCTION get_minmax_score_for_players(integer, integer, varchar) RETURNS SETOF minmax_score AS $$ DECLARE ret minmax_score; tp RECORD; ts RECORD; BEGIN FOR tp IN SELECT player FROM roundparticipation WHERE tournament=$1 AND round=$2 LOOP ret.player := tp.player; ret.min_score := 0; ret.max_score := 0; FOR ts IN SELECT song,score FROM scores WHERE tournament=$1 and round=$2 and player=tp.player LOOP IF ts.score IS NOT NULL THEN -- score is already given ret.min_score := ret.min_score + ts.score; ret.max_score := ret.max_score + ts.score; ELSE IF ts.song IS NOT NULL THEN ret.max_score := ret.max_score + ( SELECT max_score FROM get_max_score_for_songs($1, $3) WHERE song=ts.song ); ELSE ret.max_score := ret.max_score + ( SELECT max_score FROM get_max_score_for_players($1, $3) WHERE song=tp.player ); END IF; END IF; END LOOP; RETURN NEXT ret; END LOOP; RETURN; END; $$ LANGUAGE plpgsql STABLE RETURNS NULL ON NULL INPUT; -- use the minmax_score as a basis for finding best and worst possible ranks CREATE TYPE minmax_rank AS ( player INTEGER, best_rank INTEGER, worst_rank INTEGER ); -- get_minmax_score_for_players(tournament, round, playmode) CREATE TABLE temp_minmax ( player INTEGER, min_score INTEGER, max_score INTEGER ); CREATE FUNCTION get_minmax_rank_for_players(integer, integer, varchar) RETURNS SETOF minmax_rank AS $$ DECLARE ret minmax_rank; tp RECORD; BEGIN INSERT INTO temp_minmax SELECT * FROM get_minmax_score_for_players($1, $2, $3); FOR tp IN SELECT * FROM temp_minmax LOOP ret.player = tp.player; ret.best_rank = 1 + ( SELECT COUNT(*) FROM temp_minmax WHERE min_score >= tp.max_score AND player<>tp.player); ret.worst_rank = 1 + ( SELECT COUNT(*) FROM temp_minmax WHERE max_score > tp.min_score AND player<>tp.player ); RETURN NEXT ret; END LOOP; TRUNCATE temp_minmax; RETURN; END; $$ LANGUAGE plpgsql VOLATILE -- not really, but needed for the TEMPORARY TABLE RETURNS NULL ON NULL INPUT;