rtsa-services/migrations/20240830095636_init.up.sql

590 lines
22 KiB
SQL

-- 初始化数据库SCHEMA(所有轨道交通信号系统仿真的表、类型等都在rtsa SCHEMA下)
CREATE SCHEMA rtsa;
-- 创建mqtt客户端id序列
CREATE SEQUENCE rtsa.mqtt_client_id_seq;
-- 创建用户表
CREATE TABLE
rtsa.user (
id SERIAL PRIMARY KEY, -- id 自增主键
username VARCHAR(128) NOT NULL, -- 用户名
password VARCHAR(256) NOT NULL, -- 密码
email VARCHAR(128) NULL UNIQUE, -- 邮箱
mobile VARCHAR(16) NULL UNIQUE, -- 手机号
roles JSONB NOT NULL DEFAULT '[]', -- 角色列表
info JSONB NOT NULL DEFAULT '{}', -- 用户信息
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP, -- 创建时间
updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP -- 更新时间
);
-- 创建用户名称索引
CREATE INDEX ON rtsa.user (username);
-- 创建用户邮箱索引
CREATE INDEX ON rtsa.user (email);
-- 创建用户手机号索引
CREATE INDEX ON rtsa.user (mobile);
-- 创建用户角色索引
CREATE INDEX ON rtsa.user USING GIN (roles);
-- 注释用户表
COMMENT ON TABLE rtsa.user IS '用户表';
-- 注释用户表字段
COMMENT ON COLUMN rtsa.user.id IS 'id 自增主键';
COMMENT ON COLUMN rtsa.user.username IS '用户名';
COMMENT ON COLUMN rtsa.user.password IS '密码';
COMMENT ON COLUMN rtsa.user.email IS '邮箱';
COMMENT ON COLUMN rtsa.user.mobile IS '手机号';
COMMENT ON COLUMN rtsa.user.roles IS '角色列表';
COMMENT ON COLUMN rtsa.user.info IS '用户信息';
COMMENT ON COLUMN rtsa.user.created_at IS '创建时间';
COMMENT ON COLUMN rtsa.user.updated_at IS '更新时间';
-- 创建组织表
CREATE TABLE
rtsa.organization (
id SERIAL PRIMARY KEY, -- id 自增主键
code VARCHAR(128) NOT NULL UNIQUE, -- 组织编码
name VARCHAR(128) NOT NULL, -- 组织名称
config JSONB NOT NULL DEFAULT '{}', -- 配置数据
parent_id INT NULL, -- 父组织id
creator_id INT NOT NULL, -- 创建用户id
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP, -- 创建时间
updater_id INT NOT NULL, -- 更新用户id
updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP, -- 更新时间
FOREIGN KEY (parent_id) REFERENCES rtsa.organization (id) ON DELETE CASCADE, -- 父组织外键
FOREIGN KEY (creator_id) REFERENCES rtsa.user (id) ON DELETE CASCADE, -- 创建用户外键
FOREIGN KEY (updater_id) REFERENCES rtsa.user (id) ON DELETE CASCADE -- 更新用户外键
);
-- 创建组织编码索引
CREATE INDEX ON rtsa.organization (code);
-- 创建组织名称索引
CREATE INDEX ON rtsa.organization (name);
-- 创建组织父组织索引
CREATE INDEX ON rtsa.organization (parent_id);
-- 创建组织创建用户索引
CREATE INDEX ON rtsa.organization (creator_id);
-- 创建组织更新用户索引
CREATE INDEX ON rtsa.organization (updater_id);
-- 注释组织表
COMMENT ON TABLE rtsa.organization IS '组织表';
-- 注释组织表字段
COMMENT ON COLUMN rtsa.organization.id IS 'id 自增主键';
COMMENT ON COLUMN rtsa.organization.code IS '组织编码';
COMMENT ON COLUMN rtsa.organization.name IS '组织名称';
COMMENT ON COLUMN rtsa.organization.config IS '配置数据';
COMMENT ON COLUMN rtsa.organization.parent_id IS '父组织id';
COMMENT ON COLUMN rtsa.organization.creator_id IS '创建用户id';
COMMENT ON COLUMN rtsa.organization.created_at IS '创建时间';
COMMENT ON COLUMN rtsa.organization.updater_id IS '更新用户id';
COMMENT ON COLUMN rtsa.organization.updated_at IS '更新时间';
-- 创建组织用户表
CREATE TABLE
rtsa.organization_user (
id SERIAL PRIMARY KEY, -- id 自增主键
organization_id INT NOT NULL, -- 组织id
user_id INT NOT NULL, -- 用户id
student_id VARCHAR(128) NULL, -- 学工号
roles JSONB NOT NULL DEFAULT '[]', -- 组织角色列表
creator_id INT NOT NULL, -- 创建用户id
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP, -- 创建时间
updater_id INT NOT NULL, -- 更新用户id
updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP, -- 更新时间
FOREIGN KEY (organization_id) REFERENCES rtsa.organization (id) ON DELETE CASCADE, -- 组织外键
FOREIGN KEY (user_id) REFERENCES rtsa.user (id) ON DELETE CASCADE, -- 用户外键
FOREIGN KEY (creator_id) REFERENCES rtsa.user (id) ON DELETE CASCADE, -- 创建用户外键
FOREIGN KEY (updater_id) REFERENCES rtsa.user (id) ON DELETE CASCADE, -- 更新用户外键
UNIQUE(organization_id, user_id) -- 组织id和用户id唯一
);
-- 创建组织用户组织索引
CREATE INDEX ON rtsa.organization_user (organization_id);
-- 创建组织用户用户索引
CREATE INDEX ON rtsa.organization_user (user_id);
-- 创建组织用户学工号索引
CREATE INDEX ON rtsa.organization_user (student_id);
-- 创建组织用户角色索引
CREATE INDEX ON rtsa.organization_user USING GIN (roles);
-- 创建组织用户创建用户索引
CREATE INDEX ON rtsa.organization_user (creator_id);
-- 创建组织用户更新用户索引
CREATE INDEX ON rtsa.organization_user (updater_id);
-- 注释组织用户表
COMMENT ON TABLE rtsa.organization_user IS '组织用户表';
-- 注释组织用户表字段
COMMENT ON COLUMN rtsa.organization_user.id IS 'id 自增主键';
COMMENT ON COLUMN rtsa.organization_user.organization_id IS '组织id';
COMMENT ON COLUMN rtsa.organization_user.user_id IS '用户id';
COMMENT ON COLUMN rtsa.organization_user.student_id IS '学工号';
COMMENT ON COLUMN rtsa.organization_user.roles IS '组织角色列表';
COMMENT ON COLUMN rtsa.organization_user.creator_id IS '创建用户id';
COMMENT ON COLUMN rtsa.organization_user.created_at IS '创建时间';
COMMENT ON COLUMN rtsa.organization_user.updater_id IS '更新用户id';
COMMENT ON COLUMN rtsa.organization_user.updated_at IS '更新时间';
-- 创建feature表
CREATE TABLE
rtsa.feature (
id SERIAL PRIMARY KEY, -- id 自增主键
feature_type INT NOT NULL, -- feature类型
name VARCHAR(128) NOT NULL, -- feature名称
description TEXT NOT NULL, -- feature描述
config JSONB NOT NULL, -- feature配置
is_published BOOLEAN NOT NULL DEFAULT TRUE, -- 是否上架
creator_id INT NOT NULL, -- 创建用户id
updater_id INT NOT NULL, -- 更新用户id
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP, -- 创建时间
updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP, -- 更新时间
FOREIGN KEY (creator_id) REFERENCES rtsa.user (id) ON DELETE CASCADE, -- 用户外键
FOREIGN KEY (updater_id) REFERENCES rtsa.user (id) ON DELETE CASCADE, -- 用户外键
UNIQUE(feature_type, name) -- feature类型和名称唯一
);
-- 创建feature类型索引
CREATE INDEX ON rtsa.feature (feature_type);
-- 创建feature名称索引
CREATE INDEX ON rtsa.feature (name);
-- 注释仿真feature表
COMMENT ON TABLE rtsa.feature IS 'feature表';
-- 注释仿真feature表字段
COMMENT ON COLUMN rtsa.feature.id IS 'id 自增主键';
COMMENT ON COLUMN rtsa.feature.feature_type IS 'feature类型';
COMMENT ON COLUMN rtsa.feature.name IS 'feature名称';
COMMENT ON COLUMN rtsa.feature.description IS 'feature描述';
COMMENT ON COLUMN rtsa.feature.config IS 'feature配置';
COMMENT ON COLUMN rtsa.feature.is_published IS '是否上架';
COMMENT ON COLUMN rtsa.feature.creator_id IS '创建用户id';
COMMENT ON COLUMN rtsa.feature.created_at IS '创建时间';
COMMENT ON COLUMN rtsa.feature.updated_at IS '更新时间';
-- 创建组织功能表
CREATE TABLE
rtsa.organization_feature (
id SERIAL PRIMARY KEY, -- id 自增主键
organization_id INT NOT NULL, -- 组织id
feature_id INT NOT NULL, -- feature id
config JSONB NOT NULL, -- 组织功能配置
creator_id INT NOT NULL, -- 创建用户id
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP, -- 创建时间
updater_id INT NOT NULL, -- 更新用户id
updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP, -- 更新时间
FOREIGN KEY (organization_id) REFERENCES rtsa.organization (id) ON DELETE CASCADE, -- 组织外键
FOREIGN KEY (feature_id) REFERENCES rtsa.feature (id) ON DELETE CASCADE, -- feature外键
FOREIGN KEY (creator_id) REFERENCES rtsa.user (id) ON DELETE CASCADE, -- 创建用户外键
FOREIGN KEY (updater_id) REFERENCES rtsa.user (id) ON DELETE CASCADE, -- 更新用户外键
UNIQUE(organization_id, feature_id) -- 组织id和feature id唯一
);
-- 创建组织功能组织索引
CREATE INDEX ON rtsa.organization_feature (organization_id);
-- 创建组织功能feature索引
CREATE INDEX ON rtsa.organization_feature (feature_id);
-- 创建组织功能配置项索引
CREATE INDEX ON rtsa.organization_feature USING GIN (config);
-- 创建组织功能创建用户索引
CREATE INDEX ON rtsa.organization_feature (creator_id);
-- 创建组织功能更新用户索引
CREATE INDEX ON rtsa.organization_feature (updater_id);
-- 注释组织功能表
COMMENT ON TABLE rtsa.organization_feature IS '组织功能表';
-- 注释组织功能表字段
COMMENT ON COLUMN rtsa.organization_feature.id IS 'id 自增主键';
COMMENT ON COLUMN rtsa.organization_feature.organization_id IS '组织id';
COMMENT ON COLUMN rtsa.organization_feature.feature_id IS 'feature id';
COMMENT ON COLUMN rtsa.organization_feature.config IS '组织功能配置';
COMMENT ON COLUMN rtsa.organization_feature.creator_id IS '创建用户id';
COMMENT ON COLUMN rtsa.organization_feature.created_at IS '创建时间';
COMMENT ON COLUMN rtsa.organization_feature.updater_id IS '更新用户id';
COMMENT ON COLUMN rtsa.organization_feature.updated_at IS '更新时间';
-- 创建草稿数据表
CREATE TABLE
rtsa.draft_data (
id SERIAL PRIMARY KEY, -- id 自增主键
name VARCHAR(128) NOT NULL, -- 草稿名称
data_type INT NOT NULL, -- 数据类型
options JSONB NULL, -- 数据相关的参数项或配置项
data BYTEA, -- 草稿数据
default_release_data_id INT NULL, -- 默认发布数据id
user_id INT NOT NULL, -- 创建用户id
is_shared BOOLEAN NOT NULL DEFAULT FALSE, -- 是否共享
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP, -- 创建时间
updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP, -- 更新时间
FOREIGN KEY (user_id) REFERENCES rtsa.user (id) ON DELETE CASCADE, -- 用户外键
UNIQUE(name, data_type, user_id) -- 一个用户的某个类型的草稿名称唯一
);
-- 创建草稿数据用户索引
CREATE INDEX ON rtsa.draft_data (user_id);
-- 创建草稿数据类型索引
CREATE INDEX ON rtsa.draft_data (data_type);
-- 创建草稿数据配置项索引
CREATE INDEX ON rtsa.draft_data USING GIN (options);
-- 注释草稿数据表
COMMENT ON TABLE rtsa.draft_data IS '草稿数据表';
-- 注释草稿数据表字段
COMMENT ON COLUMN rtsa.draft_data.id IS 'id 自增主键';
COMMENT ON COLUMN rtsa.draft_data.name IS '草稿名称';
COMMENT ON COLUMN rtsa.draft_data.data_type IS '数据类型';
COMMENT ON COLUMN rtsa.draft_data.options IS '数据相关的参数项或配置项';
COMMENT ON COLUMN rtsa.draft_data.data IS '草稿数据';
COMMENT ON COLUMN rtsa.draft_data.user_id IS '创建用户id';
COMMENT ON COLUMN rtsa.draft_data.is_shared IS '是否共享';
COMMENT ON COLUMN rtsa.draft_data.created_at IS '创建时间';
COMMENT ON COLUMN rtsa.draft_data.updated_at IS '更新时间';
-- 创建发布数据表
CREATE TABLE
rtsa.release_data (
id SERIAL PRIMARY KEY, -- id 自增主键
name VARCHAR(128) NOT NULL, -- 发布数据名称(数据唯一标识)
data_type INT NOT NULL, -- 数据类型
options JSONB NULL, -- 数据相关的参数项或配置项
used_version_id INT NULL, -- 使用的版本数据id
user_id INT NOT NULL, -- 发布/更新用户id
is_published BOOLEAN NOT NULL DEFAULT TRUE, -- 是否上架
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP, -- 创建时间
updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP, -- 更新时间
FOREIGN KEY (user_id) REFERENCES rtsa.user (id) ON DELETE CASCADE, -- 用户外键
UNIQUE(data_type, name) -- 数据类型和名称唯一
);
-- 创建发布数据名称索引
CREATE INDEX ON rtsa.release_data (name);
-- 创建发布数据用户索引
CREATE INDEX ON rtsa.release_data (user_id);
-- 创建发布数据类型索引
CREATE INDEX ON rtsa.release_data (data_type);
-- 创建发布数据配置项索引
CREATE INDEX ON rtsa.release_data USING GIN (options);
-- 注释发布数据表
COMMENT ON TABLE rtsa.release_data IS '发布数据表';
-- 注释发布数据表字段
COMMENT ON COLUMN rtsa.release_data.id IS 'id 自增主键';
COMMENT ON COLUMN rtsa.release_data.name IS '发布数据名称(数据唯一标识)';
COMMENT ON COLUMN rtsa.release_data.data_type IS '数据类型';
COMMENT ON COLUMN rtsa.release_data.options IS '数据相关的参数项或配置项';
COMMENT ON COLUMN rtsa.release_data.used_version_id IS '使用的版本数据id';
COMMENT ON COLUMN rtsa.release_data.user_id IS '发布/更新用户id';
COMMENT ON COLUMN rtsa.release_data.is_published IS '是否上架';
COMMENT ON COLUMN rtsa.release_data.created_at IS '创建时间';
COMMENT ON COLUMN rtsa.release_data.updated_at IS '更新时间';
-- 创建发布数据版本表
CREATE TABLE
rtsa.release_data_version (
id SERIAL PRIMARY KEY, -- id 自增主键
release_data_id INT NOT NULL, -- 发布数据id
options JSONB NULL, -- 数据相关的参数项或配置项
data BYTEA NOT NULL, -- 数据
description TEXT NOT NULL, -- 版本描述
user_id INT NOT NULL, -- 发布用户id
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP, -- 创建时间
FOREIGN KEY (user_id) REFERENCES rtsa.user (id) ON DELETE CASCADE, -- 用户外键
FOREIGN KEY (release_data_id) REFERENCES rtsa.release_data (id) ON DELETE CASCADE
);
-- 创建发布数据版本发布数据索引
CREATE INDEX ON rtsa.release_data_version (release_data_id);
-- 创建发布数据版本用户索引
CREATE INDEX ON rtsa.release_data_version (user_id);
-- 创建发布数据版本配置项索引
CREATE INDEX ON rtsa.release_data_version USING GIN (options);
-- 创建发布数据当前版本外键
ALTER TABLE rtsa.release_data ADD FOREIGN KEY (used_version_id) REFERENCES rtsa.release_data_version (id) ON DELETE SET NULL;
-- 创建草稿数据默认发布数据外键
ALTER TABLE rtsa.draft_data ADD FOREIGN KEY (default_release_data_id) REFERENCES rtsa.release_data (id) ON DELETE SET NULL;
-- 注释发布数据版本表
COMMENT ON TABLE rtsa.release_data_version IS '发布数据版本表';
-- 注释发布数据版本表字段
COMMENT ON COLUMN rtsa.release_data_version.id IS 'id 自增主键';
COMMENT ON COLUMN rtsa.release_data_version.release_data_id IS '发布数据id';
COMMENT ON COLUMN rtsa.release_data_version.options IS '数据相关的参数项或配置项';
COMMENT ON COLUMN rtsa.release_data_version.data IS '数据';
COMMENT ON COLUMN rtsa.release_data_version.description IS '版本描述';
COMMENT ON COLUMN rtsa.release_data_version.user_id IS '发布用户id';
COMMENT ON COLUMN rtsa.release_data_version.created_at IS '创建时间';
-- 创建发布数据集表
CREATE TABLE
rtsa.release_data_set (
id SERIAL PRIMARY KEY, -- id 自增主键
data_set_type INT NOT NULL, -- 数据集类型
name VARCHAR(128) NOT NULL, -- 发布数据集名称
description TEXT NOT NULL, -- 发布数据集描述
config JSONB NULL, -- 数据集相关配置项
is_published BOOLEAN NOT NULL DEFAULT TRUE, -- 是否上架
creator_id INT NOT NULL, -- 创建用户id
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP, -- 创建时间
updater_id INT NOT NULL, -- 更新用户id
updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP, -- 更新时间
FOREIGN KEY (creator_id) REFERENCES rtsa.user (id) ON DELETE CASCADE, -- 创建用户外键
FOREIGN KEY (updater_id) REFERENCES rtsa.user (id) ON DELETE CASCADE, -- 更新用户外键
UNIQUE(data_set_type, name) -- 数据集类型+name唯一
);
-- 创建发布数据集类型索引
CREATE INDEX ON rtsa.release_data_set (data_set_type);
-- 创建发布数据集名称索引
CREATE INDEX ON rtsa.release_data_set (name);
-- 创建发布数据集配置项索引
CREATE INDEX ON rtsa.release_data_set USING GIN (config);
-- 创建发布数据集创建用户索引
CREATE INDEX ON rtsa.release_data_set (creator_id);
-- 创建发布数据集更新用户索引
CREATE INDEX ON rtsa.release_data_set (updater_id);
-- 创建发布数据集索引
CREATE INDEX ON rtsa.release_data_set (data_set_type, name);
-- 注释发布数据集表
COMMENT ON TABLE rtsa.release_data_set IS '发布数据集表';
-- 注释发布数据集表字段
COMMENT ON COLUMN rtsa.release_data_set.id IS 'id 自增主键';
COMMENT ON COLUMN rtsa.release_data_set.data_set_type IS '数据集类型';
COMMENT ON COLUMN rtsa.release_data_set.name IS '发布数据集名称';
COMMENT ON COLUMN rtsa.release_data_set.description IS '发布数据集描述';
COMMENT ON COLUMN rtsa.release_data_set.config IS '数据集相关配置项';
COMMENT ON COLUMN rtsa.release_data_set.is_published IS '是否上架';
COMMENT ON COLUMN rtsa.release_data_set.creator_id IS '创建用户id';
COMMENT ON COLUMN rtsa.release_data_set.created_at IS '创建时间';
COMMENT ON COLUMN rtsa.release_data_set.updater_id IS '更新用户id';
COMMENT ON COLUMN rtsa.release_data_set.updated_at IS '更新时间';
-- 创建发布数据集数据表
CREATE TABLE
rtsa.release_data_set_data (
id SERIAL PRIMARY KEY, -- id 自增主键
release_data_set_id INT NOT NULL, -- 发布数据集id
release_data_id INT NOT NULL, -- 发布数据id
order_index INT NOT NULL, -- 排序索引
FOREIGN KEY (release_data_set_id) REFERENCES rtsa.release_data_set (id) ON DELETE CASCADE, -- 发布数据集外键
FOREIGN KEY (release_data_id) REFERENCES rtsa.release_data (id) ON DELETE CASCADE, -- 发布数据外键
UNIQUE(release_data_set_id, release_data_id) -- 发布数据集id和发布数据id唯一
);
-- 创建发布数据集数据发布数据集索引
CREATE INDEX ON rtsa.release_data_set_data (release_data_set_id);
-- 创建发布数据集数据发布数据索引
CREATE INDEX ON rtsa.release_data_set_data (release_data_id);
-- 注释发布数据集数据表
COMMENT ON TABLE rtsa.release_data_set_data IS '发布数据集数据表';
-- 注释发布数据集数据表字段
COMMENT ON COLUMN rtsa.release_data_set_data.id IS 'id 自增主键';
COMMENT ON COLUMN rtsa.release_data_set_data.release_data_set_id IS '发布数据集id';
COMMENT ON COLUMN rtsa.release_data_set_data.release_data_id IS '发布数据id';
COMMENT ON COLUMN rtsa.release_data_set_data.order_index IS '排序索引';
-- 创建用户数据表
CREATE TABLE
rtsa.user_data (
id SERIAL PRIMARY KEY, -- id 自增主键
organization_id INT NOT NULL, -- 组织id
user_id INT NOT NULL, -- 用户id
data_type INT NOT NULL, -- 数据类型
data JSONB NOT NULL, -- 数据
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP, -- 创建时间
updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP, -- 更新时间
FOREIGN KEY (organization_id) REFERENCES rtsa.organization (id) ON DELETE CASCADE, -- 组织外键
FOREIGN KEY (user_id) REFERENCES rtsa.user (id) ON DELETE CASCADE -- 用户外键
);
-- 创建用户数据组织索引
CREATE INDEX ON rtsa.user_data (organization_id);
-- 创建用户数据用户索引
CREATE INDEX ON rtsa.user_data (user_id);
-- 创建用户数据类型索引
CREATE INDEX ON rtsa.user_data (data_type);
-- 创建用户数据配置项索引
CREATE INDEX ON rtsa.user_data USING GIN (data);
-- 创建用户数据索引
CREATE INDEX ON rtsa.user_data (organization_id, user_id, data_type);
-- 注释用户数据表
COMMENT ON TABLE rtsa.user_data IS '用户数据表';
-- 注释用户数据表字段
COMMENT ON COLUMN rtsa.user_data.id IS 'id 自增主键';
COMMENT ON COLUMN rtsa.user_data.user_id IS '用户id';
COMMENT ON COLUMN rtsa.user_data.data_type IS '数据类型';
COMMENT ON COLUMN rtsa.user_data.data IS '数据';
COMMENT ON COLUMN rtsa.user_data.created_at IS '创建时间';
COMMENT ON COLUMN rtsa.user_data.updated_at IS '更新时间';
-- 创建用户操作日志表
CREATE TABLE
rtsa.user_operation_log (
id SERIAL PRIMARY KEY, -- id 自增主键
organization_id INT NOT NULL, -- 组织id
user_id INT NOT NULL, -- 用户id
log_type INT NOT NULL, -- 日志类型
log_data JSONB NOT NULL, -- 日志数据
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP, -- 创建时间
FOREIGN KEY (organization_id) REFERENCES rtsa.organization (id) ON DELETE CASCADE, -- 组织外键
FOREIGN KEY (user_id) REFERENCES rtsa.user (id) ON DELETE CASCADE -- 用户外键
);
-- 创建用户操作日志组织索引
CREATE INDEX ON rtsa.user_operation_log (organization_id);
-- 创建用户操作日志用户索引
CREATE INDEX ON rtsa.user_operation_log (user_id);
-- 创建用户操作日志类型索引
CREATE INDEX ON rtsa.user_operation_log (log_type);
-- 创建用户操作日志数据索引
CREATE INDEX ON rtsa.user_operation_log USING GIN (log_data);
-- 创建用户操作日志索引
CREATE INDEX ON rtsa.user_operation_log (organization_id, user_id, log_type, created_at);
-- 注释用户操作日志表
COMMENT ON TABLE rtsa.user_operation_log IS '用户操作日志表';
-- 注释用户操作日志表字段
COMMENT ON COLUMN rtsa.user_operation_log.id IS 'id 自增主键';
COMMENT ON COLUMN rtsa.user_operation_log.organization_id IS '组织id';
COMMENT ON COLUMN rtsa.user_operation_log.user_id IS '用户id';
COMMENT ON COLUMN rtsa.user_operation_log.log_type IS '日志类型';
COMMENT ON COLUMN rtsa.user_operation_log.log_data IS '日志记录数据';
COMMENT ON COLUMN rtsa.user_operation_log.created_at IS '创建时间';