This commit is contained in:
vipg
2025-11-25 16:27:08 +08:00
parent a1ea55dffa
commit b9e840a2ba

View File

@@ -31,27 +31,27 @@ BEGIN
-- remark 子表
IF NOT EXISTS (SELECT 1 FROM information_schema.tables WHERE table_name = 'trade_remark') THEN
CREATE TABLE remark (
CREATE TABLE trade_remark (
id UUID DEFAULT gen_random_uuid() PRIMARY KEY,
trade_id UUID NOT NULL,
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_remark_updated_at
BEFORE UPDATE ON remark
CREATE TRIGGER update_trade_remark_updated_at
BEFORE UPDATE ON trade_remark
FOR EACH ROW EXECUTE FUNCTION update_data_modified_column();
RAISE NOTICE '2⃣✅ remark 子表已创建';
RAISE NOTICE '2⃣✅ trade_remark 子表已创建';
ELSE
RAISE NOTICE '2⃣⏩ remark 子表已存在,跳过';
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 open_date (
CREATE TABLE trade_open_date (
id UUID DEFAULT gen_random_uuid() PRIMARY KEY,
trade_id UUID NOT NULL,
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,
@@ -59,92 +59,92 @@ BEGIN
created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP
);
CREATE TRIGGER update_open_date_updated_at
BEFORE UPDATE ON open_date
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⃣✅ open_date 子表已创建';
RAISE NOTICE '3⃣✅ trade_open_date 子表已创建';
ELSE
RAISE NOTICE '3⃣⏩ open_date 子表已存在,跳过';
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 variety (
CREATE TABLE trade_variety (
id UUID DEFAULT gen_random_uuid() PRIMARY KEY,
trade_id UUID NOT NULL,
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_variety_updated_at
BEFORE UPDATE ON variety
CREATE TRIGGER update_trade_variety_updated_at
BEFORE UPDATE ON trade_variety
FOR EACH ROW EXECUTE FUNCTION update_data_modified_column();
RAISE NOTICE '4⃣✅ variety 子表已创建';
RAISE NOTICE '4⃣✅ trade_variety 子表已创建';
ELSE
RAISE NOTICE '4⃣⏩ variety 子表已存在,跳过';
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 direction (
CREATE TABLE trade_direction (
id UUID DEFAULT gen_random_uuid() PRIMARY KEY,
trade_id UUID NOT NULL,
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_direction_updated_at
BEFORE UPDATE ON direction
CREATE TRIGGER update_trade_direction_updated_at
BEFORE UPDATE ON trade_direction
FOR EACH ROW EXECUTE FUNCTION update_data_modified_column();
RAISE NOTICE '5⃣✅ direction 子表已创建';
RAISE NOTICE '5⃣✅ trade_direction 子表已创建';
ELSE
RAISE NOTICE '5⃣⏩ direction 子表已存在,跳过';
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 open_price (
CREATE TABLE trade_open_price (
id UUID DEFAULT gen_random_uuid() PRIMARY KEY,
trade_id UUID NOT NULL,
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_open_price_updated_at
BEFORE UPDATE ON open_price
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⃣✅ open_price 子表已创建';
RAISE NOTICE '6⃣✅ trade_open_price 子表已创建';
ELSE
RAISE NOTICE '6⃣⏩ open_price 子表已存在,跳过';
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 open_fee (
CREATE TABLE trade_open_fee (
id UUID DEFAULT gen_random_uuid() PRIMARY KEY,
trade_id UUID NOT NULL,
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_open_fee_updated_at
BEFORE UPDATE ON open_fee
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⃣✅ open_fee 子表已创建';
RAISE NOTICE '7⃣✅ trade_open_fee 子表已创建';
ELSE
RAISE NOTICE '7⃣⏩ open_fee 子表已存在,跳过';
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 close_date (
CREATE TABLE trade_close_date (
id UUID DEFAULT gen_random_uuid() PRIMARY KEY,
trade_id UUID NOT NULL,
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,
@@ -152,55 +152,55 @@ BEGIN
created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP
);
CREATE TRIGGER update_close_date_updated_at
BEFORE UPDATE ON close_date
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⃣✅ close_date 子表已创建';
RAISE NOTICE '8⃣✅ trade_close_date 子表已创建';
ELSE
RAISE NOTICE '8⃣⏩ close_date 子表已存在,跳过';
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 close_price (
CREATE TABLE trade_close_price (
id UUID DEFAULT gen_random_uuid() PRIMARY KEY,
trade_id UUID NOT NULL,
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_close_price_updated_at
BEFORE UPDATE ON close_price
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⃣✅ close_price 子表已创建';
RAISE NOTICE '9⃣✅ trade_close_price 子表已创建';
ELSE
RAISE NOTICE '9⃣⏩ close_price 子表已存在,跳过';
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 close_fee (
CREATE TABLE trade_close_fee (
id UUID DEFAULT gen_random_uuid() PRIMARY KEY,
trade_id UUID NOT NULL,
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_close_fee_updated_at
BEFORE UPDATE ON close_fee
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 '🔟✅ close_fee 子表已创建';
RAISE NOTICE '🔟✅ trade_close_fee 子表已创建';
ELSE
RAISE NOTICE '🔟⏩ close_fee 子表已存在,跳过';
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 profit (
CREATE TABLE trade_profit (
id UUID DEFAULT gen_random_uuid() PRIMARY KEY,
trade_id UUID NOT NULL,
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,
@@ -211,12 +211,12 @@ BEGIN
created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP
);
CREATE TRIGGER update_profit_updated_at
BEFORE UPDATE ON profit
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⃣✅ profit 子表已创建';
RAISE NOTICE '1⃣1⃣✅ trade_profit 子表已创建';
ELSE
RAISE NOTICE '1⃣1⃣⏩ profit 子表已存在,跳过';
RAISE NOTICE '1⃣1⃣⏩ trade_profit 子表已存在,跳过';
END IF;
END $$;
@@ -245,30 +245,32 @@ SELECT
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 remark r ON t.id = r.trade_id AND r.deleted = FALSE
LEFT JOIN open_date od ON t.id = od.trade_id AND od.deleted = FALSE
LEFT JOIN variety v ON t.id = v.trade_id AND v.deleted = FALSE
LEFT JOIN direction d ON t.id = d.trade_id AND d.deleted = FALSE
LEFT JOIN open_price op ON t.id = op.trade_id AND op.deleted = FALSE
LEFT JOIN open_fee of ON t.id = of.trade_id AND of.deleted = FALSE
LEFT JOIN close_date cd ON t.id = cd.trade_id AND cd.deleted = FALSE
LEFT JOIN close_price cp ON t.id = cp.trade_id AND cp.deleted = FALSE
LEFT JOIN close_fee cf ON t.id = cf.trade_id AND cf.deleted = FALSE
LEFT JOIN profit p ON t.id = p.trade_id AND p.deleted = FALSE
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_remark_trade_id_deleted ON remark(trade_id, deleted);
CREATE INDEX IF NOT EXISTS idx_open_date_trade_id_deleted ON open_date(trade_id, deleted);
CREATE INDEX IF NOT EXISTS idx_variety_trade_id_deleted ON variety(trade_id, deleted);
CREATE INDEX IF NOT EXISTS idx_direction_trade_id_deleted ON direction(trade_id, deleted);
CREATE INDEX IF NOT EXISTS idx_open_price_trade_id_deleted ON open_price(trade_id, deleted);
CREATE INDEX IF NOT EXISTS idx_open_fee_trade_id_deleted ON open_fee(trade_id, deleted);
CREATE INDEX IF NOT EXISTS idx_close_date_trade_id_deleted ON close_date(trade_id, deleted);
CREATE INDEX IF NOT EXISTS idx_close_price_trade_id_deleted ON close_price(trade_id, deleted);
CREATE INDEX IF NOT EXISTS idx_close_fee_trade_id_deleted ON close_fee(trade_id, deleted);
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);
-- 🔍 补 profit 表索引
CREATE INDEX IF NOT EXISTS idx_trade_profit_trade_id_deleted ON trade_profit(trade_id, deleted);
RAISE NOTICE '5⃣✅ 全部索引已确保存在';