X-Git-Url: https://git.sesse.net/?p=ccbs;a=blobdiff_plain;f=sql%2Fccbs.sql;h=99b67003306220af9b40e6ce7234d0ede634c4e7;hp=d48fbeb04c33385c27929a10defee15003bd842d;hb=4ef40bec0dfd1b5e01a79f6267cfc758be8ac939;hpb=23a9b9ce42cd6a8c5752b217bccb581425267fdb diff --git a/sql/ccbs.sql b/sql/ccbs.sql index d48fbeb..99b6700 100644 --- a/sql/ccbs.sql +++ b/sql/ccbs.sql @@ -256,3 +256,122 @@ $$ 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, $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;