-- ========================================================= -- country.sql 🌍 -- 无物化视图 | 超可视提示 | 可重复执行 -- PostgreSQL 17.4+ 👍 -- ========================================================= -- 1️⃣ 开始 🚀 DO $$ BEGIN RAISE NOTICE '🚀============ country 部署开始 ============🚀'; END $$; -- 2️⃣ 连接目标库 \c postgres; -- 3️⃣ 表结构 ----------------------------------- DO $$ BEGIN -- country 主表 IF NOT EXISTS (SELECT 1 FROM information_schema.tables WHERE table_name = 'country') THEN CREATE TABLE country ( 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_country_updated_at BEFORE UPDATE ON country FOR EACH ROW EXECUTE FUNCTION update_data_modified_column(); RAISE NOTICE '1️⃣✅ country 主表已创建'; ELSE RAISE NOTICE '1️⃣⏩ country 主表已存在,跳过'; END IF; -- country_name IF NOT EXISTS (SELECT 1 FROM information_schema.tables WHERE table_name = 'country_name') THEN CREATE TABLE country_name ( id UUID DEFAULT gen_random_uuid() PRIMARY KEY, country_id UUID NOT NULL, name 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_country_name_updated_at BEFORE UPDATE ON country_name FOR EACH ROW EXECUTE FUNCTION update_data_modified_column(); RAISE NOTICE '2️⃣✅ country_name 子表已创建'; ELSE RAISE NOTICE '2️⃣⏩ country_name 子表已存在,跳过'; END IF; -- country_code IF NOT EXISTS (SELECT 1 FROM information_schema.tables WHERE table_name = 'country_code') THEN CREATE TABLE country_code ( id UUID DEFAULT gen_random_uuid() PRIMARY KEY, country_id UUID NOT NULL, code 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_country_code_updated_at BEFORE UPDATE ON country_code FOR EACH ROW EXECUTE FUNCTION update_data_modified_column(); RAISE NOTICE '3️⃣✅ country_code 子表已创建'; ELSE RAISE NOTICE '3️⃣⏩ country_code 子表已存在,跳过'; END IF; -- country_flag IF NOT EXISTS (SELECT 1 FROM information_schema.tables WHERE table_name = 'country_flag') THEN CREATE TABLE country_flag ( id UUID DEFAULT gen_random_uuid() PRIMARY KEY, country_id UUID NOT NULL, flag 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_country_flag_updated_at BEFORE UPDATE ON country_flag FOR EACH ROW EXECUTE FUNCTION update_data_modified_column(); RAISE NOTICE '4️⃣✅ country_flag 子表已创建'; ELSE RAISE NOTICE '4️⃣⏩ country_flag 子表已存在,跳过'; END IF; END $$; -- 4️⃣ 视图 ------------------------------------ DO $$ DECLARE view_exists BOOLEAN; BEGIN SELECT EXISTS ( SELECT 1 FROM information_schema.views WHERE table_name = 'country_info_view' ) INTO view_exists; IF view_exists THEN DROP VIEW country_info_view; RAISE NOTICE '4️⃣♻️ 已删除旧视图 country_info_view'; END IF; CREATE OR REPLACE VIEW country_info_view AS SELECT u.id AS country_id, n.name, c.code, f.flag FROM country u LEFT JOIN country_name n ON u.id = n.country_id AND n.deleted = FALSE LEFT JOIN country_code c ON u.id = c.country_id AND c.deleted = FALSE LEFT JOIN country_flag f ON u.id = f.country_id AND f.deleted = FALSE WHERE u.deleted = FALSE; RAISE NOTICE '4️⃣✅ country_info_view 已创建/更新'; EXCEPTION WHEN OTHERS THEN RAISE NOTICE '4️⃣❌ 处理视图时发生错误: %', SQLERRM; END $$; -- 5️⃣ 性能索引 ------------------------------------------------ CREATE INDEX IF NOT EXISTS idx_country_name_country_id_deleted ON country_name(country_id, deleted); CREATE INDEX IF NOT EXISTS idx_country_code_country_id_deleted ON country_code(country_id, deleted); CREATE INDEX IF NOT EXISTS idx_country_flag_country_id_deleted ON country_flag(country_id, deleted); DO $$ BEGIN RAISE NOTICE '5️⃣✅ 全部索引已确保存在'; END $$; -- 6️⃣ 完成 🎉 DO $$ BEGIN RAISE NOTICE '🎉============ country 部署完成 ============🎉'; END $$;