From 062b6fd4d7b88ae334abb9472bbcd08eb6e0a34b Mon Sep 17 00:00:00 2001 From: SilverNexus Date: Sat, 10 Dec 2022 17:53:18 -0500 Subject: [PATCH] Adjust the schema update code to allow for schema updates, and apply the first one. --- python/CFReputation/__init__.py | 22 +++++++++++++----- python/CFReputation/sql/schema.sql | 2 +- python/CFReputation/sql/update_schema_1_2.sql | 23 +++++++++++++++++++ 3 files changed, 40 insertions(+), 7 deletions(-) create mode 100644 python/CFReputation/sql/update_schema_1_2.sql diff --git a/python/CFReputation/__init__.py b/python/CFReputation/__init__.py index 5add0c776..dcab71ad8 100644 --- a/python/CFReputation/__init__.py +++ b/python/CFReputation/__init__.py @@ -7,14 +7,23 @@ def _init_schema(con, version, *schema_files): con.execute("PRAGMA journal_mode=WAL;"); con.execute("PRAGMA synchronous=NORMAL;"); con.execute("CREATE TABLE IF NOT EXISTS schema(version INT);"); - result = con.execute("SELECT version FROM schema").fetchall(); - curr = len(result) + # We will always return something, either a zero or the highest version number. + result = con.execute("SELECT COALESCE(MAX(version), 0) FROM schema").fetchall(); + curr = result[0][0] if curr < version: Crossfire.Log(Crossfire.LogInfo, "Initializing factions schema %d->%d" % (curr, version)) - for f in schema_files: - with open(f) as initfile: + if curr == 0: + # schema.sql is already updated to load in the current schema. + with open(schema_files[0]) as initfile: con.executescript(initfile.read()) + else: + for f in schema_files: + # Compare just the file name + if f.split("/").pop() == f"update_schema_{curr}_{curr+1}.sql": + with open(f) as updfile: + con.executescript(updfile.read()) + curr += 1 con.commit() def _get_sql_path(f): @@ -22,11 +31,12 @@ def _get_sql_path(f): "python/CFReputation/sql", f) def _init_db(): - schema_files = map(_get_sql_path, ["schema.sql"]) + # Schema update files must go in order. + schema_files = map(_get_sql_path, ["schema.sql", "update_schema_1_2.sql"]) init_files = map(_get_sql_path, ["init.sql", "gods.sql"]) db_path = os.path.join(Crossfire.LocalDirectory(), "factions.db") con = sqlite3.connect(db_path) - _init_schema(con, 1, *schema_files) + _init_schema(con, 2, *schema_files) for f in init_files: with open(f) as initfile: con.executescript(initfile.read()) diff --git a/python/CFReputation/sql/schema.sql b/python/CFReputation/sql/schema.sql index 200ba2505..b006c2d03 100644 --- a/python/CFReputation/sql/schema.sql +++ b/python/CFReputation/sql/schema.sql @@ -23,4 +23,4 @@ CREATE TABLE reputations( CONSTRAINT reputation_range CHECK(reputation BETWEEN -1 AND 1) ); -INSERT INTO schema VALUES(1); +INSERT INTO schema VALUES(2); diff --git a/python/CFReputation/sql/update_schema_1_2.sql b/python/CFReputation/sql/update_schema_1_2.sql new file mode 100644 index 000000000..dffeed7fd --- /dev/null +++ b/python/CFReputation/sql/update_schema_1_2.sql @@ -0,0 +1,23 @@ +-- For the update from schema 1 to 2, we add a primary key +-- to the regions table. This prevents duplicate entries being added +-- on every initialization of the reputation code. +-- To keep most configurations functional, we will select the set of distinct +-- table entries into a temporary table, then drop the cluttered table, and +-- rename the tmp table to be the same name as the dropped table. + +CREATE TABLE regions_tmp( + faction TEXT, + region TEXT, -- region name (or 'ALL') this faction controls + influence NUMERIC, + PRIMARY KEY (faction, region), + CONSTRAINT influence_range CHECK(influence BETWEEN 0 AND 1) +); + +INSERT INTO regions_tmp + SELECT DISTINCT faction, region, influence FROM regions; + +DROP TABLE regions; + +ALTER TABLE regions_tmp RENAME TO regions; + +UPDATE schema SET version = 2;