diff --git a/backend/sql/07_variety.sql b/backend/sql/07_variety.sql index 9116ce0..002873c 100644 --- a/backend/sql/07_variety.sql +++ b/backend/sql/07_variety.sql @@ -1,26 +1,29 @@ --- 切换到目标数据库 +-- ========================================================= +-- variety.sql +-- 服务器一次性部署:原结构 + 性能优化 +-- PostgreSQL 17.4+ +-- ========================================================= + +-- 1. 连接目标库(按需改名字) \c postgres; +-- 2. 表结构 ----------------------------------- DO $$ BEGIN - -- 创建主表 variety + -- variety 主表 IF NOT EXISTS (SELECT 1 FROM information_schema.tables WHERE table_name = 'variety') THEN - CREATE TABLE variety ( - id UUID DEFAULT gen_random_uuid_v7() PRIMARY KEY NOT NULL, + CREATE TABLE variety ( + 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 ); - - RAISE NOTICE 'created variety table, trigger and indexes'; - ELSE - RAISE NOTICE 'variety table already exists'; END IF; - -- 创建子表 variety_exchange + -- variety_exchange IF NOT EXISTS (SELECT 1 FROM information_schema.tables WHERE table_name = 'variety_exchange') THEN - CREATE TABLE variety_exchange ( - id UUID DEFAULT gen_random_uuid_v7() PRIMARY KEY NOT NULL, + CREATE TABLE variety_exchange ( + id UUID DEFAULT gen_random_uuid() PRIMARY KEY, variety_id UUID NOT NULL, exchange_id VARCHAR(50) NOT NULL, deleted BOOLEAN NOT NULL DEFAULT FALSE, @@ -28,19 +31,14 @@ BEGIN updated_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP ); CREATE TRIGGER update_variety_exchange_updated_at - BEFORE UPDATE ON "variety_exchange" - FOR EACH ROW - EXECUTE FUNCTION update_data_modified_column(); - - RAISE NOTICE 'created variety_exchange table, trigger, foreign key and indexes'; - ELSE - RAISE NOTICE 'variety_exchange table already exists'; + BEFORE UPDATE ON variety_exchange + FOR EACH ROW EXECUTE FUNCTION update_data_modified_column(); END IF; - -- 创建子表 variety_name + -- variety_name IF NOT EXISTS (SELECT 1 FROM information_schema.tables WHERE table_name = 'variety_name') THEN - CREATE TABLE variety_name ( - id UUID DEFAULT gen_random_uuid_v7() PRIMARY KEY NOT NULL, + CREATE TABLE variety_name ( + id UUID DEFAULT gen_random_uuid() PRIMARY KEY, variety_id UUID NOT NULL, name VARCHAR(50) NOT NULL, deleted BOOLEAN NOT NULL DEFAULT FALSE, @@ -48,19 +46,14 @@ BEGIN updated_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP ); CREATE TRIGGER update_variety_name_updated_at - BEFORE UPDATE ON "variety_name" - FOR EACH ROW - EXECUTE FUNCTION update_data_modified_column(); - - RAISE NOTICE 'created variety_name table, trigger, foreign key and indexes'; - ELSE - RAISE NOTICE 'variety_name table already exists'; + BEFORE UPDATE ON variety_name + FOR EACH ROW EXECUTE FUNCTION update_data_modified_column(); END IF; - -- 创建子表 variety_code + -- variety_code IF NOT EXISTS (SELECT 1 FROM information_schema.tables WHERE table_name = 'variety_code') THEN - CREATE TABLE variety_code ( - id UUID DEFAULT gen_random_uuid_v7() PRIMARY KEY NOT NULL, + CREATE TABLE variety_code ( + id UUID DEFAULT gen_random_uuid() PRIMARY KEY, variety_id UUID NOT NULL, code VARCHAR(50) NOT NULL, deleted BOOLEAN NOT NULL DEFAULT FALSE, @@ -68,108 +61,114 @@ BEGIN updated_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP ); CREATE TRIGGER update_variety_code_updated_at - BEFORE UPDATE ON "variety_code" - FOR EACH ROW - EXECUTE FUNCTION update_data_modified_column(); - - RAISE NOTICE 'created variety_code table, trigger, foreign key and indexes'; - ELSE - RAISE NOTICE 'variety_code table already exists'; + BEFORE UPDATE ON variety_code + FOR EACH ROW EXECUTE FUNCTION update_data_modified_column(); END IF; - -- 创建子表 variety_tick + -- variety_tick IF NOT EXISTS (SELECT 1 FROM information_schema.tables WHERE table_name = 'variety_tick') THEN - CREATE TABLE variety_tick ( - id UUID DEFAULT gen_random_uuid_v7() PRIMARY KEY NOT NULL, + CREATE TABLE variety_tick ( + id UUID DEFAULT gen_random_uuid() PRIMARY KEY, variety_id UUID NOT NULL, - tick NUMERIC(12, 6), + tick NUMERIC(12,6), 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_variety_tick_updated_at - BEFORE UPDATE ON "variety_tick" - FOR EACH ROW - EXECUTE FUNCTION update_data_modified_column(); - - RAISE NOTICE 'created variety_tick table, trigger, foreign key and indexes'; - ELSE - RAISE NOTICE 'variety_tick table already exists'; + BEFORE UPDATE ON variety_tick + FOR EACH ROW EXECUTE FUNCTION update_data_modified_column(); END IF; - -- 创建子表 variety_tick_price + -- variety_tick_price IF NOT EXISTS (SELECT 1 FROM information_schema.tables WHERE table_name = 'variety_tick_price') THEN - CREATE TABLE variety_tick_price ( - id UUID DEFAULT gen_random_uuid_v7() PRIMARY KEY NOT NULL, + CREATE TABLE variety_tick_price ( + id UUID DEFAULT gen_random_uuid() PRIMARY KEY, variety_id UUID NOT NULL, - price NUMERIC(12, 6), + price NUMERIC(12,6), 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_variety_tick_price_updated_at - BEFORE UPDATE ON "variety_tick_price" - FOR EACH ROW - EXECUTE FUNCTION update_data_modified_column(); - - RAISE NOTICE 'created variety_tick_price table, trigger, foreign key and indexes'; - ELSE - RAISE NOTICE 'variety_tick_price table already exists'; + BEFORE UPDATE ON variety_tick_price + FOR EACH ROW EXECUTE FUNCTION update_data_modified_column(); END IF; END $$; +-- 3. 视图 -------------------------------------- DO $$ -DECLARE - view_exists BOOLEAN; BEGIN - -- 检查视图是否已存在 - SELECT EXISTS ( - SELECT 1 FROM information_schema.views - WHERE table_name = 'variety_info_view' - ) INTO view_exists; - - -- 若视图存在,先删除(避免字段名冲突) - IF view_exists THEN + IF EXISTS (SELECT 1 FROM information_schema.views WHERE table_name = 'variety_info_view') THEN DROP VIEW variety_info_view; - RAISE NOTICE '已删除旧视图 variety_info_view'; END IF; - -- 创建或更新视图 CREATE OR REPLACE VIEW variety_info_view AS SELECT v.id AS variety_id, - vn.name AS name, - vc.code AS code, - -- 调用格式化函数:自动去除尾部多余0 + vn.name, + vc.code, format_numeric_to_original(vt.tick) AS tick, format_numeric_to_original(vtp.price) AS tick_price, - -- 可选:保留原始精度字段(供计算使用) vt.tick AS tick_original, vtp.price AS tick_price_original - FROM - variety v - LEFT JOIN variety_name vn - ON v.id = vn.variety_id - AND vn.deleted = FALSE - LEFT JOIN variety_code vc - ON v.id = vc.variety_id - AND vc.deleted = FALSE - LEFT JOIN variety_tick vt - ON v.id = vt.variety_id - AND vt.deleted = FALSE - LEFT JOIN variety_tick_price vtp - ON v.id = vtp.variety_id - AND vtp.deleted = FALSE - WHERE - v.deleted = FALSE; + FROM variety v + LEFT JOIN variety_name vn ON v.id = vn.variety_id AND vn.deleted = FALSE + LEFT JOIN variety_code vc ON v.id = vc.variety_id AND vc.deleted = FALSE + LEFT JOIN variety_tick vt ON v.id = vt.variety_id AND vt.deleted = FALSE + LEFT JOIN variety_tick_price vtp ON v.id = vtp.variety_id AND vtp.deleted = FALSE + WHERE v.deleted = FALSE; +END $$; - -- 根据视图是否已存在输出不同提示 - IF view_exists THEN - RAISE NOTICE '视图 variety_info_view 已更新(删除旧视图后重建)'; - ELSE - RAISE NOTICE '视图 variety_info_view 已创建'; - END IF; -EXCEPTION - WHEN OTHERS THEN - RAISE NOTICE '处理视图时发生错误: %', SQLERRM; +-- 4. 性能优化:索引 ----------------------------------------- +CREATE INDEX IF NOT EXISTS idx_variety_exchange_variety_id_deleted ON variety_exchange(variety_id, deleted); +CREATE INDEX IF NOT EXISTS idx_variety_name_variety_id_deleted ON variety_name(variety_id, deleted); +CREATE INDEX IF NOT EXISTS idx_variety_code_variety_id_deleted ON variety_code(variety_id, deleted); +CREATE INDEX IF NOT EXISTS idx_variety_tick_variety_id_deleted ON variety_tick(variety_id, deleted); +CREATE INDEX IF NOT EXISTS idx_variety_tick_price_variety_id_deleted ON variety_tick_price(variety_id, deleted); + +-- 5. 性能优化:轻量视图 + 物化视图 -------------------------- +CREATE OR REPLACE VIEW variety_info_view_lean AS +SELECT + v.id AS variety_id, + vn.name, + vc.code, + vt.tick AS tick_original, + vtp.price AS tick_price_original +FROM variety v +LEFT JOIN variety_name vn ON vn.variety_id = v.id AND vn.deleted = FALSE +LEFT JOIN variety_code vc ON vc.variety_id = v.id AND vc.deleted = FALSE +LEFT JOIN variety_tick vt ON vt.variety_id = v.id AND vt.deleted = FALSE +LEFT JOIN variety_tick_price vtp ON vtp.variety_id = v.id AND vtp.deleted = FALSE +WHERE v.deleted = FALSE; + +CREATE MATERIALIZED VIEW IF NOT EXISTS variety_info_mv AS +SELECT * FROM variety_info_view_lean; + +CREATE UNIQUE INDEX IF NOT EXISTS uq_variety_info_mv ON variety_info_mv(variety_id); + +-- 6. 刷新函数 ------------------------------------------------ +CREATE OR REPLACE FUNCTION refresh_variety_info_mv() +RETURNS void +LANGUAGE plpgsql +AS $$ +BEGIN + REFRESH MATERIALIZED VIEW CONCURRENTLY variety_info_mv; +END; +$$; + +-- 7. 首次填充 +PERFORM refresh_variety_info_mv(); + +-- 8. 小贴士 ---------------------------------------------- +DO $$ +BEGIN + RAISE NOTICE ' +=== 部署完成 === +1. 若从旧库迁数据,可执行: + pg_dump -U old_user -t variety -t variety_* old_db | psql -U new_user -d new_db +2. 刷新物化视图:SELECT refresh_variety_info_mv(); +3. 建议 cron 每 15 min 刷新一次: + */15 * * * * psql -U new_user -d new_db -c "SELECT refresh_variety_info_mv();" +'; END $$; \ No newline at end of file