@@ -1,298 +1,339 @@
-- +goose Up
-- +goose StatementBegin
-- Users
CREATE TABLE IF NOT EXISTS users (
id BIGSERIAL PRIMARY KEY ,
username VARCHAR ( 255 ) NOT NULL UNIQUE ,
password VARCHAR ( 255 ) NOT NULL ,
roles TEXT [ ] DEFAULT ' {user} ' ,
status VARCHAR ( 50 ) DEFAULT ' active ' ,
metas JSONB DEFAULT ' {} ' ,
balance BIGINT DEFAULT 0 ,
balance_frozen BIGINT DEFAULT 0 ,
verified_at TIMESTAMP WITH TIME ZONE ,
CREATE TABLE IF NOT EXISTS users (
id bigserial PRIMARY KEY , -- 主键ID: 自增
username varchar ( 255 ) NOT NULL UNIQUE , -- 用户名:唯一,用于登录
password VARCHAR ( 255 ) NOT NULL , -- 密码:加密存储
roles text [ ] DEFAULT ' {user} ' , -- 角色:用户角色列表,如 {user, super_admin}
status varchar ( 50 ) DEFAULT ' active ' , -- 状态: active/inactive/banned
metas jsonb DEFAULT ' {} ' , -- 元数据:额外扩展信息
balance bigint DEFAULT 0 , -- 全局可用余额:分/最小货币单位;用户在所有已加入租户内共享该余额;默认 0
balance_frozen bigint DEFAULT 0 , -- 全局冻结余额:分/最小货币单位;用于下单冻结等;默认 0
verified_at timestamp with time zone , -- 实名认证时间
-- New fields
nickname VARCHAR ( 255 ) DEFAULT ' ' ,
avatar VARCHAR ( 512 ) DEFAULT ' ' ,
gender VARCHAR ( 32 ) DEFAULT ' secret ' ,
bio VARCHAR ( 512 ) DEFAULT ' ' ,
birthday DATE ,
location JSONB DEFAULT ' {} ' ,
points BIGINT DEFAULT 0 ,
phone VARCHAR ( 32 ) DEFAULT ' ' ,
is_real_name_verified BOOLEAN DEFAULT FALSE ,
cre ated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW ( ) ,
upda ted_at TIMESTAMP WITH TIME ZONE DEFAULT NOW ( ) ,
deleted_at TIMESTAMP WITH TIME ZONE
nickname varchar ( 255 ) DEFAULT ' ' , -- 昵称:用户显示名称
avatar varchar ( 512 ) DEFAULT ' ' , -- 头像: URL地址
gender varchar ( 32 ) DEFAULT ' secret ' , -- 性别: male/female/secret
bio varchar ( 512 ) DEFAULT ' ' , -- 简介:用户个人简介
birthday date , -- 生日: YYYY-MM-DD
location jsonb DEFAULT ' {} ' , -- 位置:省市区信息 {province: "...", city: "..."}
points bigint DEFAULT 0 , -- 积分:用户积分
phone varchar ( 32 ) DEFAULT ' ' , -- 手机号:用于登录/验证
is_real_name_verified boolean DEFAULT FALSE , -- 是否实名认证: true/false
created_at timestamp with time zone DEFAULT NOW ( ) , -- 创建时间:默认 now()
upd ated_at timestamp with time zone DEFAULT NOW ( ) , -- 更新时间:默认 now()
dele ted_at timestamp with time zone -- 删除时间:软删除
) ;
-- Tenants
CREATE TABLE IF NOT EXISTS tenants (
id BIGSERIAL PRIMARY KEY ,
user_id BIGINT NOT NULL ,
code VARCHAR ( 64 ) NOT NULL UNIQUE ,
uuid UUID NOT NULL ,
name VARCHAR ( 128 ) NOT NULL ,
status VARCHAR ( 64 ) NOT NULL ,
config JSONB DEFAULT ' {} ' ,
expired_at TIMESTAMP WITH TIME ZONE ,
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW ( ) ,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW ( )
CREATE TABLE IF NOT EXISTS tenants (
id bigserial PRIMARY KEY , -- 主键ID: 自增
user_id bigint NOT NULL , -- 创建者ID: 关联 users.id
code varchar ( 64 ) NOT NULL UNIQUE , -- 租户代码:唯一标识,用于 URL 等
uuid uuid NOT NULL , -- UUID: 全局唯一标识
name varchar ( 128 ) NOT NULL , -- 租户名称
status varchar ( 64 ) NOT NULL , -- 状态: pending_verify/verified/banned
config jsonb DEFAULT ' {} ' , -- 配置:租户配置信息
expired_at timestamp with time zone , -- 过期时间:租户有效期
created_at timestamp with time zone DEFAULT NOW ( ) , -- 创建时间:默认 now()
updated_at timestamp with time zone DEFAULT NOW ( ) -- 更新时间:默认 now()
) ;
CREATE INDEX IF NOT EXISTS idx_tenants_user_id ON tenants ( user_id ) ;
-- TenantUsers
CREATE TABLE IF NOT EXISTS tenant_users (
id BIGSERIAL PRIMARY KEY ,
tenant_id BIGINT NOT NULL ,
user_id BIGINT NOT NULL ,
role TEXT [ ] DEFAULT ' {member} ' ,
status VARCHAR ( 50 ) DEFAULT ' verified ' ,
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW ( ) ,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW ( ) ,
UNIQUE ( tenant_id , user_id )
CREATE TABLE IF NOT EXISTS tenant_users (
id bigserial PRIMARY KEY , -- 主键ID: 自增
tenant_id bigint NOT NULL , -- 租户ID: 关联 tenants.id
user_id bigint NOT NULL , -- 用户ID: 关联 users.id
role TEXT [ ] DEFAULT ' {member} ' , -- 角色: member/tenant_admin
status varchar ( 50 ) DEFAULT ' verified ' , -- 状态: pending_verify/verified/banned
created_at timestamp with time zone DEFAULT NOW ( ) , -- 创建时间:默认 now()
updated_at timestamp with time zone DEFAULT NOW ( ) , -- 更新时间:默认 now()
UNIQUE ( tenant_id , user_id )
) ;
-- Contents
CREATE TABLE IF NOT EXISTS contents (
id BIGSERIAL PRIMARY KEY ,
tenant_id BIGINT NOT NULL ,
user_id BIGINT NOT NULL ,
title VARCHAR ( 255 ) NOT NULL ,
description TEXT NOT NULL ,
status VARCHAR ( 32 ) DEFAULT ' draft ' ,
visibility VARCHAR ( 32 ) DEFAULT ' tenant_only ' ,
preview_seconds INT DEFAULT 60 ,
preview_downloadable BOOLEAN DEFAULT FALSE ,
published_at TIMESTAMP WITH TIME ZONE ,
summary VARCHAR ( 256 ) DEFAULT ' ' ,
tags JSONB DEFAULT ' [] ' ,
CREATE TABLE IF NOT EXISTS contents (
id bigserial PRIMARY KEY , -- 主键ID: 自增; 用于内容引用
tenant_id bigint NOT NULL , -- 租户ID: 多租户隔离关键字段; 所有查询/写入必须限定 tenant_id
user_id bigint NOT NULL , -- 用户ID: 内容创建者/发布者;用于权限与审计(例如私有内容仅作者可见)
title varchar ( 255 ) NOT NULL , -- 标题:用于列表展示与搜索;建议限制长度(由业务校验)
description text NOT NULL , -- 描述:用于详情页展示;可为空字符串
status varchar ( 32 ) DEFAULT ' draft ' , -- 状态: draft/reviewing/published/unpublished/blocked; published 才对外展示
visibility varchar ( 32 ) DEFAULT ' tenant_only ' , -- 可见性: public/tenant_only/private; 仅控制详情可见, 正片资源仍需按价格/权益校验
preview_seconds int DEFAULT 60 , -- 试看秒数:默认 60; 只对 preview 资源生效;必须为正整数
preview_downloadable boolean DEFAULT FALSE , -- 试看是否允许下载:默认 false; 当前策略固定为不允许下载( 仅 streaming)
published_at timestamp with time zone , -- 发布时间:首次发布时写入;用于时间窗与排序
summary varchar ( 256 ) DEFAULT ' ' , -- 简介:用于列表/卡片展示的短文本;建议 <= 256 字符(由业务校验)
tags jsonb DEFAULT ' [] ' , -- 标签: JSON 数组(字符串列表);用于分类/检索与聚合展示
-- New fields
body TEXT DEFAULT ' ' ,
genre VARCHAR ( 64 ) DEFAULT ' ' ,
views INT DEFAULT 0 ,
likes INT DEFAULT 0 ,
cre ated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW ( ) ,
upda ted_at TIMESTAMP WITH TIME ZONE DEFAULT NOW ( ) ,
deleted_at TIMESTAMP WITH TIME ZONE
body text DEFAULT ' ' , -- 内容主体:文章内容/详细介绍
genre varchar ( 64 ) DEFAULT ' ' , -- 类型/流派:如 video/audio/article 或具体的音乐流派
views int DEFAULT 0 , -- 浏览量
likes int DEFAULT 0 , -- 点赞数
created_at timestamp with time zone DEFAULT NOW ( ) , -- 创建时间:默认 now();用于审计与排序
upd ated_at timestamp with time zone DEFAULT NOW ( ) , -- 更新时间:默认 now();编辑内容时写入
dele ted_at timestamp with time zone -- 软删除时间:非空表示已删除;对外接口需过滤
) ;
CREATE INDEX IF NOT EXISTS idx_contents_tenant_id ON contents ( tenant_id ) ;
-- MediaAssets
CREATE TABLE IF NOT EXISTS media_assets (
id BIGSERIAL PRIMARY KEY ,
tenant_id BIGINT NOT NULL ,
user_id BIGINT NOT NULL ,
type VARCHAR ( 32 ) DEFAULT ' video ' ,
status VARCHAR ( 32 ) DEFAULT ' uploaded ' ,
provider VARCHAR ( 64 ) NOT NULL ,
bucket VARCHAR ( 128 ) NOT NULL ,
object_key VARCHAR ( 512 ) NOT NULL ,
meta JSONB DEFAULT ' {} ' ,
variant VARCHAR ( 32 ) DEFAULT ' main ' ,
source_asset_id BIGINT DEFAULT 0 ,
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW ( ) ,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW ( ) ,
deleted_at TIMESTAMP WITH TIME ZONE
CREATE TABLE IF NOT EXISTS media_assets (
id bigserial PRIMARY KEY , -- 主键ID: 自增; 仅用于内部关联
tenant_id bigint NOT NULL , -- 租户ID: 多租户隔离关键字段; 所有查询/写入必须限定 tenant_id
user_id bigint NOT NULL , -- 用户ID: 资源上传者; 用于审计与权限控制
type VARCHAR ( 32 ) DEFAULT ' video ' , -- 资源类型: video/audio/image; 决定后续处理流程( 转码/缩略图/封面等)
status varchar ( 32 ) DEFAULT ' uploaded ' , -- 处理状态: uploaded/processing/ready/failed/deleted; ready 才可被内容引用对外提供
provider varchar ( 64 ) NOT NULL , -- 存储提供方:例如 s3/minio/oss; 便于多存储扩展
bucket varchar ( 128 ) NOT NULL , -- 存储桶:对象所在 bucket; 与 provider 组合确定存储定位
object_key varchar ( 512 ) NOT NULL , -- 对象键:对象在 bucket 内的 key; 不得暴露可长期复用的直链( 通过签名URL/token下发)
meta jsonb DEFAULT ' {} ' , -- 元数据: JSON; 包含 hash、duration、width、height、bitrate、codec 等;用于展示与计费/风控
variant varchar ( 32 ) DEFAULT ' main ' , -- 产物类型: main/preview; 用于强制试看资源必须绑定独立产物, 避免用正片绕过
source_asset_id bigint DEFAULT 0 , -- 派生来源资源ID: preview 产物可指向对应 main 资源;用于建立 preview/main 的 1:1 追溯关系
created_at timestamp with time zone DEFAULT NOW ( ) , -- 创建时间:默认 now();用于审计与排序
updated_at timestamp with time zone DEFAULT NOW ( ) , -- 更新时间:默认 now();更新状态/元数据时写入
deleted_at timestamp with time zone -- 软删除时间:非空表示已删除;对外接口需过滤
) ;
-- ContentAssets
CREATE TABLE IF NOT EXISTS content_assets (
id BIGSERIAL PRIMARY KEY ,
tenant_id BIGINT NOT NULL ,
user_id BIGINT NOT NULL ,
content_id BIGINT NOT NULL ,
asset_id BIGINT NOT NULL ,
role VARCHAR ( 32 ) DEFAULT ' main ' ,
sort INT DEFAULT 0 ,
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW ( ) ,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW ( )
CREATE TABLE IF NOT EXISTS content_assets (
id bigserial PRIMARY KEY , -- 主键ID: 自增
tenant_id bigint NOT NULL , -- 租户ID: 多租户隔离; 必须与 content_id、asset_id 所属租户一致
user_id bigint NOT NULL , -- 用户ID: 操作人/绑定人;用于审计(通常为租户管理员或作者)
content_id bigint NOT NULL , -- 内容ID: 关联 contents.id; 用于查询内容下资源列表
asset_id bigint NOT NULL , -- 资源ID: 关联 media_assets.id; 用于查询资源归属内容
role VARCHAR ( 32 ) DEFAULT ' main ' , -- 资源角色: main/cover/preview; preview 必须为独立资源以满足禁下载与防绕过
sort int DEFAULT 0 , -- 排序:同一 role 下的展示顺序,数值越小越靠前
created_at timestamp with time zone DEFAULT NOW ( ) , -- 创建时间:默认 now();用于审计
updated_at timestamp with time zone DEFAULT NOW ( ) -- 更新时间:默认 now();更新 sort/role 时写入
) ;
-- ContentPrices
CREATE TABLE IF NOT EXISTS content_prices (
id BIGSERIAL PRIMARY KEY ,
tenant_id BIGINT NOT NULL ,
user_id BIGINT NOT NULL ,
content_id BIGINT NOT NULL ,
currency VARCHAR ( 16 ) DEFAULT ' CNY ' ,
price_amount BIGINT NOT NULL ,
discount_type VARCHAR ( 16 ) DEFAULT ' none ' ,
discount_value BIGINT DEFAULT 0 ,
discount_start_at TIMESTAMP WITH TIME ZONE ,
discount_end_at TIMESTAMP WITH TIME ZONE ,
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW ( ) ,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW ( ) ,
UNIQUE ( tenant_id , content_id )
CREATE TABLE IF NOT EXISTS content_prices (
id bigserial PRIMARY KEY , -- 主键ID: 自增
tenant_id bigint NOT NULL , -- 租户ID: 多租户隔离; 与内容归属一致
user_id bigint NOT NULL , -- 用户ID: 设置/更新价格的操作人(通常为 tenant_admin) ; 用于审计
content_id bigint NOT NULL , -- 内容ID: 唯一约束 (tenant_id, content_id);一个内容在一个租户内仅一份定价
currency varchar ( 16 ) DEFAULT ' CNY ' , -- 币种:当前固定 CNY; 金额单位为分
price_amount bigint NOT NULL , -- 基础价格: 分; 0 表示免费(可直接访问正片资源)
discount_type varchar ( 16 ) DEFAULT ' none ' , -- 折扣类型: none/percent/amount; 仅影响下单时成交价, 需写入订单快照
discount_value bigint DEFAULT 0 , -- 折扣值: percent=0-100( 按业务校验) ; amount=分; none 时忽略
discount_start_at timestamp with time zone , -- 折扣开始时间:可为空;为空表示立即生效(由业务逻辑解释)
discount_end_at timestamp with time zone , -- 折扣结束时间:可为空;为空表示长期有效(由业务逻辑解释)
created_at timestamp with time zone DEFAULT NOW ( ) , -- 创建时间:默认 now();用于审计
updated_at timestamp with time zone DEFAULT NOW ( ) , -- 更新时间:默认 now();更新价格/折扣时写入
UNIQUE ( tenant_id , content_id )
) ;
-- ContentAccess
CREATE TABLE IF NOT EXISTS content_access (
id BIGSERIAL PRIMARY KEY ,
tenant_id BIGINT NOT NULL ,
user_id BIGINT NOT NULL ,
content_id BIGINT NOT NULL ,
order_id BIGINT DEFAULT 0 ,
status VARCHAR ( 16 ) DEFAULT ' active ' ,
revoked_at TIMESTAMP WITH TIME ZONE ,
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW ( ) ,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW ( ) ,
UNIQUE ( tenant_id , user_id , content_id )
CREATE TABLE IF NOT EXISTS content_access (
id bigserial PRIMARY KEY , -- 主键ID: 自增
tenant_id bigint NOT NULL , -- 租户ID: 多租户隔离; 与内容、用户归属一致
user_id bigint NOT NULL , -- 用户ID: 权益所属用户; 用于访问校验
content_id bigint NOT NULL , -- 内容ID: 权益对应内容; 唯一约束 (tenant_id, user_id, content_id)
order_id bigint DEFAULT 0 , -- 订单ID: 产生该权益的订单; 可为空( 例如后台补发/迁移)
status varchar ( 16 ) DEFAULT ' active ' , -- 权益状态: active/revoked/expired; revoked 表示立即失效(例如退款/违规)
revoked_at timestamp with time zone , -- 撤销时间:当 status=revoked 时写入;用于审计与追责
created_at timestamp with time zone DEFAULT NOW ( ) , -- 创建时间:默认 now();用于审计
updated_at timestamp with time zone DEFAULT NOW ( ) , -- 更新时间:默认 now();更新 status 时写入
UNIQUE ( tenant_id , user_id , content_id )
) ;
-- Orders
CREATE TABLE IF NOT EXISTS orders (
id BIGSERIAL PRIMARY KEY ,
tenant_id BIGINT NOT NULL ,
user_id BIGINT NOT NULL ,
type VARCHAR ( 32 ) DEFAULT ' content_purchase ' ,
status VARCHAR ( 32 ) DEFAULT ' created ' ,
currency VARCHAR ( 16 ) DEFAULT ' CNY ' ,
amount_original BIGINT NOT NULL ,
amount_discount BIGINT NOT NULL ,
amount_paid BIGINT NOT NULL ,
snapshot JSONB DEFAULT ' {} ' ,
idempotency_key VARCHAR ( 128 ) NOT NULL ,
paid_at TIMESTAMP WITH TIME ZONE ,
refunded_at TIMESTAMP WITH TIME ZONE ,
refund_forced BOOLEAN DEFAULT FALSE ,
refund_operator_user_id BIGINT DEFAULT 0 ,
refund_reason VARCHAR ( 255 ) DEFAULT ' ' ,
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW ( ) ,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW ( )
CREATE TABLE IF NOT EXISTS orders (
id bigserial PRIMARY KEY , -- 主键ID: 自增; 用于关联订单明细、账本流水、权益等
tenant_id bigint NOT NULL , -- 租户ID: 多租户隔离关键字段; 所有查询/写入必须限定 tenant_id
user_id bigint NOT NULL , -- 用户ID: 下单用户( buyer) ; 余额扣款与权益归属以该 user_id 为准
type VARCHAR ( 32 ) DEFAULT ' content_purchase ' , -- 订单类型: content_purchase( 购买内容) 等; 当前默认 content_purchase
status varchar ( 32 ) DEFAULT ' created ' , -- 订单状态: created/paid/refunding/refunded/canceled/failed; 状态变更需与账本/权益保持一致
currency varchar ( 16 ) DEFAULT ' CNY ' , -- 币种:当前固定 CNY; 金额单位为分
amount_original bigint NOT NULL , -- 原价金额:分;未折扣前金额(用于展示与对账)
amount_discount bigint NOT NULL , -- 优惠金额: 分; amount_paid = amount_original - amount_discount( 下单时快照)
amount_paid bigint NOT NULL , -- 实付金额:分;从租户内余额扣款的金额(下单时快照)
snapshot JSONB DEFAULT ' {} ' , -- 订单快照: JSON; 建议包含 content 标题/定价/折扣、请求来源等,避免改价影响历史展示
idempotency_key varchar ( 128 ) NOT NULL , -- 幂等键:同一租户同一用户同一业务请求可用;用于防重复下单/重复扣款(建议由客户端生成)
paid_at timestamp with time zone , -- 支付/扣款完成时间:余额支付在 debit_purchase 成功后写入
refunded_at timestamp with time zone , -- 退款完成时间:退款落账成功后写入
refund_forced boolean DEFAULT FALSE , -- 是否强制退款: true 表示租户管理侧绕过时间窗执行退款(需审计)
refund_operator_user_id bigint DEFAULT 0 , -- 退款操作人用户ID: 租户管理员/系统;用于审计与追责
refund_reason varchar ( 255 ) DEFAULT ' ' , -- 退款原因:后台/用户发起退款的原因说明;用于审计
created_at timestamp with time zone DEFAULT NOW ( ) , -- 创建时间:默认 now();用于审计与排序
updated_at timestamp with time zone DEFAULT NOW ( ) -- 更新时间:默认 now();状态变更/退款写入时更新
) ;
-- OrderItems
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 ,
amount_paid BIGINT NOT NULL ,
snapshot JSONB DEFAULT ' {} ' ,
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW ( ) ,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW ( )
CREATE TABLE IF NOT EXISTS order_items (
id bigserial PRIMARY KEY , -- 主键ID: 自增
tenant_id bigint NOT NULL , -- 租户ID: 多租户隔离关键字段; 必须与 orders.tenant_id 一致
user_id bigint NOT NULL , -- 用户ID: 下单用户( buyer) ; 冗余字段用于查询加速与审计
order_id bigint NOT NULL , -- 订单ID: 关联 orders.id; 用于聚合订单明细
content_id bigint NOT NULL , -- 内容ID: 关联 contents.id; 用于生成/撤销 content_access
content_user_id bigint NOT NULL , -- 内容作者用户ID: 用于后续分成/对账扩展;当前可为 0 或写入内容创建者
amount_paid bigint NOT NULL , -- 该行实付金额:分;通常等于订单 amount_paid( 单内容场景)
snapshot JSONB DEFAULT ' {} ' , -- 内容快照: JSON; 建议包含 title/price/discount 等,用于历史展示与审计
created_at timestamp with time zone DEFAULT NOW ( ) , -- 创建时间:默认 now()
updated_at timestamp with time zone DEFAULT NOW ( ) -- 更新时间:默认 now()
) ;
-- TenantLedgers
CREATE TABLE IF NOT EXISTS tenant_ledgers (
id BIGSERIAL PRIMARY KEY ,
tenant_id BIGINT NOT NULL ,
user_id BIGINT NOT NULL ,
order_id BIGINT DEFAULT 0 ,
type VARCHAR ( 32 ) NOT NULL ,
amount BIGINT NOT NULL ,
balance_before BIGINT NOT NULL ,
balance_after BIGINT NOT NULL ,
frozen_before BIGINT NOT NULL ,
frozen_after BIGINT NOT NULL ,
idempotency_key VARCHAR ( 128 ) NOT NULL ,
remark VARCHAR ( 255 ) NOT NULL ,
operator_user_id BIGINT DEFAULT 0 ,
biz_ref_type VARCHAR ( 32 ) DEFAULT ' ' ,
biz_ref_id BIGINT DEFAULT 0 ,
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW ( ) ,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW ( )
CREATE TABLE IF NOT EXISTS tenant_ledgers (
id bigserial PRIMARY KEY , -- 主键ID: 自增
tenant_id bigint NOT NULL , -- 租户ID: 多租户隔离关键字段; 必须与 tenant_users.tenant_id 一致
user_id bigint NOT NULL , -- 用户ID: 余额账户归属用户; 对应 tenant_users.user_id
order_id bigint DEFAULT 0 , -- 关联订单ID: 购买/退款类流水应关联 orders.id; 非订单类可为空
type VARCHAR ( 32 ) NOT NULL , -- 流水类型: debit_purchase/credit_refund/freeze/unfreeze/adjustment; 不同类型决定余额/冻结余额的变更方向
amount bigint NOT NULL , -- 流水金额:分/最小货币单位;通常为正数,方向由 type 决定(由业务层约束)
balance_before bigint NOT NULL , -- 变更前可用余额:用于审计与对账回放
balance_after bigint NOT NULL , -- 变更后可用余额:用于审计与对账回放
frozen_before bigint NOT NULL , -- 变更前冻结余额:用于审计与对账回放
frozen_after bigint NOT NULL , -- 变更后冻结余额:用于审计与对账回放
idempotency_key varchar ( 128 ) NOT NULL , -- 幂等键:同一租户同一用户同一业务操作固定;用于防止重复落账(建议由业务层生成)
remark varchar ( 255 ) NOT NULL , -- 备注:业务说明/后台操作原因等;用于审计
operator_user_id bigint DEFAULT 0 , -- 操作者用户ID: 谁触发该流水( admin/buyer/system) ; 用于审计与追责; 可为空( 历史数据或无法识别时)
biz_ref_type varchar ( 32 ) DEFAULT ' ' , -- 业务引用类型: order/refund/etc; 与 biz_ref_id 组成可选的结构化幂等/追溯键
biz_ref_id bigint DEFAULT 0 , -- 业务引用ID: 与 biz_ref_type 配合使用(例如 orders.id) ; 用于对账与审计
created_at timestamp with time zone DEFAULT NOW ( ) , -- 创建时间:默认 now()
updated_at timestamp with time zone DEFAULT NOW ( ) -- 更新时间:默认 now()
) ;
-- TenantInvites
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 ) DEFAULT ' active ' ,
max_uses INT NOT NULL ,
used_count INT DEFAULT 0 ,
expires_at TIMESTAMP WITH TIME ZONE ,
disabled_at TIMESTAMP WITH TIME ZONE ,
disabled_operator_user_id BIGINT DEFAULT 0 ,
remark VARCHAR ( 255 ) DEFAULT ' ' ,
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW ( ) ,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW ( )
CREATE TABLE IF NOT EXISTS tenant_invites (
id bigserial PRIMARY KEY , -- 主键ID: 自增
tenant_id bigint NOT NULL , -- 租户ID: 多租户隔离关键字段; 所有查询/写入必须限定 tenant_id
user_id bigint NOT NULL , -- 创建人用户ID: 生成邀请码的租户管理员( 审计用)
code varchar ( 64 ) NOT NULL , -- 邀请码:用户加入租户时提交;同一租户内唯一
status varchar ( 32 ) DEFAULT ' active ' , -- 邀请状态: active/disabled/expired; expired 也可由 expires_at 推导,业务侧需保持一致
max_uses int NOT NULL , -- 最大可使用次数: 0 表示不限制;>0 时 used_count 达到该值后视为失效
used_count int DEFAULT 0 , -- 已使用次数:每次成功加入时 +1; 需事务保证并发下不超发
expires_at timestamp with time zone , -- 过期时间: 到期后不可再使用( UTC) ; 为空表示不过期
disabled_at timestamp with time zone , -- 禁用时间: 租户管理员禁用该邀请的时间( UTC)
disabled_operator_user_id bigint DEFAULT 0 , -- 禁用操作人用户ID: 租户管理员( 审计用)
remark varchar ( 255 ) DEFAULT ' ' , -- 备注:生成/禁用原因等(审计用)
created_at timestamp with time zone DEFAULT NOW ( ) , -- 创建时间:默认 now()
updated_at timestamp with time zone DEFAULT NOW ( ) -- 更新时间:默认 now()
) ;
-- TenantJoinRequests
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 ) DEFAULT ' pending ' ,
reason VARCHAR ( 255 ) NOT NULL ,
decided_at TIMESTAMP WITH TIME ZONE ,
decided_operator_user_id BIGINT DEFAULT 0 ,
decided_reason VARCHAR ( 255 ) DEFAULT ' ' ,
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW ( ) ,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW ( )
CREATE TABLE IF NOT EXISTS tenant_join_requests (
id bigserial PRIMARY KEY , -- 主键ID: 自增
tenant_id bigint NOT NULL , -- 租户ID: 多租户隔离关键字段; 所有查询/写入必须限定 tenant_id
user_id bigint NOT NULL , -- 申请人用户ID: 发起加入申请的用户
status varchar ( 32 ) DEFAULT ' pending ' , -- 申请状态: pending/approved/rejected; 状态变更需记录 decided_at 与 decided_operator_user_id
reason varchar ( 255 ) NOT NULL , -- 申请原因:用户填写的加入说明(可选)
decided_at timestamp with time zone , -- 处理时间:审核通过/拒绝时记录( UTC)
decided_operator_user_id bigint DEFAULT 0 , -- 处理人用户ID: 租户管理员( 审计用)
decided_reason varchar ( 255 ) DEFAULT ' ' , -- 处理说明:管理员通过/拒绝的原因(可选,审计用)
created_at timestamp with time zone DEFAULT NOW ( ) , -- 创建时间:默认 now()
updated_at timestamp with time zone DEFAULT NOW ( ) -- 更新时间:默认 now()
) ;
-- Comments
CREATE TABLE IF NOT EXISTS comments (
id BIGSERIAL PRIMARY KEY ,
tenant_id BIGINT NOT NULL ,
user_id BIGINT NOT NULL ,
content_id BIGINT NOT NULL ,
reply_to BIGINT DEFAULT 0 ,
content TEXT NOT NULL ,
likes INT DEFAULT 0 ,
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW ( ) ,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW ( ) ,
deleted_at TIMESTAMP WITH TIME ZONE
CREATE TABLE IF NOT EXISTS comments (
id bigserial PRIMARY KEY , -- 主键ID: 自增
tenant_id bigint NOT NULL , -- 租户ID: 关联 tenants.id
user_id bigint NOT NULL , -- 用户ID: 关联 users.id
content_id bigint NOT NULL , -- 内容ID: 关联 contents.id
reply_to bigint DEFAULT 0 , -- 回复评论ID: 0表示一级评论
content text NOT NULL , -- 评论内容
likes int DEFAULT 0 , -- 点赞数
created_at timestamp with time zone DEFAULT NOW ( ) , -- 创建时间:默认 now()
updated_at timestamp with time zone DEFAULT NOW ( ) , -- 更新时间:默认 now()
deleted_at timestamp with time zone -- 软删除时间
) ;
CREATE INDEX IF NOT EXISTS idx_comments_content_id ON comments ( content_id ) ;
CREATE INDEX IF NOT EXISTS idx_comments_user_id ON comments ( user_id ) ;
-- User Content Actions (Like, Favorite)
CREATE TABLE IF NOT EXISTS user_content_actions (
id BIGSERIAL PRIMARY KEY ,
user_id BIGINT NOT NULL ,
content_id BIGINT NOT NULL ,
type VARCHAR ( 32 ) NOT NULL , -- like, favorite
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW ( ) ,
UNIQUE ( user_id , content_id , type )
CREATE TABLE IF NOT EXISTS user_content_actions (
id bigserial PRIMARY KEY , -- 主键ID: 自增
user_id bigint NOT NULL , -- 用户ID
content_id bigint NOT NULL , -- 内容ID
type VARCHAR ( 32 ) NOT NULL , -- 类型: like, favorite
created_at timestamp with time zone DEFAULT NOW ( ) , -- 创建时间
UNIQUE ( user_id , content_id , type )
) ;
-- User Comment Actions (Like)
CREATE TABLE IF NOT EXISTS user_comment_actions (
id BIGSERIAL PRIMARY KEY ,
user_id BIGINT NOT NULL ,
comment_id BIGINT NOT NULL ,
type VARCHAR ( 32 ) NOT NULL , -- like
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW ( ) ,
UNIQUE ( user_id , comment_id , type )
CREATE TABLE IF NOT EXISTS user_comment_actions (
id bigserial PRIMARY KEY , -- 主键ID: 自增
user_id bigint NOT NULL , -- 用户ID
comment_id bigint NOT NULL , -- 评论ID
type VARCHAR ( 32 ) NOT NULL , -- 类型: like
created_at timestamp with time zone DEFAULT NOW ( ) , -- 创建时间
UNIQUE ( user_id , comment_id , type )
) ;
-- Payout Accounts
CREATE TABLE IF NOT EXISTS payout_accounts (
id BIGSERIAL PRIMARY KEY ,
tenant_id BIGINT NOT NULL , -- Associated with a creator tenant
user_id BIGINT NOT NULL , -- Creator user
type VARCHAR ( 32 ) NOT NULL , -- bank, alipay
name VARCHAR ( 128 ) NOT NULL ,
account VARCHAR ( 128 ) NOT NULL ,
realname VARCHAR ( 128 ) NOT NULL ,
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW ( ) ,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW ( )
CREATE TABLE IF NOT EXISTS payout_accounts (
id bigserial PRIMARY KEY , -- 主键ID: 自增
tenant_id bigint NOT NULL , -- 租户ID: 关联创建者租户
user_id bigint NOT NULL , -- 用户ID: 创建者
type VARCHAR ( 32 ) NOT NULL , -- 类型: bank, alipay
name varchar ( 128 ) NOT NULL , -- 账户名称/开户行
account varchar ( 128 ) NOT NULL , -- 账号
realname varchar ( 128 ) NOT NULL , -- 真实姓名
created_at timestamp with time zone DEFAULT NOW ( ) , -- 创建时间
updated_at timestamp with time zone DEFAULT NOW ( ) -- 更新时间
) ;
CREATE INDEX IF NOT EXISTS idx_payout_accounts_tenant_id ON payout_accounts ( tenant_id ) ;
-- Notifications
CREATE TABLE IF NOT EXISTS notifications (
id BIGSERIAL PRIMARY KEY ,
user_id BIGINT NOT NULL ,
tenant_id BIGINT DEFAULT 0 , -- Optional source tenant
type VARCHAR ( 32 ) NOT NULL , -- system, order, audit, interaction
title VARCHAR ( 255 ) NOT NULL ,
content TEXT NOT NULL ,
is_read BOOLEAN DEFAULT FALSE ,
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW ( )
CREATE TABLE IF NOT EXISTS notifications (
id bigserial PRIMARY KEY , -- 主键ID: 自增
user_id bigint NOT NULL , -- 接收用户ID
tenant_id bigint DEFAULT 0 , -- 来源租户ID: 可选
type VARCHAR ( 32 ) NOT NULL , -- 类型: system, order, audit, interaction
title varchar ( 255 ) NOT NULL , -- 标题
content text NOT NULL , -- 内容
is_read boolean DEFAULT FALSE , -- 是否已读
created_at timestamp with time zone DEFAULT NOW ( ) -- 创建时间
) ;
CREATE INDEX IF NOT EXISTS idx_notifications_user_id ON notifications ( user_id ) ;
-- +goose StatementEnd
-- +goose Down
-- Revert logic omitted for dev speed in this context
-- +goose StatementBegin
DROP TABLE IF EXISTS notifications ;
DROP TABLE IF EXISTS payout_accounts ;
DROP TABLE IF EXISTS user_comment_actions ;
DROP TABLE IF EXISTS user_content_actions ;
DROP TABLE IF EXISTS comments ;
DROP TABLE IF EXISTS tenant_join_requests ;
DROP TABLE IF EXISTS tenant_invites ;
DROP TABLE IF EXISTS tenant_ledgers ;
DROP TABLE IF EXISTS order_items ;
DROP TABLE IF EXISTS orders ;
DROP TABLE IF EXISTS content_access ;
DROP TABLE IF EXISTS content_prices ;
DROP TABLE IF EXISTS content_assets ;
DROP TABLE IF EXISTS media_assets ;
DROP TABLE IF EXISTS contents ;
DROP TABLE IF EXISTS tenant_users ;
DROP TABLE IF EXISTS tenants ;
DROP TABLE IF EXISTS users ;
-- +goose StatementEnd