/** * 차량 운행 리포트 서비스 */ import { getPool } from "../database/db"; interface DailyReportFilters { startDate?: string; endDate?: string; userId?: string; vehicleId?: number; } interface WeeklyReportFilters { year: number; month: number; userId?: string; vehicleId?: number; } interface MonthlyReportFilters { year: number; userId?: string; vehicleId?: number; } interface DriverReportFilters { startDate?: string; endDate?: string; limit?: number; } interface RouteReportFilters { startDate?: string; endDate?: string; limit?: number; } class VehicleReportService { private get pool() { return getPool(); } /** * 일별 통계 조회 */ async getDailyReport(companyCode: string, filters: DailyReportFilters) { const conditions: string[] = ["company_code = $1"]; const params: any[] = [companyCode]; let paramIndex = 2; // 기본값: 최근 30일 const endDate = filters.endDate || new Date().toISOString().split("T")[0]; const startDate = filters.startDate || new Date(Date.now() - 30 * 24 * 60 * 60 * 1000).toISOString().split("T")[0]; conditions.push(`DATE(start_time) >= $${paramIndex++}`); params.push(startDate); conditions.push(`DATE(start_time) <= $${paramIndex++}`); params.push(endDate); if (filters.userId) { conditions.push(`user_id = $${paramIndex++}`); params.push(filters.userId); } if (filters.vehicleId) { conditions.push(`vehicle_id = $${paramIndex++}`); params.push(filters.vehicleId); } const whereClause = conditions.join(" AND "); const query = ` SELECT DATE(start_time) as date, COUNT(*) as trip_count, COUNT(CASE WHEN status = 'completed' THEN 1 END) as completed_count, COUNT(CASE WHEN status = 'cancelled' THEN 1 END) as cancelled_count, COALESCE(SUM(CASE WHEN status = 'completed' THEN total_distance ELSE 0 END), 0) as total_distance, COALESCE(SUM(CASE WHEN status = 'completed' THEN duration_minutes ELSE 0 END), 0) as total_duration, COALESCE(AVG(CASE WHEN status = 'completed' THEN total_distance END), 0) as avg_distance, COALESCE(AVG(CASE WHEN status = 'completed' THEN duration_minutes END), 0) as avg_duration FROM vehicle_trip_summary WHERE ${whereClause} GROUP BY DATE(start_time) ORDER BY DATE(start_time) DESC `; const result = await this.pool.query(query, params); return { startDate, endDate, data: result.rows.map((row) => ({ date: row.date, tripCount: parseInt(row.trip_count), completedCount: parseInt(row.completed_count), cancelledCount: parseInt(row.cancelled_count), totalDistance: parseFloat(row.total_distance), totalDuration: parseInt(row.total_duration), avgDistance: parseFloat(row.avg_distance), avgDuration: parseFloat(row.avg_duration), })), }; } /** * 주별 통계 조회 */ async getWeeklyReport(companyCode: string, filters: WeeklyReportFilters) { const { year, month, userId, vehicleId } = filters; const conditions: string[] = ["company_code = $1"]; const params: any[] = [companyCode]; let paramIndex = 2; conditions.push(`EXTRACT(YEAR FROM start_time) = $${paramIndex++}`); params.push(year); conditions.push(`EXTRACT(MONTH FROM start_time) = $${paramIndex++}`); params.push(month); if (userId) { conditions.push(`user_id = $${paramIndex++}`); params.push(userId); } if (vehicleId) { conditions.push(`vehicle_id = $${paramIndex++}`); params.push(vehicleId); } const whereClause = conditions.join(" AND "); const query = ` SELECT EXTRACT(WEEK FROM start_time) as week_number, MIN(DATE(start_time)) as week_start, MAX(DATE(start_time)) as week_end, COUNT(*) as trip_count, COUNT(CASE WHEN status = 'completed' THEN 1 END) as completed_count, COALESCE(SUM(CASE WHEN status = 'completed' THEN total_distance ELSE 0 END), 0) as total_distance, COALESCE(SUM(CASE WHEN status = 'completed' THEN duration_minutes ELSE 0 END), 0) as total_duration, COALESCE(AVG(CASE WHEN status = 'completed' THEN total_distance END), 0) as avg_distance FROM vehicle_trip_summary WHERE ${whereClause} GROUP BY EXTRACT(WEEK FROM start_time) ORDER BY week_number `; const result = await this.pool.query(query, params); return { year, month, data: result.rows.map((row) => ({ weekNumber: parseInt(row.week_number), weekStart: row.week_start, weekEnd: row.week_end, tripCount: parseInt(row.trip_count), completedCount: parseInt(row.completed_count), totalDistance: parseFloat(row.total_distance), totalDuration: parseInt(row.total_duration), avgDistance: parseFloat(row.avg_distance), })), }; } /** * 월별 통계 조회 */ async getMonthlyReport(companyCode: string, filters: MonthlyReportFilters) { const { year, userId, vehicleId } = filters; const conditions: string[] = ["company_code = $1"]; const params: any[] = [companyCode]; let paramIndex = 2; conditions.push(`EXTRACT(YEAR FROM start_time) = $${paramIndex++}`); params.push(year); if (userId) { conditions.push(`user_id = $${paramIndex++}`); params.push(userId); } if (vehicleId) { conditions.push(`vehicle_id = $${paramIndex++}`); params.push(vehicleId); } const whereClause = conditions.join(" AND "); const query = ` SELECT EXTRACT(MONTH FROM start_time) as month, COUNT(*) as trip_count, COUNT(CASE WHEN status = 'completed' THEN 1 END) as completed_count, COUNT(CASE WHEN status = 'cancelled' THEN 1 END) as cancelled_count, COALESCE(SUM(CASE WHEN status = 'completed' THEN total_distance ELSE 0 END), 0) as total_distance, COALESCE(SUM(CASE WHEN status = 'completed' THEN duration_minutes ELSE 0 END), 0) as total_duration, COALESCE(AVG(CASE WHEN status = 'completed' THEN total_distance END), 0) as avg_distance, COALESCE(AVG(CASE WHEN status = 'completed' THEN duration_minutes END), 0) as avg_duration, COUNT(DISTINCT user_id) as driver_count FROM vehicle_trip_summary WHERE ${whereClause} GROUP BY EXTRACT(MONTH FROM start_time) ORDER BY month `; const result = await this.pool.query(query, params); return { year, data: result.rows.map((row) => ({ month: parseInt(row.month), tripCount: parseInt(row.trip_count), completedCount: parseInt(row.completed_count), cancelledCount: parseInt(row.cancelled_count), totalDistance: parseFloat(row.total_distance), totalDuration: parseInt(row.total_duration), avgDistance: parseFloat(row.avg_distance), avgDuration: parseFloat(row.avg_duration), driverCount: parseInt(row.driver_count), })), }; } /** * 요약 통계 조회 (대시보드용) */ async getSummaryReport(companyCode: string, period: string) { let dateCondition = ""; switch (period) { case "today": dateCondition = "DATE(start_time) = CURRENT_DATE"; break; case "week": dateCondition = "start_time >= CURRENT_DATE - INTERVAL '7 days'"; break; case "month": dateCondition = "start_time >= CURRENT_DATE - INTERVAL '30 days'"; break; case "year": dateCondition = "EXTRACT(YEAR FROM start_time) = EXTRACT(YEAR FROM CURRENT_DATE)"; break; default: dateCondition = "DATE(start_time) = CURRENT_DATE"; } const query = ` SELECT COUNT(*) as total_trips, COUNT(CASE WHEN status = 'completed' THEN 1 END) as completed_trips, COUNT(CASE WHEN status = 'active' THEN 1 END) as active_trips, COUNT(CASE WHEN status = 'cancelled' THEN 1 END) as cancelled_trips, COALESCE(SUM(CASE WHEN status = 'completed' THEN total_distance ELSE 0 END), 0) as total_distance, COALESCE(SUM(CASE WHEN status = 'completed' THEN duration_minutes ELSE 0 END), 0) as total_duration, COALESCE(AVG(CASE WHEN status = 'completed' THEN total_distance END), 0) as avg_distance, COALESCE(AVG(CASE WHEN status = 'completed' THEN duration_minutes END), 0) as avg_duration, COUNT(DISTINCT user_id) as active_drivers FROM vehicle_trip_summary WHERE company_code = $1 AND ${dateCondition} `; const result = await this.pool.query(query, [companyCode]); const row = result.rows[0]; // 완료율 계산 const totalTrips = parseInt(row.total_trips) || 0; const completedTrips = parseInt(row.completed_trips) || 0; const completionRate = totalTrips > 0 ? (completedTrips / totalTrips) * 100 : 0; return { period, totalTrips, completedTrips, activeTrips: parseInt(row.active_trips) || 0, cancelledTrips: parseInt(row.cancelled_trips) || 0, completionRate: parseFloat(completionRate.toFixed(1)), totalDistance: parseFloat(row.total_distance) || 0, totalDuration: parseInt(row.total_duration) || 0, avgDistance: parseFloat(row.avg_distance) || 0, avgDuration: parseFloat(row.avg_duration) || 0, activeDrivers: parseInt(row.active_drivers) || 0, }; } /** * 운전자별 통계 조회 */ async getDriverReport(companyCode: string, filters: DriverReportFilters) { const conditions: string[] = ["vts.company_code = $1"]; const params: any[] = [companyCode]; let paramIndex = 2; if (filters.startDate) { conditions.push(`DATE(vts.start_time) >= $${paramIndex++}`); params.push(filters.startDate); } if (filters.endDate) { conditions.push(`DATE(vts.start_time) <= $${paramIndex++}`); params.push(filters.endDate); } const whereClause = conditions.join(" AND "); const limit = filters.limit || 10; const query = ` SELECT vts.user_id, ui.user_name, COUNT(*) as trip_count, COUNT(CASE WHEN vts.status = 'completed' THEN 1 END) as completed_count, COALESCE(SUM(CASE WHEN vts.status = 'completed' THEN vts.total_distance ELSE 0 END), 0) as total_distance, COALESCE(SUM(CASE WHEN vts.status = 'completed' THEN vts.duration_minutes ELSE 0 END), 0) as total_duration, COALESCE(AVG(CASE WHEN vts.status = 'completed' THEN vts.total_distance END), 0) as avg_distance FROM vehicle_trip_summary vts LEFT JOIN user_info ui ON vts.user_id = ui.user_id WHERE ${whereClause} GROUP BY vts.user_id, ui.user_name ORDER BY total_distance DESC LIMIT $${paramIndex} `; params.push(limit); const result = await this.pool.query(query, params); return result.rows.map((row) => ({ userId: row.user_id, userName: row.user_name || row.user_id, tripCount: parseInt(row.trip_count), completedCount: parseInt(row.completed_count), totalDistance: parseFloat(row.total_distance), totalDuration: parseInt(row.total_duration), avgDistance: parseFloat(row.avg_distance), })); } /** * 구간별 통계 조회 */ async getRouteReport(companyCode: string, filters: RouteReportFilters) { const conditions: string[] = ["company_code = $1"]; const params: any[] = [companyCode]; let paramIndex = 2; if (filters.startDate) { conditions.push(`DATE(start_time) >= $${paramIndex++}`); params.push(filters.startDate); } if (filters.endDate) { conditions.push(`DATE(start_time) <= $${paramIndex++}`); params.push(filters.endDate); } // 출발지/도착지가 있는 것만 conditions.push("departure IS NOT NULL"); conditions.push("arrival IS NOT NULL"); const whereClause = conditions.join(" AND "); const limit = filters.limit || 10; const query = ` SELECT departure, arrival, departure_name, destination_name, COUNT(*) as trip_count, COUNT(CASE WHEN status = 'completed' THEN 1 END) as completed_count, COALESCE(SUM(CASE WHEN status = 'completed' THEN total_distance ELSE 0 END), 0) as total_distance, COALESCE(AVG(CASE WHEN status = 'completed' THEN total_distance END), 0) as avg_distance, COALESCE(AVG(CASE WHEN status = 'completed' THEN duration_minutes END), 0) as avg_duration FROM vehicle_trip_summary WHERE ${whereClause} GROUP BY departure, arrival, departure_name, destination_name ORDER BY trip_count DESC LIMIT $${paramIndex} `; params.push(limit); const result = await this.pool.query(query, params); return result.rows.map((row) => ({ departure: row.departure, arrival: row.arrival, departureName: row.departure_name || row.departure, destinationName: row.destination_name || row.arrival, tripCount: parseInt(row.trip_count), completedCount: parseInt(row.completed_count), totalDistance: parseFloat(row.total_distance), avgDistance: parseFloat(row.avg_distance), avgDuration: parseFloat(row.avg_duration), })); } } export const vehicleReportService = new VehicleReportService();