283 lines
13 KiB
SQL
283 lines
13 KiB
SQL
-- =========================================================
|
||
-- trade.sql 🎉
|
||
-- 无物化视图 | 超可视提示 | 可重复执行
|
||
-- PostgreSQL 17.4+ 👍
|
||
-- =========================================================
|
||
|
||
-- 1️⃣ 开始 🚀
|
||
DO $$
|
||
BEGIN
|
||
RAISE NOTICE '🚀============ trade 部署开始 ============🚀';
|
||
END $$;
|
||
|
||
-- 2️⃣ 连接目标库
|
||
\c postgres;
|
||
|
||
-- 3️⃣ 表结构 -----------------------------------
|
||
DO $$
|
||
BEGIN
|
||
-- trade 主表
|
||
IF NOT EXISTS (SELECT 1 FROM information_schema.tables WHERE table_name = 'trade') THEN
|
||
CREATE TABLE trade (
|
||
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 '1️⃣✅ trade 主表已创建';
|
||
ELSE
|
||
RAISE NOTICE '1️⃣⏩ trade 主表已存在,跳过';
|
||
END IF;
|
||
|
||
-- remark 子表
|
||
IF NOT EXISTS (SELECT 1 FROM information_schema.tables WHERE table_name = 'trade_remark') THEN
|
||
CREATE TABLE trade_remark (
|
||
id UUID DEFAULT gen_random_uuid() PRIMARY KEY,
|
||
trade_id UUID NOT NULL REFERENCES trade(id) ON DELETE CASCADE,
|
||
remark VARCHAR 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_trade_remark_updated_at
|
||
BEFORE UPDATE ON trade_remark
|
||
FOR EACH ROW EXECUTE FUNCTION update_data_modified_column();
|
||
RAISE NOTICE '2️⃣✅ trade_remark 子表已创建';
|
||
ELSE
|
||
RAISE NOTICE '2️⃣⏩ trade_remark 子表已存在,跳过';
|
||
END IF;
|
||
|
||
-- open_date 子表
|
||
IF NOT EXISTS (SELECT 1 FROM information_schema.tables WHERE table_name = 'trade_open_date') THEN
|
||
CREATE TABLE trade_open_date (
|
||
id UUID DEFAULT gen_random_uuid() PRIMARY KEY,
|
||
trade_id UUID NOT NULL REFERENCES trade(id) ON DELETE CASCADE,
|
||
year INT NOT NULL DEFAULT 0,
|
||
month INT NOT NULL DEFAULT 0,
|
||
day INT NOT NULL DEFAULT 0,
|
||
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_trade_open_date_updated_at
|
||
BEFORE UPDATE ON trade_open_date
|
||
FOR EACH ROW EXECUTE FUNCTION update_data_modified_column();
|
||
RAISE NOTICE '3️⃣✅ trade_open_date 子表已创建';
|
||
ELSE
|
||
RAISE NOTICE '3️⃣⏩ trade_open_date 子表已存在,跳过';
|
||
END IF;
|
||
|
||
-- variety 子表
|
||
IF NOT EXISTS (SELECT 1 FROM information_schema.tables WHERE table_name = 'trade_variety') THEN
|
||
CREATE TABLE trade_variety (
|
||
id UUID DEFAULT gen_random_uuid() PRIMARY KEY,
|
||
trade_id UUID NOT NULL REFERENCES trade(id) ON DELETE CASCADE,
|
||
variety_id UUID NOT NULL,
|
||
variety_name VARCHAR 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_trade_variety_updated_at
|
||
BEFORE UPDATE ON trade_variety
|
||
FOR EACH ROW EXECUTE FUNCTION update_data_modified_column();
|
||
RAISE NOTICE '4️⃣✅ trade_variety 子表已创建';
|
||
ELSE
|
||
RAISE NOTICE '4️⃣⏩ trade_variety 子表已存在,跳过';
|
||
END IF;
|
||
|
||
-- direction 子表
|
||
IF NOT EXISTS (SELECT 1 FROM information_schema.tables WHERE table_name = 'trade_direction') THEN
|
||
CREATE TABLE trade_direction (
|
||
id UUID DEFAULT gen_random_uuid() PRIMARY KEY,
|
||
trade_id UUID NOT NULL REFERENCES trade(id) ON DELETE CASCADE,
|
||
direction VARCHAR 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_trade_direction_updated_at
|
||
BEFORE UPDATE ON trade_direction
|
||
FOR EACH ROW EXECUTE FUNCTION update_data_modified_column();
|
||
RAISE NOTICE '5️⃣✅ trade_direction 子表已创建';
|
||
ELSE
|
||
RAISE NOTICE '5️⃣⏩ trade_direction 子表已存在,跳过';
|
||
END IF;
|
||
|
||
-- open_price 子表
|
||
IF NOT EXISTS (SELECT 1 FROM information_schema.tables WHERE table_name = 'trade_open_price') THEN
|
||
CREATE TABLE trade_open_price (
|
||
id UUID DEFAULT gen_random_uuid() PRIMARY KEY,
|
||
trade_id UUID NOT NULL REFERENCES trade(id) ON DELETE CASCADE,
|
||
open_price NUMERIC(10,6) NOT NULL CHECK (open_price >= 0.00) DEFAULT 0.00,
|
||
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_trade_open_price_updated_at
|
||
BEFORE UPDATE ON trade_open_price
|
||
FOR EACH ROW EXECUTE FUNCTION update_data_modified_column();
|
||
RAISE NOTICE '6️⃣✅ trade_open_price 子表已创建';
|
||
ELSE
|
||
RAISE NOTICE '6️⃣⏩ trade_open_price 子表已存在,跳过';
|
||
END IF;
|
||
|
||
-- open_fee 子表
|
||
IF NOT EXISTS (SELECT 1 FROM information_schema.tables WHERE table_name = 'trade_open_fee') THEN
|
||
CREATE TABLE trade_open_fee (
|
||
id UUID DEFAULT gen_random_uuid() PRIMARY KEY,
|
||
trade_id UUID NOT NULL REFERENCES trade(id) ON DELETE CASCADE,
|
||
open_fee NUMERIC(10,6) NOT NULL CHECK (open_fee >= 0.00) DEFAULT 0.00,
|
||
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_trade_open_fee_updated_at
|
||
BEFORE UPDATE ON trade_open_fee
|
||
FOR EACH ROW EXECUTE FUNCTION update_data_modified_column();
|
||
RAISE NOTICE '7️⃣✅ trade_open_fee 子表已创建';
|
||
ELSE
|
||
RAISE NOTICE '7️⃣⏩ trade_open_fee 子表已存在,跳过';
|
||
END IF;
|
||
|
||
-- close_date 子表
|
||
IF NOT EXISTS (SELECT 1 FROM information_schema.tables WHERE table_name = 'trade_close_date') THEN
|
||
CREATE TABLE trade_close_date (
|
||
id UUID DEFAULT gen_random_uuid() PRIMARY KEY,
|
||
trade_id UUID NOT NULL REFERENCES trade(id) ON DELETE CASCADE,
|
||
year INT NOT NULL DEFAULT 0,
|
||
month INT NOT NULL DEFAULT 0,
|
||
day INT NOT NULL DEFAULT 0,
|
||
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_trade_close_date_updated_at
|
||
BEFORE UPDATE ON trade_close_date
|
||
FOR EACH ROW EXECUTE FUNCTION update_data_modified_column();
|
||
RAISE NOTICE '8️⃣✅ trade_close_date 子表已创建';
|
||
ELSE
|
||
RAISE NOTICE '8️⃣⏩ trade_close_date 子表已存在,跳过';
|
||
END IF;
|
||
|
||
-- close_price 子表
|
||
IF NOT EXISTS (SELECT 1 FROM information_schema.tables WHERE table_name = 'trade_close_price') THEN
|
||
CREATE TABLE trade_close_price (
|
||
id UUID DEFAULT gen_random_uuid() PRIMARY KEY,
|
||
trade_id UUID NOT NULL REFERENCES trade(id) ON DELETE CASCADE,
|
||
close_price NUMERIC(10,6) NOT NULL CHECK (close_price >= 0.00) DEFAULT 0.00,
|
||
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_trade_close_price_updated_at
|
||
BEFORE UPDATE ON trade_close_price
|
||
FOR EACH ROW EXECUTE FUNCTION update_data_modified_column();
|
||
RAISE NOTICE '9️⃣✅ trade_close_price 子表已创建';
|
||
ELSE
|
||
RAISE NOTICE '9️⃣⏩ trade_close_price 子表已存在,跳过';
|
||
END IF;
|
||
|
||
-- close_fee 子表
|
||
IF NOT EXISTS (SELECT 1 FROM information_schema.tables WHERE table_name = 'trade_close_fee') THEN
|
||
CREATE TABLE trade_close_fee (
|
||
id UUID DEFAULT gen_random_uuid() PRIMARY KEY,
|
||
trade_id UUID NOT NULL REFERENCES trade(id) ON DELETE CASCADE,
|
||
close_fee NUMERIC(10,6) NOT NULL CHECK (close_fee >= 0.00) DEFAULT 0.00,
|
||
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_trade_close_fee_updated_at
|
||
BEFORE UPDATE ON trade_close_fee
|
||
FOR EACH ROW EXECUTE FUNCTION update_data_modified_column();
|
||
RAISE NOTICE '🔟✅ trade_close_fee 子表已创建';
|
||
ELSE
|
||
RAISE NOTICE '🔟⏩ trade_close_fee 子表已存在,跳过';
|
||
END IF;
|
||
|
||
-- profit 子表
|
||
IF NOT EXISTS (SELECT 1 FROM information_schema.tables WHERE table_name = 'trade_profit') THEN
|
||
CREATE TABLE trade_profit (
|
||
id UUID DEFAULT gen_random_uuid() PRIMARY KEY,
|
||
trade_id UUID NOT NULL REFERENCES trade(id) ON DELETE CASCADE,
|
||
variety_tick NUMERIC(12,6) NOT NULL DEFAULT 0.00,
|
||
variety_tick_price NUMERIC(12,6) NOT NULL CHECK (variety_tick_price >= 0.00) DEFAULT 0.00,
|
||
win_tick NUMERIC(12,6) NOT NULL DEFAULT 0.00,
|
||
win_tick_price NUMERIC(12,6) NOT NULL DEFAULT 0.00,
|
||
fee_cost NUMERIC(12,6) NOT NULL DEFAULT 0.00,
|
||
trade_win NUMERIC(12,6) NOT NULL DEFAULT 0.00,
|
||
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_trade_profit_updated_at
|
||
BEFORE UPDATE ON trade_profit
|
||
FOR EACH ROW EXECUTE FUNCTION update_data_modified_column();
|
||
RAISE NOTICE '1️⃣1️⃣✅ trade_profit 子表已创建';
|
||
ELSE
|
||
RAISE NOTICE '1️⃣1️⃣⏩ trade_profit 子表已存在,跳过';
|
||
END IF;
|
||
END $$;
|
||
|
||
-- 4️⃣ 视图 ------------------------------------
|
||
DROP VIEW IF EXISTS trade_info_view;
|
||
CREATE OR REPLACE VIEW trade_info_view AS
|
||
SELECT
|
||
t.id AS trade_id,
|
||
r.remark AS remark,
|
||
od.year AS open_year,
|
||
od.month AS open_month,
|
||
od.day AS open_day,
|
||
v.variety_name AS variety_name,
|
||
d.direction AS direction,
|
||
format_numeric_to_original(op.open_price) AS open_price,
|
||
format_numeric_to_original(of.open_fee) AS open_fee,
|
||
cd.year AS close_year,
|
||
cd.month AS close_month,
|
||
cd.day AS close_day,
|
||
format_numeric_to_original(cp.close_price) AS close_price,
|
||
format_numeric_to_original(cf.close_fee) AS close_fee,
|
||
p.variety_tick AS variety_tick,
|
||
p.variety_tick_price AS variety_tick_price,
|
||
p.win_tick AS win_tick,
|
||
p.win_tick_price AS win_tick_price,
|
||
format_numeric_to_original(p.fee_cost) AS fee_cost,
|
||
format_numeric_to_original(p.trade_win) AS trade_win
|
||
FROM trade t
|
||
LEFT JOIN trade_remark r ON t.id = r.trade_id AND r.deleted = FALSE
|
||
LEFT JOIN trade_open_date od ON t.id = od.trade_id AND od.deleted = FALSE
|
||
LEFT JOIN trade_variety v ON t.id = v.trade_id AND v.deleted = FALSE
|
||
LEFT JOIN trade_direction d ON t.id = d.trade_id AND d.deleted = FALSE
|
||
LEFT JOIN trade_open_price op ON t.id = op.trade_id AND op.deleted = FALSE
|
||
LEFT JOIN trade_open_fee of ON t.id = of.trade_id AND of.deleted = FALSE
|
||
LEFT JOIN trade_close_date cd ON t.id = cd.trade_id AND cd.deleted = FALSE
|
||
LEFT JOIN trade_close_price cp ON t.id = cp.trade_id AND cp.deleted = FALSE
|
||
LEFT JOIN trade_close_fee cf ON t.id = cf.trade_id AND cf.deleted = FALSE
|
||
LEFT JOIN trade_profit p ON t.id = p.trade_id AND p.deleted = FALSE
|
||
WHERE t.deleted = FALSE;
|
||
|
||
RAISE NOTICE '4️⃣✅ trade_info_view 已创建/更新';
|
||
|
||
-- 5️⃣ 性能索引 ------------------------------------------------
|
||
CREATE INDEX IF NOT EXISTS idx_trade_remark_trade_id_deleted ON trade_remark(trade_id, deleted);
|
||
CREATE INDEX IF NOT EXISTS idx_trade_open_date_trade_id_deleted ON trade_open_date(trade_id, deleted);
|
||
CREATE INDEX IF NOT EXISTS idx_trade_variety_trade_id_deleted ON trade_variety(trade_id, deleted);
|
||
CREATE INDEX IF NOT EXISTS idx_trade_direction_trade_id_deleted ON trade_direction(trade_id, deleted);
|
||
CREATE INDEX IF NOT EXISTS idx_trade_open_price_trade_id_deleted ON trade_open_price(trade_id, deleted);
|
||
CREATE INDEX IF NOT EXISTS idx_trade_open_fee_trade_id_deleted ON trade_open_fee(trade_id, deleted);
|
||
CREATE INDEX IF NOT EXISTS idx_trade_close_date_trade_id_deleted ON trade_close_date(trade_id, deleted);
|
||
CREATE INDEX IF NOT EXISTS idx_trade_close_price_trade_id_deleted ON trade_close_price(trade_id, deleted);
|
||
CREATE INDEX IF NOT EXISTS idx_trade_close_fee_trade_id_deleted ON trade_close_fee(trade_id, deleted);
|
||
CREATE INDEX IF NOT EXISTS idx_trade_profit_trade_id_deleted ON trade_profit(trade_id, deleted);
|
||
|
||
DO $$
|
||
BEGIN
|
||
RAISE NOTICE '5️⃣✅ 全部索引已确保存在';
|
||
END $$;
|
||
|
||
-- 6️⃣ 完成 🎉
|
||
DO $$
|
||
BEGIN
|
||
RAISE NOTICE '🎉============ trade 部署完成 ============🎉';
|
||
END $$; |