From 0f65b8bdd3a515dc151fbb7c79d18660cdf982ee Mon Sep 17 00:00:00 2001 From: steven Date: Mon, 3 Oct 2022 18:47:31 +0800 Subject: [PATCH] fix: re-generate table columns foreign keys --- store/db/db.go | 18 +- store/db/migration/dev/LATEST__SCHEMA.sql | 27 +-- .../prod/0.2/01__memo_visibility.sql | 2 +- .../prod/0.5/00__regenerate_foreign_keys.sql | 201 ++++++++++++++++++ .../migration/prod/0.5/01__memo_resource.sql | 10 + .../migration/prod/0.5/02__system_setting.sql | 7 + .../prod/0.5/03__resource_extermal_link.sql | 1 + store/db/migration/prod/LATEST__SCHEMA.sql | 28 ++- 8 files changed, 268 insertions(+), 26 deletions(-) create mode 100644 store/db/migration/prod/0.5/00__regenerate_foreign_keys.sql create mode 100644 store/db/migration/prod/0.5/01__memo_resource.sql create mode 100644 store/db/migration/prod/0.5/02__system_setting.sql create mode 100644 store/db/migration/prod/0.5/03__resource_extermal_link.sql diff --git a/store/db/db.go b/store/db/db.go index 52db6007..ecded2b5 100644 --- a/store/db/db.go +++ b/store/db/db.go @@ -42,13 +42,13 @@ func (db *DB) Open(ctx context.Context) (err error) { return fmt.Errorf("dsn required") } - // Connect to the database. - sqlDB, err := sql.Open("sqlite3", db.profile.DSN+"?_foreign_keys=1") + // Connect to the database without foreign_keys config. + tempDB, err := sql.Open("sqlite3", db.profile.DSN) if err != nil { return fmt.Errorf("failed to open db with dsn: %s, err: %w", db.profile.DSN, err) } - db.Db = sqlDB + db.Db = tempDB // If mode is dev, we should migrate and seed the database. if db.profile.Mode == "dev" { if _, err := os.Stat(db.profile.DSN); errors.Is(err, os.ErrNotExist) { @@ -118,6 +118,18 @@ func (db *DB) Open(ctx context.Context) (err error) { } } + if err := tempDB.Close(); err != nil { + return fmt.Errorf("failed to close temp db without foreign_keys, err: %w", err) + } + + // Connect to the database with foreign_keys config. + sqlDB, err := sql.Open("sqlite3", db.profile.DSN+"?_foreign_keys=1") + if err != nil { + return fmt.Errorf("failed to open db with dsn: %s, err: %w", db.profile.DSN, err) + } + + db.Db = sqlDB + return err } diff --git a/store/db/migration/dev/LATEST__SCHEMA.sql b/store/db/migration/dev/LATEST__SCHEMA.sql index d7b1ae6e..b91e2c2f 100644 --- a/store/db/migration/dev/LATEST__SCHEMA.sql +++ b/store/db/migration/dev/LATEST__SCHEMA.sql @@ -13,7 +13,6 @@ CREATE TABLE user ( id INTEGER PRIMARY KEY AUTOINCREMENT, created_ts BIGINT NOT NULL DEFAULT (strftime('%s', 'now')), updated_ts BIGINT NOT NULL DEFAULT (strftime('%s', 'now')), - -- allowed row status are 'NORMAL', 'ARCHIVED'. row_status TEXT NOT NULL CHECK (row_status IN ('NORMAL', 'ARCHIVED')) DEFAULT 'NORMAL', email TEXT NOT NULL UNIQUE, role TEXT NOT NULL CHECK (role IN ('HOST', 'USER')) DEFAULT 'USER', @@ -39,12 +38,6 @@ WHERE rowid = old.rowid; END; -CREATE INDEX user_id_index ON user(id); - -CREATE UNIQUE INDEX user_email_index ON user(email); - -CREATE UNIQUE INDEX user_open_id_index ON user(open_id); - -- memo CREATE TABLE memo ( id INTEGER PRIMARY KEY AUTOINCREMENT, @@ -126,7 +119,8 @@ CREATE TABLE resource ( created_ts BIGINT NOT NULL DEFAULT (strftime('%s', 'now')), updated_ts BIGINT NOT NULL DEFAULT (strftime('%s', 'now')), filename TEXT NOT NULL DEFAULT '', - blob BLOB NOT NULL, + blob BLOB DEFAULT NULL, + external_link TEXT NOT NULL DEFAULT '', type TEXT NOT NULL DEFAULT '', size INTEGER NOT NULL DEFAULT 0, FOREIGN KEY(creator_id) REFERENCES user(id) ON DELETE CASCADE @@ -154,28 +148,25 @@ CREATE TABLE user_setting ( user_id INTEGER NOT NULL, key TEXT NOT NULL, value TEXT NOT NULL, - FOREIGN KEY(user_id) REFERENCES user(id) ON DELETE CASCADE + FOREIGN KEY(user_id) REFERENCES user(id) ON DELETE CASCADE, + UNIQUE(user_id, key) ); -CREATE UNIQUE INDEX user_setting_key_user_id_index ON user_setting(key, user_id); - --- memo_resourece +-- memo_resource CREATE TABLE memo_resource ( memo_id INTEGER NOT NULL, resource_id INTEGER NOT NULL, created_ts BIGINT NOT NULL DEFAULT (strftime('%s', 'now')), updated_ts BIGINT NOT NULL DEFAULT (strftime('%s', 'now')), FOREIGN KEY(memo_id) REFERENCES memo(id) ON DELETE CASCADE, - FOREIGN KEY(resource_id) REFERENCES resource(id) ON DELETE CASCADE + FOREIGN KEY(resource_id) REFERENCES resource(id) ON DELETE CASCADE, + UNIQUE(memo_id, resource_id) ); -CREATE UNIQUE INDEX memo_resource_memo_id_resource_id_index ON memo_resource(memo_id, resource_id); - -- system_setting CREATE TABLE system_setting ( name TEXT NOT NULL, value TEXT NOT NULL, - description TEXT NOT NULL DEFAULT '' + description TEXT NOT NULL DEFAULT '', + UNIQUE(name) ); - -CREATE UNIQUE INDEX system_setting_name_index ON system_setting(name); diff --git a/store/db/migration/prod/0.2/01__memo_visibility.sql b/store/db/migration/prod/0.2/01__memo_visibility.sql index 5e1122d3..1ae37829 100644 --- a/store/db/migration/prod/0.2/01__memo_visibility.sql +++ b/store/db/migration/prod/0.2/01__memo_visibility.sql @@ -1 +1 @@ -ALTER TABLE memo ADD visibility TEXT NOT NULL CHECK (visibility IN ('PUBLIC', 'PRIVATE')) DEFAULT 'PRIVATE'; +ALTER TABLE memo ADD COLUMN visibility TEXT NOT NULL CHECK (visibility IN ('PUBLIC', 'PRIVATE')) DEFAULT 'PRIVATE'; diff --git a/store/db/migration/prod/0.5/00__regenerate_foreign_keys.sql b/store/db/migration/prod/0.5/00__regenerate_foreign_keys.sql new file mode 100644 index 00000000..4ceaa03a --- /dev/null +++ b/store/db/migration/prod/0.5/00__regenerate_foreign_keys.sql @@ -0,0 +1,201 @@ +DROP TABLE IF EXISTS _user_old; + +ALTER TABLE user RENAME TO _user_old; + +-- user +CREATE TABLE user ( + id INTEGER PRIMARY KEY AUTOINCREMENT, + created_ts BIGINT NOT NULL DEFAULT (strftime('%s', 'now')), + updated_ts BIGINT NOT NULL DEFAULT (strftime('%s', 'now')), + row_status TEXT NOT NULL CHECK (row_status IN ('NORMAL', 'ARCHIVED')) DEFAULT 'NORMAL', + email TEXT NOT NULL UNIQUE, + role TEXT NOT NULL CHECK (role IN ('HOST', 'USER')) DEFAULT 'USER', + name TEXT NOT NULL, + password_hash TEXT NOT NULL, + open_id TEXT NOT NULL UNIQUE +); + +INSERT INTO user ( + id, created_ts, updated_ts, row_status, email, role, name, password_hash, open_id +) +SELECT + id, created_ts, updated_ts, row_status, email, role, name, password_hash, open_id +FROM + _user_old; + +CREATE TRIGGER IF NOT EXISTS `trigger_update_user_modification_time` +AFTER +UPDATE + ON `user` FOR EACH ROW BEGIN +UPDATE + `user` +SET + updated_ts = (strftime('%s', 'now')) +WHERE + rowid = old.rowid; +END; + +DROP TABLE IF EXISTS _user_old; + +DROP TABLE IF EXISTS _memo_old; + +ALTER TABLE memo RENAME TO _memo_old; + +-- memo +CREATE TABLE memo ( + id INTEGER PRIMARY KEY AUTOINCREMENT, + creator_id INTEGER NOT NULL, + created_ts BIGINT NOT NULL DEFAULT (strftime('%s', 'now')), + updated_ts BIGINT NOT NULL DEFAULT (strftime('%s', 'now')), + row_status TEXT NOT NULL CHECK (row_status IN ('NORMAL', 'ARCHIVED')) DEFAULT 'NORMAL', + content TEXT NOT NULL DEFAULT '', + visibility TEXT NOT NULL CHECK (visibility IN ('PUBLIC', 'PROTECTED', 'PRIVATE')) DEFAULT 'PRIVATE', + FOREIGN KEY(creator_id) REFERENCES user(id) ON DELETE CASCADE +); + +INSERT INTO memo ( + id, creator_id, created_ts, updated_ts, row_status, content, visibility +) +SELECT + id, creator_id, created_ts, updated_ts, row_status, content, visibility +FROM + _memo_old; + +CREATE TRIGGER IF NOT EXISTS `trigger_update_memo_modification_time` +AFTER +UPDATE + ON `memo` FOR EACH ROW BEGIN +UPDATE + `memo` +SET + updated_ts = (strftime('%s', 'now')) +WHERE + rowid = old.rowid; +END; + +DROP TABLE IF EXISTS _memo_old; + +DROP TABLE IF EXISTS _memo_organizer_old; + +ALTER TABLE memo_organizer RENAME TO _memo_organizer_old; + +-- memo_organizer +CREATE TABLE memo_organizer ( + id INTEGER PRIMARY KEY AUTOINCREMENT, + memo_id INTEGER NOT NULL, + user_id INTEGER NOT NULL, + pinned INTEGER NOT NULL CHECK (pinned IN (0, 1)) DEFAULT 0, + FOREIGN KEY(memo_id) REFERENCES memo(id) ON DELETE CASCADE, + FOREIGN KEY(user_id) REFERENCES user(id) ON DELETE CASCADE, + UNIQUE(memo_id, user_id) +); + +INSERT INTO memo_organizer ( + id, memo_id, user_id, pinned +) +SELECT + id, memo_id, user_id, pinned +FROM + _memo_organizer_old; + +DROP TABLE IF EXISTS _memo_organizer_old; + +DROP TABLE IF EXISTS _shortcut_old; + +ALTER TABLE shortcut RENAME TO _shortcut_old; + +-- shortcut +CREATE TABLE shortcut ( + id INTEGER PRIMARY KEY AUTOINCREMENT, + creator_id INTEGER NOT NULL, + created_ts BIGINT NOT NULL DEFAULT (strftime('%s', 'now')), + updated_ts BIGINT NOT NULL DEFAULT (strftime('%s', 'now')), + row_status TEXT NOT NULL CHECK (row_status IN ('NORMAL', 'ARCHIVED')) DEFAULT 'NORMAL', + title TEXT NOT NULL DEFAULT '', + payload TEXT NOT NULL DEFAULT '{}', + FOREIGN KEY(creator_id) REFERENCES user(id) ON DELETE CASCADE +); + +INSERT INTO shortcut ( + id, creator_id, created_ts, updated_ts, row_status, title, payload +) +SELECT + id, creator_id, created_ts, updated_ts, row_status, title, payload +FROM + _shortcut_old; + +CREATE TRIGGER IF NOT EXISTS `trigger_update_shortcut_modification_time` +AFTER +UPDATE + ON `shortcut` FOR EACH ROW BEGIN +UPDATE + `shortcut` +SET + updated_ts = (strftime('%s', 'now')) +WHERE + rowid = old.rowid; +END; + +DROP TABLE IF EXISTS _shortcut_old; + +DROP TABLE IF EXISTS _resource_old; + +ALTER TABLE resource RENAME TO _resource_old; + +-- resource +CREATE TABLE resource ( + id INTEGER PRIMARY KEY AUTOINCREMENT, + creator_id INTEGER NOT NULL, + created_ts BIGINT NOT NULL DEFAULT (strftime('%s', 'now')), + updated_ts BIGINT NOT NULL DEFAULT (strftime('%s', 'now')), + filename TEXT NOT NULL DEFAULT '', + blob BLOB DEFAULT NULL, + type TEXT NOT NULL DEFAULT '', + size INTEGER NOT NULL DEFAULT 0, + FOREIGN KEY(creator_id) REFERENCES user(id) ON DELETE CASCADE +); + +INSERT INTO resource ( + id, creator_id, created_ts, updated_ts, filename, blob, type, size +) +SELECT + id, creator_id, created_ts, updated_ts, filename, blob, type, size +FROM + _resource_old; + +CREATE TRIGGER IF NOT EXISTS `trigger_update_resource_modification_time` +AFTER +UPDATE + ON `resource` FOR EACH ROW BEGIN +UPDATE + `resource` +SET + updated_ts = (strftime('%s', 'now')) +WHERE + rowid = old.rowid; +END; + +DROP TABLE IF EXISTS _resource_old; + +DROP TABLE IF EXISTS _user_setting_old; + +ALTER TABLE user_setting RENAME TO _user_setting_old; + +-- user_setting +CREATE TABLE user_setting ( + user_id INTEGER NOT NULL, + key TEXT NOT NULL, + value TEXT NOT NULL, + FOREIGN KEY(user_id) REFERENCES user(id) ON DELETE CASCADE, + UNIQUE(user_id, key) +); + +INSERT INTO user_setting ( + user_id, key, value +) +SELECT + user_id, key, value +FROM + _user_setting_old; + +DROP TABLE IF EXISTS _user_setting_old; diff --git a/store/db/migration/prod/0.5/01__memo_resource.sql b/store/db/migration/prod/0.5/01__memo_resource.sql new file mode 100644 index 00000000..6a98fa00 --- /dev/null +++ b/store/db/migration/prod/0.5/01__memo_resource.sql @@ -0,0 +1,10 @@ +-- memo_resource +CREATE TABLE memo_resource ( + memo_id INTEGER NOT NULL, + resource_id INTEGER NOT NULL, + created_ts BIGINT NOT NULL DEFAULT (strftime('%s', 'now')), + updated_ts BIGINT NOT NULL DEFAULT (strftime('%s', 'now')), + FOREIGN KEY(memo_id) REFERENCES memo(id) ON DELETE CASCADE, + FOREIGN KEY(resource_id) REFERENCES resource(id) ON DELETE CASCADE, + UNIQUE(memo_id, resource_id) +); diff --git a/store/db/migration/prod/0.5/02__system_setting.sql b/store/db/migration/prod/0.5/02__system_setting.sql new file mode 100644 index 00000000..4f154049 --- /dev/null +++ b/store/db/migration/prod/0.5/02__system_setting.sql @@ -0,0 +1,7 @@ +-- system_setting +CREATE TABLE system_setting ( + name TEXT NOT NULL, + value TEXT NOT NULL, + description TEXT NOT NULL DEFAULT '', + UNIQUE(name) +); diff --git a/store/db/migration/prod/0.5/03__resource_extermal_link.sql b/store/db/migration/prod/0.5/03__resource_extermal_link.sql new file mode 100644 index 00000000..64bbf530 --- /dev/null +++ b/store/db/migration/prod/0.5/03__resource_extermal_link.sql @@ -0,0 +1 @@ +ALTER TABLE resource ADD COLUMN external_link TEXT NOT NULL DEFAULT ''; diff --git a/store/db/migration/prod/LATEST__SCHEMA.sql b/store/db/migration/prod/LATEST__SCHEMA.sql index 5c1bc47e..b91e2c2f 100644 --- a/store/db/migration/prod/LATEST__SCHEMA.sql +++ b/store/db/migration/prod/LATEST__SCHEMA.sql @@ -1,4 +1,6 @@ -- drop all tables +DROP TABLE IF EXISTS `system_setting`; +DROP TABLE IF EXISTS `memo_resource`; DROP TABLE IF EXISTS `memo_organizer`; DROP TABLE IF EXISTS `memo`; DROP TABLE IF EXISTS `shortcut`; @@ -11,7 +13,6 @@ CREATE TABLE user ( id INTEGER PRIMARY KEY AUTOINCREMENT, created_ts BIGINT NOT NULL DEFAULT (strftime('%s', 'now')), updated_ts BIGINT NOT NULL DEFAULT (strftime('%s', 'now')), - -- allowed row status are 'NORMAL', 'ARCHIVED'. row_status TEXT NOT NULL CHECK (row_status IN ('NORMAL', 'ARCHIVED')) DEFAULT 'NORMAL', email TEXT NOT NULL UNIQUE, role TEXT NOT NULL CHECK (role IN ('HOST', 'USER')) DEFAULT 'USER', @@ -118,7 +119,8 @@ CREATE TABLE resource ( created_ts BIGINT NOT NULL DEFAULT (strftime('%s', 'now')), updated_ts BIGINT NOT NULL DEFAULT (strftime('%s', 'now')), filename TEXT NOT NULL DEFAULT '', - blob BLOB NOT NULL, + blob BLOB DEFAULT NULL, + external_link TEXT NOT NULL DEFAULT '', type TEXT NOT NULL DEFAULT '', size INTEGER NOT NULL DEFAULT 0, FOREIGN KEY(creator_id) REFERENCES user(id) ON DELETE CASCADE @@ -146,7 +148,25 @@ CREATE TABLE user_setting ( user_id INTEGER NOT NULL, key TEXT NOT NULL, value TEXT NOT NULL, - FOREIGN KEY(user_id) REFERENCES user(id) ON DELETE CASCADE + FOREIGN KEY(user_id) REFERENCES user(id) ON DELETE CASCADE, + UNIQUE(user_id, key) ); -CREATE UNIQUE INDEX user_setting_key_user_id_index ON user_setting(key, user_id); +-- memo_resource +CREATE TABLE memo_resource ( + memo_id INTEGER NOT NULL, + resource_id INTEGER NOT NULL, + created_ts BIGINT NOT NULL DEFAULT (strftime('%s', 'now')), + updated_ts BIGINT NOT NULL DEFAULT (strftime('%s', 'now')), + FOREIGN KEY(memo_id) REFERENCES memo(id) ON DELETE CASCADE, + FOREIGN KEY(resource_id) REFERENCES resource(id) ON DELETE CASCADE, + UNIQUE(memo_id, resource_id) +); + +-- system_setting +CREATE TABLE system_setting ( + name TEXT NOT NULL, + value TEXT NOT NULL, + description TEXT NOT NULL DEFAULT '', + UNIQUE(name) +);