diff --git a/sql/01_uuid_v7_setup.sql b/sql/01_uuid_v7_setup.sql new file mode 100644 index 0000000..b317d1c --- /dev/null +++ b/sql/01_uuid_v7_setup.sql @@ -0,0 +1,48 @@ +-- 切换到目标数据库 +\c postgres; + +-- 检查并创建UUID扩展(如果不存在) +CREATE EXTENSION IF NOT EXISTS "uuid-ossp"; + +-- 定义检测UUID v7支持的函数 +CREATE OR REPLACE FUNCTION check_uuid_v7_support() RETURNS BOOLEAN AS $$ +DECLARE + test_uuid UUID; +BEGIN + BEGIN + SELECT gen_random_uuid_v7() INTO test_uuid; + RETURN TRUE; + EXCEPTION + WHEN undefined_function THEN + RETURN FALSE; + END; +END; +$$ LANGUAGE plpgsql VOLATILE; + +-- 创建UUID v7兼容函数(修复UUID格式长度问题) +CREATE OR REPLACE FUNCTION gen_random_uuid_v7() RETURNS uuid AS $$ +DECLARE + unix_ts_ms BIGINT; + rand_a BIGINT; + rand_b BIGINT; + hex_str TEXT; +BEGIN + -- 获取当前毫秒级Unix时间戳 + unix_ts_ms := (EXTRACT(EPOCH FROM NOW()) * 1000)::BIGINT; + + -- 生成随机数(调整随机数范围以确保总长度正确) + rand_a := (random() * (2^20 - 1))::BIGINT; + rand_b := (random() * (2^44 - 1))::BIGINT; -- 从48位调整为44位,减少2个字节 + + -- 组合UUID v7格式(确保总长度为32个十六进制字符) + hex_str := + lpad(to_hex(unix_ts_ms >> 12), 8, '0') || + lpad(to_hex((unix_ts_ms & 4095) << 4), 4, '0') || + '7' || lpad(to_hex(rand_a >> 18), 3, '0') || + lpad(to_hex(8 + (rand_a & 16383) >> 12), 2, '0') || + lpad(to_hex(rand_a & 4095), 3, '0') || + lpad(to_hex(rand_b), 11, '0'); -- 从12位调整为11位 + + RETURN hex_str::uuid; +END; +$$ LANGUAGE plpgsql VOLATILE; \ No newline at end of file diff --git a/sql/02_create_function.sql b/sql/02_create_function.sql new file mode 100644 index 0000000..267ab90 --- /dev/null +++ b/sql/02_create_function.sql @@ -0,0 +1,20 @@ +CREATE OR REPLACE FUNCTION update_data_modified_column() +RETURNS TRIGGER AS $$ +BEGIN + NEW.updated_at = CURRENT_TIMESTAMP; + RETURN NEW; +END; +$$ LANGUAGE plpgsql VOLATILE; + +-- 创建自动格式化小数的函数(按需去除尾部多余0) +CREATE OR REPLACE FUNCTION format_numeric_to_original(n NUMERIC) +RETURNS TEXT AS $$ +BEGIN + -- 逻辑:如果是整数(小数部分全0),返回整数文本;否则返回去除尾部0的文本 + IF n = TRUNC(n) THEN + RETURN TRUNC(n)::TEXT; -- 整数场景:1.000000 → '1' + ELSE + RETURN TRIM(TRAILING '0' FROM TRIM(TRAILING '.' FROM n::TEXT)); -- 小数场景:1.230000 → '1.23',1.002000 → '1.002' + END IF; +END; +$$ LANGUAGE plpgsql IMMUTABLE; -- IMMUTABLE:相同输入返回相同输出,支持索引 \ No newline at end of file diff --git a/sql/03_trading_records.sql b/sql/03_trading_records.sql new file mode 100644 index 0000000..1c76ea2 --- /dev/null +++ b/sql/03_trading_records.sql @@ -0,0 +1,83 @@ +-- ========================================================= +-- 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 $$; \ No newline at end of file