temp
This commit is contained in:
120
urbanLifelineServ/.bin/database/postgres/sql/createTableUser.sql
Normal file
120
urbanLifelineServ/.bin/database/postgres/sql/createTableUser.sql
Normal file
@@ -0,0 +1,120 @@
|
||||
|
||||
-- 创建 sys schema(如果不存在)
|
||||
CREATE SCHEMA IF NOT EXISTS sys;
|
||||
|
||||
-- 用户表
|
||||
DROP TABLE IF EXISTS sys.tb_sys_user CASCADE;
|
||||
CREATE TABLE sys.tb_sys_user (
|
||||
optsn varchar(50) NOT NULL, -- 流水号
|
||||
user_id varchar(50) NOT NULL, -- 用户ID
|
||||
password varchar(128) NOT NULL, -- 密码(建议存储 bcrypt/argon2 哈希)
|
||||
email varchar(100), -- 电子邮件
|
||||
phone varchar(20), -- 电话号码
|
||||
wechat_id varchar(50), -- 微信ID
|
||||
create_time timestamptz NOT NULL DEFAULT now(), -- 创建时间(使用带时区时间)
|
||||
update_time timestamptz DEFAULT NULL, -- 更新时间(由触发器维护)
|
||||
delete_time timestamptz DEFAULT NULL, -- 删除时间
|
||||
deleted boolean NOT NULL DEFAULT false, -- 是否删除(使用 boolean)
|
||||
status integer NOT NULL DEFAULT 1, -- 状态
|
||||
PRIMARY KEY (user_id),
|
||||
UNIQUE (optsn),
|
||||
UNIQUE (email),
|
||||
UNIQUE (phone),
|
||||
UNIQUE (wechat_id)
|
||||
);
|
||||
CREATE INDEX idx_tb_sys_user_phone ON sys.tb_sys_user USING btree (phone);
|
||||
|
||||
-- 按 email 域名建立表达式索引(对域名小写处理以实现不区分大小写的域名查询)
|
||||
-- 使用 split_part(email, '@', 2) 提取 @ 之后的域名部分,再做 lower() 归一化
|
||||
-- WHERE email IS NOT NULL 可以避免索引包含大量 NULL
|
||||
CREATE INDEX idx_tb_sys_user_email_domain ON sys.tb_sys_user USING btree (lower(split_part(email, '@', 2)))
|
||||
WHERE email IS NOT NULL;
|
||||
CREATE INDEX idx_tb_sys_user_wechat_id ON sys.tb_sys_user USING btree (wechat_id);
|
||||
|
||||
-- 可选:保留列注释(如果你想把 MySQL 的 COMMENT 同步到 Postgres)
|
||||
COMMENT ON TABLE sys.tb_sys_user IS '用户表';
|
||||
COMMENT ON COLUMN sys.tb_sys_user.optsn IS '流水号';
|
||||
COMMENT ON COLUMN sys.tb_sys_user.user_id IS '用户ID';
|
||||
COMMENT ON COLUMN sys.tb_sys_user.password IS '密码(建议存储 bcrypt/argon2 哈希)';
|
||||
COMMENT ON COLUMN sys.tb_sys_user.email IS '电子邮件';
|
||||
COMMENT ON COLUMN sys.tb_sys_user.phone IS '电话号码';
|
||||
COMMENT ON COLUMN sys.tb_sys_user.wechat_id IS '微信ID';
|
||||
COMMENT ON COLUMN sys.tb_sys_user.create_time IS '创建时间';
|
||||
COMMENT ON COLUMN sys.tb_sys_user.update_time IS '更新时间';
|
||||
COMMENT ON COLUMN sys.tb_sys_user.delete_time IS '删除时间';
|
||||
COMMENT ON COLUMN sys.tb_sys_user.deleted IS '是否删除';
|
||||
COMMENT ON COLUMN sys.tb_sys_user.status IS '状态';
|
||||
|
||||
-- 用户信息表
|
||||
DROP TABLE IF EXISTS sys.tb_sys_user_info CASCADE;
|
||||
CREATE TABLE sys.tb_sys_user_info (
|
||||
optsn varchar(50) NOT NULL, -- 流水号
|
||||
user_id varchar(50) NOT NULL, -- 用户ID
|
||||
avatar varchar(255), -- 头像
|
||||
gender integer DEFAULT 0, -- 性别
|
||||
family_name varchar(50), -- 姓
|
||||
given_name varchar(50), -- 名
|
||||
full_name varchar(100), -- 全名
|
||||
level integer DEFAULT 1, -- 等级
|
||||
id_card varchar(50), -- 身份证号
|
||||
address varchar(255), -- 地址
|
||||
create_time timestamptz NOT NULL DEFAULT now(), -- 创建时间
|
||||
update_time timestamptz DEFAULT NULL, -- 更新时间(触发器维护)
|
||||
delete_time timestamptz DEFAULT NULL, -- 删除时间
|
||||
deleted boolean NOT NULL DEFAULT false, -- 是否删除
|
||||
PRIMARY KEY (user_id),
|
||||
UNIQUE (optsn)
|
||||
);
|
||||
COMMENT ON TABLE sys.tb_sys_user_info IS '用户信息表';
|
||||
COMMENT ON COLUMN sys.tb_sys_user_info.optsn IS '流水号';
|
||||
COMMENT ON COLUMN sys.tb_sys_user_info.user_id IS '用户ID';
|
||||
COMMENT ON COLUMN sys.tb_sys_user_info.avatar IS '头像';
|
||||
COMMENT ON COLUMN sys.tb_sys_user_info.gender IS '性别';
|
||||
COMMENT ON COLUMN sys.tb_sys_user_info.family_name IS '姓';
|
||||
COMMENT ON COLUMN sys.tb_sys_user_info.given_name IS '名';
|
||||
COMMENT ON COLUMN sys.tb_sys_user_info.full_name IS '全名';
|
||||
COMMENT ON COLUMN sys.tb_sys_user_info.level IS '等级';
|
||||
COMMENT ON COLUMN sys.tb_sys_user_info.id_card IS '身份证号';
|
||||
COMMENT ON COLUMN sys.tb_sys_user_info.address IS '地址';
|
||||
COMMENT ON COLUMN sys.tb_sys_user_info.create_time IS '创建时间';
|
||||
COMMENT ON COLUMN sys.tb_sys_user_info.update_time IS '更新时间';
|
||||
COMMENT ON COLUMN sys.tb_sys_user_info.delete_time IS '删除时间';
|
||||
COMMENT ON COLUMN sys.tb_sys_user_info.deleted IS '是否删除';
|
||||
|
||||
-- 登录日志表
|
||||
DROP TABLE IF EXISTS sys.tb_sys_login_log CASCADE;
|
||||
CREATE TABLE sys.tb_sys_login_log (
|
||||
optsn varchar(50) NOT NULL, -- 流水号(作为主键)
|
||||
user_id varchar(50) NOT NULL, -- 用户ID
|
||||
username varchar(50) NOT NULL, -- 用户名
|
||||
ip_address varchar(45), -- IP地址
|
||||
ip_source varchar(100), -- IP来源
|
||||
browser varchar(100), -- 浏览器
|
||||
os varchar(100), -- 操作系统
|
||||
password varchar(128), -- 密码(建议存储 bcrypt/argon2 哈希)
|
||||
login_time timestamptz DEFAULT now(), -- 登录时间
|
||||
status integer DEFAULT 1, -- 登录状态(0失败 1成功)
|
||||
error_count integer DEFAULT 0, -- 错误次数
|
||||
message varchar(255), -- 登录消息
|
||||
create_time timestamptz NOT NULL DEFAULT now(), -- 创建时间
|
||||
PRIMARY KEY (optsn)
|
||||
);
|
||||
-- B-tree 索引(显式指定 USING btree,Postgres 默认即为 btree)
|
||||
CREATE INDEX idx_tb_sys_login_log_user_id ON sys.tb_sys_login_log USING btree (user_id);
|
||||
CREATE INDEX idx_tb_sys_login_log_login_time ON sys.tb_sys_login_log USING btree (login_time);
|
||||
|
||||
-- 可选:保留列注释
|
||||
COMMENT ON TABLE sys.tb_sys_login_log IS '登录日志表';
|
||||
COMMENT ON COLUMN sys.tb_sys_login_log.optsn IS '流水号';
|
||||
COMMENT ON COLUMN sys.tb_sys_login_log.user_id IS '用户ID';
|
||||
COMMENT ON COLUMN sys.tb_sys_login_log.username IS '用户名';
|
||||
COMMENT ON COLUMN sys.tb_sys_login_log.ip_address IS 'IP地址';
|
||||
COMMENT ON COLUMN sys.tb_sys_login_log.ip_source IS 'IP来源';
|
||||
COMMENT ON COLUMN sys.tb_sys_login_log.browser IS '浏览器';
|
||||
COMMENT ON COLUMN sys.tb_sys_login_log.os IS '操作系统';
|
||||
COMMENT ON COLUMN sys.tb_sys_login_log.password IS '密码(建议存储 bcrypt/argon2 哈希)';
|
||||
COMMENT ON COLUMN sys.tb_sys_login_log.login_time IS '登录时间';
|
||||
COMMENT ON COLUMN sys.tb_sys_login_log.status IS '登录状态(0失败 1成功)';
|
||||
COMMENT ON COLUMN sys.tb_sys_login_log.error_count IS '错误次数';
|
||||
COMMENT ON COLUMN sys.tb_sys_login_log.message IS '登录消息';
|
||||
COMMENT ON COLUMN sys.tb_sys_login_log.create_time IS '创建时间';
|
||||
Reference in New Issue
Block a user