member_center/docs/SCHEMA.sql

205 lines
5.9 KiB
SQL

-- PostgreSQL schema draft (MVP)
-- Note: OpenIddict/Identity tables are based on EF Core migrations.
CREATE EXTENSION IF NOT EXISTS "pgcrypto";
CREATE TABLE tenants (
id UUID PRIMARY KEY,
name TEXT NOT NULL,
domains TEXT[] NOT NULL DEFAULT '{}',
status TEXT NOT NULL DEFAULT 'active',
created_at TIMESTAMPTZ NOT NULL DEFAULT now()
);
CREATE TABLE users (
id UUID PRIMARY KEY,
user_name TEXT,
normalized_user_name TEXT,
email TEXT,
normalized_email TEXT,
email_confirmed BOOLEAN NOT NULL DEFAULT FALSE,
password_hash TEXT,
security_stamp TEXT,
concurrency_stamp TEXT,
phone_number TEXT,
phone_number_confirmed BOOLEAN NOT NULL DEFAULT FALSE,
two_factor_enabled BOOLEAN NOT NULL DEFAULT FALSE,
lockout_end TIMESTAMPTZ,
lockout_enabled BOOLEAN NOT NULL DEFAULT FALSE,
access_failed_count INTEGER NOT NULL DEFAULT 0,
created_at TIMESTAMPTZ NOT NULL DEFAULT now()
);
CREATE TABLE roles (
id UUID PRIMARY KEY,
name TEXT,
normalized_name TEXT,
concurrency_stamp TEXT,
created_at TIMESTAMPTZ NOT NULL DEFAULT now()
);
CREATE TABLE user_roles (
user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE,
role_id UUID NOT NULL REFERENCES roles(id) ON DELETE CASCADE,
created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
PRIMARY KEY (user_id, role_id)
);
CREATE TABLE user_claims (
id SERIAL PRIMARY KEY,
user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE,
claim_type TEXT,
claim_value TEXT
);
CREATE TABLE role_claims (
id SERIAL PRIMARY KEY,
role_id UUID NOT NULL REFERENCES roles(id) ON DELETE CASCADE,
claim_type TEXT,
claim_value TEXT
);
CREATE TABLE user_logins (
login_provider TEXT NOT NULL,
provider_key TEXT NOT NULL,
provider_display_name TEXT,
user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE,
PRIMARY KEY (login_provider, provider_key)
);
CREATE TABLE user_tokens (
user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE,
login_provider TEXT NOT NULL,
name TEXT NOT NULL,
value TEXT,
PRIMARY KEY (user_id, login_provider, name)
);
CREATE UNIQUE INDEX idx_users_normalized_user_name ON users(normalized_user_name);
CREATE UNIQUE INDEX idx_users_normalized_email ON users(normalized_email);
CREATE UNIQUE INDEX idx_roles_normalized_name ON roles(normalized_name);
-- OpenIddict (EF Core default tables)
CREATE TABLE "OpenIddictApplications" (
"Id" UUID PRIMARY KEY,
"ApplicationType" TEXT,
"ClientId" TEXT,
"ClientSecret" TEXT,
"ConsentType" TEXT,
"DisplayName" TEXT,
"DisplayNames" JSONB,
"Permissions" JSONB,
"PostLogoutRedirectUris" JSONB,
"Properties" JSONB,
"RedirectUris" JSONB,
"Requirements" JSONB,
"ConcurrencyToken" TEXT
);
CREATE TABLE "OpenIddictAuthorizations" (
"Id" UUID PRIMARY KEY,
"ApplicationId" UUID REFERENCES "OpenIddictApplications"("Id") ON DELETE SET NULL,
"CreationDate" TIMESTAMPTZ,
"Status" TEXT,
"Subject" TEXT,
"Type" TEXT,
"Scopes" JSONB,
"Properties" JSONB,
"ConcurrencyToken" TEXT
);
CREATE TABLE "OpenIddictScopes" (
"Id" UUID PRIMARY KEY,
"Description" TEXT,
"Descriptions" JSONB,
"DisplayName" TEXT,
"DisplayNames" JSONB,
"Name" TEXT,
"Properties" JSONB,
"Resources" JSONB,
"ConcurrencyToken" TEXT
);
CREATE TABLE "OpenIddictTokens" (
"Id" UUID PRIMARY KEY,
"ApplicationId" UUID REFERENCES "OpenIddictApplications"("Id") ON DELETE SET NULL,
"AuthorizationId" UUID REFERENCES "OpenIddictAuthorizations"("Id") ON DELETE SET NULL,
"CreationDate" TIMESTAMPTZ,
"ExpirationDate" TIMESTAMPTZ,
"RedemptionDate" TIMESTAMPTZ,
"Payload" TEXT,
"ReferenceId" TEXT,
"Status" TEXT,
"Subject" TEXT,
"Type" TEXT,
"Properties" JSONB,
"ConcurrencyToken" TEXT
);
CREATE UNIQUE INDEX idx_openiddict_applications_client_id ON "OpenIddictApplications"("ClientId");
CREATE UNIQUE INDEX idx_openiddict_scopes_name ON "OpenIddictScopes"("Name");
CREATE UNIQUE INDEX idx_openiddict_tokens_reference_id ON "OpenIddictTokens"("ReferenceId");
CREATE INDEX idx_openiddict_tokens_subject ON "OpenIddictTokens"("Subject");
CREATE TABLE newsletter_lists (
id UUID PRIMARY KEY,
tenant_id UUID NOT NULL REFERENCES tenants(id) ON DELETE CASCADE,
name TEXT NOT NULL,
status TEXT NOT NULL DEFAULT 'active',
created_at TIMESTAMPTZ NOT NULL DEFAULT now()
);
CREATE TABLE newsletter_subscriptions (
id UUID PRIMARY KEY,
list_id UUID NOT NULL REFERENCES newsletter_lists(id) ON DELETE CASCADE,
email TEXT NOT NULL,
user_id UUID REFERENCES users(id) ON DELETE SET NULL,
status TEXT NOT NULL DEFAULT 'pending',
preferences JSONB NOT NULL DEFAULT '{}'::jsonb,
created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
UNIQUE (list_id, email)
);
CREATE TABLE email_verifications (
id UUID PRIMARY KEY,
email TEXT NOT NULL,
tenant_id UUID NOT NULL REFERENCES tenants(id) ON DELETE CASCADE,
token_hash TEXT NOT NULL,
purpose TEXT NOT NULL,
expires_at TIMESTAMPTZ NOT NULL,
consumed_at TIMESTAMPTZ
);
CREATE TABLE unsubscribe_tokens (
id UUID PRIMARY KEY,
subscription_id UUID NOT NULL REFERENCES newsletter_subscriptions(id) ON DELETE CASCADE,
token_hash TEXT NOT NULL,
expires_at TIMESTAMPTZ NOT NULL,
consumed_at TIMESTAMPTZ
);
CREATE TABLE audit_logs (
id UUID PRIMARY KEY,
actor_type TEXT NOT NULL,
actor_id UUID,
action TEXT NOT NULL,
payload JSONB NOT NULL DEFAULT '{}'::jsonb,
created_at TIMESTAMPTZ NOT NULL DEFAULT now()
);
CREATE TABLE system_flags (
id UUID PRIMARY KEY,
key TEXT NOT NULL UNIQUE,
value TEXT NOT NULL,
updated_at TIMESTAMPTZ NOT NULL DEFAULT now()
);
CREATE INDEX idx_newsletter_subscriptions_email
ON newsletter_subscriptions(email);
CREATE INDEX idx_newsletter_subscriptions_list_id
ON newsletter_subscriptions(list_id);
CREATE INDEX idx_email_verifications_email
ON email_verifications(email);