1
+ -- AlterTable
2
+ ALTER TABLE " ImageMetric" ADD COLUMN " commentCount" INTEGER NOT NULL DEFAULT 0 ;
3
+
4
+ -- Add Stats
5
+ DROP VIEW IF EXISTS " ImageStat" ;
6
+ CREATE VIEW "ImageStat " AS
7
+ WITH timeframe_stats AS (
8
+ SELECT
9
+ i .id AS " imageId" ,
10
+ COALESCE(mm." heartCount" , 0 ) AS " heartCount" ,
11
+ COALESCE(mm." likeCount" , 0 ) AS " likeCount" ,
12
+ COALESCE(mm." dislikeCount" , 0 ) AS " dislikeCount" ,
13
+ COALESCE(mm." laughCount" , 0 ) AS " laughCount" ,
14
+ COALESCE(mm." cryCount" , 0 ) AS " cryCount" ,
15
+ COALESCE(mm." commentCount" , 0 ) AS " commentCount" ,
16
+ tf .timeframe
17
+ FROM " Image" i
18
+ CROSS JOIN (
19
+ SELECT unnest(enum_range(NULL ::" MetricTimeframe" )) AS timeframe
20
+ ) tf
21
+ LEFT JOIN " ImageMetric" mm ON mm." imageId" = i .id AND mm .timeframe = tf .timeframe
22
+ )
23
+ SELECT
24
+ " imageId" ,
25
+ MAX (IIF(timeframe = ' Day' ::" MetricTimeframe" , " heartCount" , NULL ::integer )) AS " heartCountDay" ,
26
+ MAX (IIF(timeframe = ' Week' ::" MetricTimeframe" , " heartCount" , NULL ::integer )) AS " heartCountWeek" ,
27
+ MAX (IIF(timeframe = ' Month' ::" MetricTimeframe" , " heartCount" , NULL ::integer )) AS " heartCountMonth" ,
28
+ MAX (IIF(timeframe = ' Year' ::" MetricTimeframe" , " heartCount" , NULL ::integer )) AS " heartCountYear" ,
29
+ MAX (IIF(timeframe = ' AllTime' ::" MetricTimeframe" , " heartCount" , NULL ::integer )) AS " heartCountAllTime" ,
30
+ MAX (IIF(timeframe = ' Day' ::" MetricTimeframe" , " likeCount" , NULL ::integer )) AS " likeCountDay" ,
31
+ MAX (IIF(timeframe = ' Week' ::" MetricTimeframe" , " likeCount" , NULL ::integer )) AS " likeCountWeek" ,
32
+ MAX (IIF(timeframe = ' Month' ::" MetricTimeframe" , " likeCount" , NULL ::integer )) AS " likeCountMonth" ,
33
+ MAX (IIF(timeframe = ' Year' ::" MetricTimeframe" , " likeCount" , NULL ::integer )) AS " likeCountYear" ,
34
+ MAX (IIF(timeframe = ' AllTime' ::" MetricTimeframe" , " likeCount" , NULL ::integer )) AS " likeCountAllTime" ,
35
+ MAX (IIF(timeframe = ' Day' ::" MetricTimeframe" , " dislikeCount" , NULL ::integer )) AS " dislikeCountDay" ,
36
+ MAX (IIF(timeframe = ' Week' ::" MetricTimeframe" , " dislikeCount" , NULL ::integer )) AS " dislikeCountWeek" ,
37
+ MAX (IIF(timeframe = ' Month' ::" MetricTimeframe" , " dislikeCount" , NULL ::integer )) AS " dislikeCountMonth" ,
38
+ MAX (IIF(timeframe = ' Year' ::" MetricTimeframe" , " dislikeCount" , NULL ::integer )) AS " dislikeCountYear" ,
39
+ MAX (IIF(timeframe = ' AllTime' ::" MetricTimeframe" , " dislikeCount" , NULL ::integer )) AS " dislikeCountAllTime" ,
40
+ MAX (IIF(timeframe = ' Day' ::" MetricTimeframe" , " laughCount" , NULL ::integer )) AS " laughCountDay" ,
41
+ MAX (IIF(timeframe = ' Week' ::" MetricTimeframe" , " laughCount" , NULL ::integer )) AS " laughCountWeek" ,
42
+ MAX (IIF(timeframe = ' Month' ::" MetricTimeframe" , " laughCount" , NULL ::integer )) AS " laughCountMonth" ,
43
+ MAX (IIF(timeframe = ' Year' ::" MetricTimeframe" , " laughCount" , NULL ::integer )) AS " laughCountYear" ,
44
+ MAX (IIF(timeframe = ' AllTime' ::" MetricTimeframe" , " laughCount" , NULL ::integer )) AS " laughCountAllTime" ,
45
+ MAX (IIF(timeframe = ' Day' ::" MetricTimeframe" , " cryCount" , NULL ::integer )) AS " cryCountDay" ,
46
+ MAX (IIF(timeframe = ' Week' ::" MetricTimeframe" , " cryCount" , NULL ::integer )) AS " cryCountWeek" ,
47
+ MAX (IIF(timeframe = ' Month' ::" MetricTimeframe" , " cryCount" , NULL ::integer )) AS " cryCountMonth" ,
48
+ MAX (IIF(timeframe = ' Year' ::" MetricTimeframe" , " cryCount" , NULL ::integer )) AS " cryCountYear" ,
49
+ MAX (IIF(timeframe = ' AllTime' ::" MetricTimeframe" , " cryCount" , NULL ::integer )) AS " cryCountAllTime"
50
+ FROM timeframe_stats
51
+ GROUP BY " imageId" ;
52
+
53
+ -- Add Rank
54
+ CREATE MATERIALIZED VIEW " ImageRank" AS
55
+ WITH timeframe_stats AS (
56
+ SELECT
57
+ i .id AS " imageId" ,
58
+ COALESCE(im." heartCount" , 0 ) AS " heartCount" ,
59
+ COALESCE(im." likeCount" , 0 ) AS " likeCount" ,
60
+ COALESCE(im." dislikeCount" , 0 ) AS " dislikeCount" ,
61
+ COALESCE(im." laughCount" , 0 ) AS " laughCount" ,
62
+ COALESCE(im." cryCount" , 0 ) AS " cryCount" ,
63
+ COALESCE(im." commentCount" , 0 ) AS " commentCount" ,
64
+ COALESCE(im." heartCount" + im." likeCount" + im." dislikeCount" + im." laughCount" + im." cryCount" , 0 ) AS " reactionCount" ,
65
+ tf .timeframe
66
+ FROM " Image" i
67
+ CROSS JOIN (
68
+ SELECT unnest(enum_range(NULL ::" MetricTimeframe" )) AS timeframe
69
+ ) tf
70
+ LEFT JOIN " ImageMetric" im ON im." imageId" = i .id AND im .timeframe = tf .timeframe
71
+ ), timeframe_rank AS (
72
+ SELECT
73
+ " imageId" ,
74
+ ROW_NUMBER() OVER (PARTITION BY timeframe ORDER BY COALESCE(" heartCount" , 0 ) DESC , COALESCE(" likeCount" , 0 ) DESC , COALESCE(" commentCount" , 0 ) DESC , COALESCE(" reactionCount" , 0 ) DESC , " imageId" DESC ) AS " heartCountRank" ,
75
+ ROW_NUMBER() OVER (PARTITION BY timeframe ORDER BY COALESCE(" likeCount" , 0 ) DESC , COALESCE(" heartCount" , 0 ) DESC , COALESCE(" commentCount" , 0 ) DESC , COALESCE(" reactionCount" , 0 ) DESC , " imageId" DESC ) AS " likeCountRank" ,
76
+ ROW_NUMBER() OVER (PARTITION BY timeframe ORDER BY COALESCE(" dislikeCount" , 0 ) DESC , COALESCE(" reactionCount" , 0 ) DESC , COALESCE(" commentCount" , 0 ) DESC , " imageId" DESC ) AS " dislikeCountRank" ,
77
+ ROW_NUMBER() OVER (PARTITION BY timeframe ORDER BY COALESCE(" laughCount" , 0 ) DESC , COALESCE(" heartCount" , 0 ) DESC , COALESCE(" likeCount" , 0 ) DESC , COALESCE(" reactionCount" , 0 ) DESC , COALESCE(" commentCount" , 0 ) DESC , " imageId" DESC ) AS " laughCountRank" ,
78
+ ROW_NUMBER() OVER (PARTITION BY timeframe ORDER BY COALESCE(" cryCount" , 0 ) DESC , COALESCE(" heartCount" , 0 ) DESC , COALESCE(" likeCount" , 0 ) DESC , COALESCE(" reactionCount" , 0 ) DESC , COALESCE(" commentCount" , 0 ) DESC , " imageId" DESC ) AS " cryCountRank" ,
79
+ ROW_NUMBER() OVER (PARTITION BY timeframe ORDER BY COALESCE(" reactionCount" , 0 ) DESC , COALESCE(" heartCount" , 0 ) DESC , COALESCE(" likeCount" , 0 ) DESC , COALESCE(" commentCount" , 0 ) DESC , " imageId" DESC ) AS " reactionCountRank" ,
80
+ ROW_NUMBER() OVER (PARTITION BY timeframe ORDER BY COALESCE(" commentCount" , 0 ) DESC , COALESCE(" reactionCount" , 0 ) DESC , COALESCE(" heartCount" , 0 ) DESC , COALESCE(" likeCount" , 0 ) DESC , COALESCE(" laughCount" , 0 ) DESC , " imageId" DESC ) AS " commentCountRank" ,
81
+ timeframe
82
+ FROM timeframe_stats
83
+ )
84
+ SELECT
85
+ " imageId" ,
86
+ MAX (IIF(timeframe = ' Day' ::" MetricTimeframe" , " heartCountRank" , NULL ::bigint )) AS " heartCountDayRank" ,
87
+ MAX (IIF(timeframe = ' Week' ::" MetricTimeframe" , " heartCountRank" , NULL ::bigint )) AS " heartCountWeekRank" ,
88
+ MAX (IIF(timeframe = ' Month' ::" MetricTimeframe" , " heartCountRank" , NULL ::bigint )) AS " heartCountMonthRank" ,
89
+ MAX (IIF(timeframe = ' Year' ::" MetricTimeframe" , " heartCountRank" , NULL ::bigint )) AS " heartCountYearRank" ,
90
+ MAX (IIF(timeframe = ' AllTime' ::" MetricTimeframe" , " heartCountRank" , NULL ::bigint )) AS " heartCountAllTimeRank" ,
91
+ MAX (IIF(timeframe = ' Day' ::" MetricTimeframe" , " likeCountRank" , NULL ::bigint )) AS " likeCountDayRank" ,
92
+ MAX (IIF(timeframe = ' Week' ::" MetricTimeframe" , " likeCountRank" , NULL ::bigint )) AS " likeCountWeekRank" ,
93
+ MAX (IIF(timeframe = ' Month' ::" MetricTimeframe" , " likeCountRank" , NULL ::bigint )) AS " likeCountMonthRank" ,
94
+ MAX (IIF(timeframe = ' Year' ::" MetricTimeframe" , " likeCountRank" , NULL ::bigint )) AS " likeCountYearRank" ,
95
+ MAX (IIF(timeframe = ' AllTime' ::" MetricTimeframe" , " likeCountRank" , NULL ::bigint )) AS " likeCountAllTimeRank" ,
96
+ MAX (IIF(timeframe = ' Day' ::" MetricTimeframe" , " dislikeCountRank" , NULL ::bigint )) AS " dislikeCountDayRank" ,
97
+ MAX (IIF(timeframe = ' Week' ::" MetricTimeframe" , " dislikeCountRank" , NULL ::bigint )) AS " dislikeCountWeekRank" ,
98
+ MAX (IIF(timeframe = ' Month' ::" MetricTimeframe" , " dislikeCountRank" , NULL ::bigint )) AS " dislikeCountMonthRank" ,
99
+ MAX (IIF(timeframe = ' Year' ::" MetricTimeframe" , " dislikeCountRank" , NULL ::bigint )) AS " dislikeCountYearRank" ,
100
+ MAX (IIF(timeframe = ' AllTime' ::" MetricTimeframe" , " dislikeCountRank" , NULL ::bigint )) AS " dislikeCountAllTimeRank" ,
101
+ MAX (IIF(timeframe = ' Day' ::" MetricTimeframe" , " laughCountRank" , NULL ::bigint )) AS " laughCountDayRank" ,
102
+ MAX (IIF(timeframe = ' Week' ::" MetricTimeframe" , " laughCountRank" , NULL ::bigint )) AS " laughCountWeekRank" ,
103
+ MAX (IIF(timeframe = ' Month' ::" MetricTimeframe" , " laughCountRank" , NULL ::bigint )) AS " laughCountMonthRank" ,
104
+ MAX (IIF(timeframe = ' Year' ::" MetricTimeframe" , " laughCountRank" , NULL ::bigint )) AS " laughCountYearRank" ,
105
+ MAX (IIF(timeframe = ' AllTime' ::" MetricTimeframe" , " laughCountRank" , NULL ::bigint )) AS " laughCountAllTimeRank" ,
106
+ MAX (IIF(timeframe = ' Day' ::" MetricTimeframe" , " cryCountRank" , NULL ::bigint )) AS " cryCountDayRank" ,
107
+ MAX (IIF(timeframe = ' Week' ::" MetricTimeframe" , " cryCountRank" , NULL ::bigint )) AS " cryCountWeekRank" ,
108
+ MAX (IIF(timeframe = ' Month' ::" MetricTimeframe" , " cryCountRank" , NULL ::bigint )) AS " cryCountMonthRank" ,
109
+ MAX (IIF(timeframe = ' Year' ::" MetricTimeframe" , " cryCountRank" , NULL ::bigint )) AS " cryCountYearRank" ,
110
+ MAX (IIF(timeframe = ' AllTime' ::" MetricTimeframe" , " cryCountRank" , NULL ::bigint )) AS " cryCountAllTimeRank" ,
111
+ MAX (IIF(timeframe = ' Day' ::" MetricTimeframe" , " reactionCountRank" , NULL ::bigint )) AS " reactionCountDayRank" ,
112
+ MAX (IIF(timeframe = ' Week' ::" MetricTimeframe" , " reactionCountRank" , NULL ::bigint )) AS " reactionCountWeekRank" ,
113
+ MAX (IIF(timeframe = ' Month' ::" MetricTimeframe" , " reactionCountRank" , NULL ::bigint )) AS " reactionCountMonthRank" ,
114
+ MAX (IIF(timeframe = ' Year' ::" MetricTimeframe" , " reactionCountRank" , NULL ::bigint )) AS " reactionCountYearRank" ,
115
+ MAX (IIF(timeframe = ' AllTime' ::" MetricTimeframe" , " reactionCountRank" , NULL ::bigint )) AS " reactionCountAllTimeRank" ,
116
+ MAX (IIF(timeframe = ' Day' ::" MetricTimeframe" , " commentCountRank" , NULL ::bigint )) AS " commentCountDayRank" ,
117
+ MAX (IIF(timeframe = ' Week' ::" MetricTimeframe" , " commentCountRank" , NULL ::bigint )) AS " commentCountWeekRank" ,
118
+ MAX (IIF(timeframe = ' Month' ::" MetricTimeframe" , " commentCountRank" , NULL ::bigint )) AS " commentCountMonthRank" ,
119
+ MAX (IIF(timeframe = ' Year' ::" MetricTimeframe" , " commentCountRank" , NULL ::bigint )) AS " commentCountYearRank" ,
120
+ MAX (IIF(timeframe = ' AllTime' ::" MetricTimeframe" , " commentCountRank" , NULL ::bigint )) AS " commentCountAllTimeRank"
121
+ FROM timeframe_rank
122
+ GROUP BY " imageId" ;
123
+
124
+ CREATE UNIQUE INDEX irank_image_id ON " ImageRank" (" imageId" );
0 commit comments