Separated schema into two files, system.sql and user.sql -- the former contains tables that can be wiped and reinitialized at any time *as long as ids are kept the same* (like scrapers.sql), whereas the latter contains user data that has to be migrated from one version to the other with transition steps

This should make development much easier, as we can, for example, add 80 item types without having to write transition steps

Pretty sure this won't delete anyone's data. Might want to test that theory, though.
This commit is contained in:
Dan Stillman 2006-09-10 20:08:59 +00:00
parent 3dfca25879
commit 14e3b05ca4
3 changed files with 262 additions and 263 deletions

View file

@ -11,35 +11,51 @@ Scholar.Schema = new function(){
* Checks if the DB schema exists and is up-to-date, updating if necessary
*/
function updateSchema(){
var dbVersion = _getDBVersion();
var schemaVersion = _getSchemaSQLVersion();
if (dbVersion == schemaVersion){
if (SCHOLAR_CONFIG['DB_REBUILD']){
if (confirm('Erase all data and recreate database from schema?')){
_initializeSchema();
return;
}
}
_updateScrapersLocal();
return;
}
// If DB version is less than schema file, create or update
else if (dbVersion < schemaVersion){
if (!dbVersion){
Scholar.debug('Database does not exist -- creating\n');
if (SCHOLAR_CONFIG['DB_REBUILD']){
if (confirm('Erase all user data and recreate database from schema?')){
_initializeSchema();
return;
}
_migrateSchema(dbVersion);
_updateScrapersLocal();
}
var dbVersion = _getDBVersion('user');
// 'schema' check is for old (<= 1.0b1) schema system
if (!dbVersion && !_getDBVersion('schema')){
Scholar.debug('Database does not exist -- creating\n');
_initializeSchema();
return;
}
else {
throw("Scholar DB version is newer than schema version");
// Old schema system
if (!dbVersion){
dbVersion = 0;
}
var schemaVersion = _getSchemaSQLVersion('user');
if (dbVersion > schemaVersion){
throw("Zotero user DB version is newer than SQL file");
}
Scholar.DB.beginTransaction();
try {
// If user DB version is less than schema file, create or update
if (dbVersion < schemaVersion){
_migrateUserSchema(dbVersion);
}
_updateSchema('system');
_updateSchema('scrapers');
Scholar.DB.commitTransaction();
}
catch(e){
Scholar.debug(e);
Scholar.DB.rollbackTransaction();
throw(e);
}
return;
}
@ -126,20 +142,8 @@ Scholar.Schema = new function(){
}
if (Scholar.DB.tableExists('version')){
try {
var dbVersion = Scholar.DB.valueQuery("SELECT version FROM "
+ "version WHERE schema='" + schema + "'");
}
// DEBUG: this is temporary to handle version table schema change
catch(e){
if (e=='no such column: schema'){
Scholar.debug(e, 1);
return false;
}
// If some other problem, bail
throw(e);
}
var dbVersion = Scholar.DB.valueQuery("SELECT version FROM "
+ "version WHERE schema='" + schema + "'");
_dbVersions[schema] = dbVersion;
return dbVersion;
}
@ -151,9 +155,8 @@ Scholar.Schema = new function(){
* Retrieve the version from the top line of the schema SQL file
*/
function _getSchemaSQLVersion(schema){
// Default to schema.sql
if (!schema){
schema = 'schema';
throw ('Schema type not provided to _getSchemaSQLVersion()');
}
var schemaFile = schema + '.sql';
@ -189,12 +192,11 @@ Scholar.Schema = new function(){
/*
* Load in SQL schema
*
* Returns an _array_ of SQL statements for feeding into query()
* Returns the contents of an SQL file for feeding into query()
*/
function _getSchemaSQL(schema){
// Default to schema.sql
if (!schema){
schema = 'schema';
throw ('Schema type not provided to _getSchemaSQL()');
}
var schemaFile = schema + '.sql';
@ -234,18 +236,21 @@ Scholar.Schema = new function(){
* Create new DB schema
*/
function _initializeSchema(){
Scholar.DB.beginTransaction();
try {
Scholar.DB.beginTransaction();
Scholar.DB.query(_getSchemaSQL());
_updateDBVersion('schema', _getSchemaSQLVersion());
Scholar.DB.query(_getSchemaSQL('user'));
_updateDBVersion('user', _getSchemaSQLVersion('user'));
Scholar.DB.query(_getSchemaSQL('system'));
_updateDBVersion('system', _getSchemaSQLVersion('system'));
Scholar.DB.query(_getSchemaSQL('scrapers'));
_updateDBVersion('scrapers', _getSchemaSQLVersion('scrapers'));
Scholar.DB.commitTransaction();
}
catch(e){
Scholar.debug(e, 1);
alert('Error initializing Scholar database'); // TODO: localize
Scholar.DB.rollbackTransaction();
alert('Error initializing Zotero database'); // TODO: localize
throw(e);
}
}
@ -260,25 +265,30 @@ Scholar.Schema = new function(){
}
/*
* Update the scrapers in the DB to the latest bundled versions
*/
function _updateScrapersLocal(){
var dbVersion = _getDBVersion('scrapers');
var schemaVersion = _getSchemaSQLVersion('scrapers');
function _updateSchema(schema){
var dbVersion = _getDBVersion(schema);
var schemaVersion = _getSchemaSQLVersion(schema);
if (dbVersion == schemaVersion){
return;
}
else if (dbVersion < schemaVersion){
Scholar.DB.beginTransaction();
Scholar.DB.query(_getSchemaSQL('scrapers'));
_updateDBVersion('scrapers', schemaVersion);
Scholar.DB.commitTransaction();
try {
Scholar.DB.query(_getSchemaSQL(schema));
_updateDBVersion(schema, schemaVersion);
Scholar.DB.commitTransaction();
}
catch (e){
Scholar.debug(e, 1);
Scholar.DB.rollbackTransaction();
alert('Error updating Zotero database'); // TODO: localize
throw(e);
}
return;
}
else {
throw("Scraper set in DB is newer than schema version");
throw("Zotero '" + schema + "' DB version is newer than SQL file");
}
}
@ -395,63 +405,40 @@ Scholar.Schema = new function(){
/*
* Migrate schema from an older version, preserving data
* Migrate user schema from an older version, preserving data
*/
function _migrateSchema(fromVersion){
function _migrateUserSchema(fromVersion){
//
// Change this value to match the schema version
//
var toVersion = 48;
var toVersion = 1;
if (toVersion != _getSchemaSQLVersion()){
throw('Schema version does not match version in _migrateSchema()');
if (toVersion != _getSchemaSQLVersion('user')){
throw('User schema file version does not match version in _migrateUserSchema()');
}
Scholar.debug('Updating DB from version ' + fromVersion + ' to ' + toVersion + '\n');
Scholar.debug('Updating user tables from version ' + fromVersion + ' to ' + toVersion);
Scholar.DB.beginTransaction();
// Step through version changes until we reach the current version
//
// Each block performs the changes necessary to move from the
// previous revision to that one.
for (var i=fromVersion + 1; i<=toVersion; i++){
if (i==30){
// Remove old SQLite DB
var file = Scholar.getProfileDirectory();
file.append('scholar.sqlite');
if (file.exists()){
file.remove(null);
try {
// Step through version changes until we reach the current version
//
// Each block performs the changes necessary to move from the
// previous revision to that one.
for (var i=fromVersion + 1; i<=toVersion; i++){
if (i==1){
Scholar.DB.query("DELETE FROM version WHERE schema='schema'");
}
}
if (i==47){
// Clear storage directory
var file = Scholar.getStorageDirectory();
if (file.exists()){
file.remove(true);
}
_initializeSchema();
}
if(i==48) {
Scholar.DB.query('DROP TABLE IF EXISTS translators;\n'
+'CREATE TABLE translators (\n'
+' translatorID TEXT PRIMARY KEY,\n'
+' lastUpdated DATETIME,\n'
+' inRepository INT,\n'
+' priority INT,\n'
+' translatorType INT,\n'
+' label TEXT,\n'
+' creator TEXT,\n'
+' target TEXT,\n'
+' detectCode TEXT,\n'
+' code TEXT\n'
+');');
}
_updateDBVersion('user', i-1);
Scholar.DB.commitTransaction();
}
catch(e){
Scholar.debug(e);
alert('Error migrating Zotero database');
throw(e);
}
_updateDBVersion('schema', i-1);
Scholar.DB.commitTransaction();
}
}

View file

@ -1,23 +1,9 @@
-- 48
-- 1
-- This file creates system tables that can be safely wiped and reinitialized
-- at any time, as long as existing ids are preserved.
DROP TABLE IF EXISTS version;
CREATE TABLE version (
schema TEXT PRIMARY KEY,
version INT NOT NULL
);
DROP INDEX IF EXISTS schema;
CREATE INDEX schema ON version(schema);
-- The foundational table; every item collected has a unique record here
DROP TABLE IF EXISTS items;
CREATE TABLE items (
itemID INTEGER PRIMARY KEY,
itemTypeID INT,
title TEXT,
dateAdded DATETIME DEFAULT CURRENT_TIMESTAMP,
dateModified DATETIME DEFAULT CURRENT_TIMESTAMP
);
-- Valid item types ("book," "journalArticle," etc.)
DROP TABLE IF EXISTS itemTypes;
CREATE TABLE itemTypes (
@ -55,32 +41,6 @@
FOREIGN KEY (fieldID) REFERENCES itemTypes(itemTypeID)
);
-- Type-specific data for individual items
DROP TABLE IF EXISTS itemData;
CREATE TABLE itemData (
itemID INT,
fieldID INT,
value,
PRIMARY KEY (itemID, fieldID),
FOREIGN KEY (itemID) REFERENCES items(itemID),
FOREIGN KEY (fieldID) REFERENCES fields(fieldID)
);
DROP INDEX IF EXISTS value;
CREATE INDEX value ON itemData(value);
-- Note data for note items
DROP TABLE IF EXISTS itemNotes;
CREATE TABLE itemNotes (
itemID INT,
sourceItemID INT,
note TEXT,
PRIMARY KEY (itemID),
FOREIGN KEY (itemID) REFERENCES items(itemID),
FOREIGN KEY (sourceItemID) REFERENCES items(itemID)
);
DROP INDEX IF EXISTS itemNotes_sourceItemID;
CREATE INDEX itemNotes_sourceItemID ON itemNotes(sourceItemID);
DROP TABLE IF EXISTS charsets;
CREATE TABLE charsets (
charsetID INTEGER PRIMARY KEY,
@ -107,66 +67,6 @@
DROP INDEX IF EXISTS fileTypeMimeTypes_mimeType;
CREATE INDEX fileTypeMimeTypes_mimeType ON fileTypeMimeTypes(mimeType);
-- Metadata for attachment items
DROP TABLE IF EXISTS itemAttachments;
CREATE TABLE itemAttachments (
itemID INT,
sourceItemID INT,
linkMode INT,
mimeType TEXT,
charsetID INT,
path TEXT,
originalPath TEXT,
PRIMARY KEY (itemID),
FOREIGN KEY (itemID) REFERENCES items(itemID),
FOREIGN KEY (sourceItemID) REFERENCES items(sourceItemID)
);
DROP INDEX IF EXISTS itemAttachments_sourceItemID;
CREATE INDEX itemAttachments_sourceItemID ON itemAttachments(sourceItemID);
DROP INDEX IF EXISTS itemAttachments_mimeType;
CREATE INDEX itemAttachments_mimeType ON itemAttachments(mimeType);
-- Individual entries for each tag
DROP TABLE IF EXISTS tags;
CREATE TABLE tags (
tagID INT,
tag TEXT UNIQUE,
PRIMARY KEY (tagID)
);
-- Associates items with keywords
DROP TABLE IF EXISTS itemTags;
CREATE TABLE itemTags (
itemID INT,
tagID INT,
PRIMARY KEY (itemID, tagID),
FOREIGN KEY (itemID) REFERENCES items(itemID),
FOREIGN KEY (tagID) REFERENCES tags(tagID)
);
DROP INDEX IF EXISTS itemTags_tagID;
CREATE INDEX itemTags_tagID ON itemTags(tagID);
DROP TABLE IF EXISTS itemSeeAlso;
CREATE TABLE itemSeeAlso (
itemID INT,
linkedItemID INT,
PRIMARY KEY (itemID, linkedItemID),
FOREIGN KEY (itemID) REFERENCES items(itemID),
FOREIGN KEY (linkedItemID) REFERENCES items(itemID)
);
DROP INDEX IF EXISTS itemSeeAlso_linkedItemID;
CREATE INDEX itemSeeAlso_linkedItemID ON itemSeeAlso(linkedItemID);
-- Names of each individual "creator" (inc. authors, editors, etc.)
DROP TABLE IF EXISTS creators;
CREATE TABLE creators (
creatorID INT,
firstName TEXT,
lastName TEXT,
isInstitution INT,
PRIMARY KEY (creatorID)
);
-- Defines the possible creator types (contributor, editor, author)
DROP TABLE IF EXISTS creatorTypes;
CREATE TABLE creatorTypes (
@ -174,61 +74,6 @@
creatorType TEXT
);
-- Associates single or multiple creators to items
DROP TABLE IF EXISTS itemCreators;
CREATE TABLE itemCreators (
itemID INT,
creatorID INT,
creatorTypeID INT DEFAULT 1,
orderIndex INT DEFAULT 0,
PRIMARY KEY (itemID, creatorID, creatorTypeID, orderIndex),
FOREIGN KEY (itemID) REFERENCES items(itemID),
FOREIGN KEY (creatorID) REFERENCES creators(creatorID)
FOREIGN KEY (creatorTypeID) REFERENCES creatorTypes(creatorTypeID)
);
-- Collections for holding items
DROP TABLE IF EXISTS collections;
CREATE TABLE collections (
collectionID INT,
collectionName TEXT,
parentCollectionID INT,
PRIMARY KEY (collectionID),
FOREIGN KEY (parentCollectionID) REFERENCES collections(collectionID)
);
-- Associates items with the various collections they belong to
DROP TABLE IF EXISTS collectionItems;
CREATE TABLE collectionItems (
collectionID INT,
itemID INT,
orderIndex INT DEFAULT 0,
PRIMARY KEY (collectionID, itemID),
FOREIGN KEY (collectionID) REFERENCES collections(collectionID),
FOREIGN KEY (itemID) REFERENCES items(itemID)
);
DROP INDEX IF EXISTS itemID;
CREATE INDEX itemID ON collectionItems(itemID);
DROP TABLE IF EXISTS savedSearches;
CREATE TABLE savedSearches (
savedSearchID INT,
savedSearchName TEXT,
PRIMARY KEY(savedSearchID)
);
DROP TABLE IF EXISTS savedSearchConditions;
CREATE TABLE savedSearchConditions (
savedSearchID INT,
searchConditionID INT,
condition TEXT,
operator TEXT,
value TEXT,
required NONE,
PRIMARY KEY(savedSearchID, searchConditionID),
FOREIGN KEY (savedSearchID) REFERENCES savedSearches(savedSearchID)
);
DROP TABLE IF EXISTS translators;
CREATE TABLE translators (
translatorID TEXT PRIMARY KEY,
@ -678,6 +523,4 @@
INSERT INTO "creatorTypes" VALUES(2, "contributor");
INSERT INTO "creatorTypes" VALUES(3, "editor");
INSERT INTO "creatorTypes" VALUES(4, "translator");
INSERT INTO "items" VALUES(1233, 14, 'Zotero - Quick Start Guide', '2006-08-31 20:00:00', '2006-08-31 20:00:00');
INSERT INTO "itemAttachments" VALUES(1233, NULL, 3, 'text/html', 25, 'http://www.zotero.org/docs/quick_start_guide.php', NULL);

169
user.sql Normal file
View file

@ -0,0 +1,169 @@
-- 1
-- This file creates tables containing user-specific data -- any changes made
-- here must be mirrored in transition steps in schema.js::_migrateSchema(),
-- as this file will only be used for new users.
DROP TABLE IF EXISTS version;
CREATE TABLE version (
schema TEXT PRIMARY KEY,
version INT NOT NULL
);
DROP INDEX IF EXISTS schema;
CREATE INDEX schema ON version(schema);
-- The foundational table; every item collected has a unique record here
DROP TABLE IF EXISTS items;
CREATE TABLE items (
itemID INTEGER PRIMARY KEY,
itemTypeID INT,
title TEXT,
dateAdded DATETIME DEFAULT CURRENT_TIMESTAMP,
dateModified DATETIME DEFAULT CURRENT_TIMESTAMP
);
-- Type-specific data for individual items
DROP TABLE IF EXISTS itemData;
CREATE TABLE itemData (
itemID INT,
fieldID INT,
value,
PRIMARY KEY (itemID, fieldID),
FOREIGN KEY (itemID) REFERENCES items(itemID),
FOREIGN KEY (fieldID) REFERENCES fields(fieldID)
);
DROP INDEX IF EXISTS value;
CREATE INDEX value ON itemData(value);
-- Note data for note items
DROP TABLE IF EXISTS itemNotes;
CREATE TABLE itemNotes (
itemID INT,
sourceItemID INT,
note TEXT,
PRIMARY KEY (itemID),
FOREIGN KEY (itemID) REFERENCES items(itemID),
FOREIGN KEY (sourceItemID) REFERENCES items(itemID)
);
DROP INDEX IF EXISTS itemNotes_sourceItemID;
CREATE INDEX itemNotes_sourceItemID ON itemNotes(sourceItemID);
-- Metadata for attachment items
DROP TABLE IF EXISTS itemAttachments;
CREATE TABLE itemAttachments (
itemID INT,
sourceItemID INT,
linkMode INT,
mimeType TEXT,
charsetID INT,
path TEXT,
originalPath TEXT,
PRIMARY KEY (itemID),
FOREIGN KEY (itemID) REFERENCES items(itemID),
FOREIGN KEY (sourceItemID) REFERENCES items(sourceItemID)
);
DROP INDEX IF EXISTS itemAttachments_sourceItemID;
CREATE INDEX itemAttachments_sourceItemID ON itemAttachments(sourceItemID);
DROP INDEX IF EXISTS itemAttachments_mimeType;
CREATE INDEX itemAttachments_mimeType ON itemAttachments(mimeType);
-- Individual entries for each tag
DROP TABLE IF EXISTS tags;
CREATE TABLE tags (
tagID INT,
tag TEXT UNIQUE,
PRIMARY KEY (tagID)
);
-- Associates items with keywords
DROP TABLE IF EXISTS itemTags;
CREATE TABLE itemTags (
itemID INT,
tagID INT,
PRIMARY KEY (itemID, tagID),
FOREIGN KEY (itemID) REFERENCES items(itemID),
FOREIGN KEY (tagID) REFERENCES tags(tagID)
);
DROP INDEX IF EXISTS itemTags_tagID;
CREATE INDEX itemTags_tagID ON itemTags(tagID);
DROP TABLE IF EXISTS itemSeeAlso;
CREATE TABLE itemSeeAlso (
itemID INT,
linkedItemID INT,
PRIMARY KEY (itemID, linkedItemID),
FOREIGN KEY (itemID) REFERENCES items(itemID),
FOREIGN KEY (linkedItemID) REFERENCES items(itemID)
);
DROP INDEX IF EXISTS itemSeeAlso_linkedItemID;
CREATE INDEX itemSeeAlso_linkedItemID ON itemSeeAlso(linkedItemID);
-- Names of each individual "creator" (inc. authors, editors, etc.)
DROP TABLE IF EXISTS creators;
CREATE TABLE creators (
creatorID INT,
firstName TEXT,
lastName TEXT,
isInstitution INT,
PRIMARY KEY (creatorID)
);
-- Associates single or multiple creators to items
DROP TABLE IF EXISTS itemCreators;
CREATE TABLE itemCreators (
itemID INT,
creatorID INT,
creatorTypeID INT DEFAULT 1,
orderIndex INT DEFAULT 0,
PRIMARY KEY (itemID, creatorID, creatorTypeID, orderIndex),
FOREIGN KEY (itemID) REFERENCES items(itemID),
FOREIGN KEY (creatorID) REFERENCES creators(creatorID)
FOREIGN KEY (creatorTypeID) REFERENCES creatorTypes(creatorTypeID)
);
-- Collections for holding items
DROP TABLE IF EXISTS collections;
CREATE TABLE collections (
collectionID INT,
collectionName TEXT,
parentCollectionID INT,
PRIMARY KEY (collectionID),
FOREIGN KEY (parentCollectionID) REFERENCES collections(collectionID)
);
-- Associates items with the various collections they belong to
DROP TABLE IF EXISTS collectionItems;
CREATE TABLE collectionItems (
collectionID INT,
itemID INT,
orderIndex INT DEFAULT 0,
PRIMARY KEY (collectionID, itemID),
FOREIGN KEY (collectionID) REFERENCES collections(collectionID),
FOREIGN KEY (itemID) REFERENCES items(itemID)
);
DROP INDEX IF EXISTS itemID;
CREATE INDEX itemID ON collectionItems(itemID);
DROP TABLE IF EXISTS savedSearches;
CREATE TABLE savedSearches (
savedSearchID INT,
savedSearchName TEXT,
PRIMARY KEY(savedSearchID)
);
DROP TABLE IF EXISTS savedSearchConditions;
CREATE TABLE savedSearchConditions (
savedSearchID INT,
searchConditionID INT,
condition TEXT,
operator TEXT,
value TEXT,
required NONE,
PRIMARY KEY(savedSearchID, searchConditionID),
FOREIGN KEY (savedSearchID) REFERENCES savedSearches(savedSearchID)
);
INSERT INTO "items" VALUES(1233, 14, 'Zotero - Quick Start Guide', '2006-08-31 20:00:00', '2006-08-31 20:00:00');
INSERT INTO "itemAttachments" VALUES(1233, NULL, 3, 'text/html', 25, 'http://www.zotero.org/docs/quick_start_guide.php', NULL);