-- Add 2FA support to users table -- Migration: 002_add_2fa_support -- Database: PostgreSQL -- Add 2FA columns to users table ALTER TABLE users ADD COLUMN IF NOT EXISTS two_factor_secret VARCHAR(255), ADD COLUMN IF NOT EXISTS two_factor_enabled BOOLEAN NOT NULL DEFAULT false, ADD COLUMN IF NOT EXISTS backup_codes TEXT[], -- Array of backup codes ADD COLUMN IF NOT EXISTS last_login_at TIMESTAMPTZ, ADD COLUMN IF NOT EXISTS failed_login_attempts INTEGER NOT NULL DEFAULT 0, ADD COLUMN IF NOT EXISTS locked_until TIMESTAMPTZ; -- Create 2FA recovery codes table CREATE TABLE IF NOT EXISTS two_factor_recovery_codes ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE, code_hash VARCHAR(255) NOT NULL, used_at TIMESTAMPTZ, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); -- Create login attempts table for security tracking CREATE TABLE IF NOT EXISTS login_attempts ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), user_id UUID REFERENCES users(id) ON DELETE CASCADE, ip_address INET, user_agent TEXT, success BOOLEAN NOT NULL, failure_reason VARCHAR(255), attempted_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); -- Create password reset tokens table CREATE TABLE IF NOT EXISTS password_reset_tokens ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE, token_hash VARCHAR(255) NOT NULL UNIQUE, expires_at TIMESTAMPTZ NOT NULL, used_at TIMESTAMPTZ, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); -- Create email verification tokens table CREATE TABLE IF NOT EXISTS email_verification_tokens ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE, token_hash VARCHAR(255) NOT NULL UNIQUE, email VARCHAR(255) NOT NULL, -- Allow email change verification expires_at TIMESTAMPTZ NOT NULL, verified_at TIMESTAMPTZ, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); -- 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); -- Add constraint to ensure backup codes are valid JSON array ALTER TABLE users ADD CONSTRAINT backup_codes_valid_json CHECK (backup_codes IS NULL OR jsonb_typeof(backup_codes::jsonb) = 'array'); -- Function to clean up expired tokens CREATE OR REPLACE FUNCTION cleanup_expired_tokens() RETURNS INTEGER AS $$ DECLARE deleted_count INTEGER := 0; BEGIN -- Clean up expired password reset tokens DELETE FROM password_reset_tokens WHERE expires_at < NOW() AND used_at IS NULL; GET DIAGNOSTICS deleted_count = ROW_COUNT; -- Clean up expired email verification tokens DELETE FROM email_verification_tokens WHERE expires_at < NOW() AND verified_at IS NULL; GET DIAGNOSTICS deleted_count = deleted_count + ROW_COUNT; -- Clean up old login attempts (keep last 30 days) DELETE FROM login_attempts WHERE attempted_at < NOW() - INTERVAL '30 days'; GET DIAGNOSTICS deleted_count = deleted_count + ROW_COUNT; -- Clean up expired user sessions DELETE FROM user_sessions WHERE expires_at < NOW(); GET DIAGNOSTICS deleted_count = deleted_count + ROW_COUNT; RETURN deleted_count; END; $$ LANGUAGE plpgsql; -- Function to unlock user accounts after lock period CREATE OR REPLACE FUNCTION unlock_expired_accounts() RETURNS INTEGER AS $$ DECLARE unlocked_count INTEGER := 0; BEGIN UPDATE users SET locked_until = NULL, failed_login_attempts = 0 WHERE locked_until IS NOT NULL AND locked_until < NOW(); GET DIAGNOSTICS unlocked_count = ROW_COUNT; RETURN unlocked_count; END; $$ LANGUAGE plpgsql; -- Add comments for documentation COMMENT ON COLUMN users.two_factor_secret IS 'Base32-encoded TOTP secret for 2FA'; COMMENT ON COLUMN users.two_factor_enabled IS 'Whether 2FA is enabled for this user'; COMMENT ON COLUMN users.backup_codes IS 'JSON array of hashed backup codes for 2FA recovery'; COMMENT ON COLUMN users.last_login_at IS 'Timestamp of last successful login'; COMMENT ON COLUMN users.failed_login_attempts IS 'Number of consecutive failed login attempts'; COMMENT ON COLUMN users.locked_until IS 'Account locked until this timestamp due to failed attempts'; COMMENT ON TABLE two_factor_recovery_codes IS 'Individual 2FA recovery codes for account recovery'; COMMENT ON TABLE login_attempts IS 'Log of all login attempts for security monitoring'; COMMENT ON TABLE password_reset_tokens IS 'Tokens for password reset functionality'; COMMENT ON TABLE email_verification_tokens IS 'Tokens for email verification and changes';