auto_trade_sys/backend/database/init.sql
薇薇安 e5a281569c a
2026-01-22 19:30:57 +08:00

251 lines
13 KiB
SQL
Raw Permalink Blame History

This file contains ambiguous Unicode characters

This file contains Unicode characters that might be confused with other characters. If you think that this is intentional, you can safely ignore this warning. Use the Escape button to reveal them.

-- 自动交易系统数据库初始化脚本
CREATE DATABASE IF NOT EXISTS `auto_trade_sys` DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
USE `auto_trade_sys`;
-- 用户表(登录用户:管理员/普通用户)
CREATE TABLE IF NOT EXISTS `users` (
`id` INT PRIMARY KEY AUTO_INCREMENT,
`username` VARCHAR(64) NOT NULL,
`password_hash` VARCHAR(255) NOT NULL,
`role` VARCHAR(20) NOT NULL DEFAULT 'user' COMMENT 'admin, user',
`status` VARCHAR(20) NOT NULL DEFAULT 'active' COMMENT 'active, disabled',
`created_at` TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
`updated_at` TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
UNIQUE KEY `uk_username` (`username`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='登录用户';
-- 用户-交易账号授权关系
CREATE TABLE IF NOT EXISTS `user_account_memberships` (
`id` INT PRIMARY KEY AUTO_INCREMENT,
`user_id` INT NOT NULL,
`account_id` INT NOT NULL,
`role` VARCHAR(20) NOT NULL DEFAULT 'viewer' COMMENT 'owner, viewer',
`created_at` TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
UNIQUE KEY `uk_user_account` (`user_id`, `account_id`),
INDEX `idx_user_id` (`user_id`),
INDEX `idx_account_id` (`account_id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='用户-交易账号授权';
-- 账号表(多账号)
CREATE TABLE IF NOT EXISTS `accounts` (
`id` INT PRIMARY KEY AUTO_INCREMENT,
`name` VARCHAR(100) NOT NULL,
`status` VARCHAR(20) DEFAULT 'active' COMMENT 'active, disabled',
`api_key_enc` TEXT NULL COMMENT '加密后的 API KEYenc:v1:...',
`api_secret_enc` TEXT NULL COMMENT '加密后的 API SECRETenc:v1:...',
`use_testnet` BOOLEAN DEFAULT FALSE,
`created_at` TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
`updated_at` TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='账号表(多账号)';
-- 默认账号(兼容单账号)
INSERT INTO `accounts` (`id`, `name`, `status`, `use_testnet`)
VALUES (1, 'default', 'active', false)
ON DUPLICATE KEY UPDATE `name`=VALUES(`name`);
-- 配置表
CREATE TABLE IF NOT EXISTS `trading_config` (
`id` INT PRIMARY KEY AUTO_INCREMENT,
`account_id` INT NOT NULL DEFAULT 1,
`config_key` VARCHAR(100) NOT NULL,
`config_value` TEXT NOT NULL,
`config_type` VARCHAR(50) NOT NULL COMMENT 'string, number, boolean, json',
`category` VARCHAR(50) NOT NULL COMMENT 'position, risk, scan, strategy, api',
`description` TEXT,
`updated_at` TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
`updated_by` VARCHAR(50),
INDEX `idx_category` (`category`),
INDEX `idx_account_id` (`account_id`),
UNIQUE KEY `uk_account_config_key` (`account_id`, `config_key`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='交易配置表';
-- 注意:多账号需要 (account_id, config_key) 唯一。旧库升级请跑迁移脚本(见 add_multi_account.sql
-- 交易记录表
CREATE TABLE IF NOT EXISTS `trades` (
`id` INT PRIMARY KEY AUTO_INCREMENT,
`account_id` INT NOT NULL DEFAULT 1,
`symbol` VARCHAR(20) NOT NULL,
`side` VARCHAR(10) NOT NULL COMMENT 'BUY, SELL',
`quantity` DECIMAL(20, 8) NOT NULL,
`entry_price` DECIMAL(20, 8) NOT NULL,
`notional_usdt` DECIMAL(20, 8) NULL COMMENT '名义下单量USDT入场价×数量用于统计总交易量',
`margin_usdt` DECIMAL(20, 8) NULL COMMENT '保证金USDT名义下单量/杠杆',
`exit_price` DECIMAL(20, 8),
`entry_time` INT UNSIGNED NOT NULL COMMENT '入场时间Unix时间戳秒数',
`exit_time` INT UNSIGNED NULL COMMENT '平仓时间Unix时间戳秒数',
`pnl` DECIMAL(20, 8) DEFAULT 0,
`pnl_percent` DECIMAL(10, 4) DEFAULT 0,
`leverage` INT DEFAULT 10,
`entry_order_id` BIGINT NULL COMMENT '币安开仓订单号(用于对账)',
`exit_order_id` BIGINT NULL COMMENT '币安平仓订单号(用于对账)',
`entry_reason` TEXT,
`exit_reason` VARCHAR(50) COMMENT 'stop_loss, take_profit, trailing_stop, manual',
`strategy_type` VARCHAR(50) COMMENT '策略类型: trend_following, mean_reversion',
`duration_minutes` INT COMMENT '持仓持续时间(分钟)',
`atr` DECIMAL(20, 8) NULL COMMENT '开仓时使用的ATR用于展示动态止损止盈依据',
`stop_loss_price` DECIMAL(20, 8) NULL COMMENT '实际使用的止损价格考虑了ATR等动态计算',
`take_profit_price` DECIMAL(20, 8) NULL COMMENT '实际使用的止盈价格考虑了ATR等动态计算',
`take_profit_1` DECIMAL(20, 8) NULL COMMENT '第一目标止盈价(用于展示与分步止盈)',
`take_profit_2` DECIMAL(20, 8) NULL COMMENT '第二目标止盈价(用于展示与分步止盈)',
`status` VARCHAR(20) DEFAULT 'open' COMMENT 'open, closed, cancelled',
`created_at` INT UNSIGNED NOT NULL DEFAULT (UNIX_TIMESTAMP()) COMMENT '创建时间Unix时间戳秒数',
INDEX `idx_account_id` (`account_id`),
INDEX `idx_symbol` (`symbol`),
INDEX `idx_entry_time` (`entry_time`),
INDEX `idx_status` (`status`),
INDEX `idx_symbol_status` (`symbol`, `status`),
INDEX `idx_entry_order_id` (`entry_order_id`),
INDEX `idx_exit_order_id` (`exit_order_id`),
INDEX `idx_strategy_type` (`strategy_type`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='交易记录表';
-- 账户快照表
CREATE TABLE IF NOT EXISTS `account_snapshots` (
`id` INT PRIMARY KEY AUTO_INCREMENT,
`account_id` INT NOT NULL DEFAULT 1,
`total_balance` DECIMAL(20, 8) NOT NULL,
`available_balance` DECIMAL(20, 8) NOT NULL,
`total_position_value` DECIMAL(20, 8) DEFAULT 0,
`total_pnl` DECIMAL(20, 8) DEFAULT 0,
`open_positions` INT DEFAULT 0,
`snapshot_time` TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
INDEX `idx_account_id` (`account_id`),
INDEX `idx_snapshot_time` (`snapshot_time`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='账户快照表';
-- 市场扫描记录表
CREATE TABLE IF NOT EXISTS `market_scans` (
`id` INT PRIMARY KEY AUTO_INCREMENT,
`scan_time` TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
`symbols_scanned` INT DEFAULT 0,
`symbols_found` INT DEFAULT 0,
`top_symbols` JSON,
`scan_duration` DECIMAL(10, 3) COMMENT '扫描耗时(秒)',
INDEX `idx_scan_time` (`scan_time`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='市场扫描记录表';
-- 策略信号表
CREATE TABLE IF NOT EXISTS `trading_signals` (
`id` INT PRIMARY KEY AUTO_INCREMENT,
`symbol` VARCHAR(20) NOT NULL,
`signal_direction` VARCHAR(10) NOT NULL COMMENT 'BUY, SELL',
`signal_strength` INT NOT NULL COMMENT '0-10',
`signal_reason` TEXT,
`rsi` DECIMAL(10, 4),
`macd_histogram` DECIMAL(20, 8),
`market_regime` VARCHAR(20) COMMENT 'trending, ranging',
`signal_time` TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
`executed` BOOLEAN DEFAULT FALSE,
INDEX `idx_symbol` (`symbol`),
INDEX `idx_signal_time` (`signal_time`),
INDEX `idx_executed` (`executed`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='交易信号表';
-- 推荐交易对表
CREATE TABLE IF NOT EXISTS `trade_recommendations` (
`id` INT PRIMARY KEY AUTO_INCREMENT,
`symbol` VARCHAR(20) NOT NULL,
`direction` VARCHAR(10) NOT NULL COMMENT 'BUY, SELL',
`recommendation_time` TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
`current_price` DECIMAL(20, 8) NOT NULL,
`change_percent` DECIMAL(10, 4) COMMENT '24小时涨跌幅',
`recommendation_reason` TEXT NOT NULL COMMENT '推荐原因',
`signal_strength` INT NOT NULL COMMENT '信号强度 0-10',
`market_regime` VARCHAR(20) COMMENT 'trending, ranging',
`trend_4h` VARCHAR(10) COMMENT '4H周期趋势: up, down, neutral',
-- 技术指标
`rsi` DECIMAL(10, 4) COMMENT 'RSI指标',
`macd_histogram` DECIMAL(20, 8) COMMENT 'MACD柱状图',
`bollinger_upper` DECIMAL(20, 8) COMMENT '布林带上轨',
`bollinger_middle` DECIMAL(20, 8) COMMENT '布林带中轨',
`bollinger_lower` DECIMAL(20, 8) COMMENT '布林带下轨',
`ema20` DECIMAL(20, 8) COMMENT 'EMA20',
`ema50` DECIMAL(20, 8) COMMENT 'EMA50',
`ema20_4h` DECIMAL(20, 8) COMMENT '4H周期EMA20',
`atr` DECIMAL(20, 8) COMMENT '平均真实波幅',
-- 建议参数
`suggested_stop_loss` DECIMAL(20, 8) COMMENT '建议止损价',
`suggested_take_profit_1` DECIMAL(20, 8) COMMENT '建议第一目标止盈价盈亏比1:1',
`suggested_take_profit_2` DECIMAL(20, 8) COMMENT '建议第二目标止盈价',
`suggested_position_percent` DECIMAL(10, 4) COMMENT '建议仓位百分比',
`suggested_leverage` INT DEFAULT 10 COMMENT '建议杠杆倍数',
-- 市场数据
`volume_24h` DECIMAL(20, 8) COMMENT '24小时成交量',
`volatility` DECIMAL(10, 4) COMMENT '波动率',
-- 状态
`status` VARCHAR(20) DEFAULT 'active' COMMENT 'active: 有效, expired: 已过期, executed: 已执行, cancelled: 已取消',
`executed_at` TIMESTAMP NULL COMMENT '执行时间',
`execution_result` VARCHAR(50) COMMENT '执行结果: success, failed',
`execution_trade_id` INT COMMENT '关联的交易记录ID',
`expires_at` TIMESTAMP NULL COMMENT '推荐过期时间默认24小时后',
`notes` TEXT COMMENT '备注信息',
INDEX `idx_symbol` (`symbol`),
INDEX `idx_recommendation_time` (`recommendation_time`),
INDEX `idx_status` (`status`),
INDEX `idx_direction` (`direction`),
INDEX `idx_signal_strength` (`signal_strength`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='推荐交易对表';
-- 初始化默认配置
INSERT INTO `trading_config` (`config_key`, `config_value`, `config_type`, `category`, `description`) VALUES
-- 仓位控制
('MAX_POSITION_PERCENT', '0.08', 'number', 'position', '单笔最大仓位账户余额的8%(提高收益)'),
('MAX_TOTAL_POSITION_PERCENT', '0.40', 'number', 'position', '总仓位上限账户余额的40%(允许更多持仓)'),
('MIN_POSITION_PERCENT', '0.02', 'number', 'position', '单笔最小仓位账户余额的2%(避免过小仓位)'),
('MIN_MARGIN_USDT', '5.0', 'number', 'position', '最小保证金要求5 USDT提高收益'),
-- 涨跌幅阈值
('MIN_CHANGE_PERCENT', '2.0', 'number', 'scan', '最小涨跌幅阈值2%'),
('TOP_N_SYMBOLS', '10', 'number', 'scan', '每次扫描后处理的交易对数量从符合条件的交易对中选择前N个进行详细分析'),
('MAX_SCAN_SYMBOLS', '500', 'number', 'scan', '扫描的最大交易对数量0表示扫描所有建议100-500'),
-- 风险控制
('STOP_LOSS_PERCENT', '0.10', 'number', 'risk', '止损10%(相对于保证金)'),
('TAKE_PROFIT_PERCENT', '0.30', 'number', 'risk', '止盈30%相对于保证金盈亏比3:1'),
('MIN_STOP_LOSS_PRICE_PCT', '0.02', 'number', 'risk', '最小止损价格变动2%(防止止损过紧)'),
('MIN_TAKE_PROFIT_PRICE_PCT', '0.02', 'number', 'risk', '最小止盈价格变动2%防止ATR过小时计算出不切实际的微小止盈距离'),
('USE_ATR_STOP_LOSS', 'true', 'boolean', 'risk', '是否使用ATR动态止损优先于固定百分比'),
('ATR_STOP_LOSS_MULTIPLIER', '1.8', 'number', 'risk', 'ATR止损倍数1.5-2倍ATR默认1.8'),
('ATR_TAKE_PROFIT_MULTIPLIER', '1.5', 'number', 'risk', 'ATR止盈倍数从4.5降至1.5将盈亏比从3:1降至更现实、可达成的1.5:1提升止盈触发率'),
('RISK_REWARD_RATIO', '1.5', 'number', 'risk', '盈亏比止损距离的倍数用于计算止盈从3.0降至1.5,更容易达成)'),
('ATR_PERIOD', '14', 'number', 'risk', 'ATR计算周期默认14'),
('USE_DYNAMIC_ATR_MULTIPLIER', 'false', 'boolean', 'risk', '是否根据波动率动态调整ATR倍数'),
('ATR_MULTIPLIER_MIN', '1.5', 'number', 'risk', '动态ATR倍数最小值'),
('ATR_MULTIPLIER_MAX', '2.5', 'number', 'risk', '动态ATR倍数最大值'),
-- 市场扫描1小时主周期
('SCAN_INTERVAL', '3600', 'number', 'scan', '扫描间隔1小时'),
('KLINE_INTERVAL', '1h', 'string', 'scan', 'K线周期1小时'),
('PRIMARY_INTERVAL', '1h', 'string', 'scan', '主周期1小时'),
('CONFIRM_INTERVAL', '4h', 'string', 'scan', '确认周期4小时'),
('ENTRY_INTERVAL', '15m', 'string', 'scan', '入场周期15分钟'),
-- 过滤条件
('MIN_VOLUME_24H', '10000000', 'number', 'scan', '最小24小时成交量1000万USDT'),
('MIN_VOLATILITY', '0.02', 'number', 'scan', '最小波动率2%'),
-- 高胜率策略参数
('MIN_SIGNAL_STRENGTH', '7', 'number', 'strategy', '最小信号强度0-10已提升至7以提高入场质量'),
('LEVERAGE', '10', 'number', 'strategy', '基础杠杆倍数'),
('USE_DYNAMIC_LEVERAGE', 'true', 'boolean', 'strategy', '是否启用动态杠杆(根据信号强度调整杠杆倍数)'),
('MAX_LEVERAGE', '15', 'number', 'strategy', '最大杠杆倍数动态杠杆上限降低到15更保守'),
('USE_TRAILING_STOP', 'true', 'boolean', 'strategy', '是否使用移动止损'),
('TRAILING_STOP_ACTIVATION', '0.10', 'number', 'strategy', '移动止损激活阈值盈利10%后激活,给趋势更多空间)'),
('TRAILING_STOP_PROTECT', '0.05', 'number', 'strategy', '移动止损保护利润保护5%利润,更合理)'),
-- 持仓同步
('POSITION_SYNC_INTERVAL', '60', 'number', 'scan', '持仓状态同步间隔默认1分钟用于同步币安实际持仓与数据库状态'),
-- API配置
('BINANCE_API_KEY', '', 'string', 'api', '币安API密钥'),
('BINANCE_API_SECRET', '', 'string', 'api', '币安API密钥'),
('USE_TESTNET', 'false', 'boolean', 'api', '是否使用测试网')
ON DUPLICATE KEY UPDATE `config_value` = VALUES(`config_value`);