83 lines
3.5 KiB
SQL
83 lines
3.5 KiB
SQL
-- =========================================================
|
|
-- trading_records.sql (PostgreSQL 17.4+)
|
|
-- =========================================================
|
|
\pset pager off
|
|
\timing on
|
|
|
|
-- 1 保证扩展存在(重复执行无害)
|
|
CREATE EXTENSION IF NOT EXISTS "moddatetime" SCHEMA public;
|
|
|
|
DO $$
|
|
BEGIN
|
|
RAISE NOTICE '🚀============ trading_records 部署开始 ============🚀';
|
|
END $$;
|
|
|
|
-- 2 建表(幂等)
|
|
DO $$
|
|
BEGIN
|
|
IF NOT EXISTS (
|
|
SELECT 1
|
|
FROM information_schema.tables
|
|
WHERE table_schema = 'public'
|
|
AND table_name = 'trading_records'
|
|
) THEN
|
|
CREATE TABLE trading_records (
|
|
id UUID DEFAULT gen_random_uuid() PRIMARY KEY, -- id
|
|
open_year SMALLINT NOT NULL, -- 开仓时间-年
|
|
open_month SMALLINT NOT NULL CHECK (open_month BETWEEN 1 AND 12), -- 开仓时间-月
|
|
open_day SMALLINT NOT NULL CHECK (open_day BETWEEN 1 AND 31), -- 开仓时间-日
|
|
symbol VARCHAR(32) NOT NULL, -- 品种
|
|
contract VARCHAR(32) NOT NULL, -- 合约
|
|
direction VARCHAR(4) NOT NULL CHECK (direction IN ('多','空')), -- 方向
|
|
open_price NUMERIC(18,8) NOT NULL, -- 开仓价格
|
|
open_fee NUMERIC(18,8) NOT NULL, -- 开仓手续费
|
|
close_year SMALLINT, -- 平仓时间-年
|
|
close_month SMALLINT CHECK (close_month BETWEEN 1 AND 12), -- 平仓时间-月
|
|
close_day SMALLINT CHECK (close_day BETWEEN 1 AND 31), -- 平仓时间-日
|
|
close_price NUMERIC(18,8), -- 平仓价格
|
|
close_fee NUMERIC(18,8), -- 平仓手续费
|
|
close_diff NUMERIC(18,8), -- 平仓差价
|
|
tick_price NUMERIC(18,8), -- 跳点价格
|
|
diff_pnl NUMERIC(18,8), -- 差价盈亏
|
|
total_fee NUMERIC(18,8), -- 手续费
|
|
close_pnl NUMERIC(18,8), -- 平仓盈亏
|
|
deleted BOOLEAN NOT NULL DEFAULT FALSE, -- 删除状态
|
|
created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP, -- 记录创建时间
|
|
updated_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP -- 记录修改时间
|
|
);
|
|
|
|
-- 3 触发器:自动刷新 updated_at
|
|
CREATE TRIGGER trg_trading_records_updated_at
|
|
BEFORE UPDATE ON trading_records
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION moddatetime(updated_at);
|
|
|
|
RAISE NOTICE 'trading_records 表已创建';
|
|
ELSE
|
|
RAISE NOTICE 'trading_records 表已存在,跳过';
|
|
END IF;
|
|
END $$;
|
|
|
|
-- 4 索引(幂等)
|
|
CREATE INDEX IF NOT EXISTS idx_trd_open_ym
|
|
ON trading_records (open_year, open_month);
|
|
|
|
CREATE INDEX IF NOT EXISTS idx_trd_close_ym
|
|
ON trading_records (close_year, close_month)
|
|
WHERE close_year IS NOT NULL;
|
|
|
|
CREATE INDEX IF NOT EXISTS idx_trd_symbol_contract
|
|
ON trading_records (symbol, contract);
|
|
|
|
CREATE INDEX IF NOT EXISTS idx_trd_deleted_updated
|
|
ON trading_records (deleted, updated_at DESC);
|
|
|
|
DO $$
|
|
BEGIN
|
|
RAISE NOTICE '全部索引已确保存在';
|
|
END $$;
|
|
|
|
DO $$
|
|
BEGIN
|
|
RAISE NOTICE '============ trading_records 部署完成 ============';
|
|
END $$; |