add
This commit is contained in:
@@ -16,12 +16,15 @@ BEGIN
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION update_data_modified_column();
|
||||
|
||||
RAISE NOTICE 'created variety table and trigger';
|
||||
-- 主表索引:deleted+created_at 组合索引(常用于查询未删除数据并排序)
|
||||
CREATE INDEX idx_variety_deleted_created_at ON variety(deleted, created_at);
|
||||
|
||||
RAISE NOTICE 'created variety table, trigger and indexes';
|
||||
ELSE
|
||||
RAISE NOTICE 'variety table already exists';
|
||||
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,
|
||||
@@ -34,20 +37,25 @@ BEGIN
|
||||
CONSTRAINT fk_variety_name_variety
|
||||
FOREIGN KEY (variety_id)
|
||||
REFERENCES variety(id)
|
||||
ON DELETE CASCADE -- 主表记录删除时,子表关联记录也删除
|
||||
ON UPDATE CASCADE -- 主表id更新时,子表关联id同步更新
|
||||
ON DELETE CASCADE
|
||||
ON UPDATE CASCADE
|
||||
);
|
||||
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 and foreign key';
|
||||
-- 子表索引:外键+deleted组合索引(关联查询时高效过滤)
|
||||
CREATE INDEX idx_variety_name_variety_id_deleted ON variety_name(variety_id, deleted);
|
||||
-- 名称查询索引(支持按名称搜索品种)
|
||||
CREATE INDEX idx_variety_name_name_deleted ON variety_name(name, deleted);
|
||||
|
||||
RAISE NOTICE 'created variety_name table, trigger, foreign key and indexes';
|
||||
ELSE
|
||||
RAISE NOTICE 'variety_name table already exists';
|
||||
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,
|
||||
@@ -68,12 +76,17 @@ BEGIN
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION update_data_modified_column();
|
||||
|
||||
RAISE NOTICE 'created variety_code table, trigger and foreign key';
|
||||
-- 子表索引:外键+deleted组合索引
|
||||
CREATE INDEX idx_variety_code_variety_id_deleted ON variety_code(variety_id, deleted);
|
||||
-- 代码查询索引(支持按代码搜索品种)
|
||||
CREATE INDEX idx_variety_code_code_deleted ON variety_code(code, deleted);
|
||||
|
||||
RAISE NOTICE 'created variety_code table, trigger, foreign key and indexes';
|
||||
ELSE
|
||||
RAISE NOTICE 'variety_code table already exists';
|
||||
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,
|
||||
@@ -94,12 +107,17 @@ BEGIN
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION update_data_modified_column();
|
||||
|
||||
RAISE NOTICE 'created variety_tick table, trigger and foreign key';
|
||||
-- 子表索引:外键+deleted组合索引
|
||||
CREATE INDEX idx_variety_tick_variety_id_deleted ON variety_tick(variety_id, deleted);
|
||||
-- 跳点值范围查询索引
|
||||
CREATE INDEX idx_variety_tick_tick_deleted ON variety_tick(tick, deleted);
|
||||
|
||||
RAISE NOTICE 'created variety_tick table, trigger, foreign key and indexes';
|
||||
ELSE
|
||||
RAISE NOTICE 'variety_tick table already exists';
|
||||
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,
|
||||
@@ -120,7 +138,12 @@ BEGIN
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION update_data_modified_column();
|
||||
|
||||
RAISE NOTICE 'created variety_tick_price table, trigger and foreign key';
|
||||
-- 子表索引:外键+deleted组合索引
|
||||
CREATE INDEX idx_variety_tick_price_variety_id_deleted ON variety_tick_price(variety_id, deleted);
|
||||
-- 价格范围查询索引
|
||||
CREATE INDEX idx_variety_tick_price_price_deleted ON variety_tick_price(price, deleted);
|
||||
|
||||
RAISE NOTICE 'created variety_tick_price table, trigger, foreign key and indexes';
|
||||
ELSE
|
||||
RAISE NOTICE 'variety_tick_price table already exists';
|
||||
END IF;
|
||||
@@ -139,17 +162,16 @@ BEGIN
|
||||
-- 创建或更新视图
|
||||
CREATE OR REPLACE VIEW variety_info_view AS
|
||||
SELECT
|
||||
v.id AS variety_id, -- 品种主表唯一ID
|
||||
vn.name AS name, -- 品种名称(来自variety_name)
|
||||
vc.code AS code, -- 品种代码(来自variety_code)
|
||||
vt.tick AS tick, -- 品种跳点(来自variety_tick)
|
||||
vtp.price AS tick_price -- 跳点价格(来自variety_tick_price)
|
||||
v.id AS variety_id,
|
||||
vn.name AS name,
|
||||
vc.code AS code,
|
||||
vt.tick AS tick,
|
||||
vtp.price AS tick_price
|
||||
FROM
|
||||
variety v
|
||||
-- 左连接:确保主表存在时,即使子表无数据也保留记录(避免数据丢失)
|
||||
LEFT JOIN variety_name vn
|
||||
ON v.id = vn.variety_id
|
||||
AND vn.deleted = FALSE -- 子表筛选未删除数据(连接时过滤更高效)
|
||||
AND vn.deleted = FALSE
|
||||
LEFT JOIN variety_code vc
|
||||
ON v.id = vc.variety_id
|
||||
AND vc.deleted = FALSE
|
||||
@@ -160,9 +182,8 @@ BEGIN
|
||||
ON v.id = vtp.variety_id
|
||||
AND vtp.deleted = FALSE
|
||||
WHERE
|
||||
v.deleted = FALSE; -- 主表筛选未删除的品种
|
||||
v.deleted = FALSE;
|
||||
|
||||
-- 根据视图是否已存在输出不同提示
|
||||
IF view_exists THEN
|
||||
RAISE NOTICE '视图 variety_info_view 已更新';
|
||||
ELSE
|
||||
@@ -171,4 +192,4 @@ BEGIN
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN
|
||||
RAISE NOTICE '处理视图时发生错误: %', SQLERRM;
|
||||
END $$;
|
||||
END $$;
|
||||
Reference in New Issue
Block a user