175 lines
6.6 KiB
SQL
175 lines
6.6 KiB
SQL
-- 切换到目标数据库
|
||
\c postgres;
|
||
|
||
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_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
|
||
);
|
||
|
||
RAISE NOTICE 'created variety table, trigger and indexes';
|
||
ELSE
|
||
RAISE NOTICE 'variety table already exists';
|
||
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_v7() PRIMARY KEY NOT NULL,
|
||
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();
|
||
|
||
RAISE NOTICE 'created variety_exchange table, trigger, foreign key and indexes';
|
||
ELSE
|
||
RAISE NOTICE 'variety_exchange table already exists';
|
||
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_v7() PRIMARY KEY NOT NULL,
|
||
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();
|
||
|
||
RAISE NOTICE 'created variety_name table, trigger, foreign key and indexes';
|
||
ELSE
|
||
RAISE NOTICE 'variety_name table already exists';
|
||
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_v7() PRIMARY KEY NOT NULL,
|
||
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();
|
||
|
||
RAISE NOTICE 'created variety_code table, trigger, foreign key and indexes';
|
||
ELSE
|
||
RAISE NOTICE 'variety_code table already exists';
|
||
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_v7() PRIMARY KEY NOT NULL,
|
||
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();
|
||
|
||
RAISE NOTICE 'created variety_tick table, trigger, foreign key and indexes';
|
||
ELSE
|
||
RAISE NOTICE 'variety_tick table already exists';
|
||
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_v7() PRIMARY KEY NOT NULL,
|
||
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();
|
||
|
||
RAISE NOTICE 'created variety_tick_price table, trigger, foreign key and indexes';
|
||
ELSE
|
||
RAISE NOTICE 'variety_tick_price table already exists';
|
||
END IF;
|
||
END $$;
|
||
|
||
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
|
||
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
|
||
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;
|
||
|
||
-- 根据视图是否已存在输出不同提示
|
||
IF view_exists THEN
|
||
RAISE NOTICE '视图 variety_info_view 已更新(删除旧视图后重建)';
|
||
ELSE
|
||
RAISE NOTICE '视图 variety_info_view 已创建';
|
||
END IF;
|
||
EXCEPTION
|
||
WHEN OTHERS THEN
|
||
RAISE NOTICE '处理视图时发生错误: %', SQLERRM;
|
||
END $$; |