Files
2026-02-10 12:19:41 +08:00

78 lines
3.7 KiB
PL/PgSQL
Raw Permalink 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.
-- 1. 创建用户基础信息表
CREATE TABLE IF NOT EXISTS users (
user_id UUID PRIMARY KEY DEFAULT uuidv7(),
deleted BOOLEAN NOT NULL DEFAULT false,
create_time TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP,
update_time TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP
);
COMMENT ON TABLE users IS '用户唯一标识信息表';
COMMENT ON COLUMN users.user_id IS '用户唯一标识主键自动生成UUIDv7';
COMMENT ON COLUMN users.deleted IS '逻辑删除标识false-未删除true-已删除';
COMMENT ON COLUMN users.create_time IS '记录创建时间(带时区)';
COMMENT ON COLUMN users.update_time IS '记录更新时间(带时区)';
-- 2. 创建用户登录账户表
CREATE TABLE IF NOT EXISTS user_login_accounts (
follow_id UUID PRIMARY KEY DEFAULT uuidv7(),
user_id UUID NOT NULL,
value VARCHAR(100) NOT NULL,
deleted BOOLEAN NOT NULL DEFAULT false,
create_time TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP,
update_time TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP,
CONSTRAINT fk_user_login_accounts_user_id FOREIGN KEY (user_id) REFERENCES users(user_id),
CONSTRAINT uk_user_login_accounts_value UNIQUE (value, deleted)
);
COMMENT ON TABLE user_login_accounts IS '用户登录账户表';
COMMENT ON COLUMN user_login_accounts.follow_id IS '记录唯一标识主键自动生成UUIDv7';
COMMENT ON COLUMN user_login_accounts.user_id IS '关联用户ID外键关联users表';
COMMENT ON COLUMN user_login_accounts.value IS '登录账户值(手机号/邮箱/用户名)';
COMMENT ON COLUMN user_login_accounts.deleted IS '逻辑删除标识false-未删除true-已删除';
COMMENT ON COLUMN user_login_accounts.create_time IS '记录创建时间(带时区)';
COMMENT ON COLUMN user_login_accounts.update_time IS '记录更新时间(带时区)';
-- 3. 创建用户登录密码表
CREATE TABLE IF NOT EXISTS user_login_passwords (
follow_id UUID PRIMARY KEY DEFAULT uuidv7(),
user_id UUID NOT NULL,
value VARCHAR(255) NOT NULL,
deleted BOOLEAN NOT NULL DEFAULT false,
create_time TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP,
update_time TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP,
CONSTRAINT fk_user_login_passwords_user_id FOREIGN KEY (user_id) REFERENCES users(user_id),
CONSTRAINT uk_user_login_passwords_user_id UNIQUE (user_id, deleted)
);
COMMENT ON TABLE user_login_passwords IS '用户登录密码表(存储加密后的密码)';
COMMENT ON COLUMN user_login_passwords.follow_id IS '记录唯一标识主键自动生成UUIDv7';
COMMENT ON COLUMN user_login_passwords.user_id IS '关联用户ID外键关联users表';
COMMENT ON COLUMN user_login_passwords.value IS '加密后的登录密码建议使用bcrypt/argon2等算法';
COMMENT ON COLUMN user_login_passwords.deleted IS '逻辑删除标识false-未删除true-已删除';
COMMENT ON COLUMN user_login_passwords.create_time IS '记录创建时间(带时区)';
COMMENT ON COLUMN user_login_passwords.update_time IS '记录更新时间(带时区)';
-- 4. 创建update_time自动更新触发器
CREATE OR REPLACE FUNCTION update_timestamp()
RETURNS TRIGGER AS $$
BEGIN
NEW.update_time = CURRENT_TIMESTAMP;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
CREATE TRIGGER trigger_users_update_time
BEFORE UPDATE ON users
FOR EACH ROW
EXECUTE FUNCTION update_timestamp();
CREATE TRIGGER trigger_user_login_accounts_update_time
BEFORE UPDATE ON user_login_accounts
FOR EACH ROW
EXECUTE FUNCTION update_timestamp();
CREATE TRIGGER trigger_user_login_passwords_update_time
BEFORE UPDATE ON user_login_passwords
FOR EACH ROW
EXECUTE FUNCTION update_timestamp();