Merge pull request #235 - Schema upgrade by skizzerz

Fix FK deferrable status, ensure that FKs are always enforced in the
bot, and redo how fool wins are stored/tracked. Drop unneded table.
This commit is contained in:
Ryan Schmidt 2016-07-27 09:38:23 -07:00 committed by Emanuel Barry
parent 0caaba9152
commit 22aa7af5c6
6 changed files with 371 additions and 79 deletions

1
.gitignore vendored
View File

@ -15,6 +15,7 @@ botconfig.py
# Database files
*.sqlite3
*.bak
# Log files
*.log

121
src/db.py
View File

@ -3,12 +3,15 @@ import src.settings as var
import sqlite3
import os
import json
import shutil
import sys
import time
from collections import defaultdict
import threading
# increment this whenever making a schema change so that the schema upgrade functions run on start
# they do not run by default for performance reasons
SCHEMA_VERSION = 1
SCHEMA_VERSION = 2
_ts = threading.local()
@ -27,10 +30,8 @@ def init_vars():
pe.stasis_expires,
COALESCE(at.flags, a.flags)
FROM person pe
JOIN person_player pp
ON pp.person = pe.id
JOIN player pl
ON pl.id = pp.player
ON pl.person = pe.id
LEFT JOIN access a
ON a.person = pe.id
LEFT JOIN access_template at
@ -93,10 +94,8 @@ def init_vars():
ON ws.warning = w.id
JOIN person pe
ON pe.id = w.target
JOIN person_player pp
ON pp.person = pe.id
JOIN player pl
ON pl.id = pp.player
ON pl.person = pe.id
WHERE
ws.sanction = 'deny command'
AND w.deleted = 0
@ -258,17 +257,6 @@ def add_game(mode, size, started, finished, winner, players, options):
p["personid"], p["playerid"] = _get_ids(p["account"], p["hostmask"], add=True)
with conn:
c = conn.cursor()
if winner.startswith("@"):
# fool won, convert the nick portion into a player id
for p in players:
if p["nick"] == winner[1:]:
winner = "@" + str(p["playerid"])
break
else:
# invalid winner? We can't find the fool's nick in the player list
# maybe raise an exception here instead of silently failing
return
c.execute("""INSERT INTO game (gamemode, options, started, finished, gamesize, winner)
VALUES (?, ?, ?, ?, ?, ?)""", (mode, json.dumps(options), started, finished, size, winner))
gameid = c.lastrowid
@ -297,10 +285,10 @@ def get_player_stats(acc, hostmask, role):
SUM(gp.indiv_win) AS indiv,
COUNT(1) AS total
FROM person pe
JOIN person_player pmap
ON pmap.person = pe.id
JOIN player pl
ON pl.person = pe.id
JOIN game_player gp
ON gp.player = pmap.player
ON gp.player = pl.id
JOIN game_player_role gpr
ON gpr.game_player = gp.id
AND gpr.role = ?
@ -324,10 +312,10 @@ def get_player_totals(acc, hostmask):
gpr.role AS role,
COUNT(1) AS total
FROM person pe
JOIN person_player pmap
ON pmap.person = pe.id
JOIN player pl
ON pl.person = pe.id
JOIN game_player gp
ON gp.player = pmap.player
ON gp.player = pl.id
JOIN game_player_role gpr
ON gpr.game_player = gp.id
WHERE pe.id = ?
@ -352,9 +340,7 @@ def get_game_stats(mode, size):
if not total_games:
return "No stats for \u0002{0}\u0002 player games.".format(size)
c.execute("""SELECT
CASE substr(winner, 1, 1)
WHEN '@' THEN 'fools'
ELSE winner END AS team,
winner AS team,
COUNT(1) AS games,
CASE winner
WHEN 'villagers' THEN 0
@ -693,11 +679,47 @@ def acknowledge_warning(warning):
c = conn.cursor()
c.execute("UPDATE warning SET acknowledged = 1 WHERE id = ?", (warning,))
def _upgrade():
# no upgrades yet, once there are some, add methods like _add_table(), _add_column(), etc.
# that check for the existence of that table/column/whatever and adds/drops/whatevers them
# as needed. We can't do this purely in SQL because sqlite lacks a scripting-level IF statement.
pass
def _upgrade(oldversion):
# try to make a backup copy of the database
print ("Performing schema upgrades, this may take a while.", file=sys.stderr)
have_backup = False
try:
print ("Creating database backup...", file=sys.stderr)
shutil.copyfile("data.sqlite3", "data.sqlite3.bak")
have_backup = True
print ("Database backup created at data.sqlite3.bak...", file=sys.stderr)
except OSError:
print ("Database backup failed! Hit Ctrl+C to abort, otherwise upgrade will continue in 5 seconds...", file=sys.stderr)
time.sleep(5)
dn = os.path.dirname(__file__)
conn = _conn()
try:
with conn:
c = conn.cursor()
if oldversion < 2:
print ("Upgrade from version 1 to 2...", file=sys.stderr)
# Update FKs to be deferrable, update collations to nocase where it makes sense,
# and clean up how fool wins are tracked (giving fools team wins instead of saving the winner's
# player id as a string). When nocasing players, this may cause some records to be merged.
with open(os.path.join(dn, "db", "upgrade2.sql"), "rt") as f:
c.executescript(f.read())
c.execute("PRAGMA user_version = " + str(SCHEMA_VERSION))
print ("Upgrades complete!", file=sys.stderr)
except sqlite3.Error:
print ("An error has occurred while upgrading the database schema.",
"Please report this issue to ##werewolf-dev on irc.freenode.net.",
"Include all of the following details in your report:",
sep="\n", file=sys.stderr)
if have_backup:
try:
shutil.copyfile("data.sqlite3.bak", "data.sqlite3")
except OSError:
print ("An error has occurred while restoring your database backup.",
"You can manually move data.sqlite3.bak to data.sqlite3 to restore the original database.",
sep="\n", file=sys.stderr)
raise
def _migrate():
# try to make a backup copy of the database
@ -708,7 +730,7 @@ def _migrate():
pass
dn = os.path.dirname(__file__)
conn = _conn()
with conn, open(os.path.join(dn, "db.sql"), "rt") as f1, open(os.path.join(dn, "migrate.sql"), "rt") as f2:
with conn, open(os.path.join(dn, "db", "db.sql"), "rt") as f1, open(os.path.join(dn, "db", "migrate.sql"), "rt") as f2:
c = conn.cursor()
#######################################################
# Step 1: install the new schema (from db.sql script) #
@ -728,7 +750,7 @@ def _migrate():
def _install():
dn = os.path.dirname(__file__)
conn = _conn()
with conn, open(os.path.join(dn, "db.sql"), "rt") as f1:
with conn, open(os.path.join(dn, "db", "db.sql"), "rt") as f1:
c = conn.cursor()
c.executescript(f1.read())
c.execute("PRAGMA user_version = " + str(SCHEMA_VERSION))
@ -743,10 +765,8 @@ def _get_ids(acc, hostmask, add=False):
elif acc is None:
c.execute("""SELECT pe.id, pl.id
FROM player pl
JOIN person_player pp
ON pp.player = pl.id
JOIN person pe
ON pe.id = pp.person
ON pe.id = pl.person
WHERE
pl.account IS NULL
AND pl.hostmask = ?
@ -755,10 +775,8 @@ def _get_ids(acc, hostmask, add=False):
hostmask = None
c.execute("""SELECT pe.id, pl.id
FROM player pl
JOIN person_player pp
ON pp.player = pl.id
JOIN person pe
ON pe.id = pp.person
ON pe.id = pl.person
WHERE
pl.account = ?
AND pl.hostmask IS NULL
@ -774,7 +792,7 @@ def _get_ids(acc, hostmask, add=False):
plid = c.lastrowid
c.execute("INSERT INTO person (primary_player) VALUES (?)", (plid,))
peid = c.lastrowid
c.execute("INSERT INTO person_player (person, player) VALUES (?, ?)", (peid, plid))
c.execute("UPDATE player SET person=? WHERE id=?" (peid, plid))
return (peid, plid)
def _get_display_name(peid):
@ -796,10 +814,10 @@ def _total_games(peid):
c = conn.cursor()
c.execute("""SELECT COUNT(DISTINCT gp.game)
FROM person pe
JOIN person_player pmap
ON pmap.person = pe.id
JOIN player pl
ON pl.person = pe.id
JOIN game_player gp
ON gp.player = pmap.player
ON gp.player = pl.id
WHERE
pe.id = ?""", (peid,))
# aggregates without GROUP BY always have exactly one row,
@ -826,6 +844,9 @@ def _conn():
return _ts.conn
except AttributeError:
_ts.conn = sqlite3.connect("data.sqlite3")
with _ts.conn:
c = _ts.conn.cursor()
c.execute("PRAGMA foreign_keys = ON")
return _ts.conn
need_install = not os.path.isfile("data.sqlite3")
@ -837,18 +858,20 @@ with conn:
_install()
c.execute("PRAGMA user_version")
row = c.fetchone()
if row[0] == 0:
ver = row[0]
c.close()
if ver == 0:
# new schema does not exist yet, migrate from old schema
# NOTE: game stats are NOT migrated to the new schema; the old gamestats table
# will continue to exist to allow queries against it, however given how horribly
# inaccurate the stats on it are, it would be a disservice to copy those inaccurate
# statistics over to the new schema which has the capability of actually being accurate.
_migrate()
elif row[0] < SCHEMA_VERSION:
_upgrade()
c.close()
elif ver < SCHEMA_VERSION:
_upgrade(ver)
del need_install, conn, c
del need_install, conn, c, ver
init_vars()
# vim: set expandtab:sw=4:ts=4:

View File

@ -6,16 +6,19 @@
-- here may end up corresponding to the same actual person (see below).
CREATE TABLE IF NOT EXISTS player (
id INTEGER PRIMARY KEY,
-- What person this player record belongs to
person INTEGER REFERENCES person(id) DEFERRABLE INITIALLY DEFERRED,
-- NickServ account name, or NULL if this player is based on a hostmask
account TEXT,
account TEXT COLLATE NOCASE,
-- Hostmask for the player, if not based on an account (NULL otherwise)
hostmask TEXT,
hostmask TEXT COLLATE NOCASE,
-- If a player entry needs to be retired (for example, an account expired),
-- setting this to 0 allows for that entry to be re-used without corrupting old stats/logs
active BOOLEAN NOT NULL DEFAULT 1
);
CREATE INDEX IF NOT EXISTS player_idx ON player (account, hostmask, active);
CREATE INDEX IF NOT EXISTS person_idx ON player (person);
-- Person tracking; a person can consist of multiple players (for example, someone may have
-- an account player for when they are logged in and 3 hostmask players for when they are
@ -23,7 +26,7 @@ CREATE INDEX IF NOT EXISTS player_idx ON player (account, hostmask, active);
CREATE TABLE IF NOT EXISTS person (
id INTEGER PRIMARY KEY,
-- Primary player for this person
primary_player INTEGER NOT NULL UNIQUE REFERENCES player(id),
primary_player INTEGER NOT NULL UNIQUE REFERENCES player(id) DEFERRABLE INITIALLY DEFERRED,
-- If 1, the bot will notice the player instead of sending privmsgs
notice BOOLEAN NOT NULL DEFAULT 0,
-- If 1, the bot will send simple role notifications to the player
@ -39,24 +42,15 @@ CREATE TABLE IF NOT EXISTS person (
stasis_expires DATETIME
);
-- A person can have multiple attached players, however each player can be attached
-- to only exactly one person
CREATE TABLE IF NOT EXISTS person_player (
person INTEGER NOT NULL REFERENCES person(id),
player INTEGER NOT NULL UNIQUE REFERENCES player(id)
);
CREATE INDEX IF NOT EXISTS person_player_idx ON person_player (person);
-- Sometimes people are bad, this keeps track of that for the purpose of automatically applying
-- various sanctions and viewing the past history of someone. Outside of specifically-marked
-- fields, records are never modified or deleted from this table once inserted.
CREATE TABLE IF NOT EXISTS warning (
id INTEGER PRIMARY KEY,
-- The target (recipient) of the warning
target INTEGER NOT NULL REFERENCES person(id),
target INTEGER NOT NULL REFERENCES person(id) DEFERRABLE INITIALLY DEFERRED,
-- The person who gave out the warning, or NULL if it was automatically generated
sender INTEGER REFERENCES person(id),
sender INTEGER REFERENCES person(id) DEFERRABLE INITIALLY DEFERRED,
-- Number of warning points
amount INTEGER NOT NULL,
-- When the warning was issued ('YYYY-MM-DD HH:MM:SS')
@ -74,21 +68,22 @@ CREATE TABLE IF NOT EXISTS warning (
-- Set to 1 if the warning was rescinded by an admin before it expired
deleted BOOLEAN NOT NULL DEFAULT 0,
-- If the warning was rescinded, this tracks by whom
deleted_by INTEGER REFERENCES person(id),
deleted_by INTEGER REFERENCES person(id) DEFERRABLE INITIALLY DEFERRED,
-- If the warning was rescinded, this tracks when that happened ('YYYY-MM-DD HH:MM:SS')
deleted_on DATETIME
);
CREATE INDEX IF NOT EXISTS warning_idx ON warning (target, deleted, issued);
CREATE INDEX IF NOT EXISTS warning_sender_idx ON warning (target, sender, deleted, issued);
-- In addition to giving warning points, a warning may have specific sanctions attached
-- that apply until the warning expires; for example preventing a user from joining deadchat
-- or denying them access to a particular command (such as !goat).
CREATE TABLE IF NOT EXISTS warning_sanction (
-- The warning this sanction is attached to
warning INTEGER NOT NULL REFERENCES warning(id),
warning INTEGER NOT NULL REFERENCES warning(id) DEFERRABLE INITIALLY DEFERRED,
-- The type of sanction this is
sanction TEXT NOT NULL,
sanction TEXT NOT NULL COLLATE NOCASE,
-- If the sanction type has additional data attached, it is listed here
data TEXT
);
@ -100,7 +95,7 @@ CREATE TABLE IF NOT EXISTS warning_sanction (
CREATE TABLE IF NOT EXISTS game (
id INTEGER PRIMARY KEY,
-- The gamemode played
gamemode TEXT NOT NULL,
gamemode TEXT NOT NULL COLLATE NOCASE,
-- Game options (role reveal, stats type, etc.), stored as JSON string
-- The json1 extension can be loaded into sqlite to allow for easy querying of these values
-- lykos itself does not make use of this field when calculating stats at this time
@ -112,7 +107,7 @@ CREATE TABLE IF NOT EXISTS game (
-- Game size (at game start)
gamesize INTEGER NOT NULL,
-- Winning team (NULL if no winner)
winner TEXT
winner TEXT COLLATE NOCASE
);
CREATE INDEX IF NOT EXISTS game_idx ON game (gamemode, gamesize);
@ -120,8 +115,8 @@ CREATE INDEX IF NOT EXISTS game_idx ON game (gamemode, gamesize);
-- List of people who played in each game
CREATE TABLE IF NOT EXISTS game_player (
id INTEGER PRIMARY KEY,
game INTEGER NOT NULL REFERENCES game(id),
player INTEGER NOT NULL REFERENCES player(id),
game INTEGER NOT NULL REFERENCES game(id) DEFERRABLE INITIALLY DEFERRED,
player INTEGER NOT NULL REFERENCES player(id) DEFERRABLE INITIALLY DEFERRED,
-- 1 if the player has a team win for this game
team_win BOOLEAN NOT NULL,
-- 1 if the player has an individual win for this game
@ -135,9 +130,9 @@ CREATE INDEX IF NOT EXISTS game_player_player_idx ON game_player (player);
-- List of all roles and other special qualities (e.g. lover, entranced, etc.) the player had in game
CREATE TABLE IF NOT EXISTS game_player_role (
game_player INTEGER NOT NULL REFERENCES game_player(id),
game_player INTEGER NOT NULL REFERENCES game_player(id) DEFERRABLE INITIALLY DEFERRED,
-- Name of the role or other quality recorded
role TEXT NOT NULL,
role TEXT NOT NULL COLLATE NOCASE,
-- 1 if role is a special quality instead of an actual role/template name
special BOOLEAN NOT NULL
);
@ -156,9 +151,9 @@ CREATE TABLE IF NOT EXISTS access_template (
-- Access control, owners still need to be specified in botconfig, but everyone else goes here
CREATE TABLE IF NOT EXISTS access (
person INTEGER NOT NULL PRIMARY KEY REFERENCES person(id),
person INTEGER NOT NULL PRIMARY KEY REFERENCES person(id) DEFERRABLE INITIALLY DEFERRED,
-- Template to base this person's access on, or NULL if it is not based on a template
template INTEGER REFERENCES access_template(id),
template INTEGER REFERENCES access_template(id) DEFERRABLE INITIALLY DEFERRED,
-- If template is NULL, this is the list of flags that will be used
-- Has no effect if template is not NULL
flags TEXT

266
src/db/upgrade2.sql Normal file
View File

@ -0,0 +1,266 @@
-- Upgrade script to migrate from schema version 1 to 2
PRAGMA foreign_keys = OFF;
BEGIN EXCLUSIVE TRANSACTION;
CREATE TEMPORARY TABLE mergeq (
oldperson INTEGER,
newperson INTEGER,
active BOOLEAN
);
CREATE TABLE player2 (
id INTEGER PRIMARY KEY,
-- must be nullable so that we can insert new player records
person INTEGER REFERENCES person(id) DEFERRABLE INITIALLY DEFERRED,
account TEXT COLLATE NOCASE,
hostmask TEXT COLLATE NOCASE,
active BOOLEAN NOT NULL DEFAULT 1
);
INSERT INTO player2 (
id,
person,
account,
hostmask,
active
)
SELECT
p.id,
pp.person,
p.account,
p.hostmask,
p.active
FROM player p
JOIN person_player pp
ON pp.player = p.id;
DROP TABLE player;
ALTER TABLE player2 RENAME TO player;
CREATE INDEX player_idx ON player (account, hostmask, active);
CREATE INDEX person_idx ON player (person);
-- Casefold the player table; we may have multiple records
-- with the same account/hostmask that are active
-- in that case, we need to keep track of them to merge
-- them together later on.
INSERT INTO mergeq (oldperson, newperson, active)
SELECT DISTINCT
pp1.person,
MAX(pp2.person),
0
FROM player p1
JOIN player p2
ON (p1.account IS NOT NULL AND p1.account = p2.account)
OR (p1.hostmask IS NOT NULL AND p1.hostmask = p2.hostmask)
JOIN person_player pp1
ON pp1.player = p1.id
JOIN person_player pp2
ON pp2.player = p2.id
WHERE
p1.active = 1
AND p2.active = 1
AND p1.id < p2.id
GROUP BY p1.id, pp1.person;
-- person_player no longer needs to exist; it was moved to a column on player
-- it was already set up as a one-to-many relationship, so a mapping table
-- was not needed (mapping tables are for many-to-many relationships)
DROP TABLE person_player;
-- set FKs on warning and warning_sanction to be deferrable, and make
-- sanction type case-insensitive.
CREATE TABLE warning2 (
id INTEGER PRIMARY KEY,
target INTEGER NOT NULL REFERENCES person(id) DEFERRABLE INITIALLY DEFERRED,
sender INTEGER REFERENCES person(id) DEFERRABLE INITIALLY DEFERRED,
amount INTEGER NOT NULL,
issued DATETIME NOT NULL,
expires DATETIME,
reason TEXT NOT NULL,
notes TEXT,
acknowledged BOOLEAN NOT NULL DEFAULT 0,
deleted BOOLEAN NOT NULL DEFAULT 0,
deleted_by INTEGER REFERENCES person(id) DEFERRABLE INITIALLY DEFERRED,
deleted_on DATETIME
);
INSERT INTO warning2 (
id, target, sender, amount, issued, expires, reason, notes,
acknowledged, deleted, deleted_by, deleted_on
)
SELECT
id, target, sender, amount, issued, expires, reason, notes,
acknowledged, deleted, deleted_by, deleted_on
FROM warning;
DROP TABLE warning;
ALTER TABLE warning2 RENAME TO warning;
CREATE INDEX warning_idx ON warning (target, deleted, issued);
CREATE INDEX warning_sender_idx ON warning (target, sender, deleted, issued);
CREATE TABLE warning_sanction2 (
warning INTEGER NOT NULL REFERENCES warning(id) DEFERRABLE INITIALLY DEFERRED,
sanction TEXT NOT NULL COLLATE NOCASE,
data TEXT
);
INSERT INTO warning_sanction2 (warning, sanction, data)
SELECT warning, sanction, data
FROM warning_sanction;
DROP TABLE warning_sanction;
ALTER TABLE warning_sanction2 RENAME TO warning_sanction;
-- Make game caseless, also modify winner for fool
-- instead of @id, make winner 'fool' and then game_player
-- can be checked to see what fool won (the winning fool gets a team win)
CREATE TABLE game2 (
id INTEGER PRIMARY KEY,
gamemode TEXT NOT NULL COLLATE NOCASE,
options TEXT,
started DATETIME NOT NULL,
finished DATETIME NOT NULL,
gamesize INTEGER NOT NULL,
winner TEXT COLLATE NOCASE
);
INSERT INTO game2 (id, gamemode, options, started, finished, gamesize, winner)
SELECT id, gamemode, options, started, finished, gamesize, winner
FROM game;
DROP TABLE game;
ALTER TABLE game2 RENAME TO game;
CREATE INDEX game_idx ON game (gamemode, gamesize);
CREATE TABLE game_player_role2 (
game_player INTEGER NOT NULL REFERENCES game_player(id) DEFERRABLE INITIALLY DEFERRED,
role TEXT NOT NULL COLLATE NOCASE,
special BOOLEAN NOT NULL
);
INSERT INTO game_player_role2 (game_player, role, special)
SELECT game_player, role, special
FROM game_player_role;
DROP TABLE game_player_role;
ALTER TABLE game_player_role2 RENAME TO game_player_role;
CREATE INDEX game_player_role_idx ON game_player_role (game_player);
UPDATE game_player
SET team_win = 1
WHERE id IN (
SELECT gp.id
FROM game_player gp
JOIN game g
ON g.id = gp.game
JOIN game_player_role gpr
ON gpr.game_player = gp.id
WHERE
gpr.role = 'fool'
AND g.winner = '@' || gp.player
AND gp.indiv_win = 1
);
UPDATE game
SET winner = 'fool'
WHERE SUBSTR(winner, 1, 1) = '@';
-- deferrable FK on access
CREATE TABLE access2 (
person INTEGER NOT NULL PRIMARY KEY REFERENCES person(id) DEFERRABLE INITIALLY DEFERRED,
template INTEGER REFERENCES access_template(id) DEFERRABLE INITIALLY DEFERRED,
flags TEXT
);
INSERT INTO access2 (person, template, flags)
SELECT person, template, flags
FROM access;
DROP TABLE access;
ALTER TABLE access2 RENAME TO access;
-- Merge player/person records from mergeq
-- We merge into the newest record, only thing
-- to carry over from the old are warnings and stasis
-- access entries are NOT carried over if the new
-- person has access (if old is non-null and new is null,
-- then access is migrated). If the user has multiple old
-- access records, one is selected arbitrarily.
-- annoyingly, CTEs are only supported on sqlite 3.8.3+
-- and ubuntu 14.04 ships with 3.8.2. I *really* want to
-- just move over to postgres >_>
CREATE TEMPORARY TABLE u (
player INTEGER,
person INTEGER,
active BOOLEAN
);
INSERT INTO u (player, person, active)
SELECT
p.id,
COALESCE(mergeq.newperson, p.person),
COALESCE(mergeq.active, p.active)
FROM player p
LEFT JOIN mergeq
ON mergeq.oldperson = p.person;
UPDATE player
SET
person = (SELECT u.person FROM u WHERE u.player = player.id),
active = (SELECT u.active FROM u WHERE u.player = player.id);
DROP TABLE u;
INSERT OR IGNORE INTO access (person, template, flags)
SELECT
m.newperson,
a.template,
a.flags
FROM mergeq m
JOIN access a
ON a.person = m.oldperson;
DELETE FROM access
WHERE person IN (SELECT oldperson FROM mergeq);
CREATE TEMPORARY TABLE u (
id INTEGER,
target INTEGER,
sender INTEGER,
deleted_by INTEGER
);
INSERT INTO u (id, target, sender, deleted_by)
SELECT
w.id,
COALESCE(m1.newperson, w.target),
COALESCE(m2.newperson, w.sender),
COALESCE(m3.newperson, w.deleted_by)
FROM warning w
LEFT JOIN mergeq m1
ON m1.oldperson = w.target
LEFT JOIN mergeq m2
ON m2.oldperson = w.sender
LEFT JOIN mergeq m3
ON m3.oldperson = w.deleted_by;
UPDATE warning
SET
target = (SELECT u.target FROM u WHERE u.id = warning.id),
sender = (SELECT u.sender FROM u WHERE u.id = warning.id),
deleted_by = (SELECT u.deleted_by FROM u WHERE u.id = warning.id);
DROP TABLE u;
-- finally, blow off our old person records
DELETE FROM person WHERE id IN (SELECT oldperson FROM mergeq);
DROP TABLE mergeq;
COMMIT;
PRAGMA foreign_keys = ON;

View File

@ -2571,6 +2571,8 @@ def stop_game(cli, winner = "", abort = False, additional_winners = None):
won = True
elif rol == "turncoat" and splr in var.TURNCOATS and var.TURNCOATS[splr][0] != "none":
won = (winner == var.TURNCOATS[splr][0])
elif rol == "fool" and "@" + splr == winner:
won = True
elif winner != "succubi" and splr in var.ENTRANCED:
# entranced players can't win with villager or wolf teams
won = False
@ -2677,6 +2679,11 @@ def stop_game(cli, winner = "", abort = False, additional_winners = None):
if len(pl) > 0:
game_options["roles"][role] = len(pl)
# normalize fool wins; to determine which fool won look for who got a team win for the game
# not plural (unlike other winner values) since only a singular fool wins
if winner.startswith("@"):
winner = "fool"
db.add_game(var.CURRENT_GAMEMODE.name,
len(survived) + len(var.DEAD),
time.strftime("%Y-%m-%d %H:%M:%S", time.gmtime(var.GAME_ID)),