forked from goccy/go-zetasqlite
-
Notifications
You must be signed in to change notification settings - Fork 0
/
query_test.go
4939 lines (4901 loc) · 169 KB
/
query_test.go
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
package zetasqlite_test
import (
"context"
"database/sql"
"fmt"
"math"
"reflect"
"testing"
"time"
"github.com/Recidiviz/go-zetasqlite"
"github.com/google/go-cmp/cmp"
)
func TestQuery(t *testing.T) {
now := time.Now()
ctx := context.Background()
ctx = zetasqlite.WithCurrentTime(ctx, now)
db, err := sql.Open("zetasqlite", ":memory:")
if err != nil {
t.Fatal(err)
}
defer db.Close()
floatCmpOpt := cmp.Comparer(func(x, y float64) bool {
if x == y {
return true
}
delta := math.Abs(x - y)
mean := math.Abs(x+y) / 2.0
return delta/mean < 0.00001
})
for _, test := range []struct {
name string
query string
args []interface{}
expectedRows [][]interface{}
expectedErr string
}{
// priority 2 operator
{
name: "unary plus operator",
query: "SELECT +1",
expectedRows: [][]interface{}{{int64(1)}},
},
{
name: "unary minus operator",
query: "SELECT -2",
expectedRows: [][]interface{}{{int64(-2)}},
},
{
name: "bit not operator",
query: "SELECT ~1",
expectedRows: [][]interface{}{{int64(-2)}},
},
// priority 3 operator
{
name: "mul operator",
query: "SELECT 2 * 3",
expectedRows: [][]interface{}{{int64(6)}},
},
{
name: "div operator",
query: "SELECT 10 / 2",
expectedRows: [][]interface{}{{float64(5)}},
},
{
name: "concat string operator",
query: `SELECT "a" || "b"`,
expectedRows: [][]interface{}{{"ab"}},
},
{
name: "concat array operator",
query: `SELECT [1, 2] || [3, 4]`,
expectedRows: [][]interface{}{{[]interface{}{int64(1), int64(2), int64(3), int64(4)}}},
},
// priority 4 operator
{
name: "add operator",
query: "SELECT 1 + 1",
expectedRows: [][]interface{}{{int64(2)}},
},
{
name: "sub operator",
query: "SELECT 1 - 2",
expectedRows: [][]interface{}{{int64(-1)}},
},
// priority 5 operator
{
name: "left shift operator",
query: "SELECT 1 << 2",
expectedRows: [][]interface{}{{int64(4)}},
},
{
name: "right shift operator",
query: "SELECT 4 >> 1",
expectedRows: [][]interface{}{{int64(2)}},
},
// priority 6 operator
{
name: "bit and operator",
query: "SELECT 3 & 1",
expectedRows: [][]interface{}{{int64(1)}},
},
// priority 7 operator
{
name: "bit xor operator",
query: "SELECT 10 ^ 12",
expectedRows: [][]interface{}{{int64(6)}},
},
// priority 8 operator
{
name: "bit or operator",
query: "SELECT 1 | 2",
expectedRows: [][]interface{}{{int64(3)}},
},
// priority 9 operator
{
name: "eq operator",
query: "SELECT 100 = 100",
expectedRows: [][]interface{}{{true}},
},
{
name: "lt operator",
query: "SELECT 10 < 100",
expectedRows: [][]interface{}{{true}},
},
{
name: "gt operator",
query: "SELECT 100 > 10",
expectedRows: [][]interface{}{{true}},
},
{
name: "lte operator",
query: "SELECT 10 <= 10",
expectedRows: [][]interface{}{{true}},
},
{
name: "gte operator",
query: "SELECT 10 >= 10",
expectedRows: [][]interface{}{{true}},
},
{
name: "ne operator",
query: "SELECT 100 != 10",
expectedRows: [][]interface{}{{true}},
},
{
name: "ne operator2",
query: "SELECT 100 <> 10",
expectedRows: [][]interface{}{{true}},
},
{
name: "like operator",
query: `SELECT "abcd" LIKE "a%d"`,
expectedRows: [][]interface{}{{true}},
},
{
name: "like operator2",
query: `SELECT "abcd" LIKE "%a%"`,
expectedRows: [][]interface{}{{true}},
},
{
name: "like operator3",
query: `SELECT "abcd" LIKE "%b%"`,
expectedRows: [][]interface{}{{true}},
},
{
name: "like operator4",
query: `SELECT "dog" LIKE "o%"`,
expectedRows: [][]interface{}{{false}},
},
{
name: "not like operator",
query: `SELECT "abcd" NOT LIKE "a%d"`,
expectedRows: [][]interface{}{{false}},
},
{
name: "between operator",
query: `SELECT DATE "2022-09-10" BETWEEN "2022-09-01" and "2022-10-01"`,
expectedRows: [][]interface{}{{true}},
},
{
name: "not between operator",
query: `SELECT DATE "2020-09-10" NOT BETWEEN "2022-09-01" and "2022-10-01"`,
expectedRows: [][]interface{}{{true}},
},
{
name: "in operator",
query: `SELECT 3 IN (1, 2, 3, 4)`,
expectedRows: [][]interface{}{{true}},
},
{
name: "not in operator",
query: `SELECT 5 NOT IN (1, 2, 3, 4)`,
expectedRows: [][]interface{}{{true}},
},
{
name: "is null operator",
query: `SELECT NULL IS NULL`,
expectedRows: [][]interface{}{{true}},
},
{
name: "is not null operator",
query: `SELECT 1 IS NOT NULL`,
expectedRows: [][]interface{}{{true}},
},
{
name: "is true operator",
query: `SELECT true IS TRUE`,
expectedRows: [][]interface{}{{true}},
},
{
name: "is not true operator",
query: `SELECT false IS NOT TRUE`,
expectedRows: [][]interface{}{{true}},
},
{
name: "is false operator",
query: `SELECT false IS FALSE`,
expectedRows: [][]interface{}{{true}},
},
{
name: "is not false operator",
query: `SELECT true IS NOT FALSE`,
expectedRows: [][]interface{}{{true}},
},
// priority 10 operator
{
name: "not operator",
query: `SELECT NOT 1 = 2`,
expectedRows: [][]interface{}{{true}},
},
// priority 11 operator
{
name: "and operator",
query: `SELECT 1 = 1 AND 2 = 2`,
expectedRows: [][]interface{}{{true}},
},
{
name: "and operator with true and true",
query: `SELECT TRUE AND TRUE`,
expectedRows: [][]interface{}{{true}},
},
{
name: "and operator with true and false",
query: `SELECT TRUE AND FALSE`,
expectedRows: [][]interface{}{{false}},
},
{
name: "and operator with true and null",
query: `SELECT TRUE AND NULL`,
expectedRows: [][]interface{}{{nil}},
},
{
name: "and operator with false and true",
query: `SELECT FALSE AND TRUE`,
expectedRows: [][]interface{}{{false}},
},
{
name: "and operator with false and false",
query: `SELECT FALSE AND FALSE`,
expectedRows: [][]interface{}{{false}},
},
{
name: "and operator with false and null",
query: `SELECT FALSE AND NULL`,
expectedRows: [][]interface{}{{false}},
},
{
name: "and operator with null and true",
query: `SELECT NULL AND TRUE`,
expectedRows: [][]interface{}{{nil}},
},
{
name: "and operator with null and false",
query: `SELECT NULL AND FALSE`,
expectedRows: [][]interface{}{{false}},
},
{
name: "and operator with null and null",
query: `SELECT NULL AND NULL`,
expectedRows: [][]interface{}{{nil}},
},
// priority 12 operator
{
name: "or operator",
query: `SELECT 1 = 2 OR 1 = 1`,
expectedRows: [][]interface{}{{true}},
},
{
name: "or operator with true and true",
query: `SELECT TRUE OR TRUE`,
expectedRows: [][]interface{}{{true}},
},
{
name: "or operator with true and false",
query: `SELECT TRUE OR FALSE`,
expectedRows: [][]interface{}{{true}},
},
{
name: "or operator with true and null",
query: `SELECT TRUE OR NULL`,
expectedRows: [][]interface{}{{true}},
},
{
name: "or operator with false and true",
query: `SELECT FALSE OR TRUE`,
expectedRows: [][]interface{}{{true}},
},
{
name: "or operator with false and false",
query: `SELECT FALSE OR FALSE`,
expectedRows: [][]interface{}{{false}},
},
{
name: "or operator with false and null",
query: `SELECT FALSE OR NULL`,
expectedRows: [][]interface{}{{nil}},
},
{
name: "or operator with null and true",
query: `SELECT NULL OR TRUE`,
expectedRows: [][]interface{}{{true}},
},
{
name: "or operator with null and false",
query: `SELECT NULL OR FALSE`,
expectedRows: [][]interface{}{{nil}},
},
{
name: "or operator with null and null",
query: `SELECT NULL OR NULL`,
expectedRows: [][]interface{}{{nil}},
},
{
name: "exists",
query: `SELECT EXISTS ( SELECT val FROM UNNEST([1, 2, 3]) AS val WHERE val = 1 )`,
expectedRows: [][]interface{}{{true}},
},
{
name: "not exists",
query: `SELECT EXISTS ( SELECT val FROM UNNEST([1, 2, 3]) AS val WHERE val = 4 )`,
expectedRows: [][]interface{}{{false}},
},
{
name: "is distinct from with 1 and 2",
query: `SELECT 1 IS DISTINCT FROM 2`,
expectedRows: [][]interface{}{{true}},
},
{
name: "is distinct from with 1 and null",
query: `SELECT 1 IS DISTINCT FROM NULL`,
expectedRows: [][]interface{}{{true}},
},
{
name: "is not distinct from with 1 and 1",
query: `SELECT 1 IS NOT DISTINCT FROM 1`,
expectedRows: [][]interface{}{{true}},
},
{
name: "is not distinct from with null and null",
query: `SELECT NULL IS NOT DISTINCT FROM NULL`,
expectedRows: [][]interface{}{{true}},
},
{
name: "is distinct from with null and null",
query: `SELECT NULL IS DISTINCT FROM NULL`,
expectedRows: [][]interface{}{{false}},
},
{
name: "is distinct from with 1 and 1",
query: `SELECT 1 IS DISTINCT FROM 1`,
expectedRows: [][]interface{}{{false}},
},
{
name: "is not distinct from with 1 and 2",
query: `SELECT 1 IS NOT DISTINCT FROM 2`,
expectedRows: [][]interface{}{{false}},
},
{
name: "is not distinct from with 1 and null",
query: `SELECT 1 IS NOT DISTINCT FROM NULL`,
expectedRows: [][]interface{}{{false}},
},
{
name: "case-when",
query: `
SELECT
val,
CASE val
WHEN 1 THEN 'one'
WHEN 2 THEN 'two'
WHEN 3 THEN 'three'
ELSE 'four'
END
FROM UNNEST([1, 2, 3, 4]) AS val`,
expectedRows: [][]interface{}{
{int64(1), "one"},
{int64(2), "two"},
{int64(3), "three"},
{int64(4), "four"},
},
},
{
name: "case-when with compare",
query: `
SELECT
val,
CASE
WHEN val > 3 THEN 'four'
WHEN val > 2 THEN 'three'
WHEN val > 1 THEN 'two'
ELSE 'one'
END
FROM UNNEST([1, 2, 3, 4]) AS val`,
expectedRows: [][]interface{}{
{int64(1), "one"},
{int64(2), "two"},
{int64(3), "three"},
{int64(4), "four"},
},
},
{
name: "coalesce",
query: `SELECT COALESCE('A', 'B', 'C')`,
expectedRows: [][]interface{}{{"A"}},
},
{
name: "coalesce with null",
query: `SELECT COALESCE(NULL, 'B', 'C')`,
expectedRows: [][]interface{}{{"B"}},
},
{
name: "coalesce with all nulls",
query: `SELECT COALESCE(NULL, NULL, NULL)`,
expectedRows: [][]interface{}{{nil}},
},
{
name: "if return int64",
query: `SELECT IF("a" = "b", 1, 2)`,
expectedRows: [][]interface{}{{int64(2)}},
},
{
name: "if return string",
query: `SELECT IF("a" = "a", "true", "false")`,
expectedRows: [][]interface{}{{"true"}},
},
{
name: "ifnull",
query: `SELECT IFNULL(10, 0)`,
expectedRows: [][]interface{}{{int64(10)}},
},
{
name: "ifnull with null",
query: `SELECT IFNULL(NULL, 0)`,
expectedRows: [][]interface{}{{int64(0)}},
},
{
name: "nullif true",
query: `SELECT NULLIF(0, 0)`,
expectedRows: [][]interface{}{{nil}},
},
{
name: "nullif false",
query: `SELECT NULLIF(10, 0)`,
expectedRows: [][]interface{}{{int64(10)}},
},
{
name: "with clause",
query: `
WITH sub1 AS (SELECT ["a", "b"]),
sub2 AS (SELECT ["c", "d"])
SELECT * FROM sub1
UNION ALL
SELECT * FROM sub2`,
expectedRows: [][]interface{}{
{[]interface{}{"a", "b"}},
{[]interface{}{"c", "d"}},
},
},
{
name: "field access operator",
query: `
WITH orders AS (
SELECT STRUCT(STRUCT('Yonge Street' AS street, 'Canada' AS country) AS address) AS customer
)
SELECT t.customer.address.country FROM orders AS t`,
expectedRows: [][]interface{}{{"Canada"}},
},
{
name: "struct with bool",
query: `SELECT CURRENT_TIMESTAMP() AS ts, STRUCT(NULL AS a, FALSE AS b).b AS b`,
expectedRows: [][]interface{}{{createTimestampFormatFromTime(now.UTC()), false}},
},
{
name: "array index access operator",
query: `
WITH Items AS (SELECT ["coffee", "tea", "milk"] AS item_array)
SELECT
item_array,
item_array[OFFSET(1)] AS item_offset,
item_array[ORDINAL(1)] AS item_ordinal,
item_array[SAFE_OFFSET(6)] AS item_safe_offset,
FROM Items`,
expectedRows: [][]interface{}{{
[]interface{}{"coffee", "tea", "milk"},
"tea",
"coffee",
nil,
}},
},
{
name: "create function",
query: `
CREATE FUNCTION customfunc(
arr ARRAY<STRUCT<name STRING, val INT64>>
) AS (
(SELECT SUM(IF(elem.name = "foo",elem.val,null)) FROM UNNEST(arr) AS elem)
)`,
expectedRows: [][]interface{}{},
},
{
name: "use function",
query: `
SELECT customfunc([
STRUCT<name STRING, val INT64>("foo", 10),
STRUCT<name STRING, val INT64>("bar", 40),
STRUCT<name STRING, val INT64>("foo", 20)
])`,
expectedRows: [][]interface{}{{int64(30)}},
},
{
name: "out of range error",
query: `
WITH Items AS (SELECT ["coffee", "tea", "milk"] AS item_array)
SELECT
item_array[OFFSET(6)] AS item_offset
FROM Items`,
expectedRows: [][]interface{}{},
expectedErr: "OFFSET(6) is out of range",
},
// INVALID_ARGUMENT: Subscript access using [INT64] is not supported on values of type JSON [at 2:34]
//{
// name: "json",
// query: `
// SELECT json_value.class.students[0]['name'] AS first_student
// FROM
// UNNEST(
// [
// JSON '{"class" : {"students" : [{"name" : "Jane"}]}}',
// JSON '{"class" : {"students" : []}}',
// JSON '{"class" : {"students" : [{"name" : "John"}, {"name": "Jamie"}]}}'])
// AS json_value`,
// expectedRows: [][]interface{}{
// {"Jane"},
// {nil},
// {"John"},
// },
//},
{
name: "date operator",
query: `SELECT DATE "2020-09-22" + 1 AS day_later, DATE "2020-09-22" - 7 AS week_ago`,
expectedRows: [][]interface{}{{"2020-09-23", "2020-09-15"}},
},
// aggregate functions
{
name: "any_value",
query: `SELECT ANY_VALUE(fruit) FROM UNNEST(["apple", "banana", "pear"]) as fruit`,
expectedRows: [][]interface{}{{"apple"}},
},
{
name: "any_value with window",
query: `SELECT fruit, ANY_VALUE(fruit) OVER (ORDER BY LENGTH(fruit) ROWS BETWEEN 1 PRECEDING AND CURRENT ROW) FROM UNNEST(["apple", "banana", "pear"]) as fruit`,
expectedRows: [][]interface{}{
{"pear", "pear"},
{"apple", "pear"},
{"banana", "apple"},
},
},
{
name: "array_agg",
query: `SELECT ARRAY_AGG(x) AS array_agg FROM UNNEST([2, 1,-2, 3, -2, 1, 2]) AS x`,
expectedRows: [][]interface{}{{
[]interface{}{int64(2), int64(1), int64(-2), int64(3), int64(-2), int64(1), int64(2)},
}},
},
{
name: "array_agg with distinct",
query: `SELECT ARRAY_AGG(DISTINCT x) AS array_agg FROM UNNEST([2, 1, -2, 3, -2, 1, 2]) AS x`,
expectedRows: [][]interface{}{{
[]interface{}{int64(2), int64(1), int64(-2), int64(3)},
}},
},
{
name: "array_agg with limit",
query: `SELECT ARRAY_AGG(x LIMIT 5) AS array_agg FROM UNNEST([2, 1, -2, 3, -2, 1, 2]) AS x`,
expectedRows: [][]interface{}{{
[]interface{}{int64(2), int64(1), int64(-2), int64(3), int64(-2)},
}},
},
{
name: "array_agg with nulls",
query: `SELECT ARRAY_AGG(x) AS array_agg FROM UNNEST([NULL, 1, -2, 3, -2, 1, NULL]) AS x`,
expectedErr: "ARRAY_AGG: input value must be not null",
},
{
name: "array_agg with struct",
query: `SELECT b, ARRAY_AGG(a) FROM UNNEST([STRUCT(1 AS a, 2 AS b), STRUCT(NULL AS a, 2 AS b)]) GROUP BY b`,
expectedErr: "ARRAY_AGG: input value must be not null",
},
{
name: "array_agg with ignore nulls",
query: `SELECT ARRAY_AGG(x IGNORE NULLS) AS array_agg FROM UNNEST([NULL, 1, -2, 3, -2, 1, NULL]) AS x`,
expectedRows: [][]interface{}{{
[]interface{}{int64(1), int64(-2), int64(3), int64(-2), int64(1)},
}},
},
{
name: "array_agg with ignore nulls and struct",
query: `SELECT b, ARRAY_AGG(a IGNORE NULLS) FROM UNNEST([STRUCT(NULL AS a, 2 AS b), STRUCT(1 AS a, 2 AS b)]) GROUP BY b`,
expectedRows: [][]interface{}{{int64(2), []interface{}{int64(1)}}},
},
{
name: "array_agg with abs",
query: `SELECT ARRAY_AGG(x ORDER BY ABS(x)) AS array_agg FROM UNNEST([2, 1, -2, 3, -2, 1, 2]) AS x`,
expectedRows: [][]interface{}{{
[]interface{}{int64(1), int64(1), int64(2), int64(-2), int64(-2), int64(2), int64(3)},
}},
},
{
name: "array_agg with window",
query: `SELECT x, ARRAY_AGG(x) OVER (ORDER BY ABS(x)) FROM UNNEST([2, 1, -2, 3, -2, 1, 2]) AS x`,
expectedRows: [][]interface{}{
{int64(1), []interface{}{int64(1), int64(1)}},
{int64(1), []interface{}{int64(1), int64(1)}},
{int64(2), []interface{}{int64(1), int64(1), int64(2), int64(-2), int64(-2), int64(2)}},
{int64(-2), []interface{}{int64(1), int64(1), int64(2), int64(-2), int64(-2), int64(2)}},
{int64(-2), []interface{}{int64(1), int64(1), int64(2), int64(-2), int64(-2), int64(2)}},
{int64(2), []interface{}{int64(1), int64(1), int64(2), int64(-2), int64(-2), int64(2)}},
{int64(3), []interface{}{int64(1), int64(1), int64(2), int64(-2), int64(-2), int64(2), int64(3)}},
},
},
{
name: "array_concat_agg",
query: `
SELECT ARRAY_CONCAT_AGG(x) AS array_concat_agg FROM (
SELECT [NULL, 1, 2, 3, 4] AS x
UNION ALL SELECT [5, 6]
UNION ALL SELECT [7, 8, 9]
)`,
expectedRows: [][]interface{}{{
[]interface{}{nil, int64(1), int64(2), int64(3), int64(4), int64(5), int64(6), int64(7), int64(8), int64(9)},
}},
},
{
name: "array_concat_agg with format",
query: `SELECT FORMAT("%T", ARRAY_CONCAT_AGG(x)) AS array_concat_agg FROM (
SELECT [NULL, 1, 2, 3, 4] AS x
UNION ALL SELECT NULL
UNION ALL SELECT [5, 6]
UNION ALL SELECT [7, 8, 9]
)`,
expectedRows: [][]interface{}{
{"[NULL, 1, 2, 3, 4, 5, 6, 7, 8, 9]"},
},
},
{
name: "avg",
query: `SELECT AVG(x) as avg FROM UNNEST([0, 2, 4, 4, 5]) as x`,
expectedRows: [][]interface{}{{float64(3)}},
},
{
name: "avg with distinct",
query: `SELECT AVG(DISTINCT x) AS avg FROM UNNEST([0, 2, 4, 4, 5]) AS x`,
expectedRows: [][]interface{}{{float64(2.75)}},
},
{
name: "avg with window",
query: `SELECT x, AVG(x) OVER (ORDER BY x ROWS BETWEEN 1 PRECEDING AND CURRENT ROW) FROM UNNEST([0, 2, NULL, 4, 4, 5]) AS x`,
expectedRows: [][]interface{}{
{nil, nil},
{int64(0), float64(0)},
{int64(2), float64(1)},
{int64(4), float64(3)},
{int64(4), float64(4)},
{int64(5), float64(4.5)},
},
},
{
name: "bit_and",
query: `SELECT BIT_AND(x) as bit_and FROM UNNEST([0xF001, 0x00A1]) as x`,
expectedRows: [][]interface{}{{int64(1)}},
},
{
name: "bit_or",
query: `SELECT BIT_OR(x) as bit_or FROM UNNEST([0xF001, 0x00A1]) as x`,
expectedRows: [][]interface{}{{int64(61601)}},
},
{
name: "bit_xor",
query: `SELECT BIT_XOR(x) AS bit_xor FROM UNNEST([5678, 1234]) AS x`,
expectedRows: [][]interface{}{{int64(4860)}},
},
{
name: "bit_xor 2",
query: `SELECT BIT_XOR(x) AS bit_xor FROM UNNEST([1234, 5678, 1234]) AS x`,
expectedRows: [][]interface{}{{int64(5678)}},
},
{
name: "bit_xor 3",
query: `SELECT BIT_XOR(DISTINCT x) AS bit_xor FROM UNNEST([1234, 5678, 1234]) AS x`,
expectedRows: [][]interface{}{{int64(4860)}},
},
{
name: "count star and distinct",
query: `SELECT COUNT(*) AS count_star, COUNT(DISTINCT x) AS count_dist_x FROM UNNEST([1, 4, 4, 5]) AS x`,
expectedRows: [][]interface{}{{int64(4), int64(3)}},
},
{
name: "count with null",
query: `SELECT COUNT(x) FROM UNNEST([NULL]) AS x`,
expectedRows: [][]interface{}{{int64(0)}},
},
{
name: "count with if",
query: `SELECT COUNT(DISTINCT IF(x > 0, x, NULL)) AS distinct_positive FROM UNNEST([1, -2, 4, 1, -5, 4, 1, 3, -6, 1]) AS x`,
expectedRows: [][]interface{}{{int64(3)}},
},
{
name: "count with window",
query: `SELECT x, COUNT(*) OVER (PARTITION BY MOD(x, 3)), COUNT(DISTINCT x) OVER (PARTITION BY MOD(x, 3)) FROM UNNEST([1, 4, 4, 5]) AS x`,
expectedRows: [][]interface{}{
{int64(1), int64(3), int64(2)},
{int64(4), int64(3), int64(2)},
{int64(4), int64(3), int64(2)},
{int64(5), int64(1), int64(1)},
},
},
{
name: "countif",
query: `SELECT COUNTIF(x<0) AS num_negative, COUNTIF(x>0) AS num_positive FROM UNNEST([5, -2, 3, 6, -10, -7, 4, 0]) AS x`,
expectedRows: [][]interface{}{{int64(3), int64(4)}},
},
{
name: "countif with null",
query: `SELECT COUNTIF(x<0) FROM UNNEST([NULL]) AS x`,
expectedRows: [][]interface{}{{int64(0)}},
},
{
name: "countif with window",
query: `SELECT x, COUNTIF(x<0) OVER (ORDER BY ABS(x) ROWS BETWEEN 1 PRECEDING AND 1 FOLLOWING) FROM UNNEST([5, -2, 3, 6, -10, NULL, -7, 4, 0]) AS x`,
expectedRows: [][]interface{}{
{nil, int64(0)},
{int64(0), int64(1)},
{int64(-2), int64(1)},
{int64(3), int64(1)},
{int64(4), int64(0)},
{int64(5), int64(0)},
{int64(6), int64(1)},
{int64(-7), int64(2)},
{int64(-10), int64(2)},
},
},
{
name: "logical_and",
query: `SELECT LOGICAL_AND(x) AS logical_and FROM UNNEST([true, false, true]) AS x`,
expectedRows: [][]interface{}{{false}},
},
{
name: "logical_or",
query: `SELECT LOGICAL_OR(x) AS logical_or FROM UNNEST([true, false, true]) AS x`,
expectedRows: [][]interface{}{{true}},
},
{
name: "max from int group",
query: `SELECT MAX(x) AS max FROM UNNEST([8, 37, 4, 55]) AS x`,
expectedRows: [][]interface{}{{int64(55)}},
},
{
name: "max from date group",
query: `SELECT MAX(x) AS max FROM UNNEST(['2022-01-01', '2022-02-01', '2022-01-02', '2021-03-01']) AS x`,
expectedRows: [][]interface{}{{"2022-02-01"}},
},
{
name: "max window from date group",
query: `SELECT MAX(x) OVER() AS max FROM UNNEST(['2022-01-01', '2022-02-01', '2022-01-02', '2021-03-01']) AS x`,
expectedRows: [][]interface{}{{"2022-02-01"}, {"2022-02-01"}, {"2022-02-01"}, {"2022-02-01"}},
},
{
name: "min from int group",
query: `SELECT MIN(x) AS min FROM UNNEST([8, 37, 4, 55]) AS x`,
expectedRows: [][]interface{}{{int64(4)}},
},
{
name: "min from date group",
query: `SELECT MIN(x) AS min FROM UNNEST(['2022-01-01', '2022-02-01', '2022-01-02', '2021-03-01']) AS x`,
expectedRows: [][]interface{}{{"2021-03-01"}},
},
{
name: "min window from date group",
query: `SELECT MIN(x) OVER() AS max FROM UNNEST(['2022-01-01', '2022-02-01', '2022-01-02', '2021-03-01']) AS x`,
expectedRows: [][]interface{}{{"2021-03-01"}, {"2021-03-01"}, {"2021-03-01"}, {"2021-03-01"}},
},
{
name: "string_agg",
query: `SELECT STRING_AGG(fruit) AS string_agg FROM UNNEST(["apple", NULL, "pear", "banana", "pear"]) AS fruit`,
expectedRows: [][]interface{}{{"apple,pear,banana,pear"}},
},
{
name: "string_agg with delimiter",
query: `SELECT STRING_AGG(fruit, " & ") AS string_agg FROM UNNEST(["apple", "pear", "banana", "pear"]) AS fruit`,
expectedRows: [][]interface{}{{"apple & pear & banana & pear"}},
},
{
name: "string_agg with distinct",
query: `SELECT STRING_AGG(DISTINCT fruit, " & ") AS string_agg FROM UNNEST(["apple", "pear", "banana", "pear"]) AS fruit`,
expectedRows: [][]interface{}{{"apple & pear & banana"}},
},
{
name: "string_agg with order by",
query: `SELECT STRING_AGG(fruit, " & " ORDER BY LENGTH(fruit)) AS string_agg FROM UNNEST(["apple", "pear", "banana", "pear"]) AS fruit`,
expectedRows: [][]interface{}{{"pear & pear & apple & banana"}},
},
{
name: "string_agg with limit",
query: `SELECT STRING_AGG(fruit, " & " LIMIT 2) AS string_agg FROM UNNEST(["apple", "pear", "banana", "pear"]) AS fruit`,
expectedRows: [][]interface{}{{"apple & pear"}},
},
{
name: "string_agg with distinct and order by and limit",
query: `SELECT STRING_AGG(DISTINCT fruit, " & " ORDER BY fruit DESC LIMIT 2) AS string_agg FROM UNNEST(["apple", "pear", "banana", "pear"]) AS fruit`,
expectedRows: [][]interface{}{{"pear & banana"}},
},
{
// TODO: add NULL back to the unnest once ORDER BY does not crash on NULL
name: "string_agg with window",
query: `SELECT fruit, STRING_AGG(fruit, " & ") OVER (ORDER BY LENGTH(fruit)) FROM UNNEST(["apple", "pear", "banana", "pear"]) AS fruit`,
expectedRows: [][]interface{}{
{"pear", "pear & pear"},
{"pear", "pear & pear"},
{"apple", "pear & pear & apple"},
{"banana", "pear & pear & apple & banana"},
},
},
{
name: "sum",
query: `SELECT SUM(x) AS sum FROM UNNEST([1, 2, 3, 4, 5, 4, 3, 2, 1]) AS x`,
expectedRows: [][]interface{}{{int64(25)}},
},
{
name: "sum with distinct",
query: `SELECT SUM(DISTINCT x) AS sum FROM UNNEST([1, 2, 3, 4, 5, 4, 3, 2, 1]) AS x`,
expectedRows: [][]interface{}{{int64(15)}},
},
{
name: "sum with window",
query: `SELECT x, SUM(x) OVER (PARTITION BY MOD(x, 3)) FROM UNNEST([1, 2, 3, 4, 5, 4, 3, 2, 1]) AS x`,
expectedRows: [][]interface{}{
{int64(3), int64(6)},
{int64(3), int64(6)},
{int64(1), int64(10)},
{int64(4), int64(10)},
{int64(4), int64(10)},
{int64(1), int64(10)},
{int64(2), int64(9)},
{int64(5), int64(9)},
{int64(2), int64(9)},
},
},
{
name: "sum with window and distinct",
query: `SELECT x, SUM(DISTINCT x) OVER (PARTITION BY MOD(x, 3)) FROM UNNEST([1, 2, 3, 4, 5, 4, 3, 2, 1]) AS x`,
expectedRows: [][]interface{}{
{int64(3), int64(3)},
{int64(3), int64(3)},
{int64(1), int64(5)},
{int64(4), int64(5)},
{int64(4), int64(5)},
{int64(1), int64(5)},
{int64(2), int64(7)},
{int64(5), int64(7)},
{int64(2), int64(7)},
},
},
{
name: "sum null",
query: `SELECT SUM(x) AS sum FROM UNNEST([]) AS x`,
expectedRows: [][]interface{}{{nil}},
},
{
name: "safe sum",
query: `SELECT SAFE.SUM(x) AS sum FROM UNNEST([1, 2, 3, 4, 5, 4, 3, 2, 1]) AS x`,
expectedErr: "SAFE is not supported for function SUM",
},
{
name: "approx_count_distinct",
query: `SELECT APPROX_COUNT_DISTINCT(x) FROM UNNEST([0, 1, 1, 2, 3, 5]) as x`,
expectedRows: [][]interface{}{{int64(5)}},
},
{
name: "approx_quantiles",
query: `SELECT APPROX_QUANTILES(x, 2) FROM UNNEST([1, 1, 1, 4, 5, 6, 7, 8, 9, 10]) AS x`,
expectedRows: [][]interface{}{{[]interface{}{int64(1), int64(5), int64(10)}}},
},
{
name: "approx_quantiles 2",
query: `SELECT APPROX_QUANTILES(x, 100)[OFFSET(90)] FROM UNNEST([1, 2, 3, 4, 5, 6, 7, 8, 9, 10]) AS x`,
expectedRows: [][]interface{}{{int64(9)}},
},
{
name: "approx_quantiles with distinct",
query: `SELECT APPROX_QUANTILES(DISTINCT x, 2) FROM UNNEST([1, 1, 1, 4, 5, 6, 7, 8, 9, 10]) AS x`,
expectedRows: [][]interface{}{{[]interface{}{int64(1), int64(6), int64(10)}}},
},
{
name: "approx_quantiles with null",
query: `SELECT APPROX_QUANTILES(x, 2 RESPECT NULLS) FROM UNNEST([NULL, NULL, 1, 1, 1, 4, 5, 6, 7, 8, 9, 10]) AS x`,
expectedRows: [][]interface{}{{[]interface{}{nil, int64(4), int64(10)}}},
},
{
name: "approx_quantiles with respect nulls",
query: `SELECT APPROX_QUANTILES(DISTINCT x, 2 RESPECT NULLS) FROM UNNEST([NULL, NULL, 1, 1, 1, 4, 5, 6, 7, 8, 9, 10]) AS x`,
expectedRows: [][]interface{}{{[]interface{}{nil, int64(6), int64(10)}}},
},
{
name: "approx_top_count",
query: `SELECT APPROX_TOP_COUNT(x, 2) FROM UNNEST(["apple", "apple", "pear", "pear", "pear", "banana"]) as x`,
expectedRows: [][]interface{}{
{
[]interface{}{
[]map[string]interface{}{
map[string]interface{}{
"value": "pear",
},
map[string]interface{}{
"count": int64(3),
},
},
[]map[string]interface{}{
map[string]interface{}{
"value": "apple",
},
map[string]interface{}{
"count": int64(2),
},
},
},
},
},
},
{
name: "approx_top_count with null",
query: `SELECT APPROX_TOP_COUNT(x, 2) FROM UNNEST([NULL, "pear", "pear", "pear", "apple", NULL]) as x`,
expectedRows: [][]interface{}{
{
[]interface{}{
[]map[string]interface{}{
map[string]interface{}{
"value": "pear",
},
map[string]interface{}{
"count": int64(3),
},
},
[]map[string]interface{}{
map[string]interface{}{
"value": nil,
},
map[string]interface{}{
"count": int64(2),
},
},
},
},
},
},
{
name: "approx_top_sum",
query: `
SELECT APPROX_TOP_SUM(x, weight, 2) FROM UNNEST([
STRUCT("apple" AS x, 3 AS weight),
("pear", 2),
("apple", 0),
("banana", 5),
("pear", 4)
])`,
expectedRows: [][]interface{}{
{
[]interface{}{
[]map[string]interface{}{
map[string]interface{}{
"value": "pear",
},
map[string]interface{}{
"sum": int64(6),