72 lines
2.4 KiB
SQL
72 lines
2.4 KiB
SQL
-- Initial schema for K-Notes
|
|
-- SQLite with FTS5 for full-text search
|
|
|
|
-- Users table (OIDC-ready)
|
|
CREATE TABLE IF NOT EXISTS users (
|
|
id TEXT PRIMARY KEY NOT NULL,
|
|
subject TEXT UNIQUE NOT NULL, -- OIDC subject identifier
|
|
email TEXT NOT NULL,
|
|
created_at TEXT NOT NULL DEFAULT (datetime('now'))
|
|
);
|
|
|
|
CREATE INDEX idx_users_subject ON users(subject);
|
|
CREATE INDEX idx_users_email ON users(email);
|
|
|
|
-- Notes table
|
|
CREATE TABLE IF NOT EXISTS notes (
|
|
id TEXT PRIMARY KEY NOT NULL,
|
|
user_id TEXT NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
|
title TEXT NOT NULL,
|
|
content TEXT NOT NULL DEFAULT '',
|
|
is_pinned INTEGER NOT NULL DEFAULT 0,
|
|
is_archived INTEGER NOT NULL DEFAULT 0,
|
|
created_at TEXT NOT NULL DEFAULT (datetime('now')),
|
|
updated_at TEXT NOT NULL DEFAULT (datetime('now'))
|
|
);
|
|
|
|
CREATE INDEX idx_notes_user_id ON notes(user_id);
|
|
CREATE INDEX idx_notes_is_pinned ON notes(is_pinned);
|
|
CREATE INDEX idx_notes_is_archived ON notes(is_archived);
|
|
CREATE INDEX idx_notes_updated_at ON notes(updated_at);
|
|
|
|
-- Tags table (user-scoped)
|
|
CREATE TABLE IF NOT EXISTS tags (
|
|
id TEXT PRIMARY KEY NOT NULL,
|
|
name TEXT NOT NULL,
|
|
user_id TEXT NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
|
UNIQUE(name, user_id)
|
|
);
|
|
|
|
CREATE INDEX idx_tags_user_id ON tags(user_id);
|
|
|
|
-- Junction table for note-tag relationship
|
|
CREATE TABLE IF NOT EXISTS note_tags (
|
|
note_id TEXT NOT NULL REFERENCES notes(id) ON DELETE CASCADE,
|
|
tag_id TEXT NOT NULL REFERENCES tags(id) ON DELETE CASCADE,
|
|
PRIMARY KEY (note_id, tag_id)
|
|
);
|
|
|
|
CREATE INDEX idx_note_tags_tag_id ON note_tags(tag_id);
|
|
|
|
-- Full-text search virtual table
|
|
CREATE VIRTUAL TABLE IF NOT EXISTS notes_fts USING fts5(
|
|
title,
|
|
content,
|
|
content='notes',
|
|
content_rowid='rowid'
|
|
);
|
|
|
|
-- Triggers to keep FTS index in sync
|
|
CREATE TRIGGER notes_ai AFTER INSERT ON notes BEGIN
|
|
INSERT INTO notes_fts(rowid, title, content) VALUES (NEW.rowid, NEW.title, NEW.content);
|
|
END;
|
|
|
|
CREATE TRIGGER notes_ad AFTER DELETE ON notes BEGIN
|
|
INSERT INTO notes_fts(notes_fts, rowid, title, content) VALUES('delete', OLD.rowid, OLD.title, OLD.content);
|
|
END;
|
|
|
|
CREATE TRIGGER notes_au AFTER UPDATE ON notes BEGIN
|
|
INSERT INTO notes_fts(notes_fts, rowid, title, content) VALUES('delete', OLD.rowid, OLD.title, OLD.content);
|
|
INSERT INTO notes_fts(rowid, title, content) VALUES (NEW.rowid, NEW.title, NEW.content);
|
|
END;
|