Files
quyun-v2/backend/database/migrations/20251218190000_tenant_invites_join_requests.sql

82 lines
5.2 KiB
SQL
Raw Blame History

This file contains ambiguous Unicode characters
This file contains Unicode characters that might be confused with other characters. If you think that this is intentional, you can safely ignore this warning. Use the Escape button to reveal them.
-- +goose Up
-- +goose StatementBegin
CREATE TABLE IF NOT EXISTS tenant_invites(
id bigserial PRIMARY KEY,
tenant_id bigint NOT NULL,
user_id bigint NOT NULL,
code varchar(64) NOT NULL,
status varchar(32) NOT NULL DEFAULT 'active',
max_uses int NOT NULL DEFAULT 0,
used_count int NOT NULL DEFAULT 0,
expires_at timestamptz,
disabled_at timestamptz,
disabled_operator_user_id bigint,
remark varchar(255) NOT NULL DEFAULT '',
created_at timestamptz NOT NULL DEFAULT NOW(),
updated_at timestamptz NOT NULL DEFAULT NOW(),
UNIQUE (tenant_id, code)
);
-- tenant_invites租户邀请用于用户通过邀请码加入租户
COMMENT ON TABLE tenant_invites IS '租户邀请:租户管理员生成的邀请码;用户可通过 code 加入租户;支持禁用、过期、使用次数限制;所有查询/写入必须限定 tenant_id';
COMMENT ON COLUMN tenant_invites.id IS '主键ID自增';
COMMENT ON COLUMN tenant_invites.tenant_id IS '租户ID多租户隔离关键字段所有查询/写入必须限定 tenant_id';
COMMENT ON COLUMN tenant_invites.user_id IS '创建人用户ID生成邀请码的租户管理员审计用';
COMMENT ON COLUMN tenant_invites.code IS '邀请码:用户加入租户时提交;同一租户内唯一';
COMMENT ON COLUMN tenant_invites.status IS '邀请状态active/disabled/expiredexpired 也可由 expires_at 推导,业务侧需保持一致';
COMMENT ON COLUMN tenant_invites.max_uses IS '最大可使用次数0 表示不限制;>0 时 used_count 达到该值后视为失效';
COMMENT ON COLUMN tenant_invites.used_count IS '已使用次数:每次成功加入时 +1需事务保证并发下不超发';
COMMENT ON COLUMN tenant_invites.expires_at IS '过期时间到期后不可再使用UTC为空表示不过期';
COMMENT ON COLUMN tenant_invites.disabled_at IS '禁用时间租户管理员禁用该邀请的时间UTC';
COMMENT ON COLUMN tenant_invites.disabled_operator_user_id IS '禁用操作人用户ID租户管理员审计用';
COMMENT ON COLUMN tenant_invites.remark IS '备注:生成/禁用原因等(审计用)';
COMMENT ON COLUMN tenant_invites.created_at IS '创建时间:默认 now()';
COMMENT ON COLUMN tenant_invites.updated_at IS '更新时间:默认 now()';
CREATE INDEX IF NOT EXISTS ix_tenant_invites_tenant_status ON tenant_invites(tenant_id, status);
CREATE INDEX IF NOT EXISTS ix_tenant_invites_tenant_expires_at ON tenant_invites(tenant_id, expires_at);
CREATE TABLE IF NOT EXISTS tenant_join_requests(
id bigserial PRIMARY KEY,
tenant_id bigint NOT NULL,
user_id bigint NOT NULL,
status varchar(32) NOT NULL DEFAULT 'pending',
reason varchar(255) NOT NULL DEFAULT '',
decided_at timestamptz,
decided_operator_user_id bigint,
decided_reason varchar(255) NOT NULL DEFAULT '',
created_at timestamptz NOT NULL DEFAULT NOW(),
updated_at timestamptz NOT NULL DEFAULT NOW()
);
-- tenant_join_requests加入租户申请用于无邀请码场景的人工审核
COMMENT ON TABLE tenant_join_requests IS '加入申请:用户申请加入租户,租户管理员审核通过/拒绝;所有查询/写入必须限定 tenant_id';
COMMENT ON COLUMN tenant_join_requests.id IS '主键ID自增';
COMMENT ON COLUMN tenant_join_requests.tenant_id IS '租户ID多租户隔离关键字段所有查询/写入必须限定 tenant_id';
COMMENT ON COLUMN tenant_join_requests.user_id IS '申请人用户ID发起加入申请的用户';
COMMENT ON COLUMN tenant_join_requests.status IS '申请状态pending/approved/rejected状态变更需记录 decided_at 与 decided_operator_user_id';
COMMENT ON COLUMN tenant_join_requests.reason IS '申请原因:用户填写的加入说明(可选)';
COMMENT ON COLUMN tenant_join_requests.decided_at IS '处理时间:审核通过/拒绝时记录UTC';
COMMENT ON COLUMN tenant_join_requests.decided_operator_user_id IS '处理人用户ID租户管理员审计用';
COMMENT ON COLUMN tenant_join_requests.decided_reason IS '处理说明:管理员通过/拒绝的原因(可选,审计用)';
COMMENT ON COLUMN tenant_join_requests.created_at IS '创建时间:默认 now()';
COMMENT ON COLUMN tenant_join_requests.updated_at IS '更新时间:默认 now()';
-- 约束:同一用户同一租户同一时间仅允许存在一个 pending 申请,避免重复提交淹没审核队列。
CREATE UNIQUE INDEX IF NOT EXISTS ux_tenant_join_requests_tenant_user_pending ON tenant_join_requests(tenant_id, user_id) WHERE status = 'pending';
CREATE INDEX IF NOT EXISTS ix_tenant_join_requests_tenant_status ON tenant_join_requests(tenant_id, status);
CREATE INDEX IF NOT EXISTS ix_tenant_join_requests_tenant_created_at ON tenant_join_requests(tenant_id, created_at);
-- +goose StatementEnd
-- +goose Down
-- +goose StatementBegin
DROP INDEX IF EXISTS ix_tenant_join_requests_tenant_created_at;
DROP INDEX IF EXISTS ix_tenant_join_requests_tenant_status;
DROP INDEX IF EXISTS ux_tenant_join_requests_tenant_user_pending;
DROP TABLE IF EXISTS tenant_join_requests;
DROP INDEX IF EXISTS ix_tenant_invites_tenant_expires_at;
DROP INDEX IF EXISTS ix_tenant_invites_tenant_status;
DROP TABLE IF EXISTS tenant_invites;
-- +goose StatementEnd