Files
quyun-v2/backend/database/migrations/20251217223000_media_contents.sql
2025-12-18 10:27:40 +08:00

191 lines
12 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 media_assets(
id bigserial PRIMARY KEY,
tenant_id bigint NOT NULL,
user_id bigint NOT NULL,
type varchar(32) NOT NULL DEFAULT 'video',
status varchar(32) NOT NULL DEFAULT 'uploaded',
provider varchar(64) NOT NULL DEFAULT '',
bucket varchar(128) NOT NULL DEFAULT '',
object_key varchar(512) NOT NULL DEFAULT '',
meta jsonb NOT NULL DEFAULT '{}'::jsonb,
deleted_at timestamptz,
created_at timestamptz NOT NULL DEFAULT NOW(),
updated_at timestamptz NOT NULL DEFAULT NOW()
);
-- media_assets媒体资源表视频/音频/图片),用于承载实际文件对象及其处理状态
COMMENT ON TABLE media_assets IS '媒体资源存储对象的抽象video/audio/image关联租户与上传用户记录处理状态与元数据';
COMMENT ON COLUMN media_assets.id IS '主键ID自增仅用于内部关联';
COMMENT ON COLUMN media_assets.tenant_id IS '租户ID多租户隔离关键字段所有查询/写入必须限定 tenant_id';
COMMENT ON COLUMN media_assets.user_id IS '用户ID资源上传者用于审计与权限控制';
COMMENT ON COLUMN media_assets.type IS '资源类型video/audio/image决定后续处理流程转码/缩略图/封面等)';
COMMENT ON COLUMN media_assets.status IS '处理状态uploaded/processing/ready/failed/deletedready 才可被内容引用对外提供';
COMMENT ON COLUMN media_assets.provider IS '存储提供方:例如 s3/minio/oss便于多存储扩展';
COMMENT ON COLUMN media_assets.bucket IS '存储桶:对象所在 bucket与 provider 组合确定存储定位';
COMMENT ON COLUMN media_assets.object_key IS '对象键:对象在 bucket 内的 key不得暴露可长期复用的直链通过签名URL/token下发';
COMMENT ON COLUMN media_assets.meta IS '元数据JSON包含 hash、duration、width、height、bitrate、codec 等;用于展示与计费/风控';
COMMENT ON COLUMN media_assets.deleted_at IS '软删除时间:非空表示已删除;对外接口需过滤';
COMMENT ON COLUMN media_assets.created_at IS '创建时间:默认 now();用于审计与排序';
COMMENT ON COLUMN media_assets.updated_at IS '更新时间:默认 now();更新状态/元数据时写入';
CREATE INDEX IF NOT EXISTS ix_media_assets_tenant_id ON media_assets(tenant_id);
CREATE INDEX IF NOT EXISTS ix_media_assets_tenant_user_id ON media_assets(tenant_id, user_id);
CREATE INDEX IF NOT EXISTS ix_media_assets_tenant_status ON media_assets(tenant_id, status);
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 DEFAULT '',
description text NOT NULL DEFAULT '',
status varchar(32) NOT NULL DEFAULT 'draft',
visibility varchar(32) NOT NULL DEFAULT 'tenant_only',
preview_seconds int NOT NULL DEFAULT 60,
preview_downloadable boolean NOT NULL DEFAULT false,
published_at timestamptz,
deleted_at timestamptz,
created_at timestamptz NOT NULL DEFAULT NOW(),
updated_at timestamptz NOT NULL DEFAULT NOW()
);
-- contents内容表可发布/可售卖/可试看)
COMMENT ON TABLE contents IS '内容:可发布的媒体内容实体,承载标题描述、可见性、试看配置、发布状态等';
COMMENT ON COLUMN contents.id IS '主键ID自增用于内容引用';
COMMENT ON COLUMN contents.tenant_id IS '租户ID多租户隔离关键字段所有查询/写入必须限定 tenant_id';
COMMENT ON COLUMN contents.user_id IS '用户ID内容创建者/发布者;用于权限与审计(例如私有内容仅作者可见)';
COMMENT ON COLUMN contents.title IS '标题:用于列表展示与搜索;建议限制长度(由业务校验)';
COMMENT ON COLUMN contents.description IS '描述:用于详情页展示;可为空字符串';
COMMENT ON COLUMN contents.status IS '状态draft/reviewing/published/unpublished/blockedpublished 才对外展示';
COMMENT ON COLUMN contents.visibility IS '可见性public/tenant_only/private仅控制详情可见正片资源仍需按价格/权益校验';
COMMENT ON COLUMN contents.preview_seconds IS '试看秒数:默认 60只对 preview 资源生效;必须为正整数';
COMMENT ON COLUMN contents.preview_downloadable IS '试看是否允许下载:默认 false当前策略固定为不允许下载仅 streaming';
COMMENT ON COLUMN contents.published_at IS '发布时间:首次发布时写入;用于时间窗与排序';
COMMENT ON COLUMN contents.deleted_at IS '软删除时间:非空表示已删除;对外接口需过滤';
COMMENT ON COLUMN contents.created_at IS '创建时间:默认 now();用于审计与排序';
COMMENT ON COLUMN contents.updated_at IS '更新时间:默认 now();编辑内容时写入';
CREATE INDEX IF NOT EXISTS ix_contents_tenant_id ON contents(tenant_id);
CREATE INDEX IF NOT EXISTS ix_contents_tenant_user_id ON contents(tenant_id, user_id);
CREATE INDEX IF NOT EXISTS ix_contents_tenant_status ON contents(tenant_id, status);
CREATE INDEX IF NOT EXISTS ix_contents_tenant_visibility ON contents(tenant_id, visibility);
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) NOT NULL DEFAULT 'main',
sort int NOT NULL DEFAULT 0,
created_at timestamptz NOT NULL DEFAULT NOW(),
updated_at timestamptz NOT NULL DEFAULT NOW(),
UNIQUE (tenant_id, content_id, asset_id)
);
-- content_assets内容与媒体资源的关联区分 main/cover/preview
COMMENT ON TABLE content_assets IS '内容-资源关联:将 media_assets 以角色main/cover/preview绑定到 contents支持排序';
COMMENT ON COLUMN content_assets.id IS '主键ID自增';
COMMENT ON COLUMN content_assets.tenant_id IS '租户ID多租户隔离必须与 content_id、asset_id 所属租户一致';
COMMENT ON COLUMN content_assets.user_id IS '用户ID操作人/绑定人;用于审计(通常为租户管理员或作者)';
COMMENT ON COLUMN content_assets.content_id IS '内容ID关联 contents.id用于查询内容下资源列表';
COMMENT ON COLUMN content_assets.asset_id IS '资源ID关联 media_assets.id用于查询资源归属内容';
COMMENT ON COLUMN content_assets.role IS '资源角色main/cover/previewpreview 必须为独立资源以满足禁下载与防绕过';
COMMENT ON COLUMN content_assets.sort IS '排序:同一 role 下的展示顺序,数值越小越靠前';
COMMENT ON COLUMN content_assets.created_at IS '创建时间:默认 now();用于审计';
COMMENT ON COLUMN content_assets.updated_at IS '更新时间:默认 now();更新 sort/role 时写入';
CREATE INDEX IF NOT EXISTS ix_content_assets_tenant_content ON content_assets(tenant_id, content_id);
CREATE INDEX IF NOT EXISTS ix_content_assets_tenant_asset ON content_assets(tenant_id, asset_id);
CREATE INDEX IF NOT EXISTS ix_content_assets_tenant_role ON content_assets(tenant_id, content_id, role);
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) NOT NULL DEFAULT 'CNY',
price_amount bigint NOT NULL DEFAULT 0,
discount_type varchar(16) NOT NULL DEFAULT 'none',
discount_value bigint NOT NULL DEFAULT 0,
discount_start_at timestamptz,
discount_end_at timestamptz,
created_at timestamptz NOT NULL DEFAULT NOW(),
updated_at timestamptz NOT NULL DEFAULT NOW(),
UNIQUE (tenant_id, content_id)
);
-- content_prices内容定价与折扣仅 CNY 分)
COMMENT ON TABLE content_prices IS '内容定价:为内容设置价格与折扣(订单需记录成交快照,避免改价影响历史)';
COMMENT ON COLUMN content_prices.id IS '主键ID自增';
COMMENT ON COLUMN content_prices.tenant_id IS '租户ID多租户隔离与内容归属一致';
COMMENT ON COLUMN content_prices.user_id IS '用户ID设置/更新价格的操作人(通常为 tenant_admin用于审计';
COMMENT ON COLUMN content_prices.content_id IS '内容ID唯一约束 (tenant_id, content_id);一个内容在一个租户内仅一份定价';
COMMENT ON COLUMN content_prices.currency IS '币种:当前固定 CNY金额单位为分';
COMMENT ON COLUMN content_prices.price_amount IS '基础价格0 表示免费(可直接访问正片资源)';
COMMENT ON COLUMN content_prices.discount_type IS '折扣类型none/percent/amount仅影响下单时成交价需写入订单快照';
COMMENT ON COLUMN content_prices.discount_value IS '折扣值percent=0-100按业务校验amount=分none 时忽略';
COMMENT ON COLUMN content_prices.discount_start_at IS '折扣开始时间:可为空;为空表示立即生效(由业务逻辑解释)';
COMMENT ON COLUMN content_prices.discount_end_at IS '折扣结束时间:可为空;为空表示长期有效(由业务逻辑解释)';
COMMENT ON COLUMN content_prices.created_at IS '创建时间:默认 now();用于审计';
COMMENT ON COLUMN content_prices.updated_at IS '更新时间:默认 now();更新价格/折扣时写入';
CREATE INDEX IF NOT EXISTS ix_content_prices_tenant_id ON content_prices(tenant_id);
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,
status varchar(16) NOT NULL DEFAULT 'active',
revoked_at timestamptz,
created_at timestamptz NOT NULL DEFAULT NOW(),
updated_at timestamptz NOT NULL DEFAULT NOW(),
UNIQUE (tenant_id, user_id, content_id)
);
-- content_access购买权益/访问权限(退款后撤销)
COMMENT ON TABLE content_access IS '内容权益:记录用户在租户内对内容的访问资格;退款后应立即 revoked';
COMMENT ON COLUMN content_access.id IS '主键ID自增';
COMMENT ON COLUMN content_access.tenant_id IS '租户ID多租户隔离与内容、用户归属一致';
COMMENT ON COLUMN content_access.user_id IS '用户ID权益所属用户用于访问校验';
COMMENT ON COLUMN content_access.content_id IS '内容ID权益对应内容唯一约束 (tenant_id, user_id, content_id)';
COMMENT ON COLUMN content_access.order_id IS '订单ID产生该权益的订单可为空例如后台补发/迁移)';
COMMENT ON COLUMN content_access.status IS '权益状态active/revoked/expiredrevoked 表示立即失效(例如退款/违规)';
COMMENT ON COLUMN content_access.revoked_at IS '撤销时间:当 status=revoked 时写入;用于审计与追责';
COMMENT ON COLUMN content_access.created_at IS '创建时间:默认 now();用于审计';
COMMENT ON COLUMN content_access.updated_at IS '更新时间:默认 now();更新 status 时写入';
CREATE INDEX IF NOT EXISTS ix_content_access_tenant_user ON content_access(tenant_id, user_id);
CREATE INDEX IF NOT EXISTS ix_content_access_tenant_content ON content_access(tenant_id, content_id);
-- +goose StatementEnd
-- +goose Down
-- +goose StatementBegin
DROP INDEX IF EXISTS ix_content_access_tenant_content;
DROP INDEX IF EXISTS ix_content_access_tenant_user;
DROP TABLE IF EXISTS content_access;
DROP INDEX IF EXISTS ix_content_prices_tenant_id;
DROP TABLE IF EXISTS content_prices;
DROP INDEX IF EXISTS ix_content_assets_tenant_role;
DROP INDEX IF EXISTS ix_content_assets_tenant_asset;
DROP INDEX IF EXISTS ix_content_assets_tenant_content;
DROP TABLE IF EXISTS content_assets;
DROP INDEX IF EXISTS ix_contents_tenant_visibility;
DROP INDEX IF EXISTS ix_contents_tenant_status;
DROP INDEX IF EXISTS ix_contents_tenant_user_id;
DROP INDEX IF EXISTS ix_contents_tenant_id;
DROP TABLE IF EXISTS contents;
DROP INDEX IF EXISTS ix_media_assets_tenant_status;
DROP INDEX IF EXISTS ix_media_assets_tenant_user_id;
DROP INDEX IF EXISTS ix_media_assets_tenant_id;
DROP TABLE IF EXISTS media_assets;
-- +goose StatementEnd