From 007ad0e7c4bcd4038536c08e4ae36a74316aae1e Mon Sep 17 00:00:00 2001 From: Kovid Goyal Date: Wed, 27 Apr 2011 10:34:10 -0600 Subject: [PATCH] Avoid running all the schema upgrades when creating a new database by merging them into the base SQL --- resources/metadata_sqlite.sql | 311 +++++++++++++++++++++++++------ src/calibre/library/database2.py | 7 +- src/calibre/utils/resources.py | 3 +- 3 files changed, 264 insertions(+), 57 deletions(-) diff --git a/resources/metadata_sqlite.sql b/resources/metadata_sqlite.sql index 2d95f735e2..9c4f666449 100644 --- a/resources/metadata_sqlite.sql +++ b/resources/metadata_sqlite.sql @@ -7,17 +7,30 @@ CREATE TABLE books ( id INTEGER PRIMARY KEY AUTOINCREMENT, title TEXT NOT NULL DEFAULT 'Unknown' COLLATE NOCASE, sort TEXT COLLATE NOCASE, timestamp TIMESTAMP DEFAULT CURRENT_TIMESTAMP, - uri TEXT, - series_index INTEGER NOT NULL DEFAULT 1, + pubdate TIMESTAMP DEFAULT CURRENT_TIMESTAMP, + series_index REAL NOT NULL DEFAULT 1.0, author_sort TEXT COLLATE NOCASE, isbn TEXT DEFAULT "" COLLATE NOCASE, - path TEXT NOT NULL DEFAULT "" - ); + lccn TEXT DEFAULT "" COLLATE NOCASE, + path TEXT NOT NULL DEFAULT "", + flags INTEGER NOT NULL DEFAULT 1 + , uuid TEXT, has_cover BOOL DEFAULT 0, last_modified TIMESTAMP NOT NULL DEFAULT "2000-01-01 00:00:00+00:00"); CREATE TABLE books_authors_link ( id INTEGER PRIMARY KEY, book INTEGER NOT NULL, author INTEGER NOT NULL, UNIQUE(book, author) ); +CREATE TABLE books_languages_link ( id INTEGER PRIMARY KEY, + book INTEGER NOT NULL, + lang_code INTEGER NOT NULL, + item_order INTEGER NOT NULL DEFAULT 0, + UNIQUE(book, lang_code) + ); +CREATE TABLE books_plugin_data(id INTEGER PRIMARY KEY, + book INTEGER NON NULL, + name TEXT NON NULL, + val TEXT NON NULL, + UNIQUE(book,name)); CREATE TABLE books_publishers_link ( id INTEGER PRIMARY KEY, book INTEGER NOT NULL, publisher INTEGER NOT NULL, @@ -49,11 +62,51 @@ CREATE TABLE conversion_options ( id INTEGER PRIMARY KEY, data BLOB NOT NULL, UNIQUE(format,book) ); +CREATE TABLE custom_columns ( + id INTEGER PRIMARY KEY AUTOINCREMENT, + label TEXT NOT NULL, + name TEXT NOT NULL, + datatype TEXT NOT NULL, + mark_for_delete BOOL DEFAULT 0 NOT NULL, + editable BOOL DEFAULT 1 NOT NULL, + display TEXT DEFAULT "{}" NOT NULL, + is_multiple BOOL DEFAULT 0 NOT NULL, + normalized BOOL NOT NULL, + UNIQUE(label) + ); +CREATE TABLE data ( id INTEGER PRIMARY KEY, + book INTEGER NON NULL, + format TEXT NON NULL COLLATE NOCASE, + uncompressed_size INTEGER NON NULL, + name TEXT NON NULL, + UNIQUE(book, format) +); CREATE TABLE feeds ( id INTEGER PRIMARY KEY, title TEXT NOT NULL, script TEXT NOT NULL, UNIQUE(title) ); +CREATE TABLE identifiers ( id INTEGER PRIMARY KEY, + book INTEGER NON NULL, + type TEXT NON NULL DEFAULT "isbn" COLLATE NOCASE, + val TEXT NON NULL COLLATE NOCASE, + UNIQUE(book, type) + ); +CREATE TABLE languages ( id INTEGER PRIMARY KEY, + lang_code TEXT NON NULL COLLATE NOCASE, + UNIQUE(lang_code) + ); +CREATE TABLE library_id ( id INTEGER PRIMARY KEY, + uuid TEXT NOT NULL, + UNIQUE(uuid) + ); +CREATE TABLE metadata_dirtied(id INTEGER PRIMARY KEY, + book INTEGER NOT NULL, + UNIQUE(book)); +CREATE TABLE preferences(id INTEGER PRIMARY KEY, + key TEXT NON NULL, + val TEXT NON NULL, + UNIQUE(key)); CREATE TABLE publishers ( id INTEGER PRIMARY KEY, name TEXT NOT NULL COLLATE NOCASE, sort TEXT COLLATE NOCASE, @@ -72,34 +125,143 @@ CREATE TABLE tags ( id INTEGER PRIMARY KEY, name TEXT NOT NULL COLLATE NOCASE, UNIQUE (name) ); -CREATE TABLE data ( id INTEGER PRIMARY KEY, - book INTEGER NON NULL, - format TEXT NON NULL COLLATE NOCASE, - uncompressed_size INTEGER NON NULL, - name TEXT NON NULL, - UNIQUE(book, format) -); - CREATE VIEW meta AS - SELECT id, title, - (SELECT concat(name) FROM authors WHERE authors.id IN (SELECT author from books_authors_link WHERE book=books.id)) authors, - (SELECT name FROM publishers WHERE publishers.id IN (SELECT publisher from books_publishers_link WHERE book=books.id)) publisher, - (SELECT rating FROM ratings WHERE ratings.id IN (SELECT rating from books_ratings_link WHERE book=books.id)) rating, - timestamp, - (SELECT MAX(uncompressed_size) FROM data WHERE book=books.id) size, - (SELECT concat(name) FROM tags WHERE tags.id IN (SELECT tag from books_tags_link WHERE book=books.id)) tags, - (SELECT text FROM comments WHERE book=books.id) comments, - (SELECT name FROM series WHERE series.id IN (SELECT series FROM books_series_link WHERE book=books.id)) series, - series_index, - sort, - author_sort, - (SELECT concat(format) FROM data WHERE data.book=books.id) formats, - isbn - FROM books; + SELECT id, title, + (SELECT sortconcat(bal.id, name) FROM books_authors_link AS bal JOIN authors ON(author = authors.id) WHERE book = books.id) authors, + (SELECT name FROM publishers WHERE publishers.id IN (SELECT publisher from books_publishers_link WHERE book=books.id)) publisher, + (SELECT rating FROM ratings WHERE ratings.id IN (SELECT rating from books_ratings_link WHERE book=books.id)) rating, + timestamp, + (SELECT MAX(uncompressed_size) FROM data WHERE book=books.id) size, + (SELECT concat(name) FROM tags WHERE tags.id IN (SELECT tag from books_tags_link WHERE book=books.id)) tags, + (SELECT text FROM comments WHERE book=books.id) comments, + (SELECT name FROM series WHERE series.id IN (SELECT series FROM books_series_link WHERE book=books.id)) series, + series_index, + sort, + author_sort, + (SELECT concat(format) FROM data WHERE data.book=books.id) formats, + isbn, + path, + lccn, + pubdate, + flags, + uuid + FROM books; +CREATE VIEW tag_browser_authors AS SELECT + id, + name, + (SELECT COUNT(id) FROM books_authors_link WHERE author=authors.id) count, + (SELECT AVG(ratings.rating) + FROM books_authors_link AS tl, books_ratings_link AS bl, ratings + WHERE tl.author=authors.id AND bl.book=tl.book AND + ratings.id = bl.rating AND ratings.rating <> 0) avg_rating, + sort AS sort + FROM authors; +CREATE VIEW tag_browser_filtered_authors AS SELECT + id, + name, + (SELECT COUNT(books_authors_link.id) FROM books_authors_link WHERE + author=authors.id AND books_list_filter(book)) count, + (SELECT AVG(ratings.rating) + FROM books_authors_link AS tl, books_ratings_link AS bl, ratings + WHERE tl.author=authors.id AND bl.book=tl.book AND + ratings.id = bl.rating AND ratings.rating <> 0 AND + books_list_filter(bl.book)) avg_rating, + sort AS sort + FROM authors; +CREATE VIEW tag_browser_filtered_publishers AS SELECT + id, + name, + (SELECT COUNT(books_publishers_link.id) FROM books_publishers_link WHERE + publisher=publishers.id AND books_list_filter(book)) count, + (SELECT AVG(ratings.rating) + FROM books_publishers_link AS tl, books_ratings_link AS bl, ratings + WHERE tl.publisher=publishers.id AND bl.book=tl.book AND + ratings.id = bl.rating AND ratings.rating <> 0 AND + books_list_filter(bl.book)) avg_rating, + name AS sort + FROM publishers; +CREATE VIEW tag_browser_filtered_ratings AS SELECT + id, + rating, + (SELECT COUNT(books_ratings_link.id) FROM books_ratings_link WHERE + rating=ratings.id AND books_list_filter(book)) count, + (SELECT AVG(ratings.rating) + FROM books_ratings_link AS tl, books_ratings_link AS bl, ratings + WHERE tl.rating=ratings.id AND bl.book=tl.book AND + ratings.id = bl.rating AND ratings.rating <> 0 AND + books_list_filter(bl.book)) avg_rating, + rating AS sort + FROM ratings; +CREATE VIEW tag_browser_filtered_series AS SELECT + id, + name, + (SELECT COUNT(books_series_link.id) FROM books_series_link WHERE + series=series.id AND books_list_filter(book)) count, + (SELECT AVG(ratings.rating) + FROM books_series_link AS tl, books_ratings_link AS bl, ratings + WHERE tl.series=series.id AND bl.book=tl.book AND + ratings.id = bl.rating AND ratings.rating <> 0 AND + books_list_filter(bl.book)) avg_rating, + (title_sort(name)) AS sort + FROM series; +CREATE VIEW tag_browser_filtered_tags AS SELECT + id, + name, + (SELECT COUNT(books_tags_link.id) FROM books_tags_link WHERE + tag=tags.id AND books_list_filter(book)) count, + (SELECT AVG(ratings.rating) + FROM books_tags_link AS tl, books_ratings_link AS bl, ratings + WHERE tl.tag=tags.id AND bl.book=tl.book AND + ratings.id = bl.rating AND ratings.rating <> 0 AND + books_list_filter(bl.book)) avg_rating, + name AS sort + FROM tags; +CREATE VIEW tag_browser_publishers AS SELECT + id, + name, + (SELECT COUNT(id) FROM books_publishers_link WHERE publisher=publishers.id) count, + (SELECT AVG(ratings.rating) + FROM books_publishers_link AS tl, books_ratings_link AS bl, ratings + WHERE tl.publisher=publishers.id AND bl.book=tl.book AND + ratings.id = bl.rating AND ratings.rating <> 0) avg_rating, + name AS sort + FROM publishers; +CREATE VIEW tag_browser_ratings AS SELECT + id, + rating, + (SELECT COUNT(id) FROM books_ratings_link WHERE rating=ratings.id) count, + (SELECT AVG(ratings.rating) + FROM books_ratings_link AS tl, books_ratings_link AS bl, ratings + WHERE tl.rating=ratings.id AND bl.book=tl.book AND + ratings.id = bl.rating AND ratings.rating <> 0) avg_rating, + rating AS sort + FROM ratings; +CREATE VIEW tag_browser_series AS SELECT + id, + name, + (SELECT COUNT(id) FROM books_series_link WHERE series=series.id) count, + (SELECT AVG(ratings.rating) + FROM books_series_link AS tl, books_ratings_link AS bl, ratings + WHERE tl.series=series.id AND bl.book=tl.book AND + ratings.id = bl.rating AND ratings.rating <> 0) avg_rating, + (title_sort(name)) AS sort + FROM series; +CREATE VIEW tag_browser_tags AS SELECT + id, + name, + (SELECT COUNT(id) FROM books_tags_link WHERE tag=tags.id) count, + (SELECT AVG(ratings.rating) + FROM books_tags_link AS tl, books_ratings_link AS bl, ratings + WHERE tl.tag=tags.id AND bl.book=tl.book AND + ratings.id = bl.rating AND ratings.rating <> 0) avg_rating, + name AS sort + FROM tags; CREATE INDEX authors_idx ON books (author_sort COLLATE NOCASE); CREATE INDEX books_authors_link_aidx ON books_authors_link (author); CREATE INDEX books_authors_link_bidx ON books_authors_link (book); CREATE INDEX books_idx ON books (sort COLLATE NOCASE); +CREATE INDEX books_languages_link_aidx ON books_languages_link (lang_code); +CREATE INDEX books_languages_link_bidx ON books_languages_link (book); CREATE INDEX books_publishers_link_aidx ON books_publishers_link (publisher); CREATE INDEX books_publishers_link_bidx ON books_publishers_link (book); CREATE INDEX books_ratings_link_aidx ON books_ratings_link (rating); @@ -111,32 +273,38 @@ CREATE INDEX books_tags_link_bidx ON books_tags_link (book); CREATE INDEX comments_idx ON comments (book); CREATE INDEX conversion_options_idx_a ON conversion_options (format COLLATE NOCASE); CREATE INDEX conversion_options_idx_b ON conversion_options (book); +CREATE INDEX custom_columns_idx ON custom_columns (label); CREATE INDEX data_idx ON data (book); +CREATE INDEX formats_idx ON data (format); +CREATE INDEX languages_idx ON languages (lang_code COLLATE NOCASE); CREATE INDEX publishers_idx ON publishers (name COLLATE NOCASE); -CREATE INDEX series_idx ON series (sort COLLATE NOCASE); +CREATE INDEX series_idx ON series (name COLLATE NOCASE); CREATE INDEX tags_idx ON tags (name COLLATE NOCASE); CREATE TRIGGER books_delete_trg - AFTER DELETE ON books - BEGIN - DELETE FROM books_authors_link WHERE book=OLD.id; - DELETE FROM books_publishers_link WHERE book=OLD.id; - DELETE FROM books_ratings_link WHERE book=OLD.id; - DELETE FROM books_series_link WHERE book=OLD.id; - DELETE FROM books_tags_link WHERE book=OLD.id; - DELETE FROM data WHERE book=OLD.id; - DELETE FROM comments WHERE book=OLD.id; - DELETE FROM conversion_options WHERE book=OLD.id; + AFTER DELETE ON books + BEGIN + DELETE FROM books_authors_link WHERE book=OLD.id; + DELETE FROM books_publishers_link WHERE book=OLD.id; + DELETE FROM books_ratings_link WHERE book=OLD.id; + DELETE FROM books_series_link WHERE book=OLD.id; + DELETE FROM books_tags_link WHERE book=OLD.id; + DELETE FROM books_languages_link WHERE book=OLD.id; + DELETE FROM data WHERE book=OLD.id; + DELETE FROM comments WHERE book=OLD.id; + DELETE FROM conversion_options WHERE book=OLD.id; + DELETE FROM books_plugin_data WHERE book=OLD.id; + DELETE FROM identifiers WHERE book=OLD.id; END; -CREATE TRIGGER books_insert_trg - AFTER INSERT ON books +CREATE TRIGGER books_insert_trg AFTER INSERT ON books BEGIN - UPDATE books SET sort=title_sort(NEW.title) WHERE id=NEW.id; + UPDATE books SET sort=title_sort(NEW.title),uuid=uuid4() WHERE id=NEW.id; END; CREATE TRIGGER books_update_trg - AFTER UPDATE ON books - BEGIN - UPDATE books SET sort=title_sort(NEW.title) WHERE id=NEW.id; - END; + AFTER UPDATE ON books + BEGIN + UPDATE books SET sort=title_sort(NEW.title) + WHERE id=NEW.id AND OLD.title <> NEW.title; + END; CREATE TRIGGER fkc_comments_insert BEFORE INSERT ON comments BEGIN @@ -169,23 +337,41 @@ CREATE TRIGGER fkc_data_update THEN RAISE(ABORT, 'Foreign key violation: book not in books') END; END; -CREATE TRIGGER fkc_delete_books_authors_link +CREATE TRIGGER fkc_delete_on_authors BEFORE DELETE ON authors BEGIN SELECT CASE - WHEN (SELECT COUNT(id) FROM books_authors_link WHERE book=OLD.book) > 0 - THEN RAISE(ABORT, 'Foreign key violation: author is still referenced') + WHEN (SELECT COUNT(id) FROM books_authors_link WHERE author=OLD.id) > 0 + THEN RAISE(ABORT, 'Foreign key violation: authors is still referenced') END; END; -CREATE TRIGGER fkc_delete_books_publishers_link +CREATE TRIGGER fkc_delete_on_languages + BEFORE DELETE ON languages + BEGIN + SELECT CASE + WHEN (SELECT COUNT(id) FROM books_languages_link WHERE lang_code=OLD.id) > 0 + THEN RAISE(ABORT, 'Foreign key violation: language is still referenced') + END; + END; +CREATE TRIGGER fkc_delete_on_languages_link + BEFORE INSERT ON books_languages_link + BEGIN + SELECT CASE + WHEN (SELECT id from books WHERE id=NEW.book) IS NULL + THEN RAISE(ABORT, 'Foreign key violation: book not in books') + WHEN (SELECT id from languages WHERE id=NEW.lang_code) IS NULL + THEN RAISE(ABORT, 'Foreign key violation: lang_code not in languages') + END; + END; +CREATE TRIGGER fkc_delete_on_publishers BEFORE DELETE ON publishers BEGIN SELECT CASE - WHEN (SELECT COUNT(id) FROM books_publishers_link WHERE book=OLD.book) > 0 - THEN RAISE(ABORT, 'Foreign key violation: publisher is still referenced') + WHEN (SELECT COUNT(id) FROM books_publishers_link WHERE publisher=OLD.id) > 0 + THEN RAISE(ABORT, 'Foreign key violation: publishers is still referenced') END; END; -CREATE TRIGGER fkc_delete_books_series_link +CREATE TRIGGER fkc_delete_on_series BEFORE DELETE ON series BEGIN SELECT CASE @@ -193,12 +379,12 @@ CREATE TRIGGER fkc_delete_books_series_link THEN RAISE(ABORT, 'Foreign key violation: series is still referenced') END; END; -CREATE TRIGGER fkc_delete_books_tags_link +CREATE TRIGGER fkc_delete_on_tags BEFORE DELETE ON tags BEGIN SELECT CASE WHEN (SELECT COUNT(id) FROM books_tags_link WHERE tag=OLD.id) > 0 - THEN RAISE(ABORT, 'Foreign key violation: tag is still referenced') + THEN RAISE(ABORT, 'Foreign key violation: tags is still referenced') END; END; CREATE TRIGGER fkc_insert_books_authors_link @@ -267,6 +453,22 @@ CREATE TRIGGER fkc_update_books_authors_link_b THEN RAISE(ABORT, 'Foreign key violation: author not in authors') END; END; +CREATE TRIGGER fkc_update_books_languages_link_a + BEFORE UPDATE OF book ON books_languages_link + BEGIN + SELECT CASE + WHEN (SELECT id from books WHERE id=NEW.book) IS NULL + THEN RAISE(ABORT, 'Foreign key violation: book not in books') + END; + END; +CREATE TRIGGER fkc_update_books_languages_link_b + BEFORE UPDATE OF lang_code ON books_languages_link + BEGIN + SELECT CASE + WHEN (SELECT id from languages WHERE id=NEW.lang_code) IS NULL + THEN RAISE(ABORT, 'Foreign key violation: lang_code not in languages') + END; + END; CREATE TRIGGER fkc_update_books_publishers_link_a BEFORE UPDATE OF book ON books_publishers_link BEGIN @@ -341,3 +543,4 @@ CREATE TRIGGER series_update_trg BEGIN UPDATE series SET sort=NEW.name WHERE id=NEW.id; END; +pragma user_version=20; diff --git a/src/calibre/library/database2.py b/src/calibre/library/database2.py index 3702de45c5..9d58ae4456 100644 --- a/src/calibre/library/database2.py +++ b/src/calibre/library/database2.py @@ -464,9 +464,12 @@ class LibraryDatabase2(LibraryDatabase, SchemaUpgrade, CustomColumns): self.refresh_ondevice = None def initialize_database(self): - metadata_sqlite = open(P('metadata_sqlite.sql'), 'rb').read() + metadata_sqlite = P('metadata_sqlite.sql', data=True, + allow_user_override=False).decode('utf-8') self.conn.executescript(metadata_sqlite) - self.user_version = 1 + self.conn.commit() + if self.user_version == 0: + self.user_version = 1 def last_modified(self): ''' Return last modified time as a UTC datetime object''' diff --git a/src/calibre/utils/resources.py b/src/calibre/utils/resources.py index 97c14926e4..00777973bb 100644 --- a/src/calibre/utils/resources.py +++ b/src/calibre/utils/resources.py @@ -65,7 +65,8 @@ _resolver = PathResolver() def get_path(path, data=False, allow_user_override=True): fpath = _resolver(path, allow_user_override=allow_user_override) if data: - return open(fpath, 'rb').read() + with open(fpath, 'rb') as f: + return f.read() return fpath def get_image_path(path, data=False, allow_user_override=True):