diff --git a/Makefile b/Makefile index 9a38b61..7187ef4 100644 --- a/Makefile +++ b/Makefile @@ -31,10 +31,6 @@ $(EXT_DIR)/bootstrap: bootstrap.zip unzip -n $< -d $(EXT_DIR) mv -v $(EXT_DIR)/bootstrap-3.3.5-dist $(EXT_DIR)/bootstrap -$(WEB_DIR)/registration/countries.csv: - # Official download link from http://data.okfn.org/data/core/country-list, under Public Domain - curl https://raw.githubusercontent.com/datasets/country-list/master/data.csv -o $@ - run_web: $(DEV_MANAGE) runserver @@ -58,7 +54,7 @@ docs_site: mkdocs.yml $(wildcard docs/* docs/*/*) clean: rm -rf src/ctf_gameserver/web/*/migrations - rm -f src/ctf_gameserver/web/dev-db.sqlite3 src/ctf_gameserver/web/registration/countries.csv + rm -f src/ctf_gameserver/web/dev-db.sqlite3 rm -rf src/ctf_gameserver/web/static/ext rm -rf build dist src/ctf_gameserver.egg-info rm -rf docs_site diff --git a/conf/controller/scoreboard_v2.sql b/conf/controller/scoreboard_v2.sql new file mode 100644 index 0000000..c3d368b --- /dev/null +++ b/conf/controller/scoreboard_v2.sql @@ -0,0 +1,319 @@ +-- Implements the FAUST CTF Scoring Formula as per: https://2022.faustctf.net/information/rules/ + + +-- #### flag points MATERIALIZED VIEW ##### + +DROP MATERIALIZED VIEW IF EXISTS "scoreboard_v2_board"; +DROP MATERIALIZED VIEW IF EXISTS "scoreboard_v2_flag_points"; + +-- calculates for each flag: +-- - the bonus part of the attack points: +-- "offense += (1 / count(all_captures_of[flag]))" +-- - the defense points: +-- "count(all_captures_of[flag]) ** 0.75" +CREATE MATERIALIZED VIEW "scoreboard_v2_flag_points" AS +WITH + -- calculate the captures of a flag_id in a tick + -- sparse so only captures >= 1 are in the result + captures_per_tick AS ( + SELECT scoring_capture.tick, + scoring_capture.flag_id, + COUNT(*) as captures + FROM scoring_capture + GROUP BY scoring_capture.tick, scoring_capture.flag_id + ), + -- calculate the total captures of a flag_id up to a tick + -- sparse so only changed all_captures are in the result + all_captures_of_flag AS ( + SELECT tick, flag_id, + SUM(captures) over(PARTITION BY flag_id ORDER BY tick) as all_captures + FROM captures_per_tick + ), + flag_points_per_tick AS ( + -- calculate: + -- the attack bonus (1 / count(all_captures_of[flag]) and + -- the defense points (count(all_captures_of[flag]) ** 0.75) + -- per tick and flag + SELECT tick, flag_id, + float8 '1.0' / all_captures as attack_bonus, + POWER(all_captures, float8 '0.75') as defense + FROM all_captures_of_flag + ), + flag_points_development AS ( + -- convert the value per tick to a difference to the previous tick's value + -- We do this so we can add up the points in the recurisve CTE + -- e.g. if a flag is captured 2 times @ tick 100 and 3 times @ tick 101 + -- it will generate the following output: + -- |tick|attack_bonus_delta| defense_delta | + -- | 100| 0.5| 2**0.75| + -- | 101|(1/5)-(1/2) = -0.3|5**0.75-2**0.75| + SELECT tick, flag_id, + attack_bonus, + attack_bonus - coalesce(lag(attack_bonus) OVER (PARTITION BY flag_id ORDER BY tick), float '0.0') as attack_bonus_delta, + defense - coalesce(lag(defense) OVER (PARTITION BY flag_id ORDER BY tick), float '0.0') as defense_delta + FROM flag_points_per_tick + ) +SELECT flag_points_development.tick, + flag_id, + scoring_flag.service_id as service_id, + attack_bonus, attack_bonus_delta, defense_delta +FROM flag_points_development +INNER JOIN scoring_flag ON scoring_flag.id = flag_id; + +CREATE INDEX flag_points_per_tick + ON "scoreboard_v2_flag_points" (tick, flag_id, service_id, attack_bonus, attack_bonus_delta, defense_delta); + +ALTER MATERIALIZED VIEW "scoreboard_v2_flag_points" OWNER TO gameserver_controller; +GRANT SELECT on TABLE "scoreboard_v2_flag_points" TO gameserver_web; + + +-- #### scoreboard MATERIALIZED VIEW #### + +DROP TABLE IF EXISTS "scoreboard_v2_board"; +DROP MATERIALIZED VIEW IF EXISTS "scoreboard_v2_board"; + +-- This makes heavy use of RECURSIVE CTEs: +-- https://www.postgresql.org/docs/14/queries-with.html#QUERIES-WITH-RECURSIVE +-- We do this to calculate the score based on the previous tick + +CREATE MATERIALIZED VIEW "scoreboard_v2_board" AS +WITH RECURSIVE + -- calculate the max tick of the scoreboard. + -- Normally this is current_tick - 1 because the current_tick is running and thus does not have final scoring + -- However on game end we want the scoreboard to include the current_tick==last tick as current_tick is not incremented on game end + max_scoreboard_tick AS ( + SELECT CASE WHEN ( + -- Check if the game is still running + -- Use a slack of 1 sec to avoid time sync issues + SELECT ("end" - INTERVAL '1 sec') > NOW() FROM scoring_gamecontrol + ) THEN ( + -- game is running - avoid current_tick + SELECT current_tick - 1 FROM scoring_gamecontrol + ) ELSE ( + -- game ended - include current_tick + SELECT current_tick from scoring_gamecontrol + ) END + ), + valid_ticks AS ( + SELECT valid_ticks from scoring_gamecontrol + ), + -- all teams considered for scoreboard - must be is_active and not NOP-Team + teams as ( + SELECT user_id as team_id + FROM registration_team + INNER JOIN auth_user ON auth_user.id = registration_team.user_id + WHERE is_active = true + AND nop_team = false + ), + -- calculate flags_captured using Recursive CTE + flags_captured(tick, team_id, service_id, flags_captured) AS ( + -- inital value of recursion: + -- Get the first capture of each team and service, go back 1 tick and assign 0 captures + SELECT min(scoring_capture.tick)-1 as tick, + capturing_team_id as team_id, + service_id, + integer '0' + FROM scoring_capture + INNER JOIN scoring_flag ON scoring_capture.flag_id = scoring_flag.id + GROUP BY capturing_team_id, service_id + UNION ALL + -- recursion step: + -- increment tick and add captures for tick + SELECT prev_tick.tick + 1, + prev_tick.team_id, + prev_tick.service_id, + prev_tick.flags_captured + -- calculate the captures for this tick, team and service + + coalesce((SELECT COUNT(*) + FROM scoring_capture + INNER JOIN scoring_flag ON scoring_capture.flag_id = scoring_flag.id + AND scoring_flag.service_id = prev_tick.service_id + WHERE scoring_capture.tick = prev_tick.tick + 1 + AND scoring_capture.capturing_team_id = prev_tick.team_id), 0)::integer + FROM flags_captured prev_tick + -- perform recursion until max_scoreboard_tick + WHERE prev_tick.tick + 1 <= (SELECT * FROM max_scoreboard_tick) + ), + -- calculate the attack bonus using Recursive CTE + attack_bonus(tick, team_id, service_id, attack_bonus) AS ( + -- inital value of recursion: + -- Get the first capture of each team and service, go back 1 tick and assign score 0.0 + SELECT min(scoring_capture.tick) - 1, + capturing_team_id as team_id, + service_id, + float8 '0.0' + FROM scoring_capture + INNER JOIN scoring_flag ON scoring_flag.id = scoring_capture.flag_id + GROUP BY capturing_team_id, service_id + UNION ALL + -- recursion step: + -- increment tick and add attack bonus increment for tick + SELECT prev_tick.tick + 1, + prev_tick.team_id, + prev_tick.service_id, + prev_tick.attack_bonus + -- for each flag captured in this tick get the attack_bonus from this tick + + coalesce((SELECT SUM(points.attack_bonus) + FROM scoreboard_v2_flag_points points + -- inner join scoring_capture for each flag captured in this tick + INNER JOIN scoring_capture ON scoring_capture.flag_id = points.flag_id + AND scoring_capture.capturing_team_id = prev_tick.team_id + AND scoring_capture.tick = prev_tick.tick + 1 + -- points from this tick + WHERE points.tick = prev_tick.tick + 1 + AND points.service_id = prev_tick.service_id), float8 '0.0') + -- for each flag captured in a previous tick get the attack_bonus_delta in this tick + + coalesce((SELECT SUM(points.attack_bonus_delta) + FROM scoreboard_v2_flag_points points + -- inner join scoring_capture for each flag captured in a previous tick - limit to valid_ticks for performance + INNER JOIN scoring_capture ON scoring_capture.flag_id = points.flag_id + AND scoring_capture.capturing_team_id = prev_tick.team_id + AND prev_tick.tick + 1 - (SELECT * from valid_ticks) < scoring_capture.tick + AND scoring_capture.tick < prev_tick.tick + 1 + -- points from this tick + WHERE points.tick = prev_tick.tick + 1 + AND points.service_id = prev_tick.service_id), float8 '0.0') + FROM attack_bonus prev_tick + -- perform recursion until max_scoreboard_tick + WHERE prev_tick.tick + 1 <= (SELECT * FROM max_scoreboard_tick) + ), + -- calculate flags_lost using Recursive CTE + flags_lost(tick, team_id, service_id, flags_lost) AS ( + -- inital value of recursion: + -- Get the first capture from each team and service, go back 1 ticks and assign 0 captures + SELECT min(scoring_capture.tick)-1 as tick, + protecting_team_id as team_id, + service_id, + integer '0' + FROM scoring_flag + INNER JOIN scoring_capture ON scoring_capture.flag_id = scoring_flag.id + GROUP BY protecting_team_id, service_id + UNION ALL + -- recursion step: + -- increment tick and add flag loss for tick + SELECT prev_tick.tick + 1, + prev_tick.team_id, + prev_tick.service_id, + prev_tick.flags_lost + -- calculate the captures for this tick, team and service + + coalesce((SELECT COUNT(*) + FROM scoring_flag + INNER JOIN scoring_capture ON scoring_capture.flag_id = scoring_flag.id + AND scoring_capture.tick = prev_tick.tick + 1 + -- we actually want the tick of the capture to match + -- but limiting the tick of the flag placement to a range of valid_ticks make this more efficient + WHERE prev_tick.tick + 1 - (SELECT * from valid_ticks) < scoring_flag.tick + AND scoring_flag.tick <= prev_tick.tick + 1 + AND scoring_flag.service_id = prev_tick.service_id + AND scoring_flag.protecting_team_id = prev_tick.team_id), 0)::integer + FROM flags_lost prev_tick + -- perform recursion until max_scoreboard_tick + WHERE prev_tick.tick + 1 <= (SELECT * FROM max_scoreboard_tick) + ), + -- calculate defense using Recursive CTE + defense (tick, team_id, service_id, defense) AS ( + -- inital value of recursion: + -- Get the first capture from each team and service subtract 1 from tick and assign score 0.0 + SELECT min(scoring_capture.tick) - 1, + protecting_team_id as team_id, + service_id, + float8 '0.0' + FROM scoring_capture + INNER JOIN scoring_flag ON scoring_flag.id = scoring_capture.flag_id + GROUP BY protecting_team_id, service_id + UNION ALL + -- recursion step: + -- increment tick and add defense increment for tick + SELECT prev_tick.tick + 1, + prev_tick.team_id, + prev_tick.service_id, + prev_tick.defense + -- calculate the increment of defense for this tick, team and service + + coalesce((SELECT SUM(points.defense_delta) + FROM scoreboard_v2_flag_points points + -- inner join flag to get all flags owned by team + INNER JOIN scoring_flag ON scoring_flag.id = points.flag_id + AND scoring_flag.protecting_team_id = prev_tick.team_id + AND scoring_flag.service_id = prev_tick.service_id + -- we actually want the tick of the points to match + -- but limiting the tick of the flag placement to a range of valid_ticks make this more efficient + AND prev_tick.tick + 1 - (SELECT * from valid_ticks) < scoring_flag.tick + AND scoring_flag.tick <= prev_tick.tick + 1 + WHERE points.tick = prev_tick.tick + 1), float8 '0.0') + FROM defense prev_tick + -- perform recursion until max_scoreboard_tick + WHERE prev_tick.tick + 1 <= (SELECT * FROM max_scoreboard_tick) + ), + sla (tick, team_id, service_id, sla) AS ( + -- inital value of recursion: + -- start at tick -1 for each team and service + -- To fill the whole scoreboard beginning at tick -1 this + -- must start at tick -1 cause the other tables (attack, defense, ...) might start at a later tick + SELECT -1 as tick, + team_id, + scoring_service.id AS service_id, + integer '0' + FROM teams, scoring_service + UNION ALL + -- recursion step: + -- increment tick and add sla score for tick + SELECT prev_tick.tick + 1, + prev_tick.team_id, + prev_tick.service_id, + prev_tick.sla + -- calculate the increment of sla score for this tick, team and service + -- note: this is double the value from formula and is later halfed + + coalesce((SELECT SUM( + CASE WHEN status = 0 THEN 2 ELSE 1 END) + FROM scoring_statuscheck + WHERE scoring_statuscheck.tick = prev_tick.tick + 1 + AND scoring_statuscheck.service_id = prev_tick.service_id + AND scoring_statuscheck.team_id = prev_tick.team_id + AND status IN (0, 4)), 0)::integer + FROM sla prev_tick + -- perform recursion until max_scoreboard_tick + WHERE prev_tick.tick + 1 <= (SELECT * FROM max_scoreboard_tick) + ) +SELECT tick, + team_id, + service_id, + coalesce(flags_captured, 0)::integer as flags_captured, + (coalesce(flags_captured, 0) + coalesce(attack_bonus, 0))::double precision as attack, + coalesce(flags_lost, 0)::integer as flags_lost, + (-1.0 * coalesce(defense, 0))::double precision as defense, + -- no coalesce here this must exists for each tick, team and service + (sla * 0.5 * (SELECT sqrt(count(*)) FROM teams))::double precision as sla +FROM (SELECT * FROM flags_captured ORDER BY tick) AS flags_captured +NATURAL FULL OUTER JOIN (SELECT * FROM attack_bonus ORDER BY tick) AS attack_bonus +NATURAL FULL OUTER JOIN (SELECT * FROM flags_lost ORDER BY tick) AS flags_lost +NATURAL FULL OUTER JOIN (SELECT * FROM defense ORDER BY tick) AS defense +NATURAL FULL OUTER JOIN (SELECT * FROM sla ORDER BY tick) AS sla +-- filter out -1 tick and larger ticks +WHERE tick >= 0 AND tick <= (SELECT * FROM max_scoreboard_tick); + +CREATE UNIQUE INDEX unique_per_tick + ON "scoreboard_v2_board" (tick, team_id, service_id); + +ALTER MATERIALIZED VIEW "scoreboard_v2_board" OWNER TO gameserver_controller; +GRANT SELECT on TABLE "scoreboard_v2_board" TO gameserver_web; + +-- #### first_bloods VIEW #### + +DROP TABLE IF EXISTS "scoreboard_v2_firstbloods"; +DROP VIEW IF EXISTS "scoreboard_v2_firstbloods"; + +CREATE VIEW "scoreboard_v2_firstbloods" AS +-- select first row ordered by timestamp for each service_id +SELECT DISTINCT ON (service_id) + service_id, + capturing_team_id as team_id, + scoring_capture.tick, + scoring_capture.timestamp +FROM scoring_flag +INNER JOIN scoring_capture ON scoring_capture.flag_id = scoring_flag.id +ORDER BY service_id, scoring_capture.timestamp; + +GRANT SELECT on TABLE "scoreboard_v2_firstbloods" TO gameserver_web; + +-- NOTE: REFRESH MATERIALIZED VIEW CONCURRENTLY needs additional permissions: +-- GRANT TEMPORARY ON DATABASE $db TO gameserver_controller; diff --git a/setup.py b/setup.py index 61196d8..022282f 100755 --- a/setup.py +++ b/setup.py @@ -59,6 +59,7 @@ 'static/*.css', 'static/*.gif', 'static/*.js', + 'static/faustctf.svg', 'static/ext/jquery.min.js', 'static/ext/bootstrap/css/*', 'static/ext/bootstrap/fonts/*', diff --git a/src/ctf_gameserver/controller/database.py b/src/ctf_gameserver/controller/database.py index f501749..99fa7e6 100644 --- a/src/ctf_gameserver/controller/database.py +++ b/src/ctf_gameserver/controller/database.py @@ -1,3 +1,5 @@ +import logging + from ctf_gameserver.lib.database import transaction_cursor from ctf_gameserver.lib.date_time import ensure_utc_aware from ctf_gameserver.lib.exceptions import DBDataError @@ -58,6 +60,14 @@ def update_scoring(db_conn): ' OR outerflag.bonus IS NULL') cursor.execute('REFRESH MATERIALIZED VIEW "scoring_scoreboard"') + # don't block the old scoreboard when the new one is updating + with transaction_cursor(db_conn) as cursor: + try: + cursor.execute('REFRESH MATERIALIZED VIEW "scoreboard_v2_flag_points"') + cursor.execute('REFRESH MATERIALIZED VIEW CONCURRENTLY "scoreboard_v2_board"') + except Exception as e: # noqa, pylint: disable=broad-except + # don't crash controller on problems with the new scoreboard + logging.warning("Failed to update scorebard_v2: %s", e) def get_exploiting_teams_counts(db_conn, prohibit_changes=False): diff --git a/src/ctf_gameserver/web/base_settings.py b/src/ctf_gameserver/web/base_settings.py index 20a728a..4c94431 100644 --- a/src/ctf_gameserver/web/base_settings.py +++ b/src/ctf_gameserver/web/base_settings.py @@ -28,6 +28,7 @@ 'django.contrib.staticfiles', 'ctf_gameserver.web.templatetags', 'ctf_gameserver.web.registration', + 'ctf_gameserver.web.scoreboard_v2', 'ctf_gameserver.web.scoring', 'ctf_gameserver.web.flatpages', 'ctf_gameserver.web.vpnstatus' diff --git a/src/ctf_gameserver/web/registration/countries.csv b/src/ctf_gameserver/web/registration/countries.csv new file mode 100644 index 0000000..88dc220 --- /dev/null +++ b/src/ctf_gameserver/web/registration/countries.csv @@ -0,0 +1,250 @@ +Name,Code +Afghanistan,AF +Åland Islands,AX +Albania,AL +Algeria,DZ +American Samoa,AS +Andorra,AD +Angola,AO +Anguilla,AI +Antarctica,AQ +Antigua and Barbuda,AG +Argentina,AR +Armenia,AM +Aruba,AW +Australia,AU +Austria,AT +Azerbaijan,AZ +Bahamas,BS +Bahrain,BH +Bangladesh,BD +Barbados,BB +Belarus,BY +Belgium,BE +Belize,BZ +Benin,BJ +Bermuda,BM +Bhutan,BT +"Bolivia, Plurinational State of",BO +"Bonaire, Sint Eustatius and Saba",BQ +Bosnia and Herzegovina,BA +Botswana,BW +Bouvet Island,BV +Brazil,BR +British Indian Ocean Territory,IO +Brunei Darussalam,BN +Bulgaria,BG +Burkina Faso,BF +Burundi,BI +Cambodia,KH +Cameroon,CM +Canada,CA +Cape Verde,CV +Cayman Islands,KY +Central African Republic,CF +Chad,TD +Chile,CL +China,CN +Christmas Island,CX +Cocos (Keeling) Islands,CC +Colombia,CO +Comoros,KM +Congo,CG +"Congo, the Democratic Republic of the",CD +Cook Islands,CK +Costa Rica,CR +Côte d'Ivoire,CI +Croatia,HR +Cuba,CU +Curaçao,CW +Cyprus,CY +Czech Republic,CZ +Denmark,DK +Djibouti,DJ +Dominica,DM +Dominican Republic,DO +Ecuador,EC +Egypt,EG +El Salvador,SV +Equatorial Guinea,GQ +Eritrea,ER +Estonia,EE +Ethiopia,ET +Falkland Islands (Malvinas),FK +Faroe Islands,FO +Fiji,FJ +Finland,FI +France,FR +French Guiana,GF +French Polynesia,PF +French Southern Territories,TF +Gabon,GA +Gambia,GM +Georgia,GE +Germany,DE +Ghana,GH +Gibraltar,GI +Greece,GR +Greenland,GL +Grenada,GD +Guadeloupe,GP +Guam,GU +Guatemala,GT +Guernsey,GG +Guinea,GN +Guinea-Bissau,GW +Guyana,GY +Haiti,HT +Heard Island and McDonald Islands,HM +Holy See (Vatican City State),VA +Honduras,HN +Hong Kong,HK +Hungary,HU +Iceland,IS +India,IN +Indonesia,ID +"Iran, Islamic Republic of",IR +Iraq,IQ +Ireland,IE +Isle of Man,IM +Israel,IL +Italy,IT +Jamaica,JM +Japan,JP +Jersey,JE +Jordan,JO +Kazakhstan,KZ +Kenya,KE +Kiribati,KI +"Korea, Democratic People's Republic of",KP +"Korea, Republic of",KR +Kuwait,KW +Kyrgyzstan,KG +Lao People's Democratic Republic,LA +Latvia,LV +Lebanon,LB +Lesotho,LS +Liberia,LR +Libya,LY +Liechtenstein,LI +Lithuania,LT +Luxembourg,LU +Macao,MO +"Macedonia, the Former Yugoslav Republic of",MK +Madagascar,MG +Malawi,MW +Malaysia,MY +Maldives,MV +Mali,ML +Malta,MT +Marshall Islands,MH +Martinique,MQ +Mauritania,MR +Mauritius,MU +Mayotte,YT +Mexico,MX +"Micronesia, Federated States of",FM +"Moldova, Republic of",MD +Monaco,MC +Mongolia,MN +Montenegro,ME +Montserrat,MS +Morocco,MA +Mozambique,MZ +Myanmar,MM +Namibia,NA +Nauru,NR +Nepal,NP +Netherlands,NL +New Caledonia,NC +New Zealand,NZ +Nicaragua,NI +Niger,NE +Nigeria,NG +Niue,NU +Norfolk Island,NF +Northern Mariana Islands,MP +Norway,NO +Oman,OM +Pakistan,PK +Palau,PW +"Palestine, State of",PS +Panama,PA +Papua New Guinea,PG +Paraguay,PY +Peru,PE +Philippines,PH +Pitcairn,PN +Poland,PL +Portugal,PT +Puerto Rico,PR +Qatar,QA +Réunion,RE +Romania,RO +Russian Federation,RU +Rwanda,RW +Saint Barthélemy,BL +"Saint Helena, Ascension and Tristan da Cunha",SH +Saint Kitts and Nevis,KN +Saint Lucia,LC +Saint Martin (French part),MF +Saint Pierre and Miquelon,PM +Saint Vincent and the Grenadines,VC +Samoa,WS +San Marino,SM +Sao Tome and Principe,ST +Saudi Arabia,SA +Senegal,SN +Serbia,RS +Seychelles,SC +Sierra Leone,SL +Singapore,SG +Sint Maarten (Dutch part),SX +Slovakia,SK +Slovenia,SI +Solomon Islands,SB +Somalia,SO +South Africa,ZA +South Georgia and the South Sandwich Islands,GS +South Sudan,SS +Spain,ES +Sri Lanka,LK +Sudan,SD +Suriname,SR +Svalbard and Jan Mayen,SJ +Swaziland,SZ +Sweden,SE +Switzerland,CH +Syrian Arab Republic,SY +Taiwan,TW +Tajikistan,TJ +"Tanzania, United Republic of",TZ +Thailand,TH +Timor-Leste,TL +Togo,TG +Tokelau,TK +Tonga,TO +Trinidad and Tobago,TT +Tunisia,TN +Turkey,TR +Turkmenistan,TM +Turks and Caicos Islands,TC +Tuvalu,TV +Uganda,UG +Ukraine,UA +United Arab Emirates,AE +United Kingdom,GB +United States,US +United States Minor Outlying Islands,UM +Uruguay,UY +Uzbekistan,UZ +Vanuatu,VU +"Venezuela, Bolivarian Republic of",VE +Viet Nam,VN +"Virgin Islands, British",VG +"Virgin Islands, U.S.",VI +Wallis and Futuna,WF +Western Sahara,EH +Yemen,YE +Zambia,ZM +Zimbabwe,ZW diff --git a/src/ctf_gameserver/web/scoreboard_v2/__init__.py b/src/ctf_gameserver/web/scoreboard_v2/__init__.py new file mode 100644 index 0000000..e69de29 diff --git a/src/ctf_gameserver/web/scoreboard_v2/calculations.py b/src/ctf_gameserver/web/scoreboard_v2/calculations.py new file mode 100644 index 0000000..c18d999 --- /dev/null +++ b/src/ctf_gameserver/web/scoreboard_v2/calculations.py @@ -0,0 +1,154 @@ +from collections import defaultdict, OrderedDict + +from django.core.cache import cache + +from django.db.models import F, Max + +from . import models + + +def scores(tick): + """ + Returns the scores as currently stored in the database as an OrderedDict + and the attackers/victims per service in this format: + + {team_id: { + 'services': { + service_id: { + offense_score, offense_delta, + defense_score, defense_delta, + sla_score, sla_delta, + flags_captured, flags_captured_delta, + flags_lost, flags_lost_delta + }} + 'total': { + total_score, + offense_score, offense_delta, + defense_score, defense_delta, + sla_score, sla_delta + } + }}, + {service_id: { + attackers, + victims + }} + + The scores are sorted by the total_score. + """ + + team_scores = defaultdict(lambda: { + 'services': defaultdict(lambda: { + 'offense_score': 0, 'offense_delta': 0, + 'defense_score': 0, 'defense_delta': 0, + 'sla_score': 0, 'sla_delta': 0, + 'flags_captured': 0, 'flags_captured_delta': 0, + 'flags_lost': 0, 'flags_lost_delta': 0, + }), + 'total': { + 'total_score': 0, + 'offense_score': 0, 'offense_delta': 0, + 'defense_score': 0, 'defense_delta': 0, + 'sla_score': 0, 'sla_delta': 0, + } + }) + + for score in models.Board.objects.filter(tick=tick).all(): + srv = team_scores[score.team_id]['services'][score.service_id] + srv['offense_score'] = srv['offense_delta'] = score.attack + srv['defense_score'] = srv['defense_delta'] = score.defense + srv['sla_score'] = srv['sla_delta'] = score.sla + srv['flags_captured'] = srv['flags_captured_delta'] = score.flags_captured + srv['flags_lost'] = srv['flags_lost_delta'] = score.flags_lost + total = team_scores[score.team_id]['total'] + total['offense_score'] += score.attack + total['defense_score'] += score.defense + total['sla_score'] += score.sla + total['total_score'] += score.attack + score.defense + score.sla + + # calculate the difference to the previous tick (if any) + for score in models.Board.objects.filter(tick=tick - 1).all(): + srv = team_scores[score.team_id]['services'][score.service_id] + srv['offense_delta'] -= score.attack + srv['defense_delta'] -= score.defense + srv['sla_delta'] -= score.sla + srv['flags_captured_delta'] -= score.flags_captured + srv['flags_lost_delta'] -= score.flags_lost + total = team_scores[score.team_id]['total'] + total['offense_delta'] += srv['offense_delta'] + total['defense_delta'] += srv['defense_delta'] + total['sla_delta'] += srv['sla_delta'] + + attackers_victims = defaultdict(lambda: {'attackers': 0, 'victims': 0}) + for team in team_scores.values(): + for service_id, service in team['services'].items(): + attackers_victims[service_id]['attackers'] += int(service['flags_captured_delta'] > 0) + attackers_victims[service_id]['victims'] += int(service['flags_lost_delta'] > 0) + + sorted_team_scores = OrderedDict(sorted(team_scores.items(), + key=lambda kv: kv[1]['total']['total_score'], reverse=True)) + + return sorted_team_scores, attackers_victims + +def get_scoreboard_tick(): + """ + Get the maximum tick to display on the scoreboard. Usually equal current_tick - 1 + """ + # max tick of scoreboard + scoreboard_tick = models.Board.objects.aggregate(max_tick=Max('tick'))['max_tick'] + if scoreboard_tick is None: + # game has not started: current_tick < 0 + # return -1 so scoreboard already shows services when they are public + return -1 + return scoreboard_tick + +def get_firstbloods(scoreboard_tick): + """ + Get the first bloods for each service (if any). + """ + + # cache based on scoreboard_tick which invalidates the cache + # when update_scoring() ran in the controller + cache_key = 'scoreboard_v2_firstbloods_{:d}'.format(scoreboard_tick) + cached_firstbloods = cache.get(cache_key) + + if cached_firstbloods is not None: + return cached_firstbloods + + firstbloods = models.FirstBloods.objects.only('service_id', 'team_id', 'tick').all() + + cache.set(cache_key, firstbloods, 90) + + return firstbloods + +def per_team_scores(team_id, service_ids_order): + """ + Get the point development of a team during all past ticks. + Returns an array of arrays. + The first index is the service in the order given by "service_ids_order". + The second index is the tick. + So result[0][0] is the score from service with id service_ids_order[0] and tick 0. + """ + scoreboard_tick = get_scoreboard_tick() + + # cache based on team_id and scoreboard_tick which invalidates the cache + # when update_scoring() ran in the controller + cache_key = 'scoreboard_v2_team_scores_{:d}_{:d}'.format(team_id, scoreboard_tick) + cached_team_scores = cache.get(cache_key) + + if cached_team_scores is not None: + return cached_team_scores + + team_total_scores = models.Board.objects \ + .annotate(points=F('attack')+F('defense')+F('sla')) \ + .filter(team_id = team_id, tick__lte = scoreboard_tick) \ + .order_by('tick') \ + .values('service_id', 'points') + + result = list([] for _ in service_ids_order) + + for total_score in team_total_scores: + result[service_ids_order.index(total_score['service_id'])].append(total_score['points']) + + cache.set(cache_key, result, 90) + + return result diff --git a/src/ctf_gameserver/web/scoreboard_v2/models.py b/src/ctf_gameserver/web/scoreboard_v2/models.py new file mode 100644 index 0000000..a173c44 --- /dev/null +++ b/src/ctf_gameserver/web/scoreboard_v2/models.py @@ -0,0 +1,46 @@ +from django.db import models + +from ctf_gameserver.web.registration.models import Team +from ctf_gameserver.web.scoring.models import Service + + +class Board(models.Model): + """ + Scoreboard as calculated by external, asyncron helper. May be a + (materialized) view or a real table and should just be handled + read-only from within the website. + """ + tick = models.IntegerField(editable=False, primary_key=True) + team = models.OneToOneField(Team, editable=False, on_delete=models.PROTECT) + service = models.OneToOneField(Service, editable=False, on_delete=models.PROTECT) + attack = models.FloatField(editable=False) + defense = models.FloatField(editable=False) + sla = models.FloatField(editable=False) + flags_captured = models.IntegerField(editable=False) + flags_lost = models.IntegerField(editable=False) + + class Meta: + managed = False # django should not create a table for this + constraints = [ + models.UniqueConstraint(fields=['tick', 'team', 'service'], name='unique_per_tick') + ] + + def __str__(self): + return 'Score for tick {} and team {}'.format(self.tick, self.team) + +class FirstBloods(models.Model): + """ + First team to capture a flag per service. + Calculated externally. May be a view or a real table + and should just be handled read-only from within the website. + """ + service = models.OneToOneField(Service, primary_key=True, editable=False, on_delete=models.PROTECT) + team = models.OneToOneField(Team, editable=False, on_delete=models.PROTECT) + tick = models.IntegerField(editable=False) + timestamp = models.DateTimeField(editable=False) + + class Meta: + managed = False # django should not create a table for this + + def __str__(self): + return 'Firstblood of service {} by team {} in tick {}'.format(self.service, self.team, self.tick) diff --git a/src/ctf_gameserver/web/scoreboard_v2/views.py b/src/ctf_gameserver/web/scoreboard_v2/views.py new file mode 100644 index 0000000..d78de52 --- /dev/null +++ b/src/ctf_gameserver/web/scoreboard_v2/views.py @@ -0,0 +1,168 @@ +import datetime + +from django.core.exceptions import PermissionDenied +from django.http import JsonResponse +from django.views.decorators.cache import cache_page + +import ctf_gameserver.web.registration.models as registration_models + +from ctf_gameserver.web.scoring.views import _get_status_descriptions +from ctf_gameserver.web.scoring.decorators import registration_closed_required, services_public_required +from ctf_gameserver.web.scoring import models as scoring_models +from ctf_gameserver.web.scoring import calculations as scoring_calculations + +from . import calculations + +# old scoreboard currently uses [] so database defined order +SCOREBOARD_SERVICE_ORDER = ['name'] + +# data per tick does not change so can use longer caching +@cache_page(90) +@services_public_required('json') +def round_json(_, tick=-1): + tick = int(tick) + + scoreboard_tick = calculations.get_scoreboard_tick() + + if tick > scoreboard_tick or tick < -1: + raise PermissionDenied() + + scores, attackers_victims = calculations.scores(tick) + statuses = scoring_calculations.team_statuses(tick - 3, tick, only_team_fields=['user_id']) + # convert team-keys to team_id-keys + statuses = {team.user_id: v for team, v in statuses.items()} + + services = scoring_models.Service.objects.order_by(*SCOREBOARD_SERVICE_ORDER).only('name').all() + service_ids = [] + services_json = [] + for service in services: + service_ids.append(service.id) + services_json.append({ + "name": service.name, + "first_blood": [], # this is an array for multiple flag stores + "attackers": attackers_victims[service.id]["attackers"], + "victims": attackers_victims[service.id]["victims"], + }) + + firstbloods = calculations.get_firstbloods(scoreboard_tick) + for firstblood in firstbloods: + if firstblood.tick <= tick: + service_idx = service_ids.index(firstblood.service_id) + services_json[service_idx]["first_blood"] = [firstblood.team_id] + + response = { + 'tick': tick, + 'scoreboard': [], + 'status-descriptions': _get_status_descriptions(), + 'services': services_json + } + + for rank, (team_id, points) in enumerate(scores.items(), start=1): + team_entry = { + 'rank': rank, + 'team_id': team_id, + 'services': [], + 'points': points['total']['total_score'], + 'o': points['total']['offense_score'], + 'do': points['total']['offense_delta'], + 'd': points['total']['defense_score'], + 'dd': points['total']['defense_delta'], + 's': points['total']['sla_score'], + 'ds': points['total']['sla_delta'], + } + + for service in services: + service_statuses = [] + for status_tick in range(tick - 3, tick + 1): + try: + service_statuses.insert(0, statuses[team_id][status_tick][service.id]) + except KeyError: + service_statuses.insert(0, -1) + + service_points = points['services'][service.id] + team_entry['services'].append({ + 'c': service_statuses[0], + 'dc': service_statuses[1:4], + 'o': service_points['offense_score'], + 'do': service_points['offense_delta'], + 'd': service_points['defense_score'], + 'dd': service_points['defense_delta'], + 's': service_points['sla_score'], + 'ds': service_points['sla_delta'], + 'cap': service_points['flags_captured'], + 'dcap': service_points['flags_captured_delta'], + 'st': service_points['flags_lost'], + 'dst': service_points['flags_lost_delta'], + }) + + response['scoreboard'].append(team_entry) + + return JsonResponse(response) + +# Short cache timeout only, because there is already caching going on in calculations +@cache_page(5) +@services_public_required('json') +def per_team_json(_, team=-1): + team = int(team) + + # get service ids in scoreboard order + service_ids = list(scoring_models.Service.objects \ + .order_by(*SCOREBOARD_SERVICE_ORDER) \ + .values_list('id', flat=True)) + + team_scores = calculations.per_team_scores(team, service_ids) + + response = { + 'points': team_scores + } + + return JsonResponse(response) + +# every scoreboard UI will query this every 2-10 sec so better cache this +# but don't cache it too long to avoid long wait times after tick increment +# it's not expensive anyway (two single row queries) +@cache_page(2) +@registration_closed_required +def current_json(_): + game_control = scoring_models.GameControl.get_instance() + current_tick = game_control.current_tick + + scoreboard_tick = calculations.get_scoreboard_tick() + + next_tick_start_offset = (current_tick + 1) * game_control.tick_duration + current_tick_until = game_control.start + datetime.timedelta(seconds=next_tick_start_offset) + unix_epoch = datetime.datetime(1970,1,1,tzinfo=datetime.timezone.utc) + current_tick_until_unix = (current_tick_until-unix_epoch).total_seconds() + + state = int(not game_control.competition_started() or game_control.competition_over()) + + result = { + "state": state, + "current_tick": current_tick, + "current_tick_until": current_tick_until_unix, + "scoreboard_tick": scoreboard_tick + } + return JsonResponse(result, json_dumps_params={'indent': 2}) + +@cache_page(60) +# This is essentially just a registered teams list so could be made public even earlier +@registration_closed_required +def teams_json(_): + + teams = registration_models.Team.active_not_nop_objects \ + .select_related('user') \ + .only('user__username', 'affiliation', 'country', 'image') \ + .order_by('user_id') \ + .all() + + result = {} + for team in teams: + team_json = { + "name": team.user.username, + "aff": team.affiliation, + "country": team.country, + "logo": None if not team.image else team.image.get_thumbnail_url() + } + result[team.user_id] = team_json + + return JsonResponse(result, json_dumps_params={'indent': 2}) diff --git a/src/ctf_gameserver/web/scoring/models.py b/src/ctf_gameserver/web/scoring/models.py index 8e433cb..b1cc99b 100644 --- a/src/ctf_gameserver/web/scoring/models.py +++ b/src/ctf_gameserver/web/scoring/models.py @@ -39,7 +39,8 @@ class Meta: unique_together = ('service', 'protecting_team', 'tick') index_together = ( ('service', 'tick'), - ('service', 'protecting_team', 'tick') + ('service', 'protecting_team', 'tick', 'id'), # for scoreboard_v2 + ('service', 'id'), # for scoreboard_v2 ) def __str__(self): @@ -59,7 +60,11 @@ class Capture(models.Model): class Meta: # This constraint is necessary for correct behavior of the submission server unique_together = ('flag', 'capturing_team') - index_together = ('flag', 'capturing_team') + index_together = ( + ('flag', 'capturing_team'), + ('capturing_team', 'tick', 'flag'), # for scoreboard_v2 + ('flag', 'tick') # for scoreboard_v2 + ) def __str__(self): return 'Capture {:d}'.format(self.id) diff --git a/src/ctf_gameserver/web/scoring/templates/competition_nav.html b/src/ctf_gameserver/web/scoring/templates/competition_nav.html index 156fea1..c38b161 100644 --- a/src/ctf_gameserver/web/scoring/templates/competition_nav.html +++ b/src/ctf_gameserver/web/scoring/templates/competition_nav.html @@ -1,4 +1,5 @@ {% load i18n %} +{% load static %} {% comment %} Horizontal 'nav-pill' navigation for pages from the "competition" category of the main navigation. @@ -14,6 +15,9 @@