diff --git a/isso/db/__init__.py b/isso/db/__init__.py index d3831867..71b8ef6a 100644 --- a/isso/db/__init__.py +++ b/isso/db/__init__.py @@ -22,7 +22,7 @@ class SQLite3: a trigger for automated orphan removal. """ - MAX_VERSION = 3 + MAX_VERSION = 4 def __init__(self, path, conf): @@ -121,3 +121,39 @@ def first(rv): con.execute('PRAGMA user_version = 3') logger.info("%i rows changed", con.total_changes) + + # "text" field in "comments" became NOT NULL + if self.version == 3: + with sqlite3.connect(self.path) as con: + con.execute("BEGIN TRANSACTION") + con.execute("UPDATE comments SET text = '' WHERE text IS NULL") + logger.info("%i rows changed", con.total_changes) + + # create new table with NOT NULL constraint for "text" field + con.execute('CREATE TABLE IF NOT EXISTS comments_new (' + ' tid REFERENCES threads(id), id INTEGER PRIMARY KEY, parent INTEGER,' + ' created FLOAT NOT NULL, modified FLOAT, mode INTEGER, remote_addr VARCHAR,' + ' text VARCHAR NOT NULL, author VARCHAR, email VARCHAR, website VARCHAR,' + ' likes INTEGER DEFAULT 0, dislikes INTEGER DEFAULT 0, voters BLOB NOT NULL,' + ' notification INTEGER DEFAULT 0);') + + try: + # copy data from old table to new table + con.execute(""" + INSERT INTO comments_new ( + tid, id, parent, created, modified, mode, remote_addr, text, author, email, website, likes, dislikes, voters, notification + ) + SELECT + tid, id, parent, created, modified, mode, remote_addr, text, author, email, website, likes, dislikes, voters, notification + FROM comments + """) + + # swap tables + con.execute("ALTER TABLE comments RENAME TO comments_backup_v3") + con.execute("ALTER TABLE comments_new RENAME TO comments") + + con.execute('PRAGMA user_version = 4') + con.execute("COMMIT") + except sqlite3.Error as e: + con.execute("ROLLBACK") + logger.error("Database migration to version 4 failed: %s", e) diff --git a/isso/tests/test_db.py b/isso/tests/test_db.py index 09860f17..8c4e50d2 100644 --- a/isso/tests/test_db.py +++ b/isso/tests/test_db.py @@ -82,19 +82,19 @@ def test_limit_nested_comments(self): " id INTEGER PRIMARY KEY," " parent INTEGER," " created FLOAT NOT NULL, modified FLOAT," - " text VARCHAR, email VARCHAR, website VARCHAR," + " text VARCHAR, author VARCHAR, email VARCHAR, website VARCHAR," " mode INTEGER," " remote_addr VARCHAR," " likes INTEGER DEFAULT 0," " dislikes INTEGER DEFAULT 0," - " voters BLOB)") + " voters BLOB NOT NULL)") con.execute( "INSERT INTO threads (uri, title) VALUES (?, ?)", ("/", "Test")) for (id, parent) in tree.items(): con.execute("INSERT INTO comments (" - " id, parent, created)" - "VALUEs (?, ?, ?)", (id, parent, id)) + " id, parent, created, voters)" + "VALUEs (?, ?, ?, ?)", (id, parent, id, sqlite3.Binary(b""))) conf = config.new({ "general": { @@ -118,3 +118,58 @@ def test_limit_nested_comments(self): rv = con.execute( "SELECT id, parent FROM comments ORDER BY created").fetchall() self.assertEqual(flattened, rv) + + def test_comment_text_not_null_migration(self): + conf = config.new({ + "general": { + "dbpath": "/dev/null", + "max-age": "1h" + } + }) + + with sqlite3.connect(self.path) as con: + con.execute("PRAGMA user_version = 3") + + con.execute("CREATE TABLE threads (" + " id INTEGER PRIMARY KEY," + " uri VARCHAR UNIQUE," + " title VARCHAR)") + con.execute("CREATE TABLE comments (" + " tid REFERENCES threads(id)," + " id INTEGER PRIMARY KEY," + " parent INTEGER," + " created FLOAT NOT NULL, modified FLOAT," + " text VARCHAR, author VARCHAR, email VARCHAR, website VARCHAR," + " mode INTEGER," + " remote_addr VARCHAR," + " likes INTEGER DEFAULT 0," + " dislikes INTEGER DEFAULT 0," + " voters BLOB NOT NULL)") + + con.execute( + "INSERT INTO threads (uri, title) VALUES (?, ?)", ("/", "Test")) + + con.execute("INSERT INTO comments (id, parent, created, text, voters) VALUES (?, ?, ?, ?, ?)", + (1, None, 1, None, sqlite3.Binary(b""))) + + con.execute("INSERT INTO comments (id, parent, created, text, voters) VALUES (?, ?, ?, ?, ?)", + (2, 1, 2, "foo", sqlite3.Binary(b""))) + + conf = config.new({ + "general": { + "dbpath": "/dev/null", + "max-age": "1h" + } + }) + + db = SQLite3(self.path, conf) + + self.assertEqual(db.version, SQLite3.MAX_VERSION) + + with sqlite3.connect(self.path) as con: + # assert that the "text" field has "NOT NULL" constraint + rv = con.execute("SELECT \"notnull\" FROM pragma_table_info('comments') WHERE name='text'").fetchone() + self.assertEqual(rv, (1,)) + + rv = con.execute("SELECT text FROM comments WHERE id IN (1, 2)").fetchall() + self.assertEqual(rv, [("",), ("foo",)])