diff --git a/src/main/java/com/gpt/geumpumtabackend/statistics/repository/StatisticsRepository.java b/src/main/java/com/gpt/geumpumtabackend/statistics/repository/StatisticsRepository.java index db2bbbf..fa11b4c 100644 --- a/src/main/java/com/gpt/geumpumtabackend/statistics/repository/StatisticsRepository.java +++ b/src/main/java/com/gpt/geumpumtabackend/statistics/repository/StatisticsRepository.java @@ -156,97 +156,117 @@ WeeklyStatistics getWeeklyStatistics( ); @Query(value = """ - WITH RECURSIVE - bounds AS ( - SELECT - :monthStart AS start_at, - DATE_ADD(LAST_DAY(:monthStart), INTERVAL 1 DAY) AS end_at, - TIMESTAMPDIFF( - DAY, :monthStart, - DATE_ADD(LAST_DAY(:monthStart), INTERVAL 1 DAY) - ) AS days_cnt - ), - /* 월 전체 일자를 day_idx=0..(days_cnt-1)로 생성 */ - days AS ( - SELECT - 0 AS day_idx, - b.start_at AS day_start, - LEAST(DATE_ADD(b.start_at, INTERVAL 1 DAY), b.end_at) AS day_end - FROM bounds b - UNION ALL - SELECT - d.day_idx + 1, - DATE_ADD(d.day_start, INTERVAL 1 DAY), - LEAST(DATE_ADD(d.day_start, INTERVAL 2 DAY), b.end_at) - FROM days d - JOIN bounds b - ON d.day_end < b.end_at - ), - /* 일자별 공부 총합(ms) */ - per_day AS ( - SELECT - d.day_idx, - CAST( - COALESCE( - SUM( - GREATEST( - 0, - TIMESTAMPDIFF( - MICROSECOND, - GREATEST(s.start_time, d.day_start), - LEAST(COALESCE(s.end_time, d.day_end), d.day_end) - ) / 1000 - ) - ), 0 - ) AS SIGNED - ) AS day_millis - FROM days d - LEFT JOIN study_session s - ON s.user_id = :userId - AND s.start_time < d.day_end - AND s.end_time > d.day_start - GROUP BY d.day_idx - ), - flags AS ( - SELECT - day_idx, - day_millis, - CASE WHEN day_millis > 0 THEN 1 ELSE 0 END AS has_study - FROM per_day - ), - breaks AS ( - /* 0(공부 안 한 날)을 경계로 그룹을 나눠 연속 구간 식별 */ - SELECT - day_idx, - day_millis, - has_study, - SUM(CASE WHEN has_study = 0 THEN 1 ELSE 0 END) - OVER (ORDER BY day_idx) AS zero_grp - FROM flags - ), - streaks AS ( - SELECT zero_grp, COUNT(*) AS streak_len - FROM breaks - WHERE has_study = 1 - GROUP BY zero_grp - ) - SELECT - /* 총 공부시간(ms) */ - CAST(COALESCE((SELECT SUM(day_millis) FROM per_day), 0) AS SIGNED) AS totalMonthMillis, - /* 월 일수로 나눈 일일 평균(ms; 소수 버림) */ - CAST( (COALESCE((SELECT SUM(day_millis) FROM per_day), 0) - / NULLIF((SELECT days_cnt FROM bounds), 0)) AS SIGNED) AS averageDailyMillis, - /* 최장 연속 공부 일수 */ - COALESCE((SELECT MAX(streak_len) FROM streaks), 0) AS maxConsecutiveStudyDays, - /* 이번 달 공부 일수(>0ms) */ - (SELECT COUNT(*) FROM per_day WHERE day_millis > 0) AS studiedDays - """, nativeQuery = true) + WITH RECURSIVE + bounds AS ( + SELECT + :monthStart AS start_at, + DATE_ADD(LAST_DAY(:monthStart), INTERVAL 1 DAY) AS end_at, + TIMESTAMPDIFF( + DAY, :monthStart, + DATE_ADD(LAST_DAY(:monthStart), INTERVAL 1 DAY) + ) AS days_cnt + ), + + /* (개선) 이번 달과 겹치는 "완료된" 세션만 먼저 선필터링 */ + filtered_sessions AS ( + SELECT s.user_id, s.start_time, s.end_time + FROM study_session s + JOIN bounds b + ON s.user_id = :userId + AND s.end_time IS NOT NULL /* 진행 중 세션 제외 (의도 유지) */ + AND s.start_time < b.end_at /* 달 끝보다 먼저 시작 */ + AND s.end_time > b.start_at /* 달 시작보다 나중에 끝 */ + ), + + /* 월 전체 일자를 day_idx=0..(days_cnt-1)로 생성 */ + days AS ( + SELECT + 0 AS day_idx, + b.start_at AS day_start, + LEAST(DATE_ADD(b.start_at, INTERVAL 1 DAY), b.end_at) AS day_end + FROM bounds b + UNION ALL + SELECT + d.day_idx + 1, + DATE_ADD(d.day_start, INTERVAL 1 DAY), + LEAST(DATE_ADD(d.day_start, INTERVAL 2 DAY), b.end_at) + FROM days d + JOIN bounds b + ON d.day_end < b.end_at + ), + + /* 일자별 공부 총합(ms) */ + per_day AS ( + SELECT + d.day_idx, + CAST( + COALESCE( + SUM( + GREATEST( + 0, + TIMESTAMPDIFF( + MICROSECOND, + GREATEST(s.start_time, d.day_start), + LEAST(s.end_time, d.day_end) + ) / 1000 + ) + ), 0 + ) AS SIGNED + ) AS day_millis + FROM days d + LEFT JOIN filtered_sessions s + ON s.start_time < d.day_end + AND s.end_time > d.day_start + GROUP BY d.day_idx + ), + + flags AS ( + SELECT + day_idx, + day_millis, + CASE WHEN day_millis > 0 THEN 1 ELSE 0 END AS has_study + FROM per_day + ), + + breaks AS ( + /* 0(공부 안 한 날)을 경계로 그룹을 나눠 연속 구간 식별 */ + SELECT + day_idx, + day_millis, + has_study, + SUM(CASE WHEN has_study = 0 THEN 1 ELSE 0 END) + OVER (ORDER BY day_idx) AS zero_grp + FROM flags + ), + + streaks AS ( + SELECT zero_grp, COUNT(*) AS streak_len + FROM breaks + WHERE has_study = 1 + GROUP BY zero_grp + ) + + SELECT + /* 총 공부시간(ms) */ + CAST(COALESCE((SELECT SUM(day_millis) FROM per_day), 0) AS SIGNED) AS totalMonthMillis, + + /* 월 일수로 나눈 일일 평균(ms; 소수 버림) */ + CAST( (COALESCE((SELECT SUM(day_millis) FROM per_day), 0) + / NULLIF((SELECT days_cnt FROM bounds), 0)) AS SIGNED) AS averageDailyMillis, + + /* 최장 연속 공부 일수 */ + COALESCE((SELECT MAX(streak_len) FROM streaks), 0) AS maxConsecutiveStudyDays, + + /* 이번 달 공부 일수(>0ms) */ + (SELECT COUNT(*) FROM per_day WHERE day_millis > 0) AS studiedDays + """, nativeQuery = true) MonthlyStatistics getMonthlyStatistics( @Param("monthStart") LocalDateTime monthStart, // 해당 월 1일 00:00 @Param("userId") Long userId ); + @Query(value = """ WITH RECURSIVE bounds AS (