-- MySQL数据库架构(支持创新高回踩确认策略) -- 字符集:utf8mb4,支持emoji和完整Unicode -- 策略表:存储不同的交易策略配置 CREATE TABLE IF NOT EXISTS strategies ( id INT AUTO_INCREMENT PRIMARY KEY, strategy_name VARCHAR(100) NOT NULL UNIQUE, strategy_type VARCHAR(50) NOT NULL, description TEXT, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- 扫描会话表:记录每次策略扫描的会话信息 CREATE TABLE IF NOT EXISTS scan_sessions ( id INT AUTO_INCREMENT PRIMARY KEY, strategy_id INT NOT NULL, scan_date DATE NOT NULL, total_scanned INT DEFAULT 0, total_signals INT DEFAULT 0, data_source VARCHAR(200), scan_config JSON, status VARCHAR(20) DEFAULT 'completed', created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, FOREIGN KEY (strategy_id) REFERENCES strategies(id) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- 股票信号表:存储具体的股票筛选信号(包括股票和加密货币) CREATE TABLE IF NOT EXISTS stock_signals ( id INT AUTO_INCREMENT PRIMARY KEY, session_id INT, strategy_id INT, stock_code VARCHAR(20) NOT NULL, stock_name VARCHAR(100), asset_type VARCHAR(20) DEFAULT 'stock' COMMENT '资产类型: stock(股票), crypto(加密货币)', timeframe VARCHAR(20) NOT NULL, signal_date DATE NOT NULL, signal_type VARCHAR(100) NOT NULL, -- 价格信息 breakout_price DECIMAL(10,3), yin_high DECIMAL(10,3), breakout_amount DECIMAL(15,2), breakout_pct DECIMAL(8,4), ema20_price DECIMAL(10,3), -- 技术指标 yang1_entity_ratio DECIMAL(6,4), yang2_entity_ratio DECIMAL(6,4), final_yang_entity_ratio DECIMAL(6,4), turnover_ratio DECIMAL(8,4), above_ema20 BOOLEAN, -- 创新高回踩确认字段 new_high_confirmed BOOLEAN DEFAULT FALSE, new_high_price DECIMAL(10,3), new_high_date DATE, confirmation_date DATE, confirmation_days INT, pullback_distance DECIMAL(8,4), -- K线详情(JSON格式存储) k1_data JSON, k2_data JSON, k3_data JSON, k4_data JSON, -- 元数据 created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, FOREIGN KEY (session_id) REFERENCES scan_sessions(id), FOREIGN KEY (strategy_id) REFERENCES strategies(id), INDEX idx_stock_code (stock_code), INDEX idx_signal_date (signal_date), INDEX idx_strategy_id (strategy_id), INDEX idx_session_id (session_id), INDEX idx_new_high_confirmed (new_high_confirmed), INDEX idx_asset_type (asset_type) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- 回踩监控表:存储回踩提醒信息 CREATE TABLE IF NOT EXISTS pullback_alerts ( id INT AUTO_INCREMENT PRIMARY KEY, signal_id INT, stock_code VARCHAR(20) NOT NULL, stock_name VARCHAR(100), asset_type VARCHAR(20) DEFAULT 'stock' COMMENT '资产类型: stock(股票), crypto(加密货币)', timeframe VARCHAR(20) NOT NULL, -- 原始信号信息 original_signal_date DATE, original_breakout_price DECIMAL(10,3), yin_high DECIMAL(10,3), -- 回踩信息 pullback_date DATE NOT NULL, current_price DECIMAL(10,3), current_low DECIMAL(10,3), pullback_pct DECIMAL(8,4), distance_to_yin_high DECIMAL(8,4), days_since_signal INT, -- 提醒状态 alert_sent BOOLEAN DEFAULT FALSE, alert_sent_time TIMESTAMP NULL, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, FOREIGN KEY (signal_id) REFERENCES stock_signals(id), INDEX idx_stock_code (stock_code), INDEX idx_pullback_date (pullback_date) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- 创建索引以提高查询性能(忽略重复索引错误) -- CREATE INDEX idx_scan_sessions_scan_date ON scan_sessions (scan_date); -- 创建视图:最新信号概览 CREATE OR REPLACE VIEW latest_signals_view AS SELECT ss.stock_code, ss.stock_name, ss.asset_type, ss.timeframe, ss.signal_date, ss.breakout_price, ss.yin_high, ss.breakout_pct, ss.final_yang_entity_ratio, ss.turnover_ratio, ss.new_high_confirmed, ss.new_high_price, ss.new_high_date, ss.confirmation_date, ss.confirmation_days, ss.pullback_distance, ss.above_ema20, s.strategy_name, scan.created_at as scan_time, scan.data_source FROM stock_signals ss JOIN strategies s ON ss.strategy_id = s.id JOIN scan_sessions scan ON ss.session_id = scan.id ORDER BY ss.signal_date DESC, ss.created_at DESC; -- 创建视图:策略统计概览 CREATE OR REPLACE VIEW strategy_stats_view AS SELECT s.strategy_name, s.strategy_type, COUNT(DISTINCT scan.id) as total_scans, COUNT(ss.id) as total_signals, COUNT(DISTINCT ss.stock_code) as unique_stocks, MAX(scan.created_at) as last_scan_time, AVG(ss.breakout_pct) as avg_breakout_pct, AVG(ss.final_yang_entity_ratio) as avg_entity_ratio FROM strategies s LEFT JOIN scan_sessions scan ON s.id = scan.strategy_id LEFT JOIN stock_signals ss ON scan.id = ss.session_id GROUP BY s.id, s.strategy_name, s.strategy_type ORDER BY s.strategy_name;