116 lines
4.1 KiB
SQL
116 lines
4.1 KiB
SQL
-- =========================================================
|
||
-- user.sql 👤
|
||
-- 无物化视图 | 超可视提示 | 可重复执行
|
||
-- PostgreSQL 17.4+ 👍
|
||
-- =========================================================
|
||
|
||
-- 1️⃣ 开始 🚀
|
||
DO $$
|
||
BEGIN
|
||
RAISE NOTICE '🚀============ user 部署开始 ============🚀';
|
||
END $$;
|
||
|
||
-- 2️⃣ 连接目标库
|
||
\c postgres;
|
||
|
||
-- 3️⃣ 表结构 -----------------------------------
|
||
DO $$
|
||
BEGIN
|
||
-- user 主表(关键字,双引号包裹)
|
||
IF NOT EXISTS (SELECT 1 FROM information_schema.tables WHERE table_name = 'user') THEN
|
||
CREATE TABLE "user" (
|
||
id UUID DEFAULT gen_random_uuid() PRIMARY KEY,
|
||
deleted BOOLEAN NOT NULL DEFAULT FALSE,
|
||
created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
updated_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP
|
||
);
|
||
CREATE TRIGGER update_user_updated_at
|
||
BEFORE UPDATE ON "user"
|
||
FOR EACH ROW EXECUTE FUNCTION update_data_modified_column();
|
||
RAISE NOTICE '1️⃣✅ user 主表已创建';
|
||
ELSE
|
||
RAISE NOTICE '1️⃣⏩ user 主表已存在,跳过';
|
||
END IF;
|
||
|
||
-- user_account
|
||
IF NOT EXISTS (SELECT 1 FROM information_schema.tables WHERE table_name = 'user_account') THEN
|
||
CREATE TABLE user_account (
|
||
id UUID DEFAULT gen_random_uuid() PRIMARY KEY,
|
||
user_id UUID NOT NULL,
|
||
account VARCHAR NOT NULL,
|
||
deleted BOOLEAN NOT NULL DEFAULT FALSE,
|
||
created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
updated_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP
|
||
);
|
||
CREATE TRIGGER update_user_account_updated_at
|
||
BEFORE UPDATE ON user_account
|
||
FOR EACH ROW EXECUTE FUNCTION update_data_modified_column();
|
||
RAISE NOTICE '2️⃣✅ user_account 子表已创建';
|
||
ELSE
|
||
RAISE NOTICE '2️⃣⏩ user_account 子表已存在,跳过';
|
||
END IF;
|
||
|
||
-- user_password
|
||
IF NOT EXISTS (SELECT 1 FROM information_schema.tables WHERE table_name = 'user_password') THEN
|
||
CREATE TABLE user_password (
|
||
id UUID DEFAULT gen_random_uuid() PRIMARY KEY,
|
||
user_id UUID NOT NULL,
|
||
password VARCHAR NOT NULL,
|
||
deleted BOOLEAN NOT NULL DEFAULT FALSE,
|
||
created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||
updated_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP
|
||
);
|
||
CREATE TRIGGER update_user_password_updated_at
|
||
BEFORE UPDATE ON user_password
|
||
FOR EACH ROW EXECUTE FUNCTION update_data_modified_column();
|
||
RAISE NOTICE '3️⃣✅ user_password 子表已创建';
|
||
ELSE
|
||
RAISE NOTICE '3️⃣⏩ user_password 子表已存在,跳过';
|
||
END IF;
|
||
END $$;
|
||
|
||
-- 4️⃣ 视图 ------------------------------------
|
||
DO $$
|
||
DECLARE
|
||
view_exists BOOLEAN;
|
||
BEGIN
|
||
SELECT EXISTS (
|
||
SELECT 1 FROM information_schema.views
|
||
WHERE table_name = 'user_info_view'
|
||
) INTO view_exists;
|
||
|
||
IF view_exists THEN
|
||
DROP VIEW user_info_view;
|
||
RAISE NOTICE '4️⃣♻️ 已删除旧视图 user_info_view';
|
||
END IF;
|
||
|
||
CREATE OR REPLACE VIEW user_info_view AS
|
||
SELECT
|
||
u.id AS user_id,
|
||
ua.account,
|
||
up.password
|
||
FROM "user" u
|
||
JOIN user_account ua ON u.id = ua.user_id AND ua.deleted = FALSE
|
||
JOIN user_password up ON u.id = up.user_id AND up.deleted = FALSE
|
||
WHERE u.deleted = FALSE;
|
||
|
||
RAISE NOTICE '4️⃣✅ user_info_view 已创建/更新';
|
||
EXCEPTION
|
||
WHEN OTHERS THEN
|
||
RAISE NOTICE '4️⃣❌ 处理视图时发生错误: %', SQLERRM;
|
||
END $$;
|
||
|
||
-- 5️⃣ 性能索引 ------------------------------------------------
|
||
CREATE INDEX IF NOT EXISTS idx_user_account_user_id_deleted ON user_account(user_id, deleted);
|
||
CREATE INDEX IF NOT EXISTS idx_user_password_user_id_deleted ON user_password(user_id, deleted);
|
||
|
||
DO $$
|
||
BEGIN
|
||
RAISE NOTICE '5️⃣✅ 全部索引已确保存在';
|
||
END $$;
|
||
|
||
-- 6️⃣ 完成 🎉
|
||
DO $$
|
||
BEGIN
|
||
RAISE NOTICE '🎉============ user 部署完成 ============🎉';
|
||
END $$; |