Skip to content

Commit d0fc07c

Browse files
committed
MDEV-16620: Add JSON_ARRAYAGG function
The JSON_ARRAYAGG function extends the GROUP_CONCAT function and provides a method of aggregating JSON results. The current implementation supports DISTINCT and LIMIT but not ORDER BY (Oracle supports GROUP BY). Adding GROUP BY support is possible but it requires some extra work as the grouping appears to be done inside a temporary table that complicates matters. Added test cases that covert aggregation of all JSON types and JSON validation for the generated results.
1 parent 4d6a909 commit d0fc07c

File tree

8 files changed

+354
-5
lines changed

8 files changed

+354
-5
lines changed

mysql-test/main/func_json.result

Lines changed: 150 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1028,5 +1028,155 @@ SELECT * FROM t1 WHERE CASE WHEN JSON_OBJECT('x', (SELECT MAX(a=2) FROM t1))='{"
10281028
a
10291029
DROP TABLE t1;
10301030
#
1031+
# MDEV-16620 JSON_ARRAYAGG
1032+
#
1033+
#
1034+
# Integer aggregation
1035+
#
1036+
CREATE TABLE t1 (a INT, b INT);
1037+
INSERT INTO t1 VALUES (1, 1),(2, 1), (1, 1),(2, 1), (3, 2),(2, 2),(2, 2),(2, 2);
1038+
SELECT JSON_VALID(JSON_ARRAYAGG(a)) FROM t1;
1039+
JSON_VALID(JSON_ARRAYAGG(a))
1040+
1
1041+
SELECT JSON_ARRAYAGG(a), JSON_ARRAYAGG(b) FROM t1;
1042+
JSON_ARRAYAGG(a) JSON_ARRAYAGG(b)
1043+
[1,2,1,2,3,2,2,2] [1,1,1,1,2,2,2,2]
1044+
SELECT JSON_ARRAYAGG(a), JSON_ARRAYAGG(b) FROM t1 GROUP BY b;
1045+
JSON_ARRAYAGG(a) JSON_ARRAYAGG(b)
1046+
[1,2,1,2] [1,1,1,1]
1047+
[3,2,2,2] [2,2,2,2]
1048+
DROP TABLE t1;
1049+
#
1050+
# Real aggregation
1051+
#
1052+
CREATE TABLE t1 (a FLOAT, b DOUBLE, c DECIMAL(10, 2));
1053+
INSERT INTO t1 VALUES (1.0, 2.0, 3.0),(1.0, 3.0, 9.0),(1.0, 4.0, 16.0),(1.0, 5.0, 25.0);
1054+
SELECT JSON_VALID(JSON_ARRAYAGG(a)) FROM t1;
1055+
JSON_VALID(JSON_ARRAYAGG(a))
1056+
1
1057+
SELECT JSON_ARRAYAGG(a), JSON_ARRAYAGG(b), JSON_ARRAYAGG(c) FROM t1;
1058+
JSON_ARRAYAGG(a) JSON_ARRAYAGG(b) JSON_ARRAYAGG(c)
1059+
[1,1,1,1] [2,3,4,5] [3.00,9.00,16.00,25.00]
1060+
DROP TABLE t1;
1061+
#
1062+
# Boolean aggregation
1063+
#
1064+
CREATE TABLE t1 (a BOOLEAN, b BOOLEAN);
1065+
INSERT INTO t1 VALUES (TRUE, TRUE), (TRUE, FALSE), (FALSE, TRUE), (FALSE, FALSE);
1066+
SELECT JSON_VALID(JSON_ARRAYAGG(a)) FROM t1;
1067+
JSON_VALID(JSON_ARRAYAGG(a))
1068+
1
1069+
SELECT JSON_ARRAYAGG(a), JSON_ARRAYAGG(b) FROM t1;
1070+
JSON_ARRAYAGG(a) JSON_ARRAYAGG(b)
1071+
[1,1,0,0] [1,0,1,0]
1072+
SELECT JSON_ARRAYAGG(a), JSON_ARRAYAGG(b) FROM t1 GROUP BY b;
1073+
JSON_ARRAYAGG(a) JSON_ARRAYAGG(b)
1074+
[1,0] [0,0]
1075+
[1,0] [1,1]
1076+
SELECT JSON_ARRAYAGG(TRUE), JSON_ARRAYAGG(FALSE) FROM t1;
1077+
JSON_ARRAYAGG(TRUE) JSON_ARRAYAGG(FALSE)
1078+
[true,true,true,true] [false,false,false,false]
1079+
DROP TABLE t1;
1080+
#
1081+
# Aggregation of strings with quoted
1082+
#
1083+
CREATE TABLE t1 (a VARCHAR(80));
1084+
INSERT INTO t1 VALUES
1085+
('"double_quoted_value"'), ("'single_quoted_value'"),
1086+
('"double_quoted_value"'), ("'single_quoted_value'");
1087+
SELECT JSON_VALID(JSON_ARRAYAGG(a)) FROM t1;
1088+
JSON_VALID(JSON_ARRAYAGG(a))
1089+
1
1090+
SELECT JSON_ARRAYAGG(a) FROM t1;
1091+
JSON_ARRAYAGG(a)
1092+
["\"double_quoted_value\"","'single_quoted_value'","\"double_quoted_value\"","'single_quoted_value'"]
1093+
DROP TABLE t1;
1094+
#
1095+
# Strings and NULLs
1096+
#
1097+
CREATE TABLE t1 (a INT, b VARCHAR(80));
1098+
INSERT INTO t1 VALUES
1099+
(1, "Hello"),(1, "World"), (2, "This"),(2, "Will"), (2, "Work"),(2, "!"), (3, NULL),
1100+
(1, "Hello"),(1, "World"), (2, "This"),(2, "Will"), (2, "Work"),(2, "!"), (3, NULL);
1101+
SELECT JSON_VALID(JSON_ARRAYAGG(b)) FROM t1;
1102+
JSON_VALID(JSON_ARRAYAGG(b))
1103+
1
1104+
SELECT JSON_ARRAYAGG(a), JSON_ARRAYAGG(b) FROM t1;
1105+
JSON_ARRAYAGG(a) JSON_ARRAYAGG(b)
1106+
[1,1,2,2,2,2,3,1,1,2,2,2,2,3] ["Hello","World","This","Will","Work","!",null,"Hello","World","This","Will","Work","!",null]
1107+
SELECT JSON_ARRAYAGG(a), JSON_ARRAYAGG(b) FROM t1 GROUP BY a;
1108+
JSON_ARRAYAGG(a) JSON_ARRAYAGG(b)
1109+
[1,1,1,1] ["Hello","World","Hello","World"]
1110+
[2,2,2,2,2,2,2,2] ["!","Work","Will","This","Will","This","!","Work"]
1111+
[3,3] [null,null]
1112+
#
1113+
# DISTINCT and LIMIT
1114+
#
1115+
SELECT JSON_ARRAYAGG(b LIMIT 1) FROM t1;
1116+
JSON_ARRAYAGG(b LIMIT 1)
1117+
["Hello"]
1118+
SELECT JSON_ARRAYAGG(b LIMIT 2) FROM t1;
1119+
JSON_ARRAYAGG(b LIMIT 2)
1120+
["Hello","World"]
1121+
SELECT JSON_ARRAYAGG(b LIMIT 1) FROM t1 GROUP BY b;
1122+
JSON_ARRAYAGG(b LIMIT 1)
1123+
[null]
1124+
["!"]
1125+
["Hello"]
1126+
["This"]
1127+
["Will"]
1128+
["Work"]
1129+
["World"]
1130+
SELECT JSON_ARRAYAGG(b LIMIT 2) FROM t1 GROUP BY a;
1131+
JSON_ARRAYAGG(b LIMIT 2)
1132+
["Hello","World"]
1133+
["!","Work"]
1134+
[null,null]
1135+
SELECT JSON_ARRAYAGG(DISTINCT a) FROM t1;
1136+
JSON_ARRAYAGG(DISTINCT a)
1137+
[1,2,3]
1138+
SELECT JSON_ARRAYAGG(DISTINCT b) FROM t1;
1139+
JSON_ARRAYAGG(DISTINCT b)
1140+
["Hello","World","This","Will","Work","!",null]
1141+
SELECT JSON_ARRAYAGG(DISTINCT a LIMIT 2) FROM t1;
1142+
JSON_ARRAYAGG(DISTINCT a LIMIT 2)
1143+
[1,2]
1144+
SELECT JSON_ARRAYAGG(DISTINCT b LIMIT 2) FROM t1;
1145+
JSON_ARRAYAGG(DISTINCT b LIMIT 2)
1146+
["Hello","World"]
1147+
#
1148+
# JSON aggregation
1149+
#
1150+
SELECT JSON_VALID(JSON_ARRAYAGG(JSON_ARRAY(a, b))) FROM t1;
1151+
JSON_VALID(JSON_ARRAYAGG(JSON_ARRAY(a, b)))
1152+
1
1153+
SELECT JSON_ARRAYAGG(JSON_ARRAY(a, b)) FROM t1;
1154+
JSON_ARRAYAGG(JSON_ARRAY(a, b))
1155+
[[1, "Hello"],[1, "World"],[2, "This"],[2, "Will"],[2, "Work"],[2, "!"],[3, null],[1, "Hello"],[1, "World"],[2, "This"],[2, "Will"],[2, "Work"],[2, "!"],[3, null]]
1156+
SELECT JSON_ARRAYAGG(JSON_ARRAY(a, b)) FROM t1 GROUP BY a;
1157+
JSON_ARRAYAGG(JSON_ARRAY(a, b))
1158+
[[1, "Hello"],[1, "World"],[1, "Hello"],[1, "World"]]
1159+
[[2, "!"],[2, "Work"],[2, "Will"],[2, "This"],[2, "Will"],[2, "This"],[2, "!"],[2, "Work"]]
1160+
[[3, null],[3, null]]
1161+
SELECT JSON_VALID(JSON_ARRAYAGG(JSON_OBJECT('a', a, 'b', b))) FROM t1;
1162+
JSON_VALID(JSON_ARRAYAGG(JSON_OBJECT('a', a, 'b', b)))
1163+
1
1164+
SELECT JSON_ARRAYAGG(JSON_OBJECT('a', a, 'b', b)) FROM t1;
1165+
JSON_ARRAYAGG(JSON_OBJECT('a', a, 'b', b))
1166+
[{"a": 1, "b": "Hello"},{"a": 1, "b": "World"},{"a": 2, "b": "This"},{"a": 2, "b": "Will"},{"a": 2, "b": "Work"},{"a": 2, "b": "!"},{"a": 3, "b": null},{"a": 1, "b": "Hello"},{"a": 1, "b": "World"},{"a": 2, "b": "This"},{"a": 2, "b": "Will"},{"a": 2, "b": "Work"},{"a": 2, "b": "!"},{"a": 3, "b": null}]
1167+
SELECT JSON_ARRAYAGG(JSON_OBJECT('a', a, 'b', b)) FROM t1 GROUP BY a;
1168+
JSON_ARRAYAGG(JSON_OBJECT('a', a, 'b', b))
1169+
[{"a": 1, "b": "Hello"},{"a": 1, "b": "World"},{"a": 1, "b": "Hello"},{"a": 1, "b": "World"}]
1170+
[{"a": 2, "b": "!"},{"a": 2, "b": "Work"},{"a": 2, "b": "Will"},{"a": 2, "b": "This"},{"a": 2, "b": "Will"},{"a": 2, "b": "This"},{"a": 2, "b": "!"},{"a": 2, "b": "Work"}]
1171+
[{"a": 3, "b": null},{"a": 3, "b": null}]
1172+
#
1173+
# Error checks
1174+
#
1175+
SELECT JSON_ARRAYAGG(a, b) FROM t1;
1176+
ERROR 42000: Incorrect parameter count in the call to native function 'JSON_ARRAYAGG'
1177+
SELECT JSON_ARRAYAGG(JSON_ARRAYAGG(a, b)) FROM t1;
1178+
ERROR HY000: Invalid use of group function
1179+
DROP TABLE t1;
1180+
#
10311181
# End of 10.4 tests
10321182
#

mysql-test/main/func_json.test

Lines changed: 90 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -606,6 +606,96 @@ SELECT * FROM t1 WHERE CASE WHEN JSON_OBJECT('x', (SELECT MAX(a=2) FROM t1))='{"
606606
SELECT * FROM t1 WHERE CASE WHEN JSON_OBJECT('x', (SELECT MAX(a=2) FROM t1))='{"x": false}' THEN a END;
607607

608608

609+
DROP TABLE t1;
610+
611+
-- echo #
612+
-- echo # MDEV-16620 JSON_ARRAYAGG
613+
-- echo #
614+
615+
-- echo #
616+
-- echo # Integer aggregation
617+
-- echo #
618+
CREATE TABLE t1 (a INT, b INT);
619+
INSERT INTO t1 VALUES (1, 1),(2, 1), (1, 1),(2, 1), (3, 2),(2, 2),(2, 2),(2, 2);
620+
SELECT JSON_VALID(JSON_ARRAYAGG(a)) FROM t1;
621+
SELECT JSON_ARRAYAGG(a), JSON_ARRAYAGG(b) FROM t1;
622+
SELECT JSON_ARRAYAGG(a), JSON_ARRAYAGG(b) FROM t1 GROUP BY b;
623+
DROP TABLE t1;
624+
625+
-- echo #
626+
-- echo # Real aggregation
627+
-- echo #
628+
CREATE TABLE t1 (a FLOAT, b DOUBLE, c DECIMAL(10, 2));
629+
INSERT INTO t1 VALUES (1.0, 2.0, 3.0),(1.0, 3.0, 9.0),(1.0, 4.0, 16.0),(1.0, 5.0, 25.0);
630+
SELECT JSON_VALID(JSON_ARRAYAGG(a)) FROM t1;
631+
SELECT JSON_ARRAYAGG(a), JSON_ARRAYAGG(b), JSON_ARRAYAGG(c) FROM t1;
632+
DROP TABLE t1;
633+
634+
-- echo #
635+
-- echo # Boolean aggregation
636+
-- echo #
637+
CREATE TABLE t1 (a BOOLEAN, b BOOLEAN);
638+
INSERT INTO t1 VALUES (TRUE, TRUE), (TRUE, FALSE), (FALSE, TRUE), (FALSE, FALSE);
639+
SELECT JSON_VALID(JSON_ARRAYAGG(a)) FROM t1;
640+
SELECT JSON_ARRAYAGG(a), JSON_ARRAYAGG(b) FROM t1;
641+
SELECT JSON_ARRAYAGG(a), JSON_ARRAYAGG(b) FROM t1 GROUP BY b;
642+
SELECT JSON_ARRAYAGG(TRUE), JSON_ARRAYAGG(FALSE) FROM t1;
643+
DROP TABLE t1;
644+
645+
-- echo #
646+
-- echo # Aggregation of strings with quoted
647+
-- echo #
648+
CREATE TABLE t1 (a VARCHAR(80));
649+
INSERT INTO t1 VALUES
650+
('"double_quoted_value"'), ("'single_quoted_value'"),
651+
('"double_quoted_value"'), ("'single_quoted_value'");
652+
SELECT JSON_VALID(JSON_ARRAYAGG(a)) FROM t1;
653+
SELECT JSON_ARRAYAGG(a) FROM t1;
654+
DROP TABLE t1;
655+
656+
-- echo #
657+
-- echo # Strings and NULLs
658+
-- echo #
659+
CREATE TABLE t1 (a INT, b VARCHAR(80));
660+
INSERT INTO t1 VALUES
661+
(1, "Hello"),(1, "World"), (2, "This"),(2, "Will"), (2, "Work"),(2, "!"), (3, NULL),
662+
(1, "Hello"),(1, "World"), (2, "This"),(2, "Will"), (2, "Work"),(2, "!"), (3, NULL);
663+
SELECT JSON_VALID(JSON_ARRAYAGG(b)) FROM t1;
664+
SELECT JSON_ARRAYAGG(a), JSON_ARRAYAGG(b) FROM t1;
665+
SELECT JSON_ARRAYAGG(a), JSON_ARRAYAGG(b) FROM t1 GROUP BY a;
666+
667+
-- echo #
668+
-- echo # DISTINCT and LIMIT
669+
-- echo #
670+
SELECT JSON_ARRAYAGG(b LIMIT 1) FROM t1;
671+
SELECT JSON_ARRAYAGG(b LIMIT 2) FROM t1;
672+
SELECT JSON_ARRAYAGG(b LIMIT 1) FROM t1 GROUP BY b;
673+
SELECT JSON_ARRAYAGG(b LIMIT 2) FROM t1 GROUP BY a;
674+
SELECT JSON_ARRAYAGG(DISTINCT a) FROM t1;
675+
SELECT JSON_ARRAYAGG(DISTINCT b) FROM t1;
676+
SELECT JSON_ARRAYAGG(DISTINCT a LIMIT 2) FROM t1;
677+
SELECT JSON_ARRAYAGG(DISTINCT b LIMIT 2) FROM t1;
678+
679+
-- echo #
680+
-- echo # JSON aggregation
681+
-- echo #
682+
SELECT JSON_VALID(JSON_ARRAYAGG(JSON_ARRAY(a, b))) FROM t1;
683+
SELECT JSON_ARRAYAGG(JSON_ARRAY(a, b)) FROM t1;
684+
SELECT JSON_ARRAYAGG(JSON_ARRAY(a, b)) FROM t1 GROUP BY a;
685+
686+
SELECT JSON_VALID(JSON_ARRAYAGG(JSON_OBJECT('a', a, 'b', b))) FROM t1;
687+
SELECT JSON_ARRAYAGG(JSON_OBJECT('a', a, 'b', b)) FROM t1;
688+
SELECT JSON_ARRAYAGG(JSON_OBJECT('a', a, 'b', b)) FROM t1 GROUP BY a;
689+
690+
-- echo #
691+
-- echo # Error checks
692+
-- echo #
693+
--error ER_WRONG_PARAMCOUNT_TO_NATIVE_FCT
694+
SELECT JSON_ARRAYAGG(a, b) FROM t1;
695+
696+
--error ER_INVALID_GROUP_FUNC_USE
697+
SELECT JSON_ARRAYAGG(JSON_ARRAYAGG(a, b)) FROM t1;
698+
609699
DROP TABLE t1;
610700

611701
--echo #

sql/item_jsonfunc.cc

Lines changed: 22 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -3621,3 +3621,25 @@ int Arg_comparator::compare_e_json_str_basic(Item *j, Item *s)
36213621

36223622
return MY_TEST(sortcmp(res1, res2, compare_collation()) == 0);
36233623
}
3624+
3625+
3626+
String* Item_func_json_arrayagg::convert_to_json(Item *item, String *res)
3627+
{
3628+
String tmp;
3629+
res->length(0);
3630+
append_json_value(res, item, &tmp);
3631+
return res;
3632+
}
3633+
3634+
3635+
String* Item_func_json_arrayagg::val_str(String *str)
3636+
{
3637+
str= Item_func_group_concat::val_str(str);
3638+
String s;
3639+
s.append('[');
3640+
s.swap(*str);
3641+
str->append(s);
3642+
str->append(']');
3643+
3644+
return str;
3645+
}

sql/item_jsonfunc.h

Lines changed: 28 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -23,6 +23,7 @@
2323
#include <json_lib.h>
2424
#include "item_cmpfunc.h" // Item_bool_func
2525
#include "item_strfunc.h" // Item_str_func
26+
#include "item_sum.h"
2627

2728

2829
class json_path_with_flags
@@ -523,4 +524,31 @@ class Item_func_json_format: public Item_json_func
523524
};
524525

525526

527+
class Item_func_json_arrayagg : public Item_func_group_concat
528+
{
529+
public:
530+
531+
Item_func_json_arrayagg(THD *thd, Name_resolution_context *context_arg,
532+
bool is_distinct, List<Item> *is_select,
533+
const SQL_I_List<ORDER> &is_order, String *is_separator,
534+
bool limit_clause, Item *row_limit, Item *offset_limit):
535+
Item_func_group_concat(thd, context_arg, is_distinct, is_select, is_order,
536+
is_separator, limit_clause, row_limit, offset_limit)
537+
{
538+
}
539+
540+
const char *func_name() const { return "json_arrayagg("; }
541+
enum Sumfunctype sum_func() const {return JSON_ARRAYAGG_FUNC;}
542+
543+
String* convert_to_json(Item *item, String *str);
544+
String* val_str(String *str);
545+
546+
/* Overrides Item_func_group_concat::add() */
547+
bool add()
548+
{
549+
return Item_func_group_concat::add(false);
550+
}
551+
};
552+
553+
526554
#endif /* ITEM_JSONFUNC_INCLUDED */

sql/item_sum.cc

Lines changed: 24 additions & 3 deletions
Original file line numberDiff line numberDiff line change
@@ -3535,6 +3535,14 @@ int dump_leaf_key(void* key_arg, element_count count __attribute__((unused)),
35353535
if (item->limit_clause && !(*row_limit))
35363536
return 1;
35373537

3538+
if (item->sum_func() == Item_sum::JSON_ARRAYAGG_FUNC &&
3539+
item->arg_count_field > 1)
3540+
{
3541+
/* JSON_ARRAYAGG supports only one parameter */
3542+
my_error(ER_WRONG_PARAMCOUNT_TO_NATIVE_FCT, MYF(0), "JSON_ARRAYAGG");
3543+
return 1;
3544+
}
3545+
35383546
if (item->no_appended)
35393547
item->no_appended= FALSE;
35403548
else
@@ -3576,7 +3584,19 @@ int dump_leaf_key(void* key_arg, element_count count __attribute__((unused)),
35763584
res= (*arg)->val_str(&tmp);
35773585
}
35783586
if (res)
3587+
{
3588+
if (item->sum_func() == Item_sum::JSON_ARRAYAGG_FUNC)
3589+
{
3590+
/*
3591+
JSON_ARRAYAGG needs to convert the type into valid JSON before
3592+
appending it to the result
3593+
*/
3594+
Item_func_json_arrayagg *arrayagg= (Item_func_json_arrayagg *) item_arg;
3595+
res= arrayagg->convert_to_json(*arg, res);
3596+
}
3597+
35793598
result->append(*res);
3599+
}
35803600
}
35813601

35823602
if (item->limit_clause)
@@ -3882,9 +3902,9 @@ bool Item_func_group_concat::repack_tree(THD *thd)
38823902
*/
38833903
#define GCONCAT_REPACK_FACTOR (1 << 10)
38843904

3885-
bool Item_func_group_concat::add()
3905+
bool Item_func_group_concat::add(bool exclude_nulls)
38863906
{
3887-
if (always_null)
3907+
if (always_null && exclude_nulls)
38883908
return 0;
38893909
copy_fields(tmp_table_param);
38903910
if (copy_funcs(tmp_table_param->items_to_copy, table->in_use))
@@ -3902,7 +3922,8 @@ bool Item_func_group_concat::add()
39023922
Field *field= show_item->get_tmp_table_field();
39033923
if (field)
39043924
{
3905-
if (field->is_null_in_record((const uchar*) table->record[0]))
3925+
if (field->is_null_in_record((const uchar*) table->record[0]) &&
3926+
exclude_nulls)
39063927
return 0; // Skip row if it contains null
39073928
if (tree && (res= field->val_str(&buf)))
39083929
row_str_len+= res->length();

0 commit comments

Comments
 (0)