You signed in with another tab or window. Reload to refresh your session.You signed out in another tab or window. Reload to refresh your session.You switched accounts on another tab or window. Reload to refresh your session.Dismiss alert
-- Fix for #4894: gapfill error over aggregates in expressions with groupby columns and columns out of order
230
+
CREATE TABLE hourly (
231
+
time timestamptz NOT NULL,
232
+
signal smallint NOT NULL,
233
+
value real,
234
+
level_a integer,
235
+
level_b smallint,
236
+
level_c smallint,
237
+
agg smallint
238
+
);
239
+
INSERT into hourly(time, signal,value, level_a, level_b, level_c, agg) values
240
+
('2022-10-01T00:00:00Z', 2, 685, 1, -1, -1, 2 ),
241
+
('2022-10-01T00:00:00Z', 2, 686, 1, -1, -1, 3 ),
242
+
('2022-10-01T02:00:00Z', 2, 686, 1, -1, -3, 2 ),
243
+
('2022-10-01T02:00:00Z', 2, 687, 1, -1, -1, 3 ),
244
+
('2022-10-01T03:00:00Z', 2, 687, 1, -1, -3, 2 ),
245
+
('2022-10-01T03:00:00Z', 2, 688, 1, -1, -1, 3 );
246
+
-- Expression over 1 aggregate and 1 groupby column
247
+
SELECT
248
+
time_bucket_gapfill('1 hour', time) as time,
249
+
CASE WHEN agg in (0,3) THEN max(value) ELSE null END as max,
250
+
CASE WHEN agg in (0,2) THEN min(value) ELSE null END as min
251
+
FROM hourly WHERE agg in (0,2,3) and signal in (2) AND level_a = 1 AND level_b >= -1 AND time >= '2022-10-01T00:00:00Z' AND time < '2022-10-01T05:59:59Z'
252
+
GROUP BY 1, agg order by 1,2,3;
253
+
time | max | min
254
+
------------------------------+-----+-----
255
+
Fri Sep 30 17:00:00 2022 PDT | 686 |
256
+
Fri Sep 30 17:00:00 2022 PDT | | 685
257
+
Fri Sep 30 18:00:00 2022 PDT | |
258
+
Fri Sep 30 18:00:00 2022 PDT | |
259
+
Fri Sep 30 19:00:00 2022 PDT | 687 |
260
+
Fri Sep 30 19:00:00 2022 PDT | | 686
261
+
Fri Sep 30 20:00:00 2022 PDT | 688 |
262
+
Fri Sep 30 20:00:00 2022 PDT | | 687
263
+
Fri Sep 30 21:00:00 2022 PDT | |
264
+
Fri Sep 30 21:00:00 2022 PDT | |
265
+
Fri Sep 30 22:00:00 2022 PDT | |
266
+
Fri Sep 30 22:00:00 2022 PDT | |
267
+
(12 rows)
268
+
269
+
-- Expression over 2 aggregates and 1 groupby column
270
+
SELECT
271
+
time_bucket_gapfill('1 hour', time) as time,
272
+
CASE WHEN agg in (0,3) THEN max(value) ELSE min(level_c) END as maxmin
273
+
FROM hourly WHERE agg in (0,2,3) and signal in (2) AND level_a = 1 AND level_b = -1 AND time >= '2022-10-01T00:00:00Z' AND time < '2022-10-01T05:59:59Z'
274
+
GROUP BY 1, agg order by 1,2;
275
+
time | maxmin
276
+
------------------------------+--------
277
+
Fri Sep 30 17:00:00 2022 PDT | -1
278
+
Fri Sep 30 17:00:00 2022 PDT | 686
279
+
Fri Sep 30 18:00:00 2022 PDT |
280
+
Fri Sep 30 18:00:00 2022 PDT |
281
+
Fri Sep 30 19:00:00 2022 PDT | -3
282
+
Fri Sep 30 19:00:00 2022 PDT | 687
283
+
Fri Sep 30 20:00:00 2022 PDT | -3
284
+
Fri Sep 30 20:00:00 2022 PDT | 688
285
+
Fri Sep 30 21:00:00 2022 PDT |
286
+
Fri Sep 30 21:00:00 2022 PDT |
287
+
Fri Sep 30 22:00:00 2022 PDT |
288
+
Fri Sep 30 22:00:00 2022 PDT |
289
+
(12 rows)
290
+
291
+
-- Expression over 2 aggregates and 2 groupby columns
292
+
SELECT
293
+
time_bucket_gapfill('1 hour', time) as time,
294
+
CASE WHEN agg in (0,3) THEN max(value) ELSE min(level_c)+signal END as maxmin
295
+
FROM hourly WHERE agg in (0,2,3) and signal in (2) AND level_a = 1 AND level_b = -1 AND time >= '2022-10-01T00:00:00Z' AND time < '2022-10-01T05:59:59Z'
296
+
GROUP BY 1, agg, signal order by 1,2;
297
+
time | maxmin
298
+
------------------------------+--------
299
+
Fri Sep 30 17:00:00 2022 PDT | 1
300
+
Fri Sep 30 17:00:00 2022 PDT | 686
301
+
Fri Sep 30 18:00:00 2022 PDT |
302
+
Fri Sep 30 18:00:00 2022 PDT |
303
+
Fri Sep 30 19:00:00 2022 PDT | -1
304
+
Fri Sep 30 19:00:00 2022 PDT | 687
305
+
Fri Sep 30 20:00:00 2022 PDT | -1
306
+
Fri Sep 30 20:00:00 2022 PDT | 688
307
+
Fri Sep 30 21:00:00 2022 PDT |
308
+
Fri Sep 30 21:00:00 2022 PDT |
309
+
Fri Sep 30 22:00:00 2022 PDT |
310
+
Fri Sep 30 22:00:00 2022 PDT |
311
+
(12 rows)
312
+
313
+
-- Expressions over aggregates and complex groupby expressions
314
+
SELECT
315
+
time_bucket_gapfill('1 hour', time) as time,
316
+
max(value)+(agg+1)
317
+
FROM hourly WHERE agg in (0,2,3) and signal in (2) AND level_a = 1 AND level_b = -1 AND time >= '2022-10-01T00:00:00Z' AND time < '2022-10-01T05:59:59Z'
318
+
GROUP BY 1, agg+1 order by 1,2;
319
+
time | ?column?
320
+
------------------------------+----------
321
+
Fri Sep 30 17:00:00 2022 PDT | 688
322
+
Fri Sep 30 17:00:00 2022 PDT | 690
323
+
Fri Sep 30 18:00:00 2022 PDT |
324
+
Fri Sep 30 18:00:00 2022 PDT |
325
+
Fri Sep 30 19:00:00 2022 PDT | 689
326
+
Fri Sep 30 19:00:00 2022 PDT | 691
327
+
Fri Sep 30 20:00:00 2022 PDT | 690
328
+
Fri Sep 30 20:00:00 2022 PDT | 692
329
+
Fri Sep 30 21:00:00 2022 PDT |
330
+
Fri Sep 30 21:00:00 2022 PDT |
331
+
Fri Sep 30 22:00:00 2022 PDT |
332
+
Fri Sep 30 22:00:00 2022 PDT |
333
+
(12 rows)
334
+
335
+
SELECT
336
+
time_bucket_gapfill('1 hour', time) as time,
337
+
max(value)+(agg+1)+(agg+1+1)
338
+
FROM hourly WHERE agg in (0,2,3) and signal in (2) AND level_a = 1 AND level_b = -1 AND time >= '2022-10-01T00:00:00Z' AND time < '2022-10-01T05:59:59Z'
339
+
GROUP BY 1, agg+1, agg+1+1 order by 1,2;
340
+
time | ?column?
341
+
------------------------------+----------
342
+
Fri Sep 30 17:00:00 2022 PDT | 692
343
+
Fri Sep 30 17:00:00 2022 PDT | 695
344
+
Fri Sep 30 18:00:00 2022 PDT |
345
+
Fri Sep 30 18:00:00 2022 PDT |
346
+
Fri Sep 30 19:00:00 2022 PDT | 693
347
+
Fri Sep 30 19:00:00 2022 PDT | 696
348
+
Fri Sep 30 20:00:00 2022 PDT | 694
349
+
Fri Sep 30 20:00:00 2022 PDT | 697
350
+
Fri Sep 30 21:00:00 2022 PDT |
351
+
Fri Sep 30 21:00:00 2022 PDT |
352
+
Fri Sep 30 22:00:00 2022 PDT |
353
+
Fri Sep 30 22:00:00 2022 PDT |
354
+
(12 rows)
355
+
356
+
SELECT
357
+
time_bucket_gapfill('1 hour', time) as time,
358
+
max(value) + (agg+signal) maxv,
359
+
min(value) - (agg+signal) minv,
360
+
agg+signal
361
+
FROM hourly WHERE agg in (0,2,3) and signal in (2) AND level_a = 1 AND level_b = -1 AND time >= '2022-10-01T00:00:00Z' AND time < '2022-10-01T05:59:59Z'
0 commit comments