Files
junhong_cmp_fiber/migrations/000002_rbac_data_permission.up.sql
huang f46beb2d45 docs(migration): 为 RBAC 表添加 PostgreSQL 注释
为 5 个 RBAC 核心表添加完整的表和字段注释:
- tb_account: 账号表(13 个字段)
- tb_role: 角色表(9 个字段)
- tb_permission: 权限表(13 个字段)
- tb_account_role: 账号-角色关联表(9 个字段)
- tb_role_permission: 角色-权限关联表(9 个字段)

使用 PostgreSQL COMMENT ON 语句,提供中文注释说明每个表和字段的用途。

🤖 Generated with [Claude Code](https://claude.com/claude-code)

Co-Authored-By: Claude <noreply@anthropic.com>
2025-11-18 14:57:33 +08:00

186 lines
9.6 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.
-- RBAC 表结构迁移
-- 创建 5 个 RBAC 核心表:账号、角色、权限、账号-角色关联、角色-权限关联
-- =============================================================================
-- T014: tb_account (账号表)
-- =============================================================================
CREATE TABLE IF NOT EXISTS tb_account (
id BIGSERIAL PRIMARY KEY,
username VARCHAR(50) NOT NULL,
phone VARCHAR(20) NOT NULL,
password VARCHAR(255) NOT NULL,
user_type SMALLINT NOT NULL, -- 1=root, 2=平台, 3=代理, 4=企业
shop_id INTEGER,
parent_id INTEGER, -- 上级账号 ID自关联
status SMALLINT NOT NULL DEFAULT 1, -- 0=禁用, 1=启用
creator INTEGER NOT NULL,
updater INTEGER NOT NULL,
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
deleted_at TIMESTAMP
);
-- T015: tb_account 索引
CREATE UNIQUE INDEX idx_account_username ON tb_account(username) WHERE deleted_at IS NULL;
CREATE UNIQUE INDEX idx_account_phone ON tb_account(phone) WHERE deleted_at IS NULL;
CREATE INDEX idx_account_user_type ON tb_account(user_type);
CREATE INDEX idx_account_shop_id ON tb_account(shop_id);
CREATE INDEX idx_account_parent_id ON tb_account(parent_id);
CREATE INDEX idx_account_deleted_at ON tb_account(deleted_at);
-- tb_account 表和字段注释
COMMENT ON TABLE tb_account IS '账号表:存储系统用户账号信息,支持层级关系和软删除';
COMMENT ON COLUMN tb_account.id IS '主键 ID';
COMMENT ON COLUMN tb_account.username IS '用户名(唯一,软删除后可重用)';
COMMENT ON COLUMN tb_account.phone IS '手机号(唯一,软删除后可重用)';
COMMENT ON COLUMN tb_account.password IS 'bcrypt 哈希密码';
COMMENT ON COLUMN tb_account.user_type IS '用户类型1=root超级管理员, 2=平台(平台账号), 3=代理(代理商), 4=企业(企业用户)';
COMMENT ON COLUMN tb_account.shop_id IS '所属店铺 ID用于数据权限隔离';
COMMENT ON COLUMN tb_account.parent_id IS '上级账号 ID自关联用于层级关系和递归查询';
COMMENT ON COLUMN tb_account.status IS '状态0=禁用, 1=启用';
COMMENT ON COLUMN tb_account.creator IS '创建人 ID';
COMMENT ON COLUMN tb_account.updater IS '更新人 ID';
COMMENT ON COLUMN tb_account.created_at IS '创建时间';
COMMENT ON COLUMN tb_account.updated_at IS '更新时间';
COMMENT ON COLUMN tb_account.deleted_at IS '软删除时间NULL 表示未删除)';
-- =============================================================================
-- T016: tb_role (角色表)
-- =============================================================================
CREATE TABLE IF NOT EXISTS tb_role (
id BIGSERIAL PRIMARY KEY,
role_name VARCHAR(50) NOT NULL,
role_desc VARCHAR(255),
role_type SMALLINT NOT NULL, -- 1=超级, 2=代理, 3=企业
status SMALLINT NOT NULL DEFAULT 1, -- 0=禁用, 1=启用
creator INTEGER NOT NULL,
updater INTEGER NOT NULL,
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
deleted_at TIMESTAMP
);
-- T017: tb_role 索引
CREATE INDEX idx_role_role_type ON tb_role(role_type);
CREATE INDEX idx_role_deleted_at ON tb_role(deleted_at);
-- tb_role 表和字段注释
COMMENT ON TABLE tb_role IS '角色表:定义系统角色,支持软删除';
COMMENT ON COLUMN tb_role.id IS '主键 ID';
COMMENT ON COLUMN tb_role.role_name IS '角色名称';
COMMENT ON COLUMN tb_role.role_desc IS '角色描述';
COMMENT ON COLUMN tb_role.role_type IS '角色类型1=超级角色, 2=代理角色, 3=企业角色';
COMMENT ON COLUMN tb_role.status IS '状态0=禁用, 1=启用';
COMMENT ON COLUMN tb_role.creator IS '创建人 ID';
COMMENT ON COLUMN tb_role.updater IS '更新人 ID';
COMMENT ON COLUMN tb_role.created_at IS '创建时间';
COMMENT ON COLUMN tb_role.updated_at IS '更新时间';
COMMENT ON COLUMN tb_role.deleted_at IS '软删除时间NULL 表示未删除)';
-- =============================================================================
-- T018: tb_permission (权限表)
-- =============================================================================
CREATE TABLE IF NOT EXISTS tb_permission (
id BIGSERIAL PRIMARY KEY,
perm_name VARCHAR(50) NOT NULL,
perm_code VARCHAR(100) NOT NULL, -- 权限编码(如 user:create
perm_type SMALLINT NOT NULL, -- 1=菜单, 2=按钮
url VARCHAR(255),
parent_id INTEGER, -- 上级权限 ID层级
sort INTEGER NOT NULL DEFAULT 0,
status SMALLINT NOT NULL DEFAULT 1, -- 0=禁用, 1=启用
creator INTEGER NOT NULL,
updater INTEGER NOT NULL,
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
deleted_at TIMESTAMP
);
-- T019: tb_permission 索引
CREATE UNIQUE INDEX idx_permission_code ON tb_permission(perm_code) WHERE deleted_at IS NULL;
CREATE INDEX idx_permission_type ON tb_permission(perm_type);
CREATE INDEX idx_permission_parent_id ON tb_permission(parent_id);
CREATE INDEX idx_permission_deleted_at ON tb_permission(deleted_at);
-- tb_permission 表和字段注释
COMMENT ON TABLE tb_permission IS '权限表:定义系统权限(菜单和按钮),支持层级结构和软删除';
COMMENT ON COLUMN tb_permission.id IS '主键 ID';
COMMENT ON COLUMN tb_permission.perm_name IS '权限名称';
COMMENT ON COLUMN tb_permission.perm_code IS '权限编码(唯一,如 user:create';
COMMENT ON COLUMN tb_permission.perm_type IS '权限类型1=菜单, 2=按钮';
COMMENT ON COLUMN tb_permission.url IS '权限对应的 URL 路径';
COMMENT ON COLUMN tb_permission.parent_id IS '上级权限 ID自关联用于层级结构';
COMMENT ON COLUMN tb_permission.sort IS '排序号(用于菜单排序)';
COMMENT ON COLUMN tb_permission.status IS '状态0=禁用, 1=启用';
COMMENT ON COLUMN tb_permission.creator IS '创建人 ID';
COMMENT ON COLUMN tb_permission.updater IS '更新人 ID';
COMMENT ON COLUMN tb_permission.created_at IS '创建时间';
COMMENT ON COLUMN tb_permission.updated_at IS '更新时间';
COMMENT ON COLUMN tb_permission.deleted_at IS '软删除时间NULL 表示未删除)';
-- =============================================================================
-- T020: tb_account_role (账号-角色关联表)
-- =============================================================================
CREATE TABLE IF NOT EXISTS tb_account_role (
id BIGSERIAL PRIMARY KEY,
account_id INTEGER NOT NULL,
role_id INTEGER NOT NULL,
status SMALLINT NOT NULL DEFAULT 1, -- 0=禁用, 1=启用
creator INTEGER NOT NULL,
updater INTEGER NOT NULL,
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
deleted_at TIMESTAMP
);
-- T021: tb_account_role 索引
CREATE INDEX idx_account_role_account_id ON tb_account_role(account_id);
CREATE INDEX idx_account_role_role_id ON tb_account_role(role_id);
CREATE INDEX idx_account_role_deleted_at ON tb_account_role(deleted_at);
CREATE UNIQUE INDEX idx_account_role_unique ON tb_account_role(account_id, role_id) WHERE deleted_at IS NULL;
-- tb_account_role 表和字段注释
COMMENT ON TABLE tb_account_role IS '账号-角色关联表:实现账号和角色的多对多关系,支持软删除';
COMMENT ON COLUMN tb_account_role.id IS '主键 ID';
COMMENT ON COLUMN tb_account_role.account_id IS '账号 ID';
COMMENT ON COLUMN tb_account_role.role_id IS '角色 ID';
COMMENT ON COLUMN tb_account_role.status IS '状态0=禁用, 1=启用';
COMMENT ON COLUMN tb_account_role.creator IS '创建人 ID';
COMMENT ON COLUMN tb_account_role.updater IS '更新人 ID';
COMMENT ON COLUMN tb_account_role.created_at IS '创建时间';
COMMENT ON COLUMN tb_account_role.updated_at IS '更新时间';
COMMENT ON COLUMN tb_account_role.deleted_at IS '软删除时间NULL 表示未删除)';
-- =============================================================================
-- T022: tb_role_permission (角色-权限关联表)
-- =============================================================================
CREATE TABLE IF NOT EXISTS tb_role_permission (
id BIGSERIAL PRIMARY KEY,
role_id INTEGER NOT NULL,
perm_id INTEGER NOT NULL,
status SMALLINT NOT NULL DEFAULT 1, -- 0=禁用, 1=启用
creator INTEGER NOT NULL,
updater INTEGER NOT NULL,
created_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
deleted_at TIMESTAMP
);
-- T023: tb_role_permission 索引
CREATE INDEX idx_role_permission_role_id ON tb_role_permission(role_id);
CREATE INDEX idx_role_permission_perm_id ON tb_role_permission(perm_id);
CREATE INDEX idx_role_permission_deleted_at ON tb_role_permission(deleted_at);
CREATE UNIQUE INDEX idx_role_permission_unique ON tb_role_permission(role_id, perm_id) WHERE deleted_at IS NULL;
-- tb_role_permission 表和字段注释
COMMENT ON TABLE tb_role_permission IS '角色-权限关联表:实现角色和权限的多对多关系,支持软删除';
COMMENT ON COLUMN tb_role_permission.id IS '主键 ID';
COMMENT ON COLUMN tb_role_permission.role_id IS '角色 ID';
COMMENT ON COLUMN tb_role_permission.perm_id IS '权限 ID';
COMMENT ON COLUMN tb_role_permission.status IS '状态0=禁用, 1=启用';
COMMENT ON COLUMN tb_role_permission.creator IS '创建人 ID';
COMMENT ON COLUMN tb_role_permission.updater IS '更新人 ID';
COMMENT ON COLUMN tb_role_permission.created_at IS '创建时间';
COMMENT ON COLUMN tb_role_permission.updated_at IS '更新时间';
COMMENT ON COLUMN tb_role_permission.deleted_at IS '软删除时间NULL 表示未删除)';