]> git.sesse.net Git - ccbs/blobdiff - sql/ccbs.sql
Shape text using Pango and HarfBuzz; gives us nice ligatures and exotic scripts.
[ccbs] / sql / ccbs.sql
index 4c42d56187a4c01f185ead62367b10f081503ff5..0463f742014ea9517ae9195403497d0028c96bba 100644 (file)
@@ -123,6 +123,7 @@ CREATE TABLE rounds (
        chosensongs INTEGER NOT NULL,
        numqualifying INTEGER,
 
+       UNIQUE (tournament, player),
        PRIMARY KEY (tournament, round)
 );
 
@@ -224,3 +225,154 @@ $$
     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 WHERE tournament=$1;
+$$
+    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, parallel, playmode)
+CREATE FUNCTION get_minmax_score_for_players(integer, 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 AND parallel=$3 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 parallel=$3 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, $4) WHERE song=ts.song );
+                               ELSE
+                                       ret.max_score := ret.max_score + ( SELECT max_score FROM get_max_score_for_players($1, $2, $4) 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, parallel, playmode)
+CREATE TABLE temp_minmax (
+       player INTEGER,
+       min_score INTEGER,
+       max_score INTEGER
+);
+
+CREATE FUNCTION get_minmax_rank_for_players(integer, 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, $4);
+       
+       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;
+
+-- get_minmax_score_for_players(tournament, playmode)
+CREATE TYPE minmax_rank_entire_tournament AS (
+       round INTEGER,
+       parallel INTEGER,
+       player INTEGER,
+       best_rank INTEGER,
+       worst_rank INTEGER
+);
+CREATE FUNCTION get_minmax_rank_for_players(integer, varchar) RETURNS SETOF minmax_rank_entire_tournament
+    AS $$
+DECLARE
+       ret minmax_rank_entire_tournament;
+       tr record;
+       tp record;
+BEGIN
+       FOR tr IN SELECT * FROM groups WHERE tournament=$1 LOOP
+               ret.round = tr.round;
+               ret.parallel = tr.parallel;
+
+               FOR tp IN SELECT * FROM get_minmax_rank_for_players($1, tr.round, tr.parallel, $2) LOOP
+                       ret.player = tp.player;
+                       ret.best_rank = tp.best_rank;
+                       ret.worst_rank = tp.worst_rank;
+                       RETURN NEXT ret;
+               END LOOP;
+       END LOOP;
+       RETURN;
+END;
+    $$
+    LANGUAGE plpgsql
+    STABLE
+    RETURNS NULL ON NULL INPUT;