-- Migration 002: Add Two-Factor Authentication Support -- This migration adds TOTP (Time-based One-Time Password) support for 2FA -- User 2FA settings table CREATE TABLE user_2fa ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), user_id UUID REFERENCES users(id) ON DELETE CASCADE UNIQUE, secret VARCHAR(32) NOT NULL, -- Base32 encoded TOTP secret is_enabled BOOLEAN DEFAULT FALSE, backup_codes TEXT[], -- Array of backup codes created_at TIMESTAMPTZ DEFAULT NOW(), updated_at TIMESTAMPTZ DEFAULT NOW(), last_used TIMESTAMPTZ, -- Constraints CONSTRAINT user_2fa_secret_length CHECK (char_length(secret) = 32), CONSTRAINT user_2fa_backup_codes_count CHECK (array_length(backup_codes, 1) <= 10) ); -- 2FA recovery codes table (for better tracking) CREATE TABLE user_2fa_recovery_codes ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), user_id UUID REFERENCES users(id) ON DELETE CASCADE, code_hash VARCHAR(255) NOT NULL, -- Hashed recovery code used_at TIMESTAMPTZ, created_at TIMESTAMPTZ DEFAULT NOW(), -- Constraints CONSTRAINT user_2fa_recovery_codes_unique UNIQUE(user_id, code_hash) ); -- 2FA authentication attempts table (for rate limiting and security) CREATE TABLE user_2fa_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, code_type VARCHAR(20) NOT NULL, -- 'totp' or 'backup' created_at TIMESTAMPTZ DEFAULT NOW(), -- Constraints CONSTRAINT user_2fa_attempts_valid_code_type CHECK (code_type IN ('totp', 'backup')) ); -- Add 2FA required flag to users table ALTER TABLE users ADD COLUMN two_factor_required BOOLEAN DEFAULT FALSE; -- Add 2FA verified flag to sessions table ALTER TABLE sessions ADD COLUMN two_factor_verified BOOLEAN DEFAULT FALSE; -- Update tokens table to support 2FA setup tokens ALTER TABLE tokens DROP CONSTRAINT tokens_valid_type; ALTER TABLE tokens ADD CONSTRAINT tokens_valid_type CHECK ( token_type IN ('password_reset', 'email_verification', 'account_activation', '2fa_setup') ); -- Indexes for performance CREATE INDEX idx_user_2fa_user_id ON user_2fa(user_id); CREATE INDEX idx_user_2fa_recovery_codes_user_id ON user_2fa_recovery_codes(user_id); CREATE INDEX idx_user_2fa_attempts_user_id ON user_2fa_attempts(user_id); CREATE INDEX idx_user_2fa_attempts_created_at ON user_2fa_attempts(created_at); CREATE INDEX idx_sessions_2fa_verified ON sessions(two_factor_verified); -- Function to cleanup old 2FA attempts (for maintenance) CREATE OR REPLACE FUNCTION cleanup_old_2fa_attempts() RETURNS void AS $$ BEGIN DELETE FROM user_2fa_attempts WHERE created_at < NOW() - INTERVAL '7 days'; END; $$ LANGUAGE plpgsql; -- Trigger to update updated_at on user_2fa table CREATE OR REPLACE FUNCTION update_user_2fa_updated_at() RETURNS TRIGGER AS $$ BEGIN NEW.updated_at = NOW(); RETURN NEW; END; $$ LANGUAGE plpgsql; CREATE TRIGGER trigger_user_2fa_updated_at BEFORE UPDATE ON user_2fa FOR EACH ROW EXECUTE FUNCTION update_user_2fa_updated_at(); -- Comments for documentation COMMENT ON TABLE user_2fa IS 'Stores TOTP secrets and 2FA configuration for users'; COMMENT ON COLUMN user_2fa.secret IS 'Base32 encoded TOTP secret key'; COMMENT ON COLUMN user_2fa.backup_codes IS 'Array of hashed backup codes for account recovery'; COMMENT ON COLUMN user_2fa.is_enabled IS 'Whether 2FA is currently enabled for the user'; COMMENT ON TABLE user_2fa_recovery_codes IS 'Individual recovery codes for better tracking and management'; COMMENT ON COLUMN user_2fa_recovery_codes.code_hash IS 'SHA256 hash of the recovery code'; COMMENT ON TABLE user_2fa_attempts IS 'Tracks 2FA authentication attempts for security monitoring'; COMMENT ON COLUMN user_2fa_attempts.code_type IS 'Type of 2FA code used: totp or backup'; COMMENT ON COLUMN users.two_factor_required IS 'Whether 2FA is required for this user account'; COMMENT ON COLUMN sessions.two_factor_verified IS 'Whether this session has completed 2FA verification';