-- Migration: Add authentication fields to existing users table -- This migration adds the necessary fields for the unified User model -- while preserving all existing data BEGIN; -- Add new columns to users table for authentication features ALTER TABLE users ADD COLUMN IF NOT EXISTS full_name VARCHAR(255), ADD COLUMN IF NOT EXISTS is_superuser BOOLEAN DEFAULT FALSE, ADD COLUMN IF NOT EXISTS is_verified BOOLEAN DEFAULT FALSE; -- Add username column if it doesn't exist (make it nullable for existing users) ALTER TABLE users ADD COLUMN IF NOT EXISTS username VARCHAR(50); -- Create unique index on username (partial index to handle NULLs) CREATE UNIQUE INDEX IF NOT EXISTS users_username_unique_idx ON users (username) WHERE username IS NOT NULL; -- Update existing users to have a default username if none exists -- This uses email prefix as username for existing users UPDATE users SET username = SPLIT_PART(email, '@', 1) WHERE username IS NULL; -- Add role column for backward compatibility ALTER TABLE users ADD COLUMN IF NOT EXISTS role VARCHAR(50) DEFAULT 'user'; -- Create the authentication-related tables if they don't exist -- API Keys table CREATE TABLE IF NOT EXISTS api_keys ( id SERIAL PRIMARY KEY, user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE, name VARCHAR(255) NOT NULL, key_hash VARCHAR(255) UNIQUE NOT NULL, key_prefix VARCHAR(10) NOT NULL, scopes TEXT, is_active BOOLEAN DEFAULT TRUE, last_used TIMESTAMP, usage_count INTEGER DEFAULT 0, expires_at TIMESTAMP, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); CREATE INDEX IF NOT EXISTS api_keys_user_id_idx ON api_keys(user_id); CREATE INDEX IF NOT EXISTS api_keys_key_hash_idx ON api_keys(key_hash); -- Refresh Tokens table CREATE TABLE IF NOT EXISTS refresh_tokens ( id SERIAL PRIMARY KEY, user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE, token_hash VARCHAR(255) UNIQUE NOT NULL, jti VARCHAR(36) UNIQUE NOT NULL, device_info VARCHAR(512), is_active BOOLEAN DEFAULT TRUE, expires_at TIMESTAMP NOT NULL, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, last_used TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); CREATE INDEX IF NOT EXISTS refresh_tokens_user_id_idx ON refresh_tokens(user_id); CREATE INDEX IF NOT EXISTS refresh_tokens_token_hash_idx ON refresh_tokens(token_hash); CREATE INDEX IF NOT EXISTS refresh_tokens_jti_idx ON refresh_tokens(jti); -- Token Blacklist table CREATE TABLE IF NOT EXISTS token_blacklist ( id SERIAL PRIMARY KEY, jti VARCHAR(36) UNIQUE NOT NULL, token_type VARCHAR(20) NOT NULL, expires_at TIMESTAMP NOT NULL, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); CREATE INDEX IF NOT EXISTS token_blacklist_jti_idx ON token_blacklist(jti); CREATE INDEX IF NOT EXISTS token_blacklist_expires_at_idx ON token_blacklist(expires_at); -- Create function to automatically update updated_at timestamp CREATE OR REPLACE FUNCTION update_updated_at_column() RETURNS TRIGGER AS $$ BEGIN NEW.updated_at = CURRENT_TIMESTAMP; RETURN NEW; END; $$ language 'plpgsql'; -- Create triggers for updated_at columns DROP TRIGGER IF EXISTS update_users_updated_at ON users; CREATE TRIGGER update_users_updated_at BEFORE UPDATE ON users FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); DROP TRIGGER IF EXISTS update_api_keys_updated_at ON api_keys; CREATE TRIGGER update_api_keys_updated_at BEFORE UPDATE ON api_keys FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); COMMIT;