@@ -93,101 +93,51 @@ export class SequelizeUsageRepository {
93
93
94
94
async getUserUsage ( userUuid : string ) {
95
95
const query = `
96
- WITH yearly_sums AS (
97
- SELECT
98
- date_trunc('year', period) AS year,
99
- SUM(delta) AS total_delta
100
- FROM
101
- public.usages
102
- WHERE
103
- type = 'yearly'
104
- AND user_id = :userUuid
105
- GROUP BY
106
- date_trunc('year', period)
107
- ),
108
- monthly_sums AS (
109
- SELECT
110
- date_trunc('year', period) AS year,
111
- date_trunc('month', period) AS month,
112
- SUM(delta) AS total_delta
113
- FROM
114
- public.usages
115
- WHERE
116
- type = 'monthly'
117
- AND user_id = :userUuid
118
- GROUP BY
119
- date_trunc('year', period), date_trunc('month', period)
120
- ),
121
- daily_sums AS (
122
- SELECT
123
- date_trunc('year', period) AS year,
124
- date_trunc('month', period) AS month,
125
- SUM(delta) AS total_delta
126
- FROM
127
- public.usages
128
- WHERE
129
- type = 'daily'
130
- AND user_id = :userUuid
131
- GROUP BY
132
- date_trunc('year', period), date_trunc('month', period)
133
- ),
134
- combined_monthly_and_daily AS (
135
- SELECT
136
- COALESCE(m.year, d.year) AS year,
137
- COALESCE(m.month, d.month) AS month,
138
- COALESCE(m.total_delta, 0) + COALESCE(d.total_delta, 0) AS total_delta
139
- FROM
140
- monthly_sums m
141
- FULL JOIN daily_sums d ON m.year = d.year AND m.month = d.month
142
- ),
143
- combined_sums AS (
144
- SELECT
145
- y.year,
146
- NULL AS month,
147
- y.total_delta AS total_delta
148
- FROM
149
- yearly_sums y
150
- UNION ALL
151
- SELECT
152
- cmd.year,
153
- cmd.month,
154
- cmd.total_delta
155
- FROM
156
- combined_monthly_and_daily cmd
157
- LEFT JOIN yearly_sums ys ON cmd.year = ys.year
158
- WHERE
159
- ys.year IS NULL -- Exclude months and days where a yearly row exists
160
- )
161
- SELECT
162
- SUM(
163
- CASE
164
- WHEN year < date_trunc('year', CURRENT_DATE) THEN total_delta
165
- ELSE 0
166
- END
167
- ) AS total_yearly_delta,
168
- SUM(
169
- CASE
170
- WHEN year = date_trunc('year', CURRENT_DATE) THEN total_delta
171
- ELSE 0
172
- END
173
- ) AS total_monthly_delta
174
- FROM
175
- combined_sums;
96
+ WITH years_with_yearly AS (
97
+ SELECT DISTINCT date_trunc('year', period) AS year
98
+ FROM public.usages
99
+ WHERE type = 'yearly' AND user_id = :userUuid
100
+ ),
101
+ aggregated_data AS (
102
+ -- Aggregate yearly data where it exists
103
+ SELECT
104
+ date_trunc('year', period) AS year,
105
+ SUM(delta) AS total_delta
106
+ FROM public.usages
107
+ WHERE type = 'yearly' AND user_id = :userUuid
108
+ GROUP BY date_trunc('year', period)
109
+
110
+ UNION ALL
111
+
112
+ -- Aggregate monthly + daily data for years without yearly data
113
+ SELECT
114
+ date_trunc('year', period) AS year,
115
+ SUM(delta) AS total_delta
116
+ FROM public.usages
117
+ WHERE type IN ('monthly', 'daily')
118
+ AND user_id = :userUuid
119
+ AND date_trunc('year', period) NOT IN (SELECT year FROM years_with_yearly)
120
+ GROUP BY date_trunc('year', period)
121
+ )
122
+ SELECT
123
+ SUM(CASE WHEN year < date_trunc('year', CURRENT_DATE) THEN total_delta ELSE 0 END) AS previous_years_total,
124
+ SUM(CASE WHEN year = date_trunc('year', CURRENT_DATE) THEN total_delta ELSE 0 END) AS current_year_total
125
+ FROM aggregated_data;
176
126
` ;
177
127
178
128
const [ result ] = ( await this . usageModel . sequelize . query ( query , {
179
129
replacements : { userUuid } ,
180
130
} ) ) as unknown as [
181
131
{
182
- total_yearly_delta : number ;
183
- total_monthly_delta : number ;
132
+ previous_years_total : number ;
133
+ current_year_total : number ;
184
134
} [ ] ,
185
135
] ;
186
136
187
- return {
188
- totalYearlyDelta : Number ( result [ 0 ] . total_yearly_delta || 0 ) ,
189
- totalMonthlyDelta : Number ( result [ 0 ] . total_monthly_delta || 0 ) ,
190
- } ;
137
+ return (
138
+ Number ( result [ 0 ] . previous_years_total || 0 ) +
139
+ Number ( result [ 0 ] . current_year_total || 0 )
140
+ ) ;
191
141
}
192
142
193
143
toDomain ( model : UsageModel ) : Usage {
0 commit comments