member_center/docs/SCHEMA.sql
2026-01-30 16:57:29 +09:00

145 lines
4.0 KiB
SQL

-- PostgreSQL schema draft (MVP)
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,
email TEXT NOT NULL UNIQUE,
password_hash TEXT NOT NULL,
email_verified_at TIMESTAMPTZ,
status TEXT NOT NULL DEFAULT 'active',
created_at TIMESTAMPTZ NOT NULL DEFAULT now()
);
CREATE TABLE oauth_clients (
id UUID PRIMARY KEY,
tenant_id UUID NOT NULL REFERENCES tenants(id),
name TEXT NOT NULL,
redirect_uris TEXT[] NOT NULL DEFAULT '{}',
client_type TEXT NOT NULL DEFAULT 'confidential',
client_secret_hash TEXT,
created_at TIMESTAMPTZ NOT NULL DEFAULT now()
);
ALTER TABLE oauth_clients
ADD CONSTRAINT chk_oauth_clients_secret
CHECK (
(client_type = 'confidential' AND client_secret_hash IS NOT NULL)
OR (client_type <> 'confidential')
);
CREATE TABLE oauth_codes (
id UUID PRIMARY KEY,
client_id UUID NOT NULL REFERENCES oauth_clients(id),
user_id UUID NOT NULL REFERENCES users(id),
code_hash TEXT NOT NULL,
code_challenge TEXT NOT NULL,
code_challenge_method TEXT NOT NULL DEFAULT 'S256',
expires_at TIMESTAMPTZ NOT NULL,
consumed_at TIMESTAMPTZ
);
CREATE TABLE oauth_tokens (
id UUID PRIMARY KEY,
user_id UUID NOT NULL REFERENCES users(id),
client_id UUID NOT NULL REFERENCES oauth_clients(id),
access_token_hash TEXT NOT NULL,
refresh_token_hash TEXT NOT NULL,
expires_at TIMESTAMPTZ NOT NULL,
revoked_at TIMESTAMPTZ
);
CREATE TABLE oidc_id_tokens (
id UUID PRIMARY KEY,
user_id UUID NOT NULL REFERENCES users(id),
client_id UUID NOT NULL REFERENCES oauth_clients(id),
id_token_hash TEXT NOT NULL,
expires_at TIMESTAMPTZ NOT NULL
);
CREATE TABLE newsletter_lists (
id UUID PRIMARY KEY,
tenant_id UUID NOT NULL REFERENCES tenants(id),
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),
email TEXT NOT NULL,
user_id UUID REFERENCES users(id),
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),
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),
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 roles (
id UUID PRIMARY KEY,
name TEXT NOT NULL UNIQUE,
created_at TIMESTAMPTZ NOT NULL DEFAULT now()
);
CREATE TABLE user_roles (
user_id UUID NOT NULL REFERENCES users(id),
role_id UUID NOT NULL REFERENCES roles(id),
created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
PRIMARY KEY (user_id, role_id)
);
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_oauth_tokens_user_id
ON oauth_tokens(user_id);
CREATE INDEX idx_oauth_tokens_client_id
ON oauth_tokens(client_id);
CREATE INDEX idx_oauth_codes_client_id
ON oauth_codes(client_id);
CREATE INDEX idx_email_verifications_email
ON email_verifications(email);
CREATE INDEX idx_user_roles_role_id
ON user_roles(role_id);