-- Stop Loss Decision Learning Database Schema -- This extends the existing database to support decision-level learning -- Table to track every AI decision made near stop loss CREATE TABLE IF NOT EXISTS sl_decisions ( id TEXT PRIMARY KEY, trade_id TEXT, symbol TEXT NOT NULL, decision_type TEXT NOT NULL, -- 'HOLD', 'EXIT', 'TIGHTEN_SL', 'PARTIAL_EXIT', 'EMERGENCY_EXIT' distance_from_sl REAL NOT NULL, reasoning TEXT, market_conditions TEXT, -- JSON with market context confidence_score REAL DEFAULT 0.7, expected_outcome TEXT, decision_timestamp DATETIME DEFAULT CURRENT_TIMESTAMP, -- Outcome tracking (filled when trade closes or situation resolves) outcome TEXT, -- 'HIT_ORIGINAL_SL', 'HIT_TIGHTENED_SL', 'PROFITABLE_EXIT', 'AVOIDED_LOSS', etc. outcome_timestamp DATETIME, time_to_outcome INTEGER, -- minutes from decision to outcome pnl_impact REAL, -- how much P&L was affected by the decision was_correct BOOLEAN, learning_score REAL, -- calculated learning score (0-1) additional_context TEXT, -- JSON with additional outcome context status TEXT DEFAULT 'PENDING_OUTCOME', -- 'PENDING_OUTCOME', 'ASSESSED' -- Indexing for faster queries FOREIGN KEY (trade_id) REFERENCES trades(id) ); -- Indexes for performance CREATE INDEX IF NOT EXISTS idx_sl_decisions_symbol ON sl_decisions(symbol); CREATE INDEX IF NOT EXISTS idx_sl_decisions_decision_type ON sl_decisions(decision_type); CREATE INDEX IF NOT EXISTS idx_sl_decisions_distance ON sl_decisions(distance_from_sl); CREATE INDEX IF NOT EXISTS idx_sl_decisions_timestamp ON sl_decisions(decision_timestamp); CREATE INDEX IF NOT EXISTS idx_sl_decisions_status ON sl_decisions(status); CREATE INDEX IF NOT EXISTS idx_sl_decisions_was_correct ON sl_decisions(was_correct); -- Table to store learning model parameters and thresholds CREATE TABLE IF NOT EXISTS learning_parameters ( id INTEGER PRIMARY KEY AUTOINCREMENT, parameter_name TEXT UNIQUE NOT NULL, parameter_value REAL NOT NULL, description TEXT, last_updated DATETIME DEFAULT CURRENT_TIMESTAMP, confidence_level REAL DEFAULT 0.5 -- how confident we are in this parameter ); -- Insert default learning parameters INSERT OR REPLACE INTO learning_parameters (parameter_name, parameter_value, description) VALUES ('emergency_distance_threshold', 1.0, 'Distance from SL (%) that triggers emergency decisions'), ('high_risk_distance_threshold', 2.0, 'Distance from SL (%) that triggers high risk decisions'), ('medium_risk_distance_threshold', 5.0, 'Distance from SL (%) that triggers medium risk decisions'), ('min_decisions_for_learning', 5, 'Minimum number of decisions needed to start learning'), ('confidence_threshold', 0.7, 'Minimum confidence to use learned recommendations'), ('learning_rate', 0.1, 'How quickly to adapt to new decision outcomes'); -- Table to store decision pattern insights CREATE TABLE IF NOT EXISTS decision_patterns ( id INTEGER PRIMARY KEY AUTOINCREMENT, pattern_type TEXT NOT NULL, -- 'SUCCESSFUL', 'FAILURE', 'OPTIMAL_TIMING' decision_type TEXT NOT NULL, conditions TEXT, -- JSON with conditions that trigger this pattern success_rate REAL, sample_size INTEGER, avg_pnl_impact REAL, confidence_score REAL, discovered_at DATETIME DEFAULT CURRENT_TIMESTAMP, last_validated DATETIME DEFAULT CURRENT_TIMESTAMP, is_active BOOLEAN DEFAULT TRUE ); -- View for quick decision performance analysis CREATE VIEW IF NOT EXISTS decision_performance AS SELECT decision_type, COUNT(*) as total_decisions, AVG(CASE WHEN was_correct THEN 1 ELSE 0 END) as success_rate, AVG(learning_score) as avg_learning_score, AVG(pnl_impact) as avg_pnl_impact, AVG(distance_from_sl) as avg_distance_from_sl, MIN(decision_timestamp) as first_decision, MAX(decision_timestamp) as latest_decision FROM sl_decisions WHERE status = 'ASSESSED' GROUP BY decision_type ORDER BY success_rate DESC; -- View for time-based decision analysis CREATE VIEW IF NOT EXISTS decision_timing_analysis AS SELECT CASE WHEN strftime('%H', decision_timestamp) BETWEEN '00' AND '05' THEN 'Night' WHEN strftime('%H', decision_timestamp) BETWEEN '06' AND '11' THEN 'Morning' WHEN strftime('%H', decision_timestamp) BETWEEN '12' AND '17' THEN 'Afternoon' ELSE 'Evening' END as time_period, decision_type, COUNT(*) as decisions, AVG(CASE WHEN was_correct THEN 1 ELSE 0 END) as success_rate, AVG(pnl_impact) as avg_pnl_impact FROM sl_decisions WHERE status = 'ASSESSED' GROUP BY time_period, decision_type ORDER BY success_rate DESC; -- View for distance-based decision analysis CREATE VIEW IF NOT EXISTS distance_effectiveness AS SELECT CASE WHEN distance_from_sl < 1.0 THEN 'Emergency (<1%)' WHEN distance_from_sl < 2.0 THEN 'High Risk (1-2%)' WHEN distance_from_sl < 5.0 THEN 'Medium Risk (2-5%)' ELSE 'Safe (>5%)' END as risk_level, decision_type, COUNT(*) as decisions, AVG(CASE WHEN was_correct THEN 1 ELSE 0 END) as success_rate, AVG(learning_score) as avg_score, AVG(pnl_impact) as avg_pnl_impact, AVG(time_to_outcome) as avg_resolution_time_minutes FROM sl_decisions WHERE status = 'ASSESSED' GROUP BY risk_level, decision_type ORDER BY risk_level, success_rate DESC;