Files
trading_bot_v4/scripts/fix_pnl_calculations.sql
mindesbunister 988fdb9ea4 Fix runner system + strengthen anti-chop filter
Three critical bugs fixed:
1. P&L calculation (65x inflation) - now uses collateralUSD not notional
2. handlePostTp1Adjustments() - checks tp2SizePercent===0 for runner mode
3. JavaScript || operator bug - changed to ?? for proper 0 handling

Signal quality improvements:
- Added anti-chop filter: price position <40% + ADX <25 = -25 points
- Prevents range-bound flip-flops (caught all 3 today)
- Backtest: 43.8% → 55.6% win rate, +86% profit per trade

Changes:
- lib/trading/signal-quality.ts: RANGE-BOUND CHOP penalty
- lib/drift/orders.ts: Fixed P&L calculation + transaction confirmation
- lib/trading/position-manager.ts: Runner system logic
- app/api/trading/execute/route.ts: || to ?? for tp2SizePercent
- app/api/trading/test/route.ts: || to ?? for tp1/tp2SizePercent
- prisma/schema.prisma: Added collateralUSD field
- scripts/fix_pnl_calculations.sql: Historical P&L correction
2025-11-10 15:36:51 +01:00

74 lines
2.6 KiB
SQL

-- Fix P&L calculations for all trades
-- Problem: P&L was calculated on notional position size instead of collateral
-- Formula was: realizedPnL = positionSizeUSD * profitPercent / 100
-- Should be: realizedPnL = (positionSizeUSD / leverage) * (profitPercent * leverage) / 100
-- Which simplifies to: realizedPnL = positionSizeUSD * profitPercent / 100 (but correctly calculated)
-- Step 1: Calculate and populate collateralUSD for all trades
UPDATE "Trade"
SET "collateralUSD" = "positionSizeUSD" / "leverage"
WHERE "collateralUSD" IS NULL;
-- Step 2: Recalculate realizedPnL for all closed trades
-- The bug was that closedUSD (notional) was used directly without dividing by leverage
-- Correct calculation: collateral * (price_change% * leverage) / 100
UPDATE "Trade"
SET "realizedPnL" = (
-- Collateral used
("positionSizeUSD" / "leverage") *
-- Price change percentage
(CASE
WHEN direction = 'long' THEN
(("exitPrice" - "entryPrice") / "entryPrice") * 100
WHEN direction = 'short' THEN
(("entryPrice" - "exitPrice") / "entryPrice") * 100
END) *
-- Leverage multiplier
"leverage"
) / 100
WHERE "exitReason" IS NOT NULL
AND "exitPrice" IS NOT NULL
AND "realizedPnL" IS NOT NULL;
-- Step 3: Also update realizedPnLPercent to reflect account P&L
UPDATE "Trade"
SET "realizedPnLPercent" = (
(CASE
WHEN direction = 'long' THEN
(("exitPrice" - "entryPrice") / "entryPrice") * 100
WHEN direction = 'short' THEN
(("entryPrice" - "exitPrice") / "entryPrice") * 100
END) * "leverage"
)
WHERE "exitReason" IS NOT NULL
AND "exitPrice" IS NOT NULL;
-- Step 4: Verify the fix by comparing old vs new P&L for one sample trade
SELECT
id,
direction,
"entryPrice",
"exitPrice",
"positionSizeUSD",
"collateralUSD",
leverage,
"realizedPnL" as corrected_pnl,
"realizedPnLPercent" as account_pnl_percent,
-- Show what it was before (incorrectly calculated)
"positionSizeUSD" * (("exitPrice" - "entryPrice") / "entryPrice") as old_wrong_calculation
FROM "Trade"
WHERE id = 'cmhr8papg0009p907jczfgdxn';
-- Step 5: Show summary of corrected P&L
SELECT
COUNT(*) as total_trades,
COUNT(CASE WHEN "exitReason" IS NOT NULL THEN 1 END) as closed_trades,
ROUND(SUM("realizedPnL")::numeric, 2) as total_corrected_pnl,
ROUND(AVG("realizedPnL")::numeric, 2) as avg_pnl_per_trade,
COUNT(CASE WHEN "realizedPnL" > 0 THEN 1 END) as winning_trades,
COUNT(CASE WHEN "realizedPnL" < 0 THEN 1 END) as losing_trades,
ROUND((COUNT(CASE WHEN "realizedPnL" > 0 THEN 1 END)::float /
NULLIF(COUNT(CASE WHEN "exitReason" IS NOT NULL THEN 1 END), 0) * 100)::numeric, 1) as win_rate_percent
FROM "Trade";