-- SQLite3 initialization SQL -- Enable WAL mode for better concurrency (simple performance boost) PRAGMA journal_mode = WAL; PRAGMA synchronous = NORMAL; -- Enable foreign key support PRAGMA foreign_keys = ON; -- 创建tokens表 CREATE TABLE IF NOT EXISTS tokens ( id INTEGER PRIMARY KEY AUTOINCREMENT, user_id TEXT NOT NULL, issuer TEXT NOT NULL, account TEXT NOT NULL, secret TEXT NOT NULL CHECK (length(secret) >= 16 AND secret REGEXP '^[A-Z2-7]+=*$'), type TEXT NOT NULL CHECK (type IN ('HOTP', 'TOTP')), counter INTEGER CHECK ( (type = 'HOTP' AND counter >= 0) OR (type = 'TOTP' AND counter IS NULL) ), period INTEGER DEFAULT 30 CHECK ( (type = 'TOTP' AND period >= 30) OR (type = 'HOTP' AND period IS NULL) ), digits INTEGER NOT NULL DEFAULT 6 CHECK (digits IN (6, 8)), algo TEXT NOT NULL DEFAULT 'SHA1' CHECK (algo IN ('SHA1', 'SHA256', 'SHA512')), created_at INTEGER NOT NULL DEFAULT (strftime('%s', 'now')), updated_at INTEGER NOT NULL DEFAULT (strftime('%s', 'now')), UNIQUE(user_id, issuer, account) ); -- 基本索引 CREATE INDEX IF NOT EXISTS idx_tokens_user_id ON tokens(user_id); CREATE INDEX IF NOT EXISTS idx_tokens_lookup ON tokens(user_id, issuer, account); CREATE INDEX IF NOT EXISTS idx_tokens_hotp ON tokens(user_id) WHERE type = 'HOTP'; CREATE INDEX IF NOT EXISTS idx_tokens_totp ON tokens(user_id) WHERE type = 'TOTP'; -- 简化统计视图 CREATE VIEW IF NOT EXISTS v_token_stats AS SELECT user_id, COUNT(*) as total_tokens, SUM(type = 'HOTP') as hotp_count, SUM(type = 'TOTP') as totp_count FROM tokens GROUP BY user_id; -- 设置版本号 PRAGMA user_version = 1;