-- Generated from docs/db/SPECIFICATION.md ยง5.1 (2025-11-28) CREATE SCHEMA IF NOT EXISTS authority; -- Core identity tables CREATE TABLE IF NOT EXISTS authority.tenants ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), code TEXT NOT NULL UNIQUE, display_name TEXT NOT NULL, status TEXT NOT NULL DEFAULT 'active' CHECK (status IN ('active', 'suspended', 'trial', 'terminated')), settings JSONB DEFAULT '{}', created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); CREATE TABLE IF NOT EXISTS authority.users ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), tenant_id UUID NOT NULL REFERENCES authority.tenants(id), subject_id UUID NOT NULL UNIQUE, username TEXT NOT NULL, normalized_username TEXT NOT NULL, display_name TEXT, email TEXT, email_verified BOOLEAN NOT NULL DEFAULT FALSE, disabled BOOLEAN NOT NULL DEFAULT FALSE, plugin TEXT, attributes JSONB DEFAULT '{}', created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), UNIQUE (tenant_id, normalized_username) ); CREATE TABLE IF NOT EXISTS authority.roles ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), tenant_id UUID REFERENCES authority.tenants(id), name TEXT NOT NULL, description TEXT, is_system BOOLEAN NOT NULL DEFAULT FALSE, permissions TEXT[] DEFAULT '{}', created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), UNIQUE (tenant_id, name) ); CREATE TABLE IF NOT EXISTS authority.user_roles ( user_id UUID NOT NULL REFERENCES authority.users(id) ON DELETE CASCADE, role_id UUID NOT NULL REFERENCES authority.roles(id) ON DELETE CASCADE, granted_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), granted_by TEXT, PRIMARY KEY (user_id, role_id) ); CREATE TABLE IF NOT EXISTS authority.service_accounts ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), tenant_id UUID NOT NULL REFERENCES authority.tenants(id), account_id TEXT NOT NULL, display_name TEXT NOT NULL, description TEXT, enabled BOOLEAN NOT NULL DEFAULT TRUE, allowed_scopes TEXT[] DEFAULT '{}', authorized_clients TEXT[] DEFAULT '{}', attributes JSONB DEFAULT '{}', created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), UNIQUE (tenant_id, account_id) ); CREATE TABLE IF NOT EXISTS authority.clients ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), client_id TEXT NOT NULL UNIQUE, client_secret_hash TEXT, display_name TEXT, type TEXT NOT NULL DEFAULT 'confidential' CHECK (type IN ('public', 'confidential')), redirect_uris TEXT[] DEFAULT '{}', post_logout_redirect_uris TEXT[] DEFAULT '{}', permissions TEXT[] DEFAULT '{}', requirements TEXT[] DEFAULT '{}', settings JSONB DEFAULT '{}', created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); CREATE TABLE IF NOT EXISTS authority.scopes ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), name TEXT NOT NULL UNIQUE, display_name TEXT, description TEXT, resources TEXT[] DEFAULT '{}' ); CREATE TABLE IF NOT EXISTS authority.tokens ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), subject_id UUID NOT NULL, client_id TEXT, token_type TEXT NOT NULL CHECK (token_type IN ('access', 'refresh', 'authorization_code')), token_hash TEXT NOT NULL UNIQUE, scopes TEXT[] DEFAULT '{}', issued_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), expires_at TIMESTAMPTZ NOT NULL, revoked_at TIMESTAMPTZ, revocation_reason TEXT, metadata JSONB DEFAULT '{}' ); CREATE TABLE IF NOT EXISTS authority.revocations ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), token_id UUID REFERENCES authority.tokens(id), jti TEXT, revoked_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), reason TEXT, revoked_by TEXT ); CREATE TABLE IF NOT EXISTS authority.login_attempts ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), tenant_id UUID REFERENCES authority.tenants(id), username TEXT NOT NULL, ip_address INET, user_agent TEXT, success BOOLEAN NOT NULL, failure_reason TEXT, attempted_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); CREATE TABLE IF NOT EXISTS authority.licenses ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), tenant_id UUID NOT NULL REFERENCES authority.tenants(id), license_key TEXT NOT NULL UNIQUE, edition TEXT NOT NULL CHECK (edition IN ('community', 'standard', 'enterprise', 'sovereign')), max_nodes INT, max_projects INT, features JSONB DEFAULT '{}', start_date DATE NOT NULL, end_date DATE, issued_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), issued_by TEXT, revoked_at TIMESTAMPTZ, revocation_reason TEXT ); CREATE TABLE IF NOT EXISTS authority.license_usage ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), license_id UUID NOT NULL REFERENCES authority.licenses(id), scanner_node_id TEXT NOT NULL, project_id TEXT, scanner_version TEXT, first_seen_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), last_seen_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), UNIQUE (license_id, scanner_node_id) ); -- Indexes CREATE INDEX IF NOT EXISTS idx_users_tenant ON authority.users(tenant_id); CREATE INDEX IF NOT EXISTS idx_users_email ON authority.users(email) WHERE email IS NOT NULL; CREATE INDEX IF NOT EXISTS idx_users_subject ON authority.users(subject_id); CREATE INDEX IF NOT EXISTS idx_service_accounts_tenant ON authority.service_accounts(tenant_id); CREATE INDEX IF NOT EXISTS idx_tokens_subject ON authority.tokens(subject_id); CREATE INDEX IF NOT EXISTS idx_tokens_expires ON authority.tokens(expires_at) WHERE revoked_at IS NULL; CREATE INDEX IF NOT EXISTS idx_tokens_hash ON authority.tokens(token_hash); CREATE INDEX IF NOT EXISTS idx_login_attempts_tenant_time ON authority.login_attempts(tenant_id, attempted_at DESC); CREATE INDEX IF NOT EXISTS idx_licenses_tenant ON authority.licenses(tenant_id);