-- Add 2FA support to users table -- Migration: 002_add_2fa_support -- Database: SQLite -- Add 2FA columns to users table (SQLite requires one column at a time) ALTER TABLE users ADD COLUMN two_factor_secret TEXT; ALTER TABLE users ADD COLUMN two_factor_enabled INTEGER NOT NULL DEFAULT 0; ALTER TABLE users ADD COLUMN backup_codes TEXT; -- JSON array as TEXT ALTER TABLE users ADD COLUMN last_login_at DATETIME; ALTER TABLE users ADD COLUMN failed_login_attempts INTEGER NOT NULL DEFAULT 0; ALTER TABLE users ADD COLUMN locked_until DATETIME; -- Create 2FA recovery codes table CREATE TABLE IF NOT EXISTS two_factor_recovery_codes ( id TEXT PRIMARY KEY DEFAULT (lower(hex(randomblob(16)))), user_id TEXT NOT NULL REFERENCES users(id) ON DELETE CASCADE, code_hash TEXT NOT NULL, used_at DATETIME, created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP ); -- Create login attempts table for security tracking CREATE TABLE IF NOT EXISTS login_attempts ( id TEXT PRIMARY KEY DEFAULT (lower(hex(randomblob(16)))), user_id TEXT REFERENCES users(id) ON DELETE CASCADE, ip_address TEXT, user_agent TEXT, success INTEGER NOT NULL, failure_reason TEXT, attempted_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP ); -- Create password reset tokens table CREATE TABLE IF NOT EXISTS password_reset_tokens ( id TEXT PRIMARY KEY DEFAULT (lower(hex(randomblob(16)))), user_id TEXT NOT NULL REFERENCES users(id) ON DELETE CASCADE, token_hash TEXT NOT NULL UNIQUE, expires_at DATETIME NOT NULL, used_at DATETIME, created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP ); -- Create email verification tokens table CREATE TABLE IF NOT EXISTS email_verification_tokens ( id TEXT PRIMARY KEY DEFAULT (lower(hex(randomblob(16)))), user_id TEXT NOT NULL REFERENCES users(id) ON DELETE CASCADE, token_hash TEXT NOT NULL UNIQUE, email TEXT NOT NULL, -- Allow email change verification expires_at DATETIME NOT NULL, verified_at DATETIME, created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP ); -- Create indexes for 2FA and security tables CREATE INDEX IF NOT EXISTS idx_users_2fa_enabled ON users(two_factor_enabled); CREATE INDEX IF NOT EXISTS idx_users_locked_until ON users(locked_until); CREATE INDEX IF NOT EXISTS idx_users_last_login ON users(last_login_at); CREATE INDEX IF NOT EXISTS idx_2fa_recovery_codes_user_id ON two_factor_recovery_codes(user_id); CREATE INDEX IF NOT EXISTS idx_2fa_recovery_codes_hash ON two_factor_recovery_codes(code_hash); CREATE INDEX IF NOT EXISTS idx_login_attempts_user_id ON login_attempts(user_id); CREATE INDEX IF NOT EXISTS idx_login_attempts_ip ON login_attempts(ip_address); CREATE INDEX IF NOT EXISTS idx_login_attempts_time ON login_attempts(attempted_at); CREATE INDEX IF NOT EXISTS idx_password_reset_tokens_hash ON password_reset_tokens(token_hash); CREATE INDEX IF NOT EXISTS idx_password_reset_tokens_user ON password_reset_tokens(user_id); CREATE INDEX IF NOT EXISTS idx_email_verification_tokens_hash ON email_verification_tokens(token_hash); CREATE INDEX IF NOT EXISTS idx_email_verification_tokens_user ON email_verification_tokens(user_id); -- SQLite doesn't support stored procedures, but we can create triggers for cleanup -- Trigger to automatically clean up expired password reset tokens on insert CREATE TRIGGER IF NOT EXISTS cleanup_expired_password_tokens AFTER INSERT ON password_reset_tokens BEGIN DELETE FROM password_reset_tokens WHERE expires_at < datetime('now') AND used_at IS NULL; END; -- Trigger to automatically clean up expired email verification tokens on insert CREATE TRIGGER IF NOT EXISTS cleanup_expired_email_tokens AFTER INSERT ON email_verification_tokens BEGIN DELETE FROM email_verification_tokens WHERE expires_at < datetime('now') AND verified_at IS NULL; END; -- Trigger to clean up old login attempts (keep last 1000 entries per user) CREATE TRIGGER IF NOT EXISTS cleanup_old_login_attempts AFTER INSERT ON login_attempts BEGIN DELETE FROM login_attempts WHERE id IN ( SELECT id FROM login_attempts WHERE user_id = NEW.user_id ORDER BY attempted_at DESC LIMIT -1 OFFSET 1000 ); END; -- Trigger to clean up expired user sessions on new session creation CREATE TRIGGER IF NOT EXISTS cleanup_expired_sessions AFTER INSERT ON user_sessions BEGIN DELETE FROM user_sessions WHERE expires_at < datetime('now'); END; -- Trigger to automatically unlock accounts when lock period expires CREATE TRIGGER IF NOT EXISTS auto_unlock_accounts BEFORE UPDATE ON users FOR EACH ROW WHEN NEW.locked_until IS NOT NULL AND NEW.locked_until < datetime('now') BEGIN UPDATE users SET locked_until = NULL, failed_login_attempts = 0 WHERE id = NEW.id; END;