diff --git a/db-migrations/20260215_fix_duplicate_assigned_dispatches.sql b/db-migrations/20260215_fix_duplicate_assigned_dispatches.sql new file mode 100644 index 0000000..a4c1b96 --- /dev/null +++ b/db-migrations/20260215_fix_duplicate_assigned_dispatches.sql @@ -0,0 +1,216 @@ +-- ================================================================ +-- Migration: Fix Duplicate ASSIGNED Dispatches +-- Date: 2026-02-15 +-- Description: +-- - 한 기사가 여러 개의 ASSIGNED 배차를 가지는 문제 해결 +-- - 중복 배차 정리 (가장 최근 배차만 유지) +-- - 기사 상태(dispatch_status) 동기화 +-- - UNIQUE INDEX 생성으로 중복 방지 +-- ================================================================ + +BEGIN; + +-- ================================================================ +-- Step 1: 백업 테이블 생성 (롤백 및 추적용) +-- ================================================================ +CREATE TABLE IF NOT EXISTS dispatch_backup_20260215 AS +SELECT * FROM dispatch +WHERE status = 'ASSIGNED' AND active = true; + +-- 백업된 레코드 수 출력 +DO $$ +DECLARE + backup_count INTEGER; +BEGIN + SELECT COUNT(*) INTO backup_count FROM dispatch_backup_20260215; + RAISE NOTICE 'Created backup table with % records', backup_count; +END $$; + +-- ================================================================ +-- Step 2: 중복 데이터 확인 및 로그 +-- ================================================================ +DO $$ +DECLARE + duplicate_transporter_count INTEGER; + total_duplicate_dispatch_count INTEGER; +BEGIN + -- 중복 배차를 가진 기사 수 + SELECT COUNT(*) INTO duplicate_transporter_count + FROM ( + SELECT transporter_id + FROM dispatch + WHERE status = 'ASSIGNED' + AND active = true + AND transporter_id IS NOT NULL + GROUP BY transporter_id + HAVING COUNT(*) > 1 + ) duplicates; + + -- 중복 배차 총 개수 + SELECT SUM(cnt - 1) INTO total_duplicate_dispatch_count + FROM ( + SELECT COUNT(*) as cnt + FROM dispatch + WHERE status = 'ASSIGNED' + AND active = true + AND transporter_id IS NOT NULL + GROUP BY transporter_id + HAVING COUNT(*) > 1 + ) dup_counts; + + IF duplicate_transporter_count > 0 THEN + RAISE NOTICE '========================================'; + RAISE NOTICE 'Found % transporters with duplicate ASSIGNED dispatches', duplicate_transporter_count; + RAISE NOTICE 'Total % dispatches will be canceled', total_duplicate_dispatch_count; + RAISE NOTICE '========================================'; + ELSE + RAISE NOTICE 'No duplicate ASSIGNED dispatches found'; + END IF; +END $$; + +-- ================================================================ +-- Step 3: 중복 배차 정리 (가장 최근 배차만 유지, 나머지 취소) +-- ================================================================ +WITH ranked_dispatches AS ( + SELECT + id, + transporter_id, + assigned_at, + ROW_NUMBER() OVER ( + PARTITION BY transporter_id + ORDER BY assigned_at DESC, id DESC -- 최신 배차 우선 + ) as rn + FROM dispatch + WHERE status = 'ASSIGNED' + AND active = true + AND transporter_id IS NOT NULL +) +UPDATE dispatch +SET + status = 'CANCELED', + canceled_at = NOW(), + updated_at = NOW() +FROM ranked_dispatches +WHERE dispatch.id = ranked_dispatches.id + AND ranked_dispatches.rn > 1; + +-- 취소된 레코드 수 출력 +DO $$ +DECLARE + canceled_count INTEGER; +BEGIN + -- 마지막 UPDATE로 영향받은 행 수는 별도 조회 필요 + SELECT COUNT(*) INTO canceled_count + FROM dispatch + WHERE status = 'CANCELED' + AND canceled_at >= NOW() - INTERVAL '5 seconds'; -- 방금 취소된 것만 + + RAISE NOTICE 'Canceled % duplicate dispatches', canceled_count; +END $$; + +-- ================================================================ +-- Step 4: 기사 상태(dispatch_status) 동기화 +-- ================================================================ + +-- 4-1. ASSIGNED 배차가 없는데 DISPATCH 상태인 기사 찾기 +DO $$ +DECLARE + inconsistent_count INTEGER; +BEGIN + SELECT COUNT(*) INTO inconsistent_count + FROM transporters t + LEFT JOIN dispatch d ON t.transporter_id = d.transporter_id + AND d.status = 'ASSIGNED' + AND d.active = true + WHERE t.dispatch_status = 'DISPATCH' + AND d.dispatch_id IS NULL; + + IF inconsistent_count > 0 THEN + RAISE NOTICE 'Found % transporters with inconsistent dispatch_status', inconsistent_count; + END IF; +END $$; + +-- 4-2. 기사 상태를 EMPTY로 변경 +UPDATE transporters t +SET dispatch_status = 'EMPTY' +WHERE t.dispatch_status = 'DISPATCH' + AND NOT EXISTS ( + SELECT 1 FROM dispatch d + WHERE d.transporter_id = t.transporter_id + AND d.status = 'ASSIGNED' + AND d.active = true + ); + +-- ================================================================ +-- Step 5: 검증 - 중복 데이터가 남아있는지 확인 +-- ================================================================ +DO $$ +DECLARE + duplicate_count INTEGER; +BEGIN + SELECT COUNT(*) INTO duplicate_count + FROM ( + SELECT transporter_id + FROM dispatch + WHERE status = 'ASSIGNED' + AND active = true + AND transporter_id IS NOT NULL + GROUP BY transporter_id + HAVING COUNT(*) > 1 + ) duplicates; + + IF duplicate_count > 0 THEN + RAISE EXCEPTION 'Migration validation failed: Still have % transporters with duplicate assigned dispatches', duplicate_count; + ELSE + RAISE NOTICE '✓ Validation passed: No duplicate assigned dispatches found'; + END IF; +END $$; + +-- ================================================================ +-- Step 6: UNIQUE INDEX 생성 +-- ================================================================ + +-- 기존 인덱스가 있다면 삭제 +DROP INDEX IF EXISTS idx_unique_assigned_transporter; + +-- 부분 UNIQUE INDEX 생성 +-- (한 기사는 ASSIGNED 상태 배차를 하나만 가질 수 있음) +CREATE UNIQUE INDEX idx_unique_assigned_transporter +ON dispatch (transporter_id) +WHERE status = 'ASSIGNED' AND active = true; + +RAISE NOTICE '✓ Successfully created UNIQUE INDEX: idx_unique_assigned_transporter'; + +-- ================================================================ +-- Step 7: 인덱스 정보 출력 +-- ================================================================ +DO $$ +DECLARE + index_def TEXT; +BEGIN + SELECT indexdef INTO index_def + FROM pg_indexes + WHERE indexname = 'idx_unique_assigned_transporter'; + + RAISE NOTICE '========================================'; + RAISE NOTICE 'Index definition:'; + RAISE NOTICE '%', index_def; + RAISE NOTICE '========================================'; +END $$; + +COMMIT; + +-- ================================================================ +-- 마이그레이션 완료 메시지 +-- ================================================================ +DO $$ +BEGIN + RAISE NOTICE '========================================'; + RAISE NOTICE '✓ Migration completed successfully'; + RAISE NOTICE '========================================'; + RAISE NOTICE 'Next steps:'; + RAISE NOTICE '1. Verify data integrity'; + RAISE NOTICE '2. Monitor application logs for TRANSPORTER_ALREADY_DISPATCHED errors'; + RAISE NOTICE '3. After 1 week, drop backup table: DROP TABLE dispatch_backup_20260215;'; + RAISE NOTICE '========================================'; +END $$; diff --git a/db-migrations/20260215_pre_migration_check.sql b/db-migrations/20260215_pre_migration_check.sql new file mode 100644 index 0000000..8448f15 --- /dev/null +++ b/db-migrations/20260215_pre_migration_check.sql @@ -0,0 +1,218 @@ +-- ================================================================ +-- Pre-Migration Check: Duplicate ASSIGNED Dispatches +-- Date: 2026-02-15 +-- Description: +-- 마이그레이션 실행 전에 현재 데이터 상태를 확인합니다. +-- 이 스크립트는 데이터를 변경하지 않으며, 읽기 전용입니다. +-- ================================================================ + +-- ================================================================ +-- Check 1: 중복 배차를 가진 기사 목록 +-- ================================================================ +SELECT + '=== Transporters with Duplicate ASSIGNED Dispatches ===' as check_title; + +SELECT + t.transporter_id, + t.name as transporter_name, + t.phone, + t.dispatch_status, + COUNT(d.dispatch_id) as assigned_count, + STRING_AGG(d.dispatch_id::text, ', ' ORDER BY d.assigned_at DESC) as dispatch_ids, + STRING_AGG(d.assigned_at::text, ', ' ORDER BY d.assigned_at DESC) as assigned_times, + STRING_AGG(d.charge::text, ', ' ORDER BY d.assigned_at DESC) as charges +FROM dispatch d +JOIN transporters t ON d.transporter_id = t.transporter_id +WHERE d.status = 'ASSIGNED' + AND d.active = true + AND d.transporter_id IS NOT NULL +GROUP BY t.transporter_id, t.name, t.phone, t.dispatch_status +HAVING COUNT(d.dispatch_id) > 1 +ORDER BY COUNT(d.dispatch_id) DESC, t.transporter_id; + +-- ================================================================ +-- Check 2: 중복 배차 통계 +-- ================================================================ +SELECT + '=== Duplicate Dispatch Statistics ===' as check_title; + +SELECT + COUNT(DISTINCT transporter_id) as transporters_with_duplicates, + SUM(duplicate_count - 1) as total_excess_dispatches, + MAX(duplicate_count) as max_duplicates_per_transporter, + ROUND(AVG(duplicate_count), 2) as avg_duplicates_per_transporter +FROM ( + SELECT + transporter_id, + COUNT(*) as duplicate_count + FROM dispatch + WHERE status = 'ASSIGNED' + AND active = true + AND transporter_id IS NOT NULL + GROUP BY transporter_id + HAVING COUNT(*) > 1 +) dup_stats; + +-- ================================================================ +-- Check 3: 기사 상태 불일치 확인 +-- ================================================================ +SELECT + '=== Inconsistent Transporter Dispatch Status ===' as check_title; + +-- Case 1: ASSIGNED 배차가 있는데 EMPTY 상태인 기사 +SELECT + '1. Has ASSIGNED dispatch but status is EMPTY' as inconsistency_type, + t.transporter_id, + t.name, + t.dispatch_status, + COUNT(d.dispatch_id) as assigned_dispatch_count +FROM transporters t +JOIN dispatch d ON t.transporter_id = d.transporter_id +WHERE d.status = 'ASSIGNED' + AND d.active = true + AND t.dispatch_status = 'EMPTY' +GROUP BY t.transporter_id, t.name, t.dispatch_status + +UNION ALL + +-- Case 2: ASSIGNED 배차가 없는데 DISPATCH 상태인 기사 +SELECT + '2. No ASSIGNED dispatch but status is DISPATCH' as inconsistency_type, + t.transporter_id, + t.name, + t.dispatch_status, + 0 as assigned_dispatch_count +FROM transporters t +LEFT JOIN dispatch d ON t.transporter_id = d.transporter_id + AND d.status = 'ASSIGNED' + AND d.active = true +WHERE t.dispatch_status = 'DISPATCH' + AND d.dispatch_id IS NULL; + +-- ================================================================ +-- Check 4: 중복 배차 상세 정보 (샘플 5건) +-- ================================================================ +SELECT + '=== Sample Duplicate Dispatches (Top 5) ===' as check_title; + +SELECT + d.dispatch_id, + d.transporter_id, + t.name as transporter_name, + d.status, + d.charge, + d.start_location, + d.destination_location, + d.assigned_at, + d.created_at, + ROW_NUMBER() OVER (PARTITION BY d.transporter_id ORDER BY d.assigned_at DESC) as rank_in_group +FROM dispatch d +JOIN transporters t ON d.transporter_id = t.transporter_id +WHERE d.transporter_id IN ( + SELECT transporter_id + FROM dispatch + WHERE status = 'ASSIGNED' AND active = true + GROUP BY transporter_id + HAVING COUNT(*) > 1 + LIMIT 5 +) +AND d.status = 'ASSIGNED' +AND d.active = true +ORDER BY d.transporter_id, d.assigned_at DESC; + +-- ================================================================ +-- Check 5: 현재 UNIQUE INDEX 존재 여부 +-- ================================================================ +SELECT + '=== Current Index Status ===' as check_title; + +SELECT + indexname, + indexdef +FROM pg_indexes +WHERE indexname = 'idx_unique_assigned_transporter'; + +-- 인덱스가 없으면 메시지 출력 +DO $$ +BEGIN + IF NOT EXISTS (SELECT 1 FROM pg_indexes WHERE indexname = 'idx_unique_assigned_transporter') THEN + RAISE NOTICE 'INDEX idx_unique_assigned_transporter does not exist'; + ELSE + RAISE NOTICE 'INDEX idx_unique_assigned_transporter already exists'; + END IF; +END $$; + +-- ================================================================ +-- Check 6: 마이그레이션 영향 예측 +-- ================================================================ +SELECT + '=== Migration Impact Estimate ===' as check_title; + +SELECT + 'Total ASSIGNED dispatches' as metric, + COUNT(*) as count +FROM dispatch +WHERE status = 'ASSIGNED' AND active = true + +UNION ALL + +SELECT + 'Dispatches to be canceled (excess)' as metric, + COALESCE(SUM(cnt - 1), 0) as count +FROM ( + SELECT COUNT(*) as cnt + FROM dispatch + WHERE status = 'ASSIGNED' AND active = true AND transporter_id IS NOT NULL + GROUP BY transporter_id + HAVING COUNT(*) > 1 +) dup_counts + +UNION ALL + +SELECT + 'Dispatches to remain ASSIGNED' as metric, + COUNT(*) - COALESCE((SELECT SUM(cnt - 1) FROM ( + SELECT COUNT(*) as cnt + FROM dispatch + WHERE status = 'ASSIGNED' AND active = true AND transporter_id IS NOT NULL + GROUP BY transporter_id + HAVING COUNT(*) > 1 + ) dup_counts), 0) as count +FROM dispatch +WHERE status = 'ASSIGNED' AND active = true; + +-- ================================================================ +-- 최종 요약 +-- ================================================================ +DO $$ +DECLARE + dup_count INTEGER; +BEGIN + SELECT COUNT(*) INTO dup_count + FROM ( + SELECT transporter_id + FROM dispatch + WHERE status = 'ASSIGNED' AND active = true AND transporter_id IS NOT NULL + GROUP BY transporter_id + HAVING COUNT(*) > 1 + ) duplicates; + + RAISE NOTICE '========================================'; + RAISE NOTICE 'Pre-Migration Check Summary'; + RAISE NOTICE '========================================'; + + IF dup_count > 0 THEN + RAISE NOTICE '⚠️ Found % transporters with duplicate ASSIGNED dispatches', dup_count; + RAISE NOTICE '✓ Migration is REQUIRED'; + RAISE NOTICE ''; + RAISE NOTICE 'Review the results above before proceeding with migration.'; + RAISE NOTICE 'Execute: 20260215_fix_duplicate_assigned_dispatches.sql'; + ELSE + RAISE NOTICE '✓ No duplicate ASSIGNED dispatches found'; + RAISE NOTICE '✓ Migration is NOT REQUIRED'; + RAISE NOTICE ''; + RAISE NOTICE 'You can still create the UNIQUE INDEX to prevent future duplicates.'; + END IF; + + RAISE NOTICE '========================================'; +END $$; diff --git a/db-migrations/20260215_rollback_duplicate_fix.sql b/db-migrations/20260215_rollback_duplicate_fix.sql new file mode 100644 index 0000000..a8ecf9f --- /dev/null +++ b/db-migrations/20260215_rollback_duplicate_fix.sql @@ -0,0 +1,115 @@ +-- ================================================================ +-- Rollback Script: Revert Duplicate ASSIGNED Dispatches Fix +-- Date: 2026-02-15 +-- Description: +-- 마이그레이션을 롤백하고 백업에서 데이터를 복원합니다. +-- ⚠️ 주의: 이 스크립트를 실행하면 중복 데이터가 다시 복원됩니다. +-- ================================================================ + +BEGIN; + +-- ================================================================ +-- Step 1: 백업 테이블 존재 확인 +-- ================================================================ +DO $$ +BEGIN + IF NOT EXISTS (SELECT 1 FROM information_schema.tables WHERE table_name = 'dispatch_backup_20260215') THEN + RAISE EXCEPTION 'Backup table dispatch_backup_20260215 does not exist. Cannot rollback.'; + END IF; + RAISE NOTICE 'Backup table found. Proceeding with rollback...'; +END $$; + +-- ================================================================ +-- Step 2: UNIQUE INDEX 삭제 +-- ================================================================ +DROP INDEX IF EXISTS idx_unique_assigned_transporter; +RAISE NOTICE '✓ Dropped UNIQUE INDEX: idx_unique_assigned_transporter'; + +-- ================================================================ +-- Step 3: 백업에서 데이터 복원 +-- ================================================================ + +-- 3-1. 마이그레이션으로 취소된 배차 복원 +UPDATE dispatch +SET + status = backup.status, + canceled_at = backup.canceled_at, + updated_at = backup.updated_at +FROM dispatch_backup_20260215 backup +WHERE dispatch.id = backup.id + AND dispatch.status = 'CANCELED' + AND backup.status = 'ASSIGNED'; + +-- 복원된 레코드 수 출력 +DO $$ +DECLARE + restored_count INTEGER; +BEGIN + SELECT COUNT(*) INTO restored_count + FROM dispatch d + JOIN dispatch_backup_20260215 b ON d.id = b.id + WHERE d.status = 'ASSIGNED' AND b.status = 'ASSIGNED'; + + RAISE NOTICE '✓ Restored % dispatches from backup', restored_count; +END $$; + +-- ================================================================ +-- Step 4: 기사 상태 복원 (필요한 경우) +-- ================================================================ + +-- ASSIGNED 배차가 있는데 EMPTY 상태인 기사를 DISPATCH로 변경 +UPDATE transporters t +SET dispatch_status = 'DISPATCH' +WHERE t.dispatch_status = 'EMPTY' + AND EXISTS ( + SELECT 1 FROM dispatch d + WHERE d.transporter_id = t.transporter_id + AND d.status = 'ASSIGNED' + AND d.active = true + ); + +-- ================================================================ +-- Step 5: 검증 +-- ================================================================ +DO $$ +DECLARE + current_assigned_count INTEGER; + backup_assigned_count INTEGER; +BEGIN + SELECT COUNT(*) INTO current_assigned_count + FROM dispatch + WHERE status = 'ASSIGNED' AND active = true; + + SELECT COUNT(*) INTO backup_assigned_count + FROM dispatch_backup_20260215; + + RAISE NOTICE '========================================'; + RAISE NOTICE 'Rollback validation:'; + RAISE NOTICE 'Current ASSIGNED dispatches: %', current_assigned_count; + RAISE NOTICE 'Backup ASSIGNED dispatches: %', backup_assigned_count; + + IF current_assigned_count = backup_assigned_count THEN + RAISE NOTICE '✓ Data restored successfully'; + ELSE + RAISE WARNING 'Data count mismatch. Please verify manually.'; + END IF; + RAISE NOTICE '========================================'; +END $$; + +COMMIT; + +-- ================================================================ +-- 롤백 완료 메시지 +-- ================================================================ +DO $$ +BEGIN + RAISE NOTICE '========================================'; + RAISE NOTICE '✓ Rollback completed'; + RAISE NOTICE '⚠️ WARNING: Duplicate ASSIGNED dispatches are now restored'; + RAISE NOTICE '========================================'; + RAISE NOTICE 'Next steps:'; + RAISE NOTICE '1. Verify application behavior'; + RAISE NOTICE '2. Investigate root cause of migration issues'; + RAISE NOTICE '3. Plan re-migration strategy'; + RAISE NOTICE '========================================'; +END $$; diff --git a/db-migrations/README.md b/db-migrations/README.md new file mode 100644 index 0000000..26cd5c2 --- /dev/null +++ b/db-migrations/README.md @@ -0,0 +1,273 @@ +# Database Migrations + +이 디렉토리는 수동으로 실행할 데이터베이스 마이그레이션 스크립트를 포함합니다. + +## 📁 파일 목록 + +| 파일 | 설명 | 실행 순서 | +|------|------|----------| +| `20260215_pre_migration_check.sql` | 마이그레이션 전 데이터 상태 확인 (읽기 전용) | 1️⃣ 필수 | +| `20260215_fix_duplicate_assigned_dispatches.sql` | 중복 배차 정리 + UNIQUE INDEX 생성 | 2️⃣ 필수 | +| `20260215_rollback_duplicate_fix.sql` | 마이그레이션 롤백 스크립트 | 3️⃣ 선택 (문제 발생 시) | + +--- + +## 🚀 실행 가이드 + +### Step 1: 사전 체크 (필수) + +마이그레이션 실행 전에 **반드시** 사전 체크를 실행하세요. + +```bash +# Docker 환경 +docker exec -i mobility-api-postgres psql -U user -d mobilitydb < db-migrations/20260215_pre_migration_check.sql + +# 로컬 PostgreSQL +psql -U user -d mobilitydb -f db-migrations/20260215_pre_migration_check.sql +``` + +**확인 사항**: +- 중복 배차를 가진 기사 수 +- 취소될 배차 수 (excess) +- 기사 상태 불일치 여부 + +### Step 2: 마이그레이션 실행 + +사전 체크 결과를 확인한 후 마이그레이션을 실행하세요. + +```bash +# Docker 환경 +docker exec -i mobility-api-postgres psql -U user -d mobilitydb < db-migrations/20260215_fix_duplicate_assigned_dispatches.sql + +# 로컬 PostgreSQL +psql -U user -d mobilitydb -f db-migrations/20260215_fix_duplicate_assigned_dispatches.sql +``` + +**실행 내용**: +1. 백업 테이블 생성 (`dispatch_backup_20260215`) +2. 중복 배차 정리 (최신 배차만 유지) +3. 기사 상태 동기화 +4. UNIQUE INDEX 생성 (`idx_unique_assigned_transporter`) + +### Step 3: 검증 + +마이그레이션 후 데이터를 검증하세요. + +```sql +-- 중복 배차가 남아있는지 확인 +SELECT transporter_id, COUNT(*) +FROM dispatch +WHERE status = 'ASSIGNED' AND active = true AND transporter_id IS NOT NULL +GROUP BY transporter_id +HAVING COUNT(*) > 1; +-- 결과: 0건이어야 함 + +-- UNIQUE INDEX 생성 확인 +SELECT indexname, indexdef +FROM pg_indexes +WHERE indexname = 'idx_unique_assigned_transporter'; + +-- 기사 상태 일관성 확인 +SELECT t.dispatch_status, COUNT(*) +FROM transporters t +LEFT JOIN dispatch d ON t.transporter_id = d.transporter_id + AND d.status = 'ASSIGNED' AND d.active = true +GROUP BY t.dispatch_status, (d.dispatch_id IS NOT NULL); +``` + +### Step 4: 애플리케이션 배포 + +코드 변경사항을 배포하세요. + +```bash +# 빌드 +./gradlew clean build + +# 재시작 (Docker Compose) +docker-compose down +docker-compose up -d + +# 로그 확인 +docker-compose logs -f api +``` + +--- + +## 🔙 롤백 (문제 발생 시) + +마이그레이션 후 문제가 발생한 경우에만 실행하세요. + +```bash +# Docker 환경 +docker exec -i mobility-api-postgres psql -U user -d mobilitydb < db-migrations/20260215_rollback_duplicate_fix.sql + +# 로컬 PostgreSQL +psql -U user -d mobilitydb -f db-migrations/20260215_rollback_duplicate_fix.sql +``` + +**⚠️ 주의**: 롤백 시 중복 데이터가 다시 복원됩니다. + +--- + +## 📊 마이그레이션 상세 + +### 중복 배차 정리 전략 + +**기본 전략**: 가장 최근 배차만 유지, 나머지 취소 + +```sql +-- 기사별로 assigned_at 기준 내림차순 정렬 +-- ROW_NUMBER = 1: 유지 (가장 최근) +-- ROW_NUMBER > 1: 취소 +``` + +**대안 전략**: + +스크립트를 수정하여 다른 전략을 사용할 수 있습니다: + +```sql +-- 옵션 A: 가장 오래된 배차 유지 +ORDER BY assigned_at ASC, id ASC + +-- 옵션 B: 가장 큰 요금 유지 +ORDER BY charge DESC, assigned_at DESC + +-- 옵션 C: 특정 배차 ID 수동 지정 +WHERE id IN (100, 200, 300) -- 취소할 배차 ID +``` + +### UNIQUE INDEX 상세 + +```sql +CREATE UNIQUE INDEX idx_unique_assigned_transporter +ON dispatch (transporter_id) +WHERE status = 'ASSIGNED' AND active = true; +``` + +**특징**: +- **부분 인덱스 (Partial Index)**: `status = 'ASSIGNED' AND active = true` 조건만 적용 +- **저장 공간 효율**: 전체 배차가 아닌 ASSIGNED 상태만 인덱싱 +- **성능**: 해당 조건 검색 시 빠른 조회 + +**효과**: +- 한 기사는 ASSIGNED 상태 배차를 **하나만** 가질 수 있음 +- 중복 INSERT 시도 시 PostgreSQL 에러 발생 +- 애플리케이션에서 적절히 에러 처리 필요 + +--- + +## 🧪 테스트 시나리오 + +### 1. 중복 배차 방지 테스트 + +```sql +-- 기사 1번에게 배차 할당 +UPDATE dispatch SET transporter_id = 1, status = 'ASSIGNED' WHERE dispatch_id = 100; + +-- 같은 기사에게 또 다른 배차 할당 시도 (실패해야 함) +UPDATE dispatch SET transporter_id = 1, status = 'ASSIGNED' WHERE dispatch_id = 200; +-- ERROR: duplicate key value violates unique constraint "idx_unique_assigned_transporter" +``` + +### 2. 정상적인 배차 흐름 테스트 + +```sql +-- 1. 기사 1번에게 배차 할당 +UPDATE dispatch SET transporter_id = 1, status = 'ASSIGNED' WHERE dispatch_id = 100; + +-- 2. 배차 완료 +UPDATE dispatch SET status = 'COMPLETED' WHERE dispatch_id = 100; + +-- 3. 새로운 배차 할당 (성공해야 함) +UPDATE dispatch SET transporter_id = 1, status = 'ASSIGNED' WHERE dispatch_id = 200; +``` + +--- + +## 📋 체크리스트 + +마이그레이션 실행 전: +- [ ] 프로덕션 데이터베이스 백업 완료 +- [ ] `20260215_pre_migration_check.sql` 실행 완료 +- [ ] 중복 배차 데이터 검토 완료 +- [ ] 영업팀 및 기사에게 점검 시간 공지 +- [ ] 애플리케이션 코드 변경사항 준비 완료 + +마이그레이션 실행 후: +- [ ] 중복 데이터 제거 확인 (0건) +- [ ] UNIQUE INDEX 생성 확인 +- [ ] 기사 상태 일관성 확인 +- [ ] 애플리케이션 재시작 +- [ ] API 동작 테스트 (`/api/v1/transporter/current-dispatch`) +- [ ] 새로운 배차 할당 테스트 +- [ ] 로그에서 `TRANSPORTER_ALREADY_DISPATCHED` 에러 모니터링 + +1주일 후: +- [ ] 백업 테이블 삭제 (`DROP TABLE dispatch_backup_20260215;`) + +--- + +## 🛠 트러블슈팅 + +### Q1. "duplicate key value" 에러 발생 시 + +**원인**: UNIQUE INDEX 생성 전에 중복 데이터가 제거되지 않음 + +**해결**: +```sql +-- Step 3를 다시 실행하여 중복 제거 +-- 그 후 Step 6의 INDEX 생성 재시도 +``` + +### Q2. 마이그레이션 실행 중 "Migration validation failed" 에러 + +**원인**: 중복 데이터가 완전히 제거되지 않음 + +**해결**: +```sql +-- 수동으로 중복 확인 +SELECT transporter_id, COUNT(*) +FROM dispatch +WHERE status = 'ASSIGNED' AND active = true AND transporter_id IS NOT NULL +GROUP BY transporter_id +HAVING COUNT(*) > 1; + +-- 해당 레코드 수동 처리 +``` + +### Q3. 롤백 후 애플리케이션 에러 계속 발생 + +**원인**: 코드는 이미 변경되었으나 DB는 롤백됨 + +**해결**: +1. 코드를 이전 버전으로 롤백 +2. 또는 마이그레이션을 다시 실행 + +### Q4. 백업 테이블이 너무 큰 경우 + +**확인**: +```sql +SELECT pg_size_pretty(pg_total_relation_size('dispatch_backup_20260215')); +``` + +**삭제**: +```sql +-- 1주일 후 안전하게 삭제 +DROP TABLE IF EXISTS dispatch_backup_20260215; +``` + +--- + +## 📞 지원 + +문제 발생 시: +1. 로그 확인: `/var/log/postgresql/`, `docker-compose logs -f postgres` +2. 백업 테이블 확인: `SELECT * FROM dispatch_backup_20260215 LIMIT 10;` +3. GitHub Issue 생성: [프로젝트 이슈 링크] + +--- + +## 📚 관련 문서 + +- [CONCURRENT_DISPATCH_ISSUE.md](../CONCURRENT_DISPATCH_ISSUE.md) - 문제 분석 및 해결 방안 +- [CLAUDE.md](../CLAUDE.md) - 프로젝트 아키텍처 및 데이터베이스 구조 diff --git a/src/main/java/com/mobility/api/domain/dispatch/repository/DispatchRepository.java b/src/main/java/com/mobility/api/domain/dispatch/repository/DispatchRepository.java index 568734a..8da141d 100644 --- a/src/main/java/com/mobility/api/domain/dispatch/repository/DispatchRepository.java +++ b/src/main/java/com/mobility/api/domain/dispatch/repository/DispatchRepository.java @@ -82,4 +82,17 @@ List findDispatchesByDistance( * @return 배차 정보 */ Optional findByTransporterIdAndStatus(Long transporterId, StatusType status); + + /** + * 특정 기사의 특정 상태 배차 조회 (최신순) + * 여러 건이 있을 경우 가장 최근에 할당된 배차 반환 + * @param transporterId 기사 ID + * @param status 배차 상태 + * @return 가장 최근 배차 정보 + */ + @Query("SELECT d FROM Dispatch d WHERE d.transporter.id = :transporterId AND d.status = :status ORDER BY d.assignedAt DESC LIMIT 1") + Optional findFirstByTransporterIdAndStatusOrderByAssignedAtDesc( + @Param("transporterId") Long transporterId, + @Param("status") StatusType status + ); } diff --git a/src/main/java/com/mobility/api/domain/dispatch/service/DispatcherService.java b/src/main/java/com/mobility/api/domain/dispatch/service/DispatcherService.java index 907d05a..78f3feb 100644 --- a/src/main/java/com/mobility/api/domain/dispatch/service/DispatcherService.java +++ b/src/main/java/com/mobility/api/domain/dispatch/service/DispatcherService.java @@ -36,18 +36,23 @@ public class DispatcherService { @Transactional public DispatchAssignCompleteRes assignDispatch(Long dispatchId, Long transporterId) { - // 1. 기사 정보 조회 - Transporter transporter = transporterRepository.findById(transporterId) + // 1. 기사 정보 조회 (비관적 락) + Transporter transporter = transporterRepository.findByIdWithPessimisticLock(transporterId) .orElseThrow(() -> new GlobalException(ResultCode.NOT_FOUND_USER)); - // 2. 배차 정보 조회 -> DB 로우에 락이 걸림 + // 2. 이미 배차중인 기사인지 체크 + if (transporter.getDispatchStatus() == DispatchStatus.DISPATCH) { + throw new GlobalException(ResultCode.TRANSPORTER_ALREADY_DISPATCHED); + } + + // 3. 배차 정보 조회 (비관적 락) Dispatch dispatch = dispatchRepository.findByIdWithPessimisticLock(dispatchId) .orElseThrow(() -> new GlobalException(ResultCode.NOT_FOUND_DISPATCH)); - // 3. 배차 할당 + // 4. 배차 할당 dispatch.assignDispatch(transporter); - // 4. 기사의 배차 상태를 DISPATCH로 변경 (배차중인 오더가 있음) + // 5. 기사의 배차 상태를 DISPATCH로 변경 (배차중인 오더가 있음) transporter.changeDispatchStatus(DispatchStatus.DISPATCH); return DispatchAssignCompleteRes.from(dispatch); @@ -178,8 +183,8 @@ public CurrentDispatchDetailRes getCurrentDispatch(Long transporterId) { throw new GlobalException(ResultCode.DISPATCH_NOT_ASSIGNED); } - // 3. 기사에게 ASSIGNED 상태로 배차된 오더 조회 - Dispatch dispatch = dispatchRepository.findByTransporterIdAndStatus(transporterId, StatusType.ASSIGNED) + // 3. 기사에게 ASSIGNED 상태로 배차된 오더 조회 (최신순) + Dispatch dispatch = dispatchRepository.findFirstByTransporterIdAndStatusOrderByAssignedAtDesc(transporterId, StatusType.ASSIGNED) .orElseThrow(() -> new GlobalException(ResultCode.DISPATCH_NOT_ASSIGNED)); // 4. DTO 변환 및 반환 diff --git a/src/main/java/com/mobility/api/domain/transporter/repository/TransporterRepository.java b/src/main/java/com/mobility/api/domain/transporter/repository/TransporterRepository.java index 869e29b..dfd37c1 100644 --- a/src/main/java/com/mobility/api/domain/transporter/repository/TransporterRepository.java +++ b/src/main/java/com/mobility/api/domain/transporter/repository/TransporterRepository.java @@ -4,10 +4,14 @@ import com.mobility.api.domain.transporter.TransporterStatus; import com.mobility.api.domain.transporter.dto.TransporterDistanceProjection; import com.mobility.api.domain.transporter.entity.Transporter; +import jakarta.persistence.LockModeType; +import jakarta.persistence.QueryHint; import org.springframework.data.domain.Page; import org.springframework.data.domain.Pageable; import org.springframework.data.jpa.repository.JpaRepository; +import org.springframework.data.jpa.repository.Lock; import org.springframework.data.jpa.repository.Query; +import org.springframework.data.jpa.repository.QueryHints; import org.springframework.data.repository.query.Param; import java.util.List; @@ -94,4 +98,15 @@ boolean existsEligibleDriversWithinRadius( // 2. 상태 필터 적용 조회 (페이징) Page findAllByOfficeAndStatus(Office office, TransporterStatus status, Pageable pageable); + /** + * 비관적 락을 사용한 기사 조회 (동시성 제어) + * 배차 할당 시 동시에 여러 배차가 같은 기사에게 할당되는 것을 방지 + * @param transporterId 기사 ID + * @return 기사 정보 + */ + @Lock(LockModeType.PESSIMISTIC_WRITE) + @QueryHints({@QueryHint(name = "jakarta.persistence.lock.timeout", value = "3000")}) + @Query("SELECT t FROM Transporter t WHERE t.id = :transporterId") + Optional findByIdWithPessimisticLock(@Param("transporterId") Long transporterId); + }