This commit is contained in:
vipg
2025-11-15 15:00:51 +08:00
parent a485a65395
commit 86553ed4ff

View File

@@ -0,0 +1,126 @@
-- 切换到目标数据库
\c postgres;
DO $$
BEGIN
-- 创建主表 exchange
IF NOT EXISTS (SELECT 1 FROM information_schema.tables WHERE table_name = 'exchange') THEN
CREATE TABLE exchange (
id UUID DEFAULT gen_random_uuid_v7() PRIMARY KEY 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_exchange_updated_at
BEFORE UPDATE ON "exchange"
FOR EACH ROW
EXECUTE FUNCTION update_data_modified_column();
-- 主表索引deleted+created_at 组合索引(常用于查询未删除数据并排序)
CREATE INDEX idx_exchange_deleted_created_at ON exchange(deleted, created_at);
RAISE NOTICE 'created exchange table, trigger and indexes';
ELSE
RAISE NOTICE 'exchange table already exists';
END IF;
-- 创建子表 exchange_name 并添加外键和索引
IF NOT EXISTS (SELECT 1 FROM information_schema.tables WHERE table_name = 'exchange_name') THEN
CREATE TABLE exchange_name (
id UUID DEFAULT gen_random_uuid_v7() PRIMARY KEY NOT NULL,
exchange_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,
-- 外键约束关联exchange主表
CONSTRAINT fk_exchange_name_exchange
FOREIGN KEY (exchange_id)
REFERENCES exchange(id)
ON DELETE CASCADE
ON UPDATE CASCADE
);
CREATE TRIGGER update_exchange_name_updated_at
BEFORE UPDATE ON "exchange_name"
FOR EACH ROW
EXECUTE FUNCTION update_data_modified_column();
-- 子表索引:外键+deleted组合索引关联查询时高效过滤
CREATE INDEX idx_exchange_name_exchange_id_deleted ON exchange_name(exchange_id, deleted);
-- 名称查询索引(支持按名称搜索品种)
CREATE INDEX idx_exchange_name_name_deleted ON exchange_name(name, deleted);
RAISE NOTICE 'created exchange_name table, trigger, foreign key and indexes';
ELSE
RAISE NOTICE 'exchange_name table already exists';
END IF;
-- 创建子表 exchange_code 并添加外键和索引
IF NOT EXISTS (SELECT 1 FROM information_schema.tables WHERE table_name = 'exchange_code') THEN
CREATE TABLE exchange_code (
id UUID DEFAULT gen_random_uuid_v7() PRIMARY KEY NOT NULL,
exchange_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,
-- 外键约束关联exchange主表
CONSTRAINT fk_exchange_code_exchange
FOREIGN KEY (exchange_id)
REFERENCES exchange(id)
ON DELETE CASCADE
ON UPDATE CASCADE
);
CREATE TRIGGER update_exchange_code_updated_at
BEFORE UPDATE ON "exchange_code"
FOR EACH ROW
EXECUTE FUNCTION update_data_modified_column();
-- 子表索引:外键+deleted组合索引
CREATE INDEX idx_exchange_code_exchange_id_deleted ON exchange_code(exchange_id, deleted);
-- 代码查询索引(支持按代码搜索品种)
CREATE INDEX idx_exchange_code_code_deleted ON exchange_code(code, deleted);
RAISE NOTICE 'created exchange_code table, trigger, foreign key and indexes';
ELSE
RAISE NOTICE 'exchange_code table already exists';
END IF;
END $$;
DO $$
DECLARE
view_exists BOOLEAN;
BEGIN
-- 检查视图是否已存在
SELECT EXISTS (
SELECT 1 FROM information_schema.views
WHERE table_name = 'exchange_info_view'
) INTO view_exists;
-- 创建/更新视图整合交易所ID、名称、代码仅显示未删除数据
CREATE OR REPLACE VIEW exchange_info_view AS
SELECT
e.id AS exchange_id, -- 交易所主表唯一ID
en.name AS name, -- 交易所名称来自exchange_name子表
ec.code AS code -- 交易所代码来自exchange_code子表
FROM
exchange e
-- 左连接:主表存在时,即使子表无数据也保留记录(避免数据丢失)
LEFT JOIN exchange_name en
ON e.id = en.exchange_id
AND en.deleted = FALSE -- 子句中筛选未删除数据,关联时直接过滤更高效
LEFT JOIN exchange_code ec
ON e.id = ec.exchange_id
AND ec.deleted = FALSE -- 子表未删除数据筛选
WHERE
e.deleted = FALSE; -- 主表筛选未删除的交易所
IF view_exists THEN
RAISE NOTICE '视图 exchange_info_view 已更新';
ELSE
RAISE NOTICE '视图 exchange_info_view 已创建';
END IF;
EXCEPTION
WHEN OTHERS THEN
RAISE NOTICE '处理视图时发生错误: %', SQLERRM;
END $$;