152 lines
5.7 KiB
PL/PgSQL
152 lines
5.7 KiB
PL/PgSQL
-- 新项目数据库 DDL(PostgreSQL)
|
||
-- 目标:多租户(tenant_id 全表隔离)+ tenant_uuid 用于 OSS Key:quyun/<tenant_uuid>/<md5>.<ext>
|
||
-- 注意:tenant_uuid 由业务代码生成写入(不使用 DB 扩展默认值)
|
||
|
||
BEGIN;
|
||
|
||
-- 1) 租户
|
||
CREATE TABLE IF NOT EXISTS tenants (
|
||
id BIGSERIAL PRIMARY KEY,
|
||
tenant_code VARCHAR(64) NOT NULL,
|
||
tenant_uuid UUID NOT NULL,
|
||
name VARCHAR(128) NOT NULL DEFAULT '',
|
||
status INT2 NOT NULL DEFAULT 0,
|
||
config JSONB NOT NULL DEFAULT '{}'::jsonb,
|
||
created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
|
||
updated_at TIMESTAMPTZ NOT NULL DEFAULT now()
|
||
);
|
||
|
||
-- tenant_code:不区分大小写(写入/查询均 lower),并限制字符集 a-z0-9_-
|
||
ALTER TABLE tenants
|
||
ADD CONSTRAINT tenants_tenant_code_format
|
||
CHECK (tenant_code ~ '^[A-Za-z0-9_-]+$');
|
||
|
||
CREATE UNIQUE INDEX IF NOT EXISTS ux_tenants_tenant_code_lower
|
||
ON tenants (lower(tenant_code));
|
||
|
||
CREATE UNIQUE INDEX IF NOT EXISTS ux_tenants_tenant_uuid
|
||
ON tenants (tenant_uuid);
|
||
|
||
-- 2) 租户后台账号
|
||
CREATE TABLE IF NOT EXISTS admin_users (
|
||
id BIGSERIAL PRIMARY KEY,
|
||
tenant_id BIGINT NOT NULL REFERENCES tenants(id) ON DELETE CASCADE,
|
||
username VARCHAR(64) NOT NULL,
|
||
password_hash TEXT NOT NULL,
|
||
role VARCHAR(32) NOT NULL DEFAULT 'admin',
|
||
status INT2 NOT NULL DEFAULT 0,
|
||
created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
|
||
updated_at TIMESTAMPTZ NOT NULL DEFAULT now()
|
||
);
|
||
|
||
CREATE UNIQUE INDEX IF NOT EXISTS ux_admin_users_tenant_username
|
||
ON admin_users (tenant_id, lower(username));
|
||
|
||
-- 3) 用户(微信 openid 用户)
|
||
CREATE TABLE IF NOT EXISTS users (
|
||
id BIGSERIAL PRIMARY KEY,
|
||
tenant_id BIGINT NOT NULL REFERENCES tenants(id) ON DELETE CASCADE,
|
||
created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
|
||
updated_at TIMESTAMPTZ NOT NULL DEFAULT now(),
|
||
deleted_at TIMESTAMPTZ,
|
||
status INT2 NOT NULL DEFAULT 0,
|
||
open_id VARCHAR(128) NOT NULL,
|
||
username VARCHAR(128) NOT NULL DEFAULT '',
|
||
avatar TEXT,
|
||
metas JSONB NOT NULL DEFAULT '{}'::jsonb,
|
||
auth_token JSONB NOT NULL DEFAULT '{}'::jsonb,
|
||
balance BIGINT NOT NULL DEFAULT 0
|
||
);
|
||
|
||
CREATE UNIQUE INDEX IF NOT EXISTS ux_users_tenant_openid
|
||
ON users (tenant_id, open_id);
|
||
|
||
CREATE INDEX IF NOT EXISTS ix_users_tenant_id
|
||
ON users (tenant_id, id);
|
||
|
||
-- 4) 媒体
|
||
CREATE TABLE IF NOT EXISTS medias (
|
||
id BIGSERIAL PRIMARY KEY,
|
||
tenant_id BIGINT NOT NULL REFERENCES tenants(id) ON DELETE CASCADE,
|
||
created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
|
||
name VARCHAR(255) NOT NULL DEFAULT '',
|
||
mime_type VARCHAR(128) NOT NULL DEFAULT '',
|
||
size BIGINT NOT NULL DEFAULT 0,
|
||
path VARCHAR(512) NOT NULL DEFAULT '',
|
||
metas JSONB NOT NULL DEFAULT '{}'::jsonb,
|
||
hash VARCHAR(64) NOT NULL DEFAULT ''
|
||
);
|
||
|
||
-- 租户内按 md5 去重
|
||
CREATE UNIQUE INDEX IF NOT EXISTS ux_medias_tenant_hash
|
||
ON medias (tenant_id, hash);
|
||
|
||
CREATE INDEX IF NOT EXISTS ix_medias_tenant_id
|
||
ON medias (tenant_id, id);
|
||
|
||
-- 5) 曲谱/内容
|
||
CREATE TABLE IF NOT EXISTS posts (
|
||
id BIGSERIAL PRIMARY KEY,
|
||
tenant_id BIGINT NOT NULL REFERENCES tenants(id) ON DELETE CASCADE,
|
||
created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
|
||
updated_at TIMESTAMPTZ NOT NULL DEFAULT now(),
|
||
deleted_at TIMESTAMPTZ,
|
||
status INT2 NOT NULL DEFAULT 0,
|
||
title VARCHAR(128) NOT NULL,
|
||
head_images JSONB NOT NULL DEFAULT '[]'::jsonb,
|
||
description VARCHAR(256) NOT NULL DEFAULT '',
|
||
content TEXT NOT NULL DEFAULT '',
|
||
price BIGINT NOT NULL DEFAULT 0,
|
||
discount INT2 NOT NULL DEFAULT 100,
|
||
views BIGINT NOT NULL DEFAULT 0,
|
||
likes BIGINT NOT NULL DEFAULT 0,
|
||
tags JSONB NOT NULL DEFAULT '[]'::jsonb,
|
||
assets JSONB NOT NULL DEFAULT '[]'::jsonb
|
||
);
|
||
|
||
CREATE INDEX IF NOT EXISTS ix_posts_tenant_status_deleted
|
||
ON posts (tenant_id, status, deleted_at);
|
||
|
||
-- 6) 授权关系(购买/赠送)
|
||
CREATE TABLE IF NOT EXISTS user_posts (
|
||
id BIGSERIAL PRIMARY KEY,
|
||
tenant_id BIGINT NOT NULL REFERENCES tenants(id) ON DELETE CASCADE,
|
||
created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
|
||
updated_at TIMESTAMPTZ NOT NULL DEFAULT now(),
|
||
user_id BIGINT NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
||
post_id BIGINT NOT NULL REFERENCES posts(id) ON DELETE CASCADE,
|
||
price BIGINT NOT NULL DEFAULT 0
|
||
);
|
||
|
||
CREATE UNIQUE INDEX IF NOT EXISTS ux_user_posts_tenant_user_post
|
||
ON user_posts (tenant_id, user_id, post_id);
|
||
|
||
CREATE INDEX IF NOT EXISTS ix_user_posts_tenant_user
|
||
ON user_posts (tenant_id, user_id, id);
|
||
|
||
-- 7) 订单(仅余额)
|
||
CREATE TABLE IF NOT EXISTS orders (
|
||
id BIGSERIAL PRIMARY KEY,
|
||
tenant_id BIGINT NOT NULL REFERENCES tenants(id) ON DELETE CASCADE,
|
||
created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
|
||
updated_at TIMESTAMPTZ NOT NULL DEFAULT now(),
|
||
order_no VARCHAR(64) NOT NULL,
|
||
price BIGINT NOT NULL DEFAULT 0,
|
||
discount INT2 NOT NULL DEFAULT 100,
|
||
currency VARCHAR(10) NOT NULL DEFAULT 'CNY',
|
||
payment_method VARCHAR(50) NOT NULL DEFAULT 'balance',
|
||
post_id BIGINT NOT NULL REFERENCES posts(id) ON DELETE CASCADE,
|
||
user_id BIGINT NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
||
status INT2 NOT NULL DEFAULT 0,
|
||
meta JSONB NOT NULL DEFAULT '{}'::jsonb
|
||
);
|
||
|
||
CREATE UNIQUE INDEX IF NOT EXISTS ux_orders_tenant_order_no
|
||
ON orders (tenant_id, order_no);
|
||
|
||
CREATE INDEX IF NOT EXISTS ix_orders_tenant_user
|
||
ON orders (tenant_id, user_id, id);
|
||
|
||
COMMIT;
|
||
|