-- Authentication Tables Migration -- Adds users table and updates api_keys with foreign key -- Users table CREATE TABLE IF NOT EXISTS users ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), username VARCHAR(255) UNIQUE NOT NULL, password_hash VARCHAR(255), email VARCHAR(255), is_admin BOOLEAN DEFAULT FALSE, is_active BOOLEAN DEFAULT TRUE, must_change_password BOOLEAN DEFAULT FALSE, oidc_subject VARCHAR(255), oidc_issuer VARCHAR(512), created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), last_login TIMESTAMP WITH TIME ZONE ); CREATE INDEX IF NOT EXISTS idx_users_username ON users(username); CREATE INDEX IF NOT EXISTS idx_users_email ON users(email) WHERE email IS NOT NULL; CREATE INDEX IF NOT EXISTS idx_users_oidc_subject ON users(oidc_subject) WHERE oidc_subject IS NOT NULL; CREATE INDEX IF NOT EXISTS idx_users_is_active ON users(is_active) WHERE is_active = TRUE; -- Sessions table for web login CREATE TABLE IF NOT EXISTS sessions ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE, token_hash VARCHAR(64) NOT NULL UNIQUE, created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), expires_at TIMESTAMP WITH TIME ZONE NOT NULL, last_accessed TIMESTAMP WITH TIME ZONE DEFAULT NOW(), user_agent VARCHAR(512), ip_address VARCHAR(45) ); CREATE INDEX IF NOT EXISTS idx_sessions_user_id ON sessions(user_id); CREATE INDEX IF NOT EXISTS idx_sessions_token_hash ON sessions(token_hash); CREATE INDEX IF NOT EXISTS idx_sessions_expires_at ON sessions(expires_at); -- Auth settings for OIDC configuration (future use) CREATE TABLE IF NOT EXISTS auth_settings ( key VARCHAR(255) PRIMARY KEY, value TEXT NOT NULL, updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() ); -- Add user_id foreign key to api_keys table -- First add the column (nullable initially) ALTER TABLE api_keys ADD COLUMN IF NOT EXISTS owner_id UUID REFERENCES users(id) ON DELETE CASCADE; -- Add scopes column for API key permissions ALTER TABLE api_keys ADD COLUMN IF NOT EXISTS scopes TEXT[] DEFAULT ARRAY['read', 'write']; -- Add description column ALTER TABLE api_keys ADD COLUMN IF NOT EXISTS description TEXT; -- Create index for owner_id CREATE INDEX IF NOT EXISTS idx_api_keys_owner_id ON api_keys(owner_id) WHERE owner_id IS NOT NULL; -- Trigger to update users.updated_at CREATE TRIGGER users_updated_at_trigger BEFORE UPDATE ON users FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); -- Trigger to update sessions.last_accessed on access CREATE OR REPLACE FUNCTION update_session_last_accessed() RETURNS TRIGGER AS $$ BEGIN NEW.last_accessed = NOW(); RETURN NEW; END; $$ LANGUAGE plpgsql; -- Function to clean up expired sessions (can be called periodically) CREATE OR REPLACE FUNCTION cleanup_expired_sessions() RETURNS INTEGER AS $$ DECLARE deleted_count INTEGER; BEGIN DELETE FROM sessions WHERE expires_at < NOW(); GET DIAGNOSTICS deleted_count = ROW_COUNT; RETURN deleted_count; END; $$ LANGUAGE plpgsql;