Files
quyun-v2/backend/database/migrations/20251222211500_tenant_ledgers_audit_fields.sql

41 lines
2.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
ALTER TABLE tenant_ledgers
ADD COLUMN IF NOT EXISTS operator_user_id bigint,
ADD COLUMN IF NOT EXISTS biz_ref_type varchar(32),
ADD COLUMN IF NOT EXISTS biz_ref_id bigint;
-- tenant_ledgers.operator_user_id操作者谁触发该流水
-- 用途:用于审计与风控追溯(例如后台代退款/调账等)。
COMMENT ON COLUMN tenant_ledgers.operator_user_id IS '操作者用户ID谁触发该流水admin/buyer/system用于审计与追责可为空历史数据或无法识别时';
-- tenant_ledgers.biz_ref_type/biz_ref_id业务引用幂等与追溯
-- 用途:在 idempotency_key 之外提供结构化引用(例如 order/refund 等),便于报表与按业务对象追溯。
COMMENT ON COLUMN tenant_ledgers.biz_ref_type IS '业务引用类型order/refund/etc与 biz_ref_id 组成可选的结构化幂等/追溯键';
COMMENT ON COLUMN tenant_ledgers.biz_ref_id IS '业务引用ID与 biz_ref_type 配合使用(例如 orders.id用于对账与审计';
-- 索引:按操作者检索敏感操作流水(后台审计用)。
CREATE INDEX IF NOT EXISTS ix_tenant_ledgers_tenant_operator ON tenant_ledgers(tenant_id, operator_user_id);
-- 索引:按业务引用快速定位同一业务对象的流水集合。
CREATE INDEX IF NOT EXISTS ix_tenant_ledgers_tenant_biz_ref ON tenant_ledgers(tenant_id, biz_ref_type, biz_ref_id);
-- 结构化幂等(可选):同一业务引用在同一流水类型下只能出现一条。
-- 说明biz_ref_* 允许为空;仅当两者都非空时才参与唯一性约束。
CREATE UNIQUE INDEX IF NOT EXISTS ux_tenant_ledgers_tenant_biz_ref_type_id_type
ON tenant_ledgers(tenant_id, biz_ref_type, biz_ref_id, type)
WHERE biz_ref_type IS NOT NULL AND biz_ref_id IS NOT NULL;
-- +goose StatementEnd
-- +goose Down
-- +goose StatementBegin
DROP INDEX IF EXISTS ux_tenant_ledgers_tenant_biz_ref_type_id_type;
DROP INDEX IF EXISTS ix_tenant_ledgers_tenant_biz_ref;
DROP INDEX IF EXISTS ix_tenant_ledgers_tenant_operator;
ALTER TABLE tenant_ledgers
DROP COLUMN IF EXISTS biz_ref_id,
DROP COLUMN IF EXISTS biz_ref_type,
DROP COLUMN IF EXISTS operator_user_id;
-- +goose StatementEnd