-- Complete Risk/Reward Learning Database Schema -- This extends the database to learn from BOTH stop losses AND take profits -- Table to track complete risk/reward setups and their outcomes CREATE TABLE IF NOT EXISTS risk_reward_setups ( id TEXT PRIMARY KEY, trade_id TEXT, symbol TEXT NOT NULL, entry_price REAL NOT NULL, stop_loss REAL NOT NULL, take_profit REAL NOT NULL, leverage REAL DEFAULT 1.0, side TEXT NOT NULL, -- 'LONG' or 'SHORT' -- Calculated metrics stop_loss_distance REAL NOT NULL, -- percentage from entry take_profit_distance REAL NOT NULL, -- percentage from entry risk_reward_ratio REAL NOT NULL, -- reward/risk ratio -- Market context when setup was made market_conditions TEXT, -- JSON with volatility, trend, time, etc. ai_reasoning TEXT, expected_outcome TEXT, setup_timestamp DATETIME DEFAULT CURRENT_TIMESTAMP, -- Outcome tracking (filled when trade closes) exit_price REAL, exit_reason TEXT, -- 'STOP_LOSS', 'TAKE_PROFIT', 'MANUAL_EXIT', 'LIQUIDATION' actual_pnl REAL, time_to_exit INTEGER, -- minutes from setup to exit outcome_quality TEXT, -- 'EXCELLENT', 'GOOD', 'FAIR', 'POOR', 'TERRIBLE' learning_score REAL, -- calculated learning score (0-1) actual_risk_reward REAL, -- actual RR achieved exit_timestamp DATETIME, status TEXT DEFAULT 'ACTIVE', -- 'ACTIVE', 'COMPLETED' learning_data TEXT, -- JSON with analysis and improvements FOREIGN KEY (trade_id) REFERENCES trades(id) ); -- Indexes for performance CREATE INDEX IF NOT EXISTS idx_rr_setups_symbol ON risk_reward_setups(symbol); CREATE INDEX IF NOT EXISTS idx_rr_setups_exit_reason ON risk_reward_setups(exit_reason); CREATE INDEX IF NOT EXISTS idx_rr_setups_outcome_quality ON risk_reward_setups(outcome_quality); CREATE INDEX IF NOT EXISTS idx_rr_setups_rr_ratio ON risk_reward_setups(risk_reward_ratio); CREATE INDEX IF NOT EXISTS idx_rr_setups_setup_timestamp ON risk_reward_setups(setup_timestamp); CREATE INDEX IF NOT EXISTS idx_rr_setups_status ON risk_reward_setups(status); -- Table to store learned risk/reward patterns CREATE TABLE IF NOT EXISTS rr_patterns ( id INTEGER PRIMARY KEY AUTOINCREMENT, pattern_type TEXT NOT NULL, -- 'STOP_LOSS', 'TAKE_PROFIT', 'OPTIMAL_RATIO' market_condition TEXT NOT NULL, -- 'HIGH_VOLATILITY', 'BULLISH_TREND', etc. optimal_stop_loss REAL, optimal_take_profit REAL, optimal_rr_ratio REAL, success_rate REAL, sample_size INTEGER, confidence_level REAL, discovered_at DATETIME DEFAULT CURRENT_TIMESTAMP, last_validated DATETIME DEFAULT CURRENT_TIMESTAMP, is_active BOOLEAN DEFAULT TRUE ); -- Enhanced learning parameters for risk/reward INSERT OR REPLACE INTO learning_parameters (parameter_name, parameter_value, description) VALUES ('optimal_rr_ratio_default', 2.0, 'Default risk/reward ratio when no learning data available'), ('min_stop_loss_distance', 0.5, 'Minimum stop loss distance percentage'), ('max_stop_loss_distance', 10.0, 'Maximum stop loss distance percentage'), ('min_rr_ratio', 1.0, 'Minimum acceptable risk/reward ratio'), ('max_rr_ratio', 5.0, 'Maximum reasonable risk/reward ratio'), ('rr_learning_threshold', 10, 'Minimum setups needed to learn optimal ratios'), ('volatility_adjustment_factor', 1.5, 'How much to adjust stop loss for volatility'), ('trend_adjustment_factor', 0.8, 'How much to adjust for strong trends'); -- View for stop loss effectiveness analysis CREATE VIEW IF NOT EXISTS stop_loss_effectiveness AS SELECT CASE WHEN stop_loss_distance < 1.0 THEN 'Tight (<1%)' WHEN stop_loss_distance < 3.0 THEN 'Normal (1-3%)' WHEN stop_loss_distance < 5.0 THEN 'Wide (3-5%)' ELSE 'Very Wide (>5%)' END as sl_range, COUNT(*) as total_setups, AVG(CASE WHEN exit_reason = 'STOP_LOSS' THEN 1 ELSE 0 END) as stop_loss_hit_rate, AVG(CASE WHEN exit_reason = 'TAKE_PROFIT' THEN 1 ELSE 0 END) as take_profit_hit_rate, AVG(learning_score) as avg_learning_score, AVG(actual_pnl) as avg_pnl, COUNT(CASE WHEN outcome_quality IN ('EXCELLENT', 'GOOD') THEN 1 END) as good_outcomes FROM risk_reward_setups WHERE status = 'COMPLETED' GROUP BY sl_range ORDER BY avg_learning_score DESC; -- View for take profit effectiveness analysis CREATE VIEW IF NOT EXISTS take_profit_effectiveness AS SELECT CASE WHEN risk_reward_ratio < 1.0 THEN 'Conservative (1:0-1)' WHEN risk_reward_ratio < 2.0 THEN 'Balanced (1:1-2)' WHEN risk_reward_ratio < 3.0 THEN 'Aggressive (1:2-3)' ELSE 'Very Aggressive (1:3+)' END as rr_range, COUNT(*) as total_setups, AVG(CASE WHEN exit_reason = 'TAKE_PROFIT' THEN 1 ELSE 0 END) as take_profit_hit_rate, AVG(actual_pnl) as avg_pnl, AVG(learning_score) as avg_learning_score, AVG(actual_risk_reward) as avg_actual_rr, COUNT(CASE WHEN outcome_quality = 'EXCELLENT' THEN 1 END) as excellent_outcomes FROM risk_reward_setups WHERE status = 'COMPLETED' GROUP BY rr_range ORDER BY avg_learning_score DESC; -- View for market condition analysis CREATE VIEW IF NOT EXISTS market_condition_performance AS SELECT JSON_EXTRACT(market_conditions, '$.trend') as trend, CASE WHEN CAST(JSON_EXTRACT(market_conditions, '$.volatility') AS REAL) > 0.08 THEN 'High Volatility' WHEN CAST(JSON_EXTRACT(market_conditions, '$.volatility') AS REAL) > 0.04 THEN 'Medium Volatility' ELSE 'Low Volatility' END as volatility_level, COUNT(*) as total_setups, AVG(learning_score) as avg_learning_score, AVG(actual_pnl) as avg_pnl, AVG(risk_reward_ratio) as avg_rr_ratio, AVG(CASE WHEN exit_reason = 'TAKE_PROFIT' THEN 1 ELSE 0 END) as tp_hit_rate, COUNT(CASE WHEN outcome_quality = 'EXCELLENT' THEN 1 END) as excellent_count FROM risk_reward_setups WHERE status = 'COMPLETED' AND market_conditions IS NOT NULL GROUP BY trend, volatility_level HAVING total_setups >= 3 ORDER BY avg_learning_score DESC; -- View for time-based performance analysis CREATE VIEW IF NOT EXISTS time_based_performance AS SELECT CASE WHEN strftime('%H', setup_timestamp) BETWEEN '00' AND '05' THEN 'Night (00-05)' WHEN strftime('%H', setup_timestamp) BETWEEN '06' AND '11' THEN 'Morning (06-11)' WHEN strftime('%H', setup_timestamp) BETWEEN '12' AND '17' THEN 'Afternoon (12-17)' ELSE 'Evening (18-23)' END as time_period, CASE strftime('%w', setup_timestamp) WHEN '0' THEN 'Sunday' WHEN '1' THEN 'Monday' WHEN '2' THEN 'Tuesday' WHEN '3' THEN 'Wednesday' WHEN '4' THEN 'Thursday' WHEN '5' THEN 'Friday' WHEN '6' THEN 'Saturday' END as day_of_week, COUNT(*) as total_setups, AVG(learning_score) as avg_learning_score, AVG(actual_pnl) as avg_pnl, AVG(CASE WHEN exit_reason = 'TAKE_PROFIT' THEN 1 ELSE 0 END) as tp_hit_rate, AVG(risk_reward_ratio) as avg_rr_ratio FROM risk_reward_setups WHERE status = 'COMPLETED' GROUP BY time_period, day_of_week HAVING total_setups >= 2 ORDER BY avg_learning_score DESC; -- View for optimal risk/reward recommendations by condition CREATE VIEW IF NOT EXISTS optimal_rr_by_condition AS SELECT market_condition, optimal_rr_ratio, optimal_stop_loss, success_rate, confidence_level, sample_size, last_validated FROM rr_patterns WHERE is_active = TRUE AND confidence_level >= 0.6 AND sample_size >= 5 ORDER BY confidence_level DESC, success_rate DESC;