Files
quyun-v2/backend/database/migrations/20251218120000_orders_ledgers.sql

139 lines
9.0 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 orders(
id bigserial PRIMARY KEY,
tenant_id bigint NOT NULL,
user_id bigint NOT NULL,
type varchar(32) NOT NULL DEFAULT 'content_purchase',
status varchar(32) NOT NULL DEFAULT 'created',
currency varchar(16) NOT NULL DEFAULT 'CNY',
amount_original bigint NOT NULL DEFAULT 0,
amount_discount bigint NOT NULL DEFAULT 0,
amount_paid bigint NOT NULL DEFAULT 0,
snapshot jsonb NOT NULL DEFAULT '{}'::jsonb,
idempotency_key varchar(128) NOT NULL DEFAULT '',
paid_at timestamptz,
refunded_at timestamptz,
refund_forced boolean NOT NULL DEFAULT false,
refund_operator_user_id bigint,
refund_reason varchar(255) NOT NULL DEFAULT '',
created_at timestamptz NOT NULL DEFAULT NOW(),
updated_at timestamptz NOT NULL DEFAULT NOW()
);
-- orders订单主表租户内购买等业务单据
COMMENT ON TABLE orders IS '订单:租户内的业务交易单据;记录成交金额快照、状态流转与退款信息;所有查询/写入必须限定 tenant_id';
COMMENT ON COLUMN orders.id IS '主键ID自增用于关联订单明细、账本流水、权益等';
COMMENT ON COLUMN orders.tenant_id IS '租户ID多租户隔离关键字段所有查询/写入必须限定 tenant_id';
COMMENT ON COLUMN orders.user_id IS '用户ID下单用户buyer余额扣款与权益归属以该 user_id 为准';
COMMENT ON COLUMN orders.type IS '订单类型content_purchase购买内容当前默认 content_purchase';
COMMENT ON COLUMN orders.status IS '订单状态created/paid/refunding/refunded/canceled/failed状态变更需与账本/权益保持一致';
COMMENT ON COLUMN orders.currency IS '币种:当前固定 CNY金额单位为分';
COMMENT ON COLUMN orders.amount_original IS '原价金额:分;未折扣前金额(用于展示与对账)';
COMMENT ON COLUMN orders.amount_discount IS '优惠金额amount_paid = amount_original - amount_discount下单时快照';
COMMENT ON COLUMN orders.amount_paid IS '实付金额:分;从租户内余额扣款的金额(下单时快照)';
COMMENT ON COLUMN orders.snapshot IS '订单快照JSON建议包含 content 标题/定价/折扣、请求来源等,避免改价影响历史展示';
COMMENT ON COLUMN orders.idempotency_key IS '幂等键:同一租户同一用户同一业务请求可用;用于防重复下单/重复扣款(建议由客户端生成)';
COMMENT ON COLUMN orders.paid_at IS '支付/扣款完成时间:余额支付在 debit_purchase 成功后写入';
COMMENT ON COLUMN orders.refunded_at IS '退款完成时间:退款落账成功后写入';
COMMENT ON COLUMN orders.refund_forced IS '是否强制退款true 表示租户管理侧绕过时间窗执行退款(需审计)';
COMMENT ON COLUMN orders.refund_operator_user_id IS '退款操作人用户ID租户管理员/系统;用于审计与追责';
COMMENT ON COLUMN orders.refund_reason IS '退款原因:后台/用户发起退款的原因说明;用于审计';
COMMENT ON COLUMN orders.created_at IS '创建时间:默认 now();用于审计与排序';
COMMENT ON COLUMN orders.updated_at IS '更新时间:默认 now();状态变更/退款写入时更新';
CREATE INDEX IF NOT EXISTS ix_orders_tenant_user ON orders(tenant_id, user_id);
CREATE INDEX IF NOT EXISTS ix_orders_tenant_status ON orders(tenant_id, status);
CREATE INDEX IF NOT EXISTS ix_orders_tenant_paid_at ON orders(tenant_id, paid_at);
CREATE UNIQUE INDEX IF NOT EXISTS ux_orders_tenant_idempotency_key ON orders(tenant_id, user_id, idempotency_key) WHERE idempotency_key <> '';
CREATE TABLE IF NOT EXISTS order_items(
id bigserial PRIMARY KEY,
tenant_id bigint NOT NULL,
user_id bigint NOT NULL,
order_id bigint NOT NULL,
content_id bigint NOT NULL,
content_user_id bigint NOT NULL DEFAULT 0,
amount_paid bigint NOT NULL DEFAULT 0,
snapshot jsonb NOT NULL DEFAULT '{}'::jsonb,
created_at timestamptz NOT NULL DEFAULT NOW(),
updated_at timestamptz NOT NULL DEFAULT NOW(),
UNIQUE (tenant_id, order_id, content_id)
);
-- order_items订单明细购买内容通常一单一内容但保留扩展能力
COMMENT ON TABLE order_items IS '订单明细:记录订单购买的具体内容及金额/快照;支持后续扩展为一单多内容';
COMMENT ON COLUMN order_items.id IS '主键ID自增';
COMMENT ON COLUMN order_items.tenant_id IS '租户ID多租户隔离关键字段必须与 orders.tenant_id 一致';
COMMENT ON COLUMN order_items.user_id IS '用户ID下单用户buyer冗余字段用于查询加速与审计';
COMMENT ON COLUMN order_items.order_id IS '订单ID关联 orders.id用于聚合订单明细';
COMMENT ON COLUMN order_items.content_id IS '内容ID关联 contents.id用于生成/撤销 content_access';
COMMENT ON COLUMN order_items.content_user_id IS '内容作者用户ID用于后续分成/对账扩展;当前可为 0 或写入内容创建者';
COMMENT ON COLUMN order_items.amount_paid IS '该行实付金额:分;通常等于订单 amount_paid单内容场景';
COMMENT ON COLUMN order_items.snapshot IS '内容快照JSON建议包含 title/price/discount 等,用于历史展示与审计';
COMMENT ON COLUMN order_items.created_at IS '创建时间:默认 now()';
COMMENT ON COLUMN order_items.updated_at IS '更新时间:默认 now()';
CREATE INDEX IF NOT EXISTS ix_order_items_tenant_order ON order_items(tenant_id, order_id);
CREATE INDEX IF NOT EXISTS ix_order_items_tenant_content ON order_items(tenant_id, content_id);
CREATE TABLE IF NOT EXISTS tenant_ledgers(
id bigserial PRIMARY KEY,
tenant_id bigint NOT NULL,
user_id bigint NOT NULL,
order_id bigint,
type varchar(32) NOT NULL,
amount bigint NOT NULL DEFAULT 0,
balance_before bigint NOT NULL DEFAULT 0,
balance_after bigint NOT NULL DEFAULT 0,
frozen_before bigint NOT NULL DEFAULT 0,
frozen_after bigint NOT NULL DEFAULT 0,
idempotency_key varchar(128) NOT NULL DEFAULT '',
remark varchar(255) NOT NULL DEFAULT '',
created_at timestamptz NOT NULL DEFAULT NOW(),
updated_at timestamptz NOT NULL DEFAULT NOW()
);
-- tenant_ledgers租户内余额账本流水必须可审计、可幂等
COMMENT ON TABLE tenant_ledgers IS '账本流水:记录租户内用户余额的每一次变化(冻结/扣款/退款/调账等);用于审计与对账回放';
COMMENT ON COLUMN tenant_ledgers.id IS '主键ID自增';
COMMENT ON COLUMN tenant_ledgers.tenant_id IS '租户ID多租户隔离关键字段必须与 tenant_users.tenant_id 一致';
COMMENT ON COLUMN tenant_ledgers.user_id IS '用户ID余额账户归属用户对应 tenant_users.user_id';
COMMENT ON COLUMN tenant_ledgers.order_id IS '关联订单ID购买/退款类流水应关联 orders.id非订单类可为空';
COMMENT ON COLUMN tenant_ledgers.type IS '流水类型debit_purchase/credit_refund/freeze/unfreeze/adjustment不同类型决定余额/冻结余额的变更方向';
COMMENT ON COLUMN tenant_ledgers.amount IS '流水金额:分/最小货币单位;通常为正数,方向由 type 决定(由业务层约束)';
COMMENT ON COLUMN tenant_ledgers.balance_before IS '变更前可用余额:用于审计与对账回放';
COMMENT ON COLUMN tenant_ledgers.balance_after IS '变更后可用余额:用于审计与对账回放';
COMMENT ON COLUMN tenant_ledgers.frozen_before IS '变更前冻结余额:用于审计与对账回放';
COMMENT ON COLUMN tenant_ledgers.frozen_after IS '变更后冻结余额:用于审计与对账回放';
COMMENT ON COLUMN tenant_ledgers.idempotency_key IS '幂等键:同一租户同一用户同一业务操作固定;用于防止重复落账(建议由业务层生成)';
COMMENT ON COLUMN tenant_ledgers.remark IS '备注:业务说明/后台操作原因等;用于审计';
COMMENT ON COLUMN tenant_ledgers.created_at IS '创建时间:默认 now()';
COMMENT ON COLUMN tenant_ledgers.updated_at IS '更新时间:默认 now()';
CREATE INDEX IF NOT EXISTS ix_tenant_ledgers_tenant_user ON tenant_ledgers(tenant_id, user_id);
CREATE INDEX IF NOT EXISTS ix_tenant_ledgers_tenant_order ON tenant_ledgers(tenant_id, order_id);
CREATE INDEX IF NOT EXISTS ix_tenant_ledgers_tenant_type ON tenant_ledgers(tenant_id, type);
CREATE UNIQUE INDEX IF NOT EXISTS ux_tenant_ledgers_tenant_idempotency_key ON tenant_ledgers(tenant_id, user_id, idempotency_key) WHERE idempotency_key <> '';
-- +goose StatementEnd
-- +goose Down
-- +goose StatementBegin
DROP INDEX IF EXISTS ux_tenant_ledgers_tenant_idempotency_key;
DROP INDEX IF EXISTS ix_tenant_ledgers_tenant_type;
DROP INDEX IF EXISTS ix_tenant_ledgers_tenant_order;
DROP INDEX IF EXISTS ix_tenant_ledgers_tenant_user;
DROP TABLE IF EXISTS tenant_ledgers;
DROP INDEX IF EXISTS ix_order_items_tenant_content;
DROP INDEX IF EXISTS ix_order_items_tenant_order;
DROP TABLE IF EXISTS order_items;
DROP INDEX IF EXISTS ux_orders_tenant_idempotency_key;
DROP INDEX IF EXISTS ix_orders_tenant_paid_at;
DROP INDEX IF EXISTS ix_orders_tenant_status;
DROP INDEX IF EXISTS ix_orders_tenant_user;
DROP TABLE IF EXISTS orders;
-- +goose StatementEnd