diff --git a/unwind/db.py b/unwind/db.py index 5cb72e5..176db9b 100644 --- a/unwind/db.py +++ b/unwind/db.py @@ -23,7 +23,7 @@ async def open_connection_pool() -> None: db = shared_connection() await db.connect() - await init_db(db) + await apply_db_patches(db) async def close_connection_pool() -> None: @@ -42,6 +42,81 @@ async def close_connection_pool() -> None: await db.disconnect() +async def _create_patch_db(db): + query = """ + CREATE TABLE IF NOT EXISTS db_patches ( + id INTEGER PRIMARY KEY, + current TEXT + ) + """ + await db.execute(query) + + +async def current_patch_level(db) -> str: + await _create_patch_db(db) + + query = "SELECT current FROM db_patches" + current = await db.fetch_val(query) + return current or "" + + +async def set_current_patch_level(db, current: str): + await _create_patch_db(db) + + query = """ + INSERT INTO db_patches VALUES (1, :current) + ON CONFLICT DO UPDATE SET current=excluded.current + """ + await db.execute(query, values={"current": current}) + + +db_patches_dir = Path(__file__).parent / "sql" + + +async def apply_db_patches(db: Database): + """Apply all remaining patches to the database. + + Beware that patches will be applied in lexicographical order, + i.e. "10" comes before "9". + + The current patch state is recorded in the DB itself. + + Please note that every SQL statement in a patch file MUST be terminated + using two consecutive semi-colons (;). + Failing to do so will result in an error. + """ + applied_lvl = await current_patch_level(db) + + did_patch = False + + for patchfile in sorted(db_patches_dir.glob("*.sql"), key=lambda p: p.stem): + patch_lvl = patchfile.stem + if patch_lvl <= applied_lvl: + continue + + log.info("Applying patch: %s", patch_lvl) + + sql = patchfile.read_text() + queries = sql.split(";;") + if len(queries) < 2: + log.error( + "Patch file is missing statement terminator (`;;'): %s", patchfile + ) + raise RuntimeError("No statement found.") + + async with db.transaction(): + + for query in queries: + await db.execute(query) + + await set_current_patch_level(db, patch_lvl) + + did_patch = True + + if did_patch: + await db.execute("vacuum") + + def shared_connection() -> Database: global _shared_connection @@ -52,13 +127,6 @@ def shared_connection() -> Database: return _shared_connection -async def init_db(db): - sql = Path(__file__).with_name("init.sql").read_text() - async with db.transaction(): - for stmt in sql.split(";;"): - await db.execute(query=stmt) - - async def add(item): # Support late initializing of `id` (used for optimization). if hasattr(item, "id") and getattr(item, "id") is None: diff --git a/unwind/init.sql b/unwind/sql/00000000-init-0.sql similarity index 69% rename from unwind/init.sql rename to unwind/sql/00000000-init-0.sql index eea5530..d0bd446 100644 --- a/unwind/init.sql +++ b/unwind/sql/00000000-init-0.sql @@ -1,32 +1,31 @@ PRAGMA foreign_keys = ON;; CREATE TABLE IF NOT EXISTS users ( - id TEXT PRIMARY KEY NOT NULL, + id TEXT NOT NULL PRIMARY KEY, imdb_id TEXT NOT NULL UNIQUE, name TEXT NOT NULL );; CREATE TABLE IF NOT EXISTS movies ( - id TEXT PRIMARY KEY NOT NULL, + id TEXT NOT NULL PRIMARY KEY, title TEXT NOT NULL, - original_title TEXT, - release_year INTEGER NOT NULL, + release_year NUMBER NOT NULL, media_type TEXT NOT NULL, imdb_id TEXT NOT NULL UNIQUE, - score INTEGER, - runtime INTEGER, + score NUMBER NOT NULL, + runtime NUMBER, genres TEXT NOT NULL, updated TEXT NOT NULL );; CREATE TABLE IF NOT EXISTS ratings ( - id TEXT PRIMARY KEY NOT NULL, + id TEXT NOT NULL PRIMARY KEY, movie_id TEXT NOT NULL, user_id TEXT NOT NULL, - score INTEGER NOT NULL, + score NUMBER NOT NULL, rating_date TEXT NOT NULL, - favorite BOOL, - finished BOOL, + favorite NUMBER, + finished NUMBER, FOREIGN KEY(movie_id) REFERENCES movies(id), FOREIGN KEY(user_id) REFERENCES users(id) );; diff --git a/unwind/sql/00000000-init-1.sql b/unwind/sql/00000000-init-1.sql new file mode 100644 index 0000000..85d40a6 --- /dev/null +++ b/unwind/sql/00000000-init-1.sql @@ -0,0 +1,40 @@ +-- add original_title to movies table + +-- see https://www.sqlite.org/lang_altertable.html#caution +-- 1. Create new table +-- 2. Copy data +-- 3. Drop old table +-- 4. Rename new into old + +CREATE TABLE _migrate_movies ( + id TEXT NOT NULL PRIMARY KEY, + title TEXT NOT NULL, + original_title TEXT, + release_year NUMBER NOT NULL, + media_type TEXT NOT NULL, + imdb_id TEXT NOT NULL UNIQUE, + score NUMBER, + runtime NUMBER, + genres TEXT NOT NULL, + updated TEXT NOT NULL +);; + +INSERT INTO _migrate_movies +SELECT + id, + title, + NULL, + release_year, + media_type, + imdb_id, + score, + runtime, + genres, + updated +FROM movies +WHERE true;; + +DROP TABLE movies;; + +ALTER TABLE _migrate_movies +RENAME TO movies;; diff --git a/unwind/sql/00000000-init-2.sql b/unwind/sql/00000000-init-2.sql new file mode 100644 index 0000000..68fad70 --- /dev/null +++ b/unwind/sql/00000000-init-2.sql @@ -0,0 +1,46 @@ +-- only set original_title if it differs from title, +-- and normalize media_type with an extra table. + +CREATE TABLE mediatypes ( + id INTEGER PRIMARY KEY NOT NULL, + name TEXT NOT NULL UNIQUE +);; + +INSERT INTO mediatypes (name) +SELECT DISTINCT media_type +FROM movies +WHERE true;; + +CREATE TABLE _migrate_movies ( + id TEXT PRIMARY KEY NOT NULL, + title TEXT NOT NULL, + original_title TEXT, + release_year INTEGER NOT NULL, + media_type_id INTEGER NOT NULL, + imdb_id TEXT NOT NULL UNIQUE, + score INTEGER, + runtime INTEGER, + genres TEXT NOT NULL, + updated TEXT NOT NULL, + FOREIGN KEY(media_type_id) REFERENCES mediatypes(id) +);; + +INSERT INTO _migrate_movies +SELECT + id, + title, + (CASE WHEN original_title=title THEN NULL ELSE original_title END), + release_year, + (SELECT id FROM mediatypes WHERE name=media_type) AS media_type_id, + imdb_id, + score, + runtime, + genres, + updated +FROM movies +WHERE true;; + +DROP TABLE movies;; + +ALTER TABLE _migrate_movies +RENAME TO movies;; diff --git a/unwind/sql/00000000-init-3.sql b/unwind/sql/00000000-init-3.sql new file mode 100644 index 0000000..98380c7 --- /dev/null +++ b/unwind/sql/00000000-init-3.sql @@ -0,0 +1,62 @@ +-- add convenient view for movies + +CREATE VIEW IF NOT EXISTS movies_view +AS SELECT + movies.id, + movies.title, + movies.original_title, + movies.release_year, + mediatypes.name AS media_type, + movies.imdb_id, + movies.score, + movies.runtime, + movies.genres, + movies.updated +FROM movies +JOIN mediatypes ON mediatypes.id=movies.media_type_id;; + +CREATE TRIGGER IF NOT EXISTS insert_movies_view + INSTEAD OF INSERT + ON movies_view +BEGIN + INSERT INTO movies ( + id, + title, + original_title, + release_year, + media_type_id, + imdb_id, + score, + runtime, + genres, + updated + ) VALUES ( + NEW.id, + NEW.title, + NEW.original_title, + NEW.release_year, + (SELECT id FROM mediatypes WHERE name=NEW.media_type), + NEW.imdb_id, + NEW.score, + NEW.runtime, + NEW.genres, + NEW.updated + ); +END;; + +CREATE TRIGGER IF NOT EXISTS update_movies_view + INSTEAD OF UPDATE OF media_type + ON movies_view +BEGIN + UPDATE movies + SET media_type_id=(SELECT id FROM mediatypes WHERE name=NEW.media_type) + WHERE id=OLD.id; +END;; + +CREATE TRIGGER IF NOT EXISTS delete_movies_view + INSTEAD OF DELETE + ON movies_view +BEGIN + DELETE FROM movies + WHERE movies.id=OLD.id; +END;; diff --git a/unwind/sql/00000000-init-4.sql b/unwind/sql/00000000-init-4.sql new file mode 100644 index 0000000..4d7590e --- /dev/null +++ b/unwind/sql/00000000-init-4.sql @@ -0,0 +1,37 @@ +-- denormalize movie media_type + +CREATE TABLE _migrate_movies ( + id TEXT PRIMARY KEY NOT NULL, + title TEXT NOT NULL, + original_title TEXT, + release_year INTEGER NOT NULL, + media_type TEXT NOT NULL, + imdb_id TEXT NOT NULL UNIQUE, + score INTEGER, + runtime INTEGER, + genres TEXT NOT NULL, + updated TEXT NOT NULL +);; + +INSERT INTO _migrate_movies +SELECT + id, + title, + original_title, + release_year, + (SELECT name FROM mediatypes WHERE id=media_type_id) AS media_type, + imdb_id, + score, + runtime, + genres, + updated +FROM movies +WHERE true;; + +DROP TABLE movies;; + +ALTER TABLE _migrate_movies +RENAME TO movies;; + +DROP VIEW movies_view;; +DROP TABLE mediatypes;; diff --git a/unwind/sql/00000001-fix-db.sql.disabled b/unwind/sql/00000001-fix-db.sql.disabled new file mode 100644 index 0000000..e6376a8 --- /dev/null +++ b/unwind/sql/00000001-fix-db.sql.disabled @@ -0,0 +1,2 @@ +-- see the commit of this file for details. +;;