174 lines
7.0 KiB
PL/PgSQL
174 lines
7.0 KiB
PL/PgSQL
-- =========================================================
|
||
-- variety.sql
|
||
-- 服务器一次性部署:原结构 + 性能优化
|
||
-- PostgreSQL 17.4+
|
||
-- =========================================================
|
||
|
||
-- 1. 连接目标库(按需改名字)
|
||
\c postgres;
|
||
|
||
-- 2. 原表结构(兼容旧逻辑)----------------------------------
|
||
DO $$
|
||
BEGIN
|
||
-- variety 主表
|
||
IF NOT EXISTS (SELECT 1 FROM information_schema.tables WHERE table_name = 'variety') THEN
|
||
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
|
||
);
|
||
END IF;
|
||
|
||
-- 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() PRIMARY KEY,
|
||
variety_id UUID NOT NULL,
|
||
exchange_id VARCHAR(50) 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_variety_exchange_updated_at
|
||
BEFORE UPDATE ON variety_exchange
|
||
FOR EACH ROW EXECUTE FUNCTION update_data_modified_column();
|
||
END IF;
|
||
|
||
-- 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() PRIMARY KEY,
|
||
variety_id UUID NOT NULL,
|
||
name VARCHAR(50) 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_variety_name_updated_at
|
||
BEFORE UPDATE ON variety_name
|
||
FOR EACH ROW EXECUTE FUNCTION update_data_modified_column();
|
||
END IF;
|
||
|
||
-- 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() PRIMARY KEY,
|
||
variety_id UUID NOT NULL,
|
||
code VARCHAR(50) 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_variety_code_updated_at
|
||
BEFORE UPDATE ON variety_code
|
||
FOR EACH ROW EXECUTE FUNCTION update_data_modified_column();
|
||
END IF;
|
||
|
||
-- 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() PRIMARY KEY,
|
||
variety_id UUID NOT NULL,
|
||
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();
|
||
END IF;
|
||
|
||
-- 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() PRIMARY KEY,
|
||
variety_id UUID NOT NULL,
|
||
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();
|
||
END IF;
|
||
END $$;
|
||
|
||
-- 3. 视图 --------------------------------------
|
||
DO $$
|
||
BEGIN
|
||
IF EXISTS (SELECT 1 FROM information_schema.views WHERE table_name = 'variety_info_view') THEN
|
||
DROP VIEW variety_info_view;
|
||
END IF;
|
||
|
||
CREATE OR REPLACE VIEW variety_info_view AS
|
||
SELECT
|
||
v.id AS variety_id,
|
||
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;
|
||
END $$;
|
||
|
||
-- 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 $$; |