Add Foreign Keys, Primary Keys, and NOT NULL constraints.

master
voussoir 2018-03-18 00:09:08 -07:00
parent 33d506ddaf
commit d383000441
3 changed files with 222 additions and 27 deletions

View File

@ -21,7 +21,7 @@ FILENAME_BADCHARS = '\\/:*?<>|"'
# Note: Setting user_version pragma in init sequence is safe because it only # Note: Setting user_version pragma in init sequence is safe because it only
# happens after the out-of-date check occurs, so no chance of accidentally # happens after the out-of-date check occurs, so no chance of accidentally
# overwriting it. # overwriting it.
DATABASE_VERSION = 10 DATABASE_VERSION = 11
DB_INIT = ''' DB_INIT = '''
PRAGMA cache_size = 10000; PRAGMA cache_size = 10000;
PRAGMA count_changes = OFF; PRAGMA count_changes = OFF;
@ -30,32 +30,33 @@ PRAGMA user_version = {user_version};
---------------------------------------------------------------------------------------------------- ----------------------------------------------------------------------------------------------------
CREATE TABLE IF NOT EXISTS users( CREATE TABLE IF NOT EXISTS users(
id TEXT, id TEXT PRIMARY KEY NOT NULL,
username TEXT COLLATE NOCASE, username TEXT NOT NULL COLLATE NOCASE,
password BLOB, password BLOB NOT NULL,
created INT created INT
); );
CREATE INDEX IF NOT EXISTS index_users_id on users(id); CREATE INDEX IF NOT EXISTS index_users_id on users(id);
CREATE INDEX IF NOT EXISTS index_users_username on users(username COLLATE NOCASE); CREATE INDEX IF NOT EXISTS index_users_username on users(username COLLATE NOCASE);
---------------------------------------------------------------------------------------------------- ----------------------------------------------------------------------------------------------------
CREATE TABLE IF NOT EXISTS albums( CREATE TABLE IF NOT EXISTS albums(
id TEXT, id TEXT PRIMARY KEY NOT NULL,
title TEXT, title TEXT,
description TEXT description TEXT
); );
CREATE INDEX IF NOT EXISTS index_albums_id on albums(id); CREATE INDEX IF NOT EXISTS index_albums_id on albums(id);
---------------------------------------------------------------------------------------------------- ----------------------------------------------------------------------------------------------------
CREATE TABLE IF NOT EXISTS bookmarks( CREATE TABLE IF NOT EXISTS bookmarks(
id TEXT, id TEXT PRIMARY KEY NOT NULL,
title TEXT, title TEXT,
url TEXT, url TEXT,
author_id TEXT author_id TEXT,
FOREIGN KEY(author_id) REFERENCES users(id)
); );
CREATE INDEX IF NOT EXISTS index_bookmarks_id on bookmarks(id); CREATE INDEX IF NOT EXISTS index_bookmarks_id on bookmarks(id);
CREATE INDEX IF NOT EXISTS index_bookmarks_author on bookmarks(author_id); CREATE INDEX IF NOT EXISTS index_bookmarks_author on bookmarks(author_id);
---------------------------------------------------------------------------------------------------- ----------------------------------------------------------------------------------------------------
CREATE TABLE IF NOT EXISTS photos( CREATE TABLE IF NOT EXISTS photos(
id TEXT, id TEXT PRIMARY KEY NOT NULL,
filepath TEXT COLLATE NOCASE, filepath TEXT COLLATE NOCASE,
override_filename TEXT COLLATE NOCASE, override_filename TEXT COLLATE NOCASE,
extension TEXT, extension TEXT,
@ -69,7 +70,8 @@ CREATE TABLE IF NOT EXISTS photos(
thumbnail TEXT, thumbnail TEXT,
tagged_at INT, tagged_at INT,
author_id TEXT, author_id TEXT,
searchhidden INT searchhidden INT,
FOREIGN KEY(author_id) REFERENCES users(id)
); );
CREATE INDEX IF NOT EXISTS index_photos_id on photos(id); CREATE INDEX IF NOT EXISTS index_photos_id on photos(id);
CREATE INDEX IF NOT EXISTS index_photos_filepath on photos(filepath COLLATE NOCASE); CREATE INDEX IF NOT EXISTS index_photos_filepath on photos(filepath COLLATE NOCASE);
@ -81,8 +83,8 @@ CREATE INDEX IF NOT EXISTS index_photos_author_id on photos(author_id);
CREATE INDEX IF NOT EXISTS index_photos_searchhidden on photos(searchhidden); CREATE INDEX IF NOT EXISTS index_photos_searchhidden on photos(searchhidden);
---------------------------------------------------------------------------------------------------- ----------------------------------------------------------------------------------------------------
CREATE TABLE IF NOT EXISTS tags( CREATE TABLE IF NOT EXISTS tags(
id TEXT, id TEXT PRIMARY KEY NOT NULL,
name TEXT, name TEXT NOT NULL,
description TEXT description TEXT
); );
CREATE INDEX IF NOT EXISTS index_tags_id on tags(id); CREATE INDEX IF NOT EXISTS index_tags_id on tags(id);
@ -92,8 +94,9 @@ CREATE INDEX IF NOT EXISTS index_tags_name on tags(name);
---------------------------------------------------------------------------------------------------- ----------------------------------------------------------------------------------------------------
CREATE TABLE IF NOT EXISTS album_associated_directories( CREATE TABLE IF NOT EXISTS album_associated_directories(
albumid TEXT, albumid TEXT NOT NULL,
directory TEXT COLLATE NOCASE directory TEXT NOT NULL COLLATE NOCASE,
FOREIGN KEY(albumid) REFERENCES albums(id)
); );
CREATE INDEX IF NOT EXISTS index_album_associated_directories_albumid on CREATE INDEX IF NOT EXISTS index_album_associated_directories_albumid on
album_associated_directories(albumid); album_associated_directories(albumid);
@ -101,40 +104,49 @@ CREATE INDEX IF NOT EXISTS index_album_associated_directories_directory on
album_associated_directories(directory); album_associated_directories(directory);
---------------------------------------------------------------------------------------------------- ----------------------------------------------------------------------------------------------------
CREATE TABLE IF NOT EXISTS album_group_rel( CREATE TABLE IF NOT EXISTS album_group_rel(
parentid TEXT, parentid TEXT NOT NULL,
memberid TEXT memberid TEXT NOT NULL,
FOREIGN KEY(parentid) REFERENCES albums(id),
FOREIGN KEY(memberid) REFERENCES albums(id)
); );
CREATE INDEX IF NOT EXISTS index_album_group_rel_parentid on album_group_rel(parentid); CREATE INDEX IF NOT EXISTS index_album_group_rel_parentid on album_group_rel(parentid);
CREATE INDEX IF NOT EXISTS index_album_group_rel_memberid on album_group_rel(memberid); CREATE INDEX IF NOT EXISTS index_album_group_rel_memberid on album_group_rel(memberid);
---------------------------------------------------------------------------------------------------- ----------------------------------------------------------------------------------------------------
CREATE TABLE IF NOT EXISTS album_photo_rel( CREATE TABLE IF NOT EXISTS album_photo_rel(
albumid TEXT, albumid TEXT NOT NULL,
photoid TEXT photoid TEXT NOT NULL,
FOREIGN KEY(albumid) REFERENCES albums(id),
FOREIGN KEY(photoid) REFERENCES photos(id)
); );
CREATE INDEX IF NOT EXISTS index_album_photo_rel_albumid on album_photo_rel(albumid); CREATE INDEX IF NOT EXISTS index_album_photo_rel_albumid on album_photo_rel(albumid);
CREATE INDEX IF NOT EXISTS index_album_photo_rel_photoid on album_photo_rel(photoid); CREATE INDEX IF NOT EXISTS index_album_photo_rel_photoid on album_photo_rel(photoid);
---------------------------------------------------------------------------------------------------- ----------------------------------------------------------------------------------------------------
CREATE TABLE IF NOT EXISTS id_numbers( CREATE TABLE IF NOT EXISTS id_numbers(
tab TEXT, tab TEXT NOT NULL,
last_id TEXT last_id TEXT NOT NULL
); );
---------------------------------------------------------------------------------------------------- ----------------------------------------------------------------------------------------------------
CREATE TABLE IF NOT EXISTS photo_tag_rel( CREATE TABLE IF NOT EXISTS photo_tag_rel(
photoid TEXT, photoid TEXT NOT NULL,
tagid TEXT tagid TEXT NOT NULL,
FOREIGN KEY(photoid) REFERENCES photos(id),
FOREIGN KEY(tagid) REFERENCES tags(id)
); );
CREATE INDEX IF NOT EXISTS index_photo_tag_rel_photoid on photo_tag_rel(photoid); CREATE INDEX IF NOT EXISTS index_photo_tag_rel_photoid on photo_tag_rel(photoid);
CREATE INDEX IF NOT EXISTS index_photo_tag_rel_tagid on photo_tag_rel(tagid); CREATE INDEX IF NOT EXISTS index_photo_tag_rel_tagid on photo_tag_rel(tagid);
----------------------------------------------------------------------------------------------------
CREATE TABLE IF NOT EXISTS tag_group_rel( CREATE TABLE IF NOT EXISTS tag_group_rel(
parentid TEXT, parentid TEXT NOT NULL,
memberid TEXT memberid TEXT NOT NULL,
FOREIGN KEY(parentid) REFERENCES tags(id),
FOREIGN KEY(memberid) REFERENCES tags(id)
); );
CREATE INDEX IF NOT EXISTS index_tag_group_rel_parentid on tag_group_rel(parentid); CREATE INDEX IF NOT EXISTS index_tag_group_rel_parentid on tag_group_rel(parentid);
CREATE INDEX IF NOT EXISTS index_tag_group_rel_memberid on tag_group_rel(memberid); CREATE INDEX IF NOT EXISTS index_tag_group_rel_memberid on tag_group_rel(memberid);
---------------------------------------------------------------------------------------------------- ----------------------------------------------------------------------------------------------------
CREATE TABLE IF NOT EXISTS tag_synonyms( CREATE TABLE IF NOT EXISTS tag_synonyms(
name TEXT, name TEXT NOT NULL,
mastername TEXT mastername TEXT NOT NULL
); );
CREATE INDEX IF NOT EXISTS index_tag_synonyms_name on tag_synonyms(name); CREATE INDEX IF NOT EXISTS index_tag_synonyms_name on tag_synonyms(name);
---------------------------------------------------------------------------------------------------- ----------------------------------------------------------------------------------------------------
@ -149,6 +161,7 @@ for statement in DB_INIT.split(';'):
column_names = statement.split('(')[1].rsplit(')', 1)[0] column_names = statement.split('(')[1].rsplit(')', 1)[0]
column_names = column_names.split(',') column_names = column_names.split(',')
column_names = [x.strip().split(' ')[0] for x in column_names] column_names = [x.strip().split(' ')[0] for x in column_names]
column_names = [c for c in column_names if c.lower() != 'foreign']
SQL_COLUMNS[table_name] = column_names SQL_COLUMNS[table_name] = column_names
def _sql_dictify(columns): def _sql_dictify(columns):

View File

@ -5,6 +5,8 @@ import sys
import etiquette import etiquette
import old_inits
def upgrade_1_to_2(photodb): def upgrade_1_to_2(photodb):
''' '''
In this version, a column `tagged_at` was added to the Photos table, to keep In this version, a column `tagged_at` was added to the Photos table, to keep
@ -174,6 +176,57 @@ def upgrade_9_to_10(photodb):
new_thumbnail_path = '.' + new_thumbnail_path.replace(thumbnail_dir, '') new_thumbnail_path = '.' + new_thumbnail_path.replace(thumbnail_dir, '')
cur.execute('UPDATE photos SET thumbnail = ? WHERE id == ?', [new_thumbnail_path, photo.id]) cur.execute('UPDATE photos SET thumbnail = ? WHERE id == ?', [new_thumbnail_path, photo.id])
def upgrade_10_to_11(photodb):
'''
Added Primary keys, Foreign keys, and NOT NULL constraints which cannot be
done in-place and requires the reconstruction of all the affected tables.
'''
tables_to_delete = [
'users',
'albums',
'bookmarks',
'photos',
'tags',
'album_associated_directories',
'album_group_rel',
'album_photo_rel',
'id_numbers',
'photo_tag_rel',
'tag_group_rel',
'tag_synonyms',
]
cur = photodb.sql.cursor()
cur.execute('PRAGMA foreign_keys = OFF')
print('Renaming existing tables.')
for table in tables_to_delete:
statement = 'ALTER TABLE %s RENAME TO %s_old' % (table, table)
cur.execute(statement)
lines = [line.strip() for line in old_inits.V11.splitlines()]
lines = [line for line in lines if not line.startswith('--')]
statements = '\n'.join(lines).split(';')
statements = [x.strip() for x in statements]
create_tables = [x for x in statements if x.lower().startswith('create table')]
create_indices = [x for x in statements if x.lower().startswith('create index')]
print('Recreating tables.')
for statement in create_tables:
cur.execute(statement)
print('Migrating table data.')
for table in tables_to_delete:
statement = 'INSERT INTO %s SELECT * FROM %s_old' % (table, table)
cur.execute(statement)
statement = 'DROP TABLE %s_old' % table
cur.execute(statement)
print('Recreating indices.')
for statement in create_indices:
cur.execute(statement)
cur.execute('PRAGMA foreign_keys = ON')
def upgrade_all(data_directory): def upgrade_all(data_directory):
''' '''
Given the directory containing a phototagger database, apply all of the Given the directory containing a phototagger database, apply all of the
@ -188,11 +241,11 @@ def upgrade_all(data_directory):
needed_version = etiquette.constants.DATABASE_VERSION needed_version = etiquette.constants.DATABASE_VERSION
if current_version == needed_version: if current_version == needed_version:
print('Already up-to-date with version %d.' % needed_version) print('Already up to date with version %d.' % needed_version)
return return
for version_number in range(current_version + 1, needed_version + 1): for version_number in range(current_version + 1, needed_version + 1):
print('Upgrading from %d to %d' % (current_version, version_number)) print('Upgrading from %d to %d.' % (current_version, version_number))
upgrade_function = 'upgrade_%d_to_%d' % (current_version, version_number) upgrade_function = 'upgrade_%d_to_%d' % (current_version, version_number)
upgrade_function = eval(upgrade_function) upgrade_function = eval(upgrade_function)
upgrade_function(photodb) upgrade_function(photodb)

129
utilities/old_inits.py Normal file
View File

@ -0,0 +1,129 @@
V11 = '''
PRAGMA cache_size = 10000;
PRAGMA count_changes = OFF;
PRAGMA foreign_keys = ON;
PRAGMA user_version = 11;
----------------------------------------------------------------------------------------------------
CREATE TABLE IF NOT EXISTS users(
id TEXT PRIMARY KEY NOT NULL,
username TEXT NOT NULL COLLATE NOCASE,
password BLOB NOT NULL,
created INT
);
CREATE INDEX IF NOT EXISTS index_users_id on users(id);
CREATE INDEX IF NOT EXISTS index_users_username on users(username COLLATE NOCASE);
----------------------------------------------------------------------------------------------------
CREATE TABLE IF NOT EXISTS albums(
id TEXT PRIMARY KEY NOT NULL,
title TEXT,
description TEXT
);
CREATE INDEX IF NOT EXISTS index_albums_id on albums(id);
----------------------------------------------------------------------------------------------------
CREATE TABLE IF NOT EXISTS bookmarks(
id TEXT PRIMARY KEY NOT NULL,
title TEXT,
url TEXT,
author_id TEXT,
FOREIGN KEY(author_id) REFERENCES users(id)
);
CREATE INDEX IF NOT EXISTS index_bookmarks_id on bookmarks(id);
CREATE INDEX IF NOT EXISTS index_bookmarks_author on bookmarks(author_id);
----------------------------------------------------------------------------------------------------
CREATE TABLE IF NOT EXISTS photos(
id TEXT PRIMARY KEY NOT NULL,
filepath TEXT COLLATE NOCASE,
override_filename TEXT COLLATE NOCASE,
extension TEXT,
width INT,
height INT,
ratio REAL,
area INT,
duration INT,
bytes INT,
created INT,
thumbnail TEXT,
tagged_at INT,
author_id TEXT,
searchhidden INT,
FOREIGN KEY(author_id) REFERENCES users(id)
);
CREATE INDEX IF NOT EXISTS index_photos_id on photos(id);
CREATE INDEX IF NOT EXISTS index_photos_filepath on photos(filepath COLLATE NOCASE);
CREATE INDEX IF NOT EXISTS index_photos_override_filename on
photos(override_filename COLLATE NOCASE);
CREATE INDEX IF NOT EXISTS index_photos_created on photos(created);
CREATE INDEX IF NOT EXISTS index_photos_extension on photos(extension);
CREATE INDEX IF NOT EXISTS index_photos_author_id on photos(author_id);
CREATE INDEX IF NOT EXISTS index_photos_searchhidden on photos(searchhidden);
----------------------------------------------------------------------------------------------------
CREATE TABLE IF NOT EXISTS tags(
id TEXT PRIMARY KEY NOT NULL,
name TEXT NOT NULL,
description TEXT
);
CREATE INDEX IF NOT EXISTS index_tags_id on tags(id);
CREATE INDEX IF NOT EXISTS index_tags_name on tags(name);
----------------------------------------------------------------------------------------------------
----------------------------------------------------------------------------------------------------
CREATE TABLE IF NOT EXISTS album_associated_directories(
albumid TEXT NOT NULL,
directory TEXT NOT NULL COLLATE NOCASE,
FOREIGN KEY(albumid) REFERENCES albums(id)
);
CREATE INDEX IF NOT EXISTS index_album_associated_directories_albumid on
album_associated_directories(albumid);
CREATE INDEX IF NOT EXISTS index_album_associated_directories_directory on
album_associated_directories(directory);
----------------------------------------------------------------------------------------------------
CREATE TABLE IF NOT EXISTS album_group_rel(
parentid TEXT NOT NULL,
memberid TEXT NOT NULL,
FOREIGN KEY(parentid) REFERENCES albums(id),
FOREIGN KEY(memberid) REFERENCES albums(id)
);
CREATE INDEX IF NOT EXISTS index_album_group_rel_parentid on album_group_rel(parentid);
CREATE INDEX IF NOT EXISTS index_album_group_rel_memberid on album_group_rel(memberid);
----------------------------------------------------------------------------------------------------
CREATE TABLE IF NOT EXISTS album_photo_rel(
albumid TEXT NOT NULL,
photoid TEXT NOT NULL,
FOREIGN KEY(albumid) REFERENCES albums(id),
FOREIGN KEY(photoid) REFERENCES photos(id)
);
CREATE INDEX IF NOT EXISTS index_album_photo_rel_albumid on album_photo_rel(albumid);
CREATE INDEX IF NOT EXISTS index_album_photo_rel_photoid on album_photo_rel(photoid);
----------------------------------------------------------------------------------------------------
CREATE TABLE IF NOT EXISTS id_numbers(
tab TEXT NOT NULL,
last_id TEXT NOT NULL
);
----------------------------------------------------------------------------------------------------
CREATE TABLE IF NOT EXISTS photo_tag_rel(
photoid TEXT NOT NULL,
tagid TEXT NOT NULL,
FOREIGN KEY(photoid) REFERENCES photos(id),
FOREIGN KEY(tagid) REFERENCES tags(id)
);
CREATE INDEX IF NOT EXISTS index_photo_tag_rel_photoid on photo_tag_rel(photoid);
CREATE INDEX IF NOT EXISTS index_photo_tag_rel_tagid on photo_tag_rel(tagid);
----------------------------------------------------------------------------------------------------
CREATE TABLE IF NOT EXISTS tag_group_rel(
parentid TEXT NOT NULL,
memberid TEXT NOT NULL,
FOREIGN KEY(parentid) REFERENCES tags(id),
FOREIGN KEY(memberid) REFERENCES tags(id)
);
CREATE INDEX IF NOT EXISTS index_tag_group_rel_parentid on tag_group_rel(parentid);
CREATE INDEX IF NOT EXISTS index_tag_group_rel_memberid on tag_group_rel(memberid);
----------------------------------------------------------------------------------------------------
CREATE TABLE IF NOT EXISTS tag_synonyms(
name TEXT NOT NULL,
mastername TEXT NOT NULL
);
CREATE INDEX IF NOT EXISTS index_tag_synonyms_name on tag_synonyms(name);
----------------------------------------------------------------------------------------------------
'''