-- Add password and security fields to users table ALTER TABLE users ADD COLUMN IF NOT EXISTS password_hash VARCHAR(255), ADD COLUMN IF NOT EXISTS password_salt VARCHAR(255), ADD COLUMN IF NOT EXISTS email_verified BOOLEAN DEFAULT FALSE, ADD COLUMN IF NOT EXISTS email_verification_token VARCHAR(255), ADD COLUMN IF NOT EXISTS email_verification_expires_at TIMESTAMP WITH TIME ZONE, ADD COLUMN IF NOT EXISTS password_reset_token VARCHAR(255), ADD COLUMN IF NOT EXISTS password_reset_expires_at TIMESTAMP WITH TIME ZONE, ADD COLUMN IF NOT EXISTS failed_login_attempts INTEGER DEFAULT 0, ADD COLUMN IF NOT EXISTS locked_until TIMESTAMP WITH TIME ZONE, ADD COLUMN IF NOT EXISTS two_factor_enabled BOOLEAN DEFAULT FALSE, ADD COLUMN IF NOT EXISTS two_factor_secret VARCHAR(255), ADD COLUMN IF NOT EXISTS two_factor_backup_codes TEXT[], ADD COLUMN IF NOT EXISTS last_password_change TIMESTAMP WITH TIME ZONE; -- Create password_reset_tokens table for better tracking CREATE TABLE IF NOT EXISTS password_reset_tokens ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE, token VARCHAR(255) NOT NULL UNIQUE, expires_at TIMESTAMP WITH TIME ZONE NOT NULL, used_at TIMESTAMP WITH TIME ZONE, created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(), ip_address VARCHAR(45), user_agent TEXT ); -- Create email_verification_tokens table CREATE TABLE IF NOT EXISTS email_verification_tokens ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE, token VARCHAR(255) NOT NULL UNIQUE, email VARCHAR(255) NOT NULL, expires_at TIMESTAMP WITH TIME ZONE NOT NULL, used_at TIMESTAMP WITH TIME ZONE, created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(), ip_address VARCHAR(45), user_agent TEXT ); -- Create login_attempts table for tracking failed attempts CREATE TABLE IF NOT EXISTS login_attempts ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), email VARCHAR(255) NOT NULL, ip_address VARCHAR(45) NOT NULL, user_agent TEXT, success BOOLEAN NOT NULL, failure_reason VARCHAR(255), attempted_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(), session_id VARCHAR(255) ); -- Create two_factor_recovery_codes table CREATE TABLE IF NOT EXISTS two_factor_recovery_codes ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE, code_hash VARCHAR(255) NOT NULL, used_at TIMESTAMP WITH TIME ZONE, created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW() ); -- Add indexes for security tables CREATE INDEX IF NOT EXISTS idx_password_reset_tokens_token ON password_reset_tokens(token); CREATE INDEX IF NOT EXISTS idx_password_reset_tokens_user_id ON password_reset_tokens(user_id); CREATE INDEX IF NOT EXISTS idx_password_reset_tokens_expires_at ON password_reset_tokens(expires_at); CREATE INDEX IF NOT EXISTS idx_email_verification_tokens_token ON email_verification_tokens(token); CREATE INDEX IF NOT EXISTS idx_email_verification_tokens_user_id ON email_verification_tokens(user_id); CREATE INDEX IF NOT EXISTS idx_email_verification_tokens_expires_at ON email_verification_tokens(expires_at); CREATE INDEX IF NOT EXISTS idx_login_attempts_email ON login_attempts(email); CREATE INDEX IF NOT EXISTS idx_login_attempts_ip_address ON login_attempts(ip_address); CREATE INDEX IF NOT EXISTS idx_login_attempts_attempted_at ON login_attempts(attempted_at); CREATE INDEX IF NOT EXISTS idx_two_factor_recovery_codes_user_id ON two_factor_recovery_codes(user_id); -- Add indexes for new user fields CREATE INDEX IF NOT EXISTS idx_users_email_verified ON users(email_verified); CREATE INDEX IF NOT EXISTS idx_users_email_verification_token ON users(email_verification_token); CREATE INDEX IF NOT EXISTS idx_users_password_reset_token ON users(password_reset_token); CREATE INDEX IF NOT EXISTS idx_users_locked_until ON users(locked_until); CREATE INDEX IF NOT EXISTS idx_users_two_factor_enabled ON users(two_factor_enabled); -- Update existing admin user to have verified email UPDATE users SET email_verified = TRUE, password_hash = '$2a$12$dummy.hash.for.system.admin.user.replace.with.real', last_password_change = NOW() WHERE email = 'admin@example.com';