-- drop all tables first DROP TABLE IF EXISTS migration_history; DROP TABLE IF EXISTS system_setting; DROP TABLE IF EXISTS user; DROP TABLE IF EXISTS user_setting; DROP TABLE IF EXISTS memo; DROP TABLE IF EXISTS memo_organizer; DROP TABLE IF EXISTS memo_relation; DROP TABLE IF EXISTS resource; DROP TABLE IF EXISTS tag; DROP TABLE IF EXISTS activity; DROP TABLE IF EXISTS storage; DROP TABLE IF EXISTS idp; -- migration_history CREATE TABLE migration_history ( version TEXT NOT NULL PRIMARY KEY, created_ts BIGINT NOT NULL DEFAULT (strftime('%s', 'now')) ); -- system_setting CREATE TABLE system_setting ( name TEXT NOT NULL, value TEXT NOT NULL, description TEXT NOT NULL DEFAULT '', UNIQUE(name) ); -- 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', username TEXT NOT NULL UNIQUE, role TEXT NOT NULL CHECK (role IN ('HOST', 'ADMIN', 'USER')) DEFAULT 'USER', email TEXT NOT NULL DEFAULT '', nickname TEXT NOT NULL DEFAULT '', password_hash TEXT NOT NULL, avatar_url TEXT NOT NULL DEFAULT '' ); CREATE INDEX idx_user_username ON user (username); -- user_setting CREATE TABLE user_setting ( user_id INTEGER NOT NULL, key TEXT NOT NULL, value TEXT NOT NULL, UNIQUE(user_id, key) ); -- 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' ); CREATE INDEX idx_memo_creator_id ON memo (creator_id); CREATE INDEX idx_memo_content ON memo (content); CREATE INDEX idx_memo_visibility ON memo (visibility); -- memo_organizer CREATE TABLE memo_organizer ( memo_id INTEGER NOT NULL, user_id INTEGER NOT NULL, pinned INTEGER NOT NULL CHECK (pinned IN (0, 1)) DEFAULT 0, UNIQUE(memo_id, user_id) ); -- memo_relation CREATE TABLE memo_relation ( memo_id INTEGER NOT NULL, related_memo_id INTEGER NOT NULL, type TEXT NOT NULL, UNIQUE(memo_id, related_memo_id, type) ); -- 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, external_link TEXT NOT NULL DEFAULT '', type TEXT NOT NULL DEFAULT '', size INTEGER NOT NULL DEFAULT 0, internal_path TEXT NOT NULL DEFAULT '', memo_id INTEGER ); CREATE INDEX idx_resource_creator_id ON resource (creator_id); CREATE INDEX idx_resource_memo_id ON resource (memo_id); -- tag CREATE TABLE tag ( name TEXT NOT NULL, creator_id INTEGER NOT NULL, UNIQUE(name, creator_id) ); -- activity CREATE TABLE activity ( id INTEGER PRIMARY KEY AUTOINCREMENT, creator_id INTEGER NOT NULL, created_ts BIGINT NOT NULL DEFAULT (strftime('%s', 'now')), type TEXT NOT NULL DEFAULT '', level TEXT NOT NULL CHECK (level IN ('INFO', 'WARN', 'ERROR')) DEFAULT 'INFO', payload TEXT NOT NULL DEFAULT '{}' ); -- storage CREATE TABLE storage ( id INTEGER PRIMARY KEY AUTOINCREMENT, name TEXT NOT NULL, type TEXT NOT NULL, config TEXT NOT NULL DEFAULT '{}' ); -- idp CREATE TABLE idp ( id INTEGER PRIMARY KEY AUTOINCREMENT, name TEXT NOT NULL, type TEXT NOT NULL, identifier_filter TEXT NOT NULL DEFAULT '', config TEXT NOT NULL DEFAULT '{}' ); -- inbox CREATE TABLE inbox ( id INTEGER PRIMARY KEY AUTOINCREMENT, created_ts BIGINT NOT NULL DEFAULT (strftime('%s', 'now')), sender_id INTEGER NOT NULL, receiver_id INTEGER NOT NULL, status TEXT NOT NULL CHECK (row_status IN ('UNREAD', 'READ', 'ARCHIVED')) DEFAULT 'UNREAD', message TEXT NOT NULL DEFAULT '{}' );