-- NewTube User Management Schema (SQLite) -- Timestamps are ISO8601 (UTC). Use PRAGMA foreign_keys = ON; PRAGMA foreign_keys = ON; -- Users & identity ----------------------------------------------------------- CREATE TABLE IF NOT EXISTS users ( id TEXT PRIMARY KEY, username TEXT NOT NULL UNIQUE, email TEXT UNIQUE, password_hash TEXT NOT NULL, is_active INTEGER NOT NULL DEFAULT 1, created_at TEXT NOT NULL, updated_at TEXT NOT NULL, last_login_at TEXT ); CREATE TABLE IF NOT EXISTS user_preferences ( user_id TEXT PRIMARY KEY REFERENCES users(id) ON DELETE CASCADE, language TEXT DEFAULT 'en', default_provider TEXT, theme TEXT DEFAULT 'system', video_quality TEXT DEFAULT 'auto', region TEXT, version INTEGER NOT NULL DEFAULT 1, updated_at TEXT NOT NULL ); -- Sessions: refresh tokens are stored hashed; per-device visibility ---------- CREATE TABLE IF NOT EXISTS sessions ( id TEXT PRIMARY KEY, user_id TEXT NOT NULL REFERENCES users(id) ON DELETE CASCADE, refresh_token_hash TEXT NOT NULL, user_agent TEXT, device_info TEXT, ip_address TEXT, is_remember INTEGER NOT NULL DEFAULT 0, created_at TEXT NOT NULL, last_seen_at TEXT, expires_at TEXT NOT NULL, revoked_at TEXT ); CREATE INDEX IF NOT EXISTS idx_sessions_user ON sessions(user_id); CREATE INDEX IF NOT EXISTS idx_sessions_lastseen ON sessions(last_seen_at); -- Login audit --------------------------------------------------------------- CREATE TABLE IF NOT EXISTS login_audit ( id TEXT PRIMARY KEY, user_id TEXT, username TEXT, ip_address TEXT, user_agent TEXT, success INTEGER NOT NULL, reason TEXT, created_at TEXT NOT NULL ); CREATE INDEX IF NOT EXISTS idx_login_audit_user_time ON login_audit(user_id, created_at DESC); -- Search history ------------------------------------------------------------ CREATE TABLE IF NOT EXISTS search_history ( id TEXT PRIMARY KEY, user_id TEXT NOT NULL REFERENCES users(id) ON DELETE CASCADE, query TEXT NOT NULL, filters_json TEXT, created_at TEXT NOT NULL ); CREATE INDEX IF NOT EXISTS idx_search_history_user_time ON search_history(user_id, created_at DESC); -- Watch history ------------------------------------------------------------- CREATE TABLE IF NOT EXISTS watch_history ( id TEXT PRIMARY KEY, user_id TEXT NOT NULL REFERENCES users(id) ON DELETE CASCADE, provider TEXT NOT NULL, video_id TEXT NOT NULL, title TEXT, thumbnail TEXT, watched_at TEXT NOT NULL, progress_seconds INTEGER DEFAULT 0, duration_seconds INTEGER DEFAULT 0, last_position_seconds INTEGER DEFAULT 0, last_watched_at TEXT ); CREATE UNIQUE INDEX IF NOT EXISTS uq_watch_history_user_video ON watch_history(user_id, provider, video_id); CREATE INDEX IF NOT EXISTS idx_watch_history_user_time ON watch_history(user_id, watched_at DESC); -- Subscriptions & categories ----------------------------------------------- CREATE TABLE IF NOT EXISTS categories ( id TEXT PRIMARY KEY, user_id TEXT NOT NULL REFERENCES users(id) ON DELETE CASCADE, name TEXT NOT NULL, created_at TEXT NOT NULL, UNIQUE(user_id, name) ); CREATE TABLE IF NOT EXISTS subscriptions ( id TEXT PRIMARY KEY, user_id TEXT NOT NULL REFERENCES users(id) ON DELETE CASCADE, provider TEXT NOT NULL, channel_id TEXT NOT NULL, channel_name TEXT, notify INTEGER NOT NULL DEFAULT 0, subscribed_at TEXT NOT NULL, UNIQUE(user_id, provider, channel_id) ); CREATE TABLE IF NOT EXISTS subscription_categories ( subscription_id TEXT NOT NULL REFERENCES subscriptions(id) ON DELETE CASCADE, category_id TEXT NOT NULL REFERENCES categories(id) ON DELETE CASCADE, PRIMARY KEY (subscription_id, category_id) ); CREATE INDEX IF NOT EXISTS idx_subscriptions_user ON subscriptions(user_id); -- Playlists ----------------------------------------------------------------- CREATE TABLE IF NOT EXISTS playlists ( id TEXT PRIMARY KEY, user_id TEXT NOT NULL REFERENCES users(id) ON DELETE CASCADE, name TEXT NOT NULL, created_at TEXT NOT NULL, updated_at TEXT NOT NULL, UNIQUE(user_id, name) ); CREATE TABLE IF NOT EXISTS playlist_items ( id TEXT PRIMARY KEY, playlist_id TEXT NOT NULL REFERENCES playlists(id) ON DELETE CASCADE, provider TEXT NOT NULL, video_id TEXT NOT NULL, title TEXT, added_at TEXT NOT NULL, position INTEGER NOT NULL, UNIQUE(playlist_id, provider, video_id) ); CREATE INDEX IF NOT EXISTS idx_playlist_items_order ON playlist_items(playlist_id, position); -- Tags (optional) ----------------------------------------------------------- CREATE TABLE IF NOT EXISTS tags ( id TEXT PRIMARY KEY, user_id TEXT NOT NULL REFERENCES users(id) ON DELETE CASCADE, name TEXT NOT NULL, created_at TEXT NOT NULL, UNIQUE(user_id, name) ); CREATE TABLE IF NOT EXISTS video_tags ( user_id TEXT NOT NULL REFERENCES users(id) ON DELETE CASCADE, provider TEXT NOT NULL, video_id TEXT NOT NULL, tag_id TEXT NOT NULL REFERENCES tags(id) ON DELETE CASCADE, created_at TEXT NOT NULL, PRIMARY KEY (user_id, provider, video_id, tag_id) );