|
1 | 1 | import { Pool } from 'pg'; |
| 2 | +import logger from '@/configs/logger.config'; |
| 3 | +import { DBError } from '@/exception'; |
2 | 4 |
|
3 | 5 | export class LeaderboardRepository { |
4 | 6 | constructor(private pool: Pool) {} |
| 7 | + |
| 8 | + async getLeaderboard(type: string, sort: string, dateRange: number, limit: number) { |
| 9 | + try { |
| 10 | + const cteQuery = this.buildLeaderboardCteQuery(); |
| 11 | + const selectQuery = this.buildLeaderboardSelectQuery(type); |
| 12 | + const fromClause = this.buildLeaderboardFromClause(type); |
| 13 | + const sortCol = this.mapSortColByType(sort, type); |
| 14 | + const groupOrderClause = this.buildLeaderboardGroupOrderClause(sortCol, type); |
| 15 | + |
| 16 | + const query = `${cteQuery} ${selectQuery} ${fromClause} ${groupOrderClause}`; |
| 17 | + const values = await this.pool.query(query, [dateRange, limit]); |
| 18 | + |
| 19 | + return values.rows; |
| 20 | + } catch (error) { |
| 21 | + logger.error(`Leaderboard Repo getLeaderboard error:`, error); |
| 22 | + throw new DBError(`${type === 'user' ? '유저' : '게시글'} 리더보드 조회 중 문제가 발생했습니다.`); |
| 23 | + } |
| 24 | + } |
| 25 | + |
| 26 | + // 오늘 날짜와 기준 날짜의 통계를 가져오는 CTE(임시 결과 집합) 쿼리 빌드 |
| 27 | + private buildLeaderboardCteQuery() { |
| 28 | + return ` |
| 29 | + WITH today_stats AS ( |
| 30 | + SELECT DISTINCT ON (post_id) |
| 31 | + post_id, |
| 32 | + daily_view_count AS today_view, |
| 33 | + daily_like_count AS today_like |
| 34 | + FROM posts_postdailystatistics |
| 35 | + WHERE (date AT TIME ZONE 'Asia/Seoul' AT TIME ZONE 'UTC')::date <= (NOW() AT TIME ZONE 'UTC')::date |
| 36 | + ORDER BY post_id, date DESC |
| 37 | + ), |
| 38 | + |
| 39 | + start_stats AS ( |
| 40 | + SELECT DISTINCT ON (post_id) |
| 41 | + post_id, |
| 42 | + daily_view_count AS start_view, |
| 43 | + daily_like_count AS start_like |
| 44 | + FROM posts_postdailystatistics |
| 45 | + WHERE (date AT TIME ZONE 'Asia/Seoul' AT TIME ZONE 'UTC')::date >= ((NOW() AT TIME ZONE 'UTC')::date - ($1::int * INTERVAL '1 day')) |
| 46 | + ORDER BY post_id, date ASC |
| 47 | + ) |
| 48 | + `; |
| 49 | + } |
| 50 | + |
| 51 | + // 메인 연산을 포함하는 SELECT 절 빌드 |
| 52 | + private buildLeaderboardSelectQuery(type: string) { |
| 53 | + if (type === 'post') { |
| 54 | + return ` |
| 55 | + SELECT |
| 56 | + p.id AS id, |
| 57 | + p.title, |
| 58 | + p.slug, |
| 59 | + p.released_at, |
| 60 | +
|
| 61 | + -- 총 누적 조회수 / 좋아요 수 (오늘 기준) |
| 62 | + COALESCE(ts.today_view, 0) AS total_views, |
| 63 | + COALESCE(ts.today_like, 0) AS total_likes, |
| 64 | +
|
| 65 | + -- 조회수 / 좋아요 수 상승값 = 오늘 - 기준일 (기준일이 없으면 diff = 0) |
| 66 | + COALESCE(ts.today_view, 0) - COALESCE(ss.start_view, COALESCE(ts.today_view, 0)) AS view_diff, |
| 67 | + COALESCE(ts.today_like, 0) - COALESCE(ss.start_like, COALESCE(ts.today_like, 0)) AS like_diff |
| 68 | + `; |
| 69 | + } else { |
| 70 | + return ` |
| 71 | + SELECT |
| 72 | + u.id AS id, |
| 73 | + u.email AS email, |
| 74 | +
|
| 75 | + -- 전체 게시물 누적 조회수 / 좋아요 수 합계 (오늘 기준) |
| 76 | + COALESCE(SUM(ts.today_view), 0) AS total_views, |
| 77 | + COALESCE(SUM(ts.today_like), 0) AS total_likes, |
| 78 | +
|
| 79 | + -- 전체 게시물 조회수 / 좋아요 수 상승값 합계 = 오늘 - 기준일 (기준일이 없으면 diff = 0) |
| 80 | + SUM( |
| 81 | + COALESCE(ts.today_view, 0) - COALESCE(ss.start_view, COALESCE(ts.today_view, 0)) |
| 82 | + ) AS view_diff, |
| 83 | + SUM( |
| 84 | + COALESCE(ts.today_like, 0) - COALESCE(ss.start_like, COALESCE(ts.today_like, 0)) |
| 85 | + ) AS like_diff, |
| 86 | +
|
| 87 | + -- 최근 dateRange내 업로드된 게시물 수 |
| 88 | + COUNT(DISTINCT CASE |
| 89 | + WHEN p.released_at >= CURRENT_DATE - $1::int |
| 90 | + AND p.is_active = true |
| 91 | + THEN p.id |
| 92 | + END) AS post_diff, |
| 93 | +
|
| 94 | + -- 전체 활성 게시물 수 |
| 95 | + COUNT(DISTINCT CASE WHEN p.is_active = true THEN p.id END) AS total_posts |
| 96 | + `; |
| 97 | + } |
| 98 | + } |
| 99 | + |
| 100 | + // CTE 테이블 조인 및 WHERE 절을 포함하는 FROM 절 빌드 |
| 101 | + private buildLeaderboardFromClause(type: string) { |
| 102 | + if (type === 'post') { |
| 103 | + return ` |
| 104 | + FROM posts_post p |
| 105 | + LEFT JOIN today_stats ts ON ts.post_id = p.id |
| 106 | + LEFT JOIN start_stats ss ON ss.post_id = p.id |
| 107 | + WHERE p.is_active = true |
| 108 | + `; |
| 109 | + } else { |
| 110 | + return ` |
| 111 | + FROM users_user u |
| 112 | + LEFT JOIN posts_post p ON p.user_id = u.id |
| 113 | + LEFT JOIN today_stats ts ON ts.post_id = p.id |
| 114 | + LEFT JOIN start_stats ss ON ss.post_id = p.id |
| 115 | + WHERE u.email IS NOT NULL |
| 116 | + `; |
| 117 | + } |
| 118 | + } |
| 119 | + |
| 120 | + // sort 매개변수를 정렬 컬럼으로 매핑 |
| 121 | + private mapSortColByType(sort: string, type: string) { |
| 122 | + let sortCol = ''; |
| 123 | + |
| 124 | + switch (sort) { |
| 125 | + case 'postCount': |
| 126 | + sortCol = type === 'user' ? 'post_diff' : 'view_diff'; |
| 127 | + break; |
| 128 | + case 'likeCount': |
| 129 | + sortCol = 'like_diff'; |
| 130 | + break; |
| 131 | + case 'viewCount': |
| 132 | + default: |
| 133 | + sortCol = 'view_diff'; |
| 134 | + break; |
| 135 | + } |
| 136 | + |
| 137 | + return sortCol; |
| 138 | + } |
| 139 | + |
| 140 | + // 매핑된 정렬 컬럼으로 ORDER BY 절 및 LIMIT 절 빌드 |
| 141 | + private buildLeaderboardGroupOrderClause(sortCol: string, type: string) { |
| 142 | + if (type === 'post') { |
| 143 | + return ` |
| 144 | + ORDER BY ${sortCol} DESC |
| 145 | + LIMIT $2; |
| 146 | + `; |
| 147 | + } else { |
| 148 | + return ` |
| 149 | + GROUP BY u.id |
| 150 | + ORDER BY ${sortCol} DESC |
| 151 | + LIMIT $2; |
| 152 | + `; |
| 153 | + } |
| 154 | + } |
5 | 155 | } |
0 commit comments