Files
trading_bot_v4/scripts/fix_short_pnl.sql
mindesbunister 309cad8108 Add SQL script to fix SHORT position P&L in database
Corrects all historical SHORT trades affected by the P&L calculation bug.

Results:
- 44 SHORT trades corrected
- Total P&L improved from -$388.82 to -$72.98 (+$315.84 recovered)
- SHORT win rate revealed to be 60.5% (not 39% as incorrectly shown)

Script creates backup table before making changes and includes rollback instructions.
2025-11-07 14:55:13 +01:00

94 lines
2.8 KiB
PL/PgSQL

-- Fix SHORT position P&L calculation bug in database
--
-- All SHORT trades have inverted P&L due to calculation bug in closePosition()
-- This script recalculates the correct P&L for all completed SHORT trades
BEGIN;
-- Create backup table first
CREATE TABLE IF NOT EXISTS "Trade_backup_20251107" AS
SELECT * FROM "Trade";
-- Show current SHORT trade P&L before fix
SELECT
'BEFORE FIX - SHORT Trades' as status,
COUNT(*) as total_shorts,
ROUND(SUM("realizedPnL")::numeric, 2) as total_pnl,
ROUND(AVG("realizedPnL")::numeric, 2) as avg_pnl
FROM "Trade"
WHERE direction = 'short'
AND "exitReason" IS NOT NULL
AND "exitReason" NOT LIKE '%CLEANUP%';
-- Update SHORT trades with corrected P&L
-- Formula:
-- priceDiff = entryPrice - exitPrice (profit when price falls)
-- profitPercent = (priceDiff / entryPrice) * 100
-- leverage = default 10x (stored in most trades)
-- collateral = positionSizeUSD / leverage
-- realizedPnL = collateral * (profitPercent / 100) * leverage
-- Simplifies to: realizedPnL = positionSizeUSD * (profitPercent / 100)
UPDATE "Trade"
SET "realizedPnL" = (
-- Calculate correct P&L for SHORT positions
"positionSizeUSD" *
(("entryPrice" - "exitPrice") / "entryPrice") -- Price diff / entry = profit %
)
WHERE direction = 'short'
AND "exitReason" IS NOT NULL
AND "exitReason" NOT LIKE '%CLEANUP%'
AND "exitPrice" IS NOT NULL
AND "entryPrice" > 0;
-- Show corrected SHORT trade P&L after fix
SELECT
'AFTER FIX - SHORT Trades' as status,
COUNT(*) as total_shorts,
ROUND(SUM("realizedPnL")::numeric, 2) as total_pnl,
ROUND(AVG("realizedPnL")::numeric, 2) as avg_pnl
FROM "Trade"
WHERE direction = 'short'
AND "exitReason" IS NOT NULL
AND "exitReason" NOT LIKE '%CLEANUP%';
-- Show sample of corrected trades
SELECT
symbol,
direction,
ROUND("entryPrice"::numeric, 2) as entry,
ROUND("exitPrice"::numeric, 2) as exit,
ROUND(("entryPrice" - "exitPrice")::numeric, 2) as price_diff,
ROUND((("entryPrice" - "exitPrice") / "entryPrice" * 100)::numeric, 3) as profit_pct,
ROUND("realizedPnL"::numeric, 2) as corrected_pnl,
"exitReason",
"createdAt"
FROM "Trade"
WHERE direction = 'short'
AND "exitReason" IS NOT NULL
AND "exitReason" NOT LIKE '%CLEANUP%'
ORDER BY "createdAt" DESC
LIMIT 10;
-- Show overall stats comparison
SELECT
direction,
COUNT(*) as trades,
ROUND(SUM("realizedPnL")::numeric, 2) as total_pnl,
ROUND(AVG("realizedPnL")::numeric, 2) as avg_pnl,
ROUND(100.0 * SUM(CASE WHEN "realizedPnL" > 0 THEN 1 ELSE 0 END) / COUNT(*)::numeric, 1) as win_rate
FROM "Trade"
WHERE "exitReason" IS NOT NULL
AND "exitReason" NOT LIKE '%CLEANUP%'
AND "isTestTrade" = false
GROUP BY direction
ORDER BY direction;
COMMIT;
-- To rollback if something goes wrong:
-- BEGIN;
-- DELETE FROM "Trade";
-- INSERT INTO "Trade" SELECT * FROM "Trade_backup_20251107";
-- COMMIT;