From 315e4be2d8bbb6a180c63f365b7f7ab4f775ec10 Mon Sep 17 00:00:00 2001 From: mariadb-AndreyPiskunov Date: Wed, 19 Oct 2022 22:43:47 +0300 Subject: [PATCH] First working attempt for json_arrayagg --- dbcon/execplan/jsonarrayaggcolumn.cpp | 3 +- dbcon/joblist/jsonarrayagg.cpp | 42 ++- dbcon/mysql/ha_mcs_execplan.cpp | 3 +- .../basic/r/func_jsonarrayagg.result | 296 ++++++++++++++++++ .../basic/t/func_jsonarrayagg.test | 224 +++++++++++++ 5 files changed, 552 insertions(+), 16 deletions(-) create mode 100644 mysql-test/columnstore/basic/r/func_jsonarrayagg.result create mode 100644 mysql-test/columnstore/basic/t/func_jsonarrayagg.test diff --git a/dbcon/execplan/jsonarrayaggcolumn.cpp b/dbcon/execplan/jsonarrayaggcolumn.cpp index 33809c68e..d197b52ca 100644 --- a/dbcon/execplan/jsonarrayaggcolumn.cpp +++ b/dbcon/execplan/jsonarrayaggcolumn.cpp @@ -96,7 +96,7 @@ void JsonArrayAggColumn::serialize(messageqcpp::ByteStream& b) const for (rcit = fOrderCols.begin(); rcit != fOrderCols.end(); ++rcit) (*rcit)->serialize(b); - b << ','; + b << fSeparator; } void JsonArrayAggColumn::unserialize(messageqcpp::ByteStream& b) @@ -116,6 +116,7 @@ void JsonArrayAggColumn::unserialize(messageqcpp::ByteStream& b) fOrderCols.push_back(srcp); } + b >> fSeparator; } bool JsonArrayAggColumn::operator==(const JsonArrayAggColumn& t) const diff --git a/dbcon/joblist/jsonarrayagg.cpp b/dbcon/joblist/jsonarrayagg.cpp index 8d64a06a1..53938b1d8 100644 --- a/dbcon/joblist/jsonarrayagg.cpp +++ b/dbcon/joblist/jsonarrayagg.cpp @@ -57,6 +57,10 @@ using namespace ordering; #include "limitedorderby.h" #include "mcs_decimal.h" +#include "utils/json/json.hpp" +using namespace nlohmann; + + namespace joblist { @@ -478,8 +482,18 @@ void JsonArrayAggregator::outputRow(std::ostringstream& oss, const rowgroup::Row case CalpontSystemCatalog::VARCHAR: case CalpontSystemCatalog::TEXT: { - oss << "\"" << row.getStringField(*i).c_str() << "\""; - break; + std::string maybeJson = row.getStringField(*i); + try + { + [[maybe_unused]] json j = json::parse(maybeJson); + oss << maybeJson.c_str(); + break; + } + catch (const json::parse_error& e) + { + oss << std::quoted(maybeJson.c_str()); + break; + } } case CalpontSystemCatalog::DOUBLE: @@ -504,25 +518,25 @@ void JsonArrayAggregator::outputRow(std::ostringstream& oss, const rowgroup::Row case CalpontSystemCatalog::DATE: { - oss << "\"" << DataConvert::dateToString(row.getUintField(*i)) << "\""; + oss << std::quoted(DataConvert::dateToString(row.getUintField(*i))); break; } case CalpontSystemCatalog::DATETIME: { - oss << "\"" << DataConvert::datetimeToString(row.getUintField(*i)) << "\""; + oss << std::quoted(DataConvert::datetimeToString(row.getUintField(*i))); break; } case CalpontSystemCatalog::TIMESTAMP: { - oss << "\"" << DataConvert::timestampToString(row.getUintField(*i), fTimeZone) << "\""; + oss << std::quoted(DataConvert::timestampToString(row.getUintField(*i), fTimeZone)); break; } case CalpontSystemCatalog::TIME: { - oss << "\"" << DataConvert::timeToString(row.getUintField(*i)) << "\""; + oss << std::quoted(DataConvert::timeToString(row.getUintField(*i))); break; } @@ -873,15 +887,15 @@ void JsonArrayAggOrderBy::getResult(uint8_t* buff, const string&) // need to reverse the order stack rowStack; - if (fOrderByQueue.size() > 0) + + while (fOrderByQueue.size() > 0) + { + rowStack.push(fOrderByQueue.top()); + fOrderByQueue.pop(); + } + if (rowStack.size() > 0) { oss << '['; - while (fOrderByQueue.size() > 0) - { - rowStack.push(fOrderByQueue.top()); - fOrderByQueue.pop(); - } - while (rowStack.size() > 0) { if (addSep) @@ -1023,7 +1037,7 @@ void JsonArrayAggNoOrder::getResult(uint8_t* buff, const string&) { ostringstream oss; bool addSep = false; - if (fDataQueue.size() > 0) + if (fRowGroup.getRowCount() > 0) { oss << '['; fDataQueue.push(fData); diff --git a/dbcon/mysql/ha_mcs_execplan.cpp b/dbcon/mysql/ha_mcs_execplan.cpp index e33371a6a..83fc958ef 100644 --- a/dbcon/mysql/ha_mcs_execplan.cpp +++ b/dbcon/mysql/ha_mcs_execplan.cpp @@ -4918,7 +4918,8 @@ ReturnedColumn* buildAggregateColumn(Item* item, gp_walk_info& gwi) // Argument_count() is the # of formal parms to the agg fcn. Columnstore // only supports 1 argument except UDAnF, COUNT(DISTINC) and GROUP_CONCAT if (isp->argument_count() != 1 && isp->sum_func() != Item_sum::COUNT_DISTINCT_FUNC && - isp->sum_func() != Item_sum::GROUP_CONCAT_FUNC && isp->sum_func() != Item_sum::UDF_SUM_FUNC) + isp->sum_func() != Item_sum::GROUP_CONCAT_FUNC && isp->sum_func() != Item_sum::UDF_SUM_FUNC && + isp->sum_func() != Item_sum::JSON_ARRAYAGG_FUNC) { gwi.fatalParseError = true; gwi.parseErrorText = IDBErrorInfo::instance()->errorMsg(ERR_MUL_ARG_AGG); diff --git a/mysql-test/columnstore/basic/r/func_jsonarrayagg.result b/mysql-test/columnstore/basic/r/func_jsonarrayagg.result new file mode 100644 index 000000000..8e8214ba6 --- /dev/null +++ b/mysql-test/columnstore/basic/r/func_jsonarrayagg.result @@ -0,0 +1,296 @@ +DROP DATABASE IF EXISTS json_arrayagg_db; +Warnings: +Note 1008 Can't drop database 'json_arrayagg_db'; database doesn't exist +CREATE DATABASE json_arrayagg_db; +USE json_arrayagg_db; +CREATE TABLE t1 (a INT, b INT)ENGINE=COLUMNSTORE; +INSERT INTO t1 VALUES (1, 1),(2, 1), (1, 1),(2, 1), (3, 2),(2, 2),(2, 2),(2, 2); +SELECT JSON_VALID(JSON_ARRAYAGG(a)) FROM t1; +JSON_VALID(JSON_ARRAYAGG(a)) +1 +SELECT JSON_ARRAYAGG(a), JSON_ARRAYAGG(b) FROM t1; +JSON_ARRAYAGG(a) JSON_ARRAYAGG(b) +[1,2,1,2,3,2,2,2] [1,1,1,1,2,2,2,2] +SELECT JSON_ARRAYAGG(a), JSON_ARRAYAGG(b) FROM t1 GROUP BY b; +JSON_ARRAYAGG(a) JSON_ARRAYAGG(b) +[1,2,1,2] [1,1,1,1] +[3,2,2,2] [2,2,2,2] +DROP TABLE t1; +# +# Real aggregation +# +CREATE TABLE t1 (a FLOAT, b DOUBLE, c DECIMAL(10, 2))ENGINE=COLUMNSTORE; +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); +SELECT JSON_VALID(JSON_ARRAYAGG(a)) FROM t1; +JSON_VALID(JSON_ARRAYAGG(a)) +1 +SELECT JSON_ARRAYAGG(a), JSON_ARRAYAGG(b), JSON_ARRAYAGG(c) FROM t1; +JSON_ARRAYAGG(a) JSON_ARRAYAGG(b) JSON_ARRAYAGG(c) +[1,1,1,1] [2,3,4,5] [3.00,9.00,16.00,25.00] +DROP TABLE t1; +# +# Boolean aggregation +# +CREATE TABLE t1 (a BOOLEAN, b BOOLEAN)ENGINE=COLUMNSTORE; +INSERT INTO t1 VALUES (TRUE, TRUE), (TRUE, FALSE), (FALSE, TRUE), (FALSE, FALSE); +SELECT JSON_VALID(JSON_ARRAYAGG(a)) FROM t1; +JSON_VALID(JSON_ARRAYAGG(a)) +1 +SELECT JSON_ARRAYAGG(a), JSON_ARRAYAGG(b) FROM t1; +JSON_ARRAYAGG(a) JSON_ARRAYAGG(b) +[1,1,0,0] [1,0,1,0] +SELECT JSON_ARRAYAGG(a), JSON_ARRAYAGG(b) FROM t1 GROUP BY b; +JSON_ARRAYAGG(a) JSON_ARRAYAGG(b) +[1,0] [0,0] +[1,0] [1,1] +SELECT JSON_ARRAYAGG(TRUE), JSON_ARRAYAGG(FALSE) FROM t1; +JSON_ARRAYAGG(TRUE) JSON_ARRAYAGG(FALSE) +[1,1,1,1] [0,0,0,0] +DROP TABLE t1; +# +# Aggregation of strings with quoted +# +CREATE TABLE t1 (a VARCHAR(80))ENGINE=COLUMNSTORE; +INSERT INTO t1 VALUES +('"double_quoted_value"'), ("'single_quoted_value'"), +('"double_quoted_value"'), ("'single_quoted_value'"); +SELECT JSON_VALID(JSON_ARRAYAGG(a)) FROM t1; +JSON_VALID(JSON_ARRAYAGG(a)) +1 +SELECT JSON_ARRAYAGG(a) FROM t1; +JSON_ARRAYAGG(a) +["double_quoted_value","'single_quoted_value'","double_quoted_value","'single_quoted_value'"] +DROP TABLE t1; +# +# Strings and NULLs +# +CREATE TABLE t1 (a INT, b VARCHAR(80))ENGINE=COLUMNSTORE; +INSERT INTO t1 VALUES +(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); +SELECT JSON_VALID(JSON_ARRAYAGG(b)) FROM t1; +JSON_VALID(JSON_ARRAYAGG(b)) +1 +SELECT JSON_ARRAYAGG(a), JSON_ARRAYAGG(b) FROM t1; +JSON_ARRAYAGG(a) JSON_ARRAYAGG(b) +[1,1,2,2,2,2,3,1,1,2,2,2,2,3] ["Hello","World","This","Will","Work","!","Hello","World","This","Will","Work","!"] +SELECT JSON_ARRAYAGG(a), JSON_ARRAYAGG(b) FROM t1 GROUP BY a; +JSON_ARRAYAGG(a) JSON_ARRAYAGG(b) +[3,3] NULL +[1,1,1,1] ["Hello","World","Hello","World"] +[2,2,2,2,2,2,2,2] ["This","Will","Work","!","This","Will","Work","!"] +# +# DISTINCT and LIMIT +# +SELECT JSON_ARRAYAGG(b LIMIT 1) FROM t1; +JSON_ARRAYAGG(b LIMIT 1) +["Hello","World","This","Will","Work","!","Hello","World","This","Will","Work","!"] +SELECT JSON_ARRAYAGG(b LIMIT 2) FROM t1; +JSON_ARRAYAGG(b LIMIT 2) +["Hello","World","This","Will","Work","!","Hello","World","This","Will","Work","!"] +SELECT JSON_ARRAYAGG(b LIMIT 1) FROM t1 GROUP BY b; +JSON_ARRAYAGG(b LIMIT 1) +["Hello","Hello"] +NULL +["Work","Work"] +["This","This"] +["World","World"] +["!","!"] +["Will","Will"] +SELECT JSON_ARRAYAGG(b LIMIT 2) FROM t1 GROUP BY a; +JSON_ARRAYAGG(b LIMIT 2) +NULL +["Hello","World","Hello","World"] +["This","Will","Work","!","This","Will","Work","!"] +SELECT JSON_ARRAYAGG(DISTINCT a) FROM t1; +JSON_ARRAYAGG(DISTINCT a) +[3,2,1] +SELECT JSON_ARRAYAGG(DISTINCT b) FROM t1; +JSON_ARRAYAGG(DISTINCT b) +["Will","World","Work","!","This","Hello"] +SELECT JSON_ARRAYAGG(DISTINCT a LIMIT 2) FROM t1; +JSON_ARRAYAGG(DISTINCT a LIMIT 2) +[3,2,1] +SELECT JSON_ARRAYAGG(DISTINCT b LIMIT 2) FROM t1; +JSON_ARRAYAGG(DISTINCT b LIMIT 2) +["Will","World","Work","!","This","Hello"] +# +# JSON aggregation +# +SELECT JSON_VALID(JSON_ARRAYAGG(JSON_ARRAY(a, b))) FROM t1; +JSON_VALID(JSON_ARRAYAGG(JSON_ARRAY(a, b))) +1 +SELECT JSON_ARRAYAGG(JSON_ARRAY(a, b)) FROM t1; +JSON_ARRAYAGG(JSON_ARRAY(a, b)) +[[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]] +SELECT JSON_ARRAYAGG(JSON_ARRAY(a, b)) FROM t1 GROUP BY a; +JSON_ARRAYAGG(JSON_ARRAY(a, b)) +[[3, null],[3, null]] +[[1, "Hello"],[1, "World"],[1, "Hello"],[1, "World"]] +[[2, "This"],[2, "Will"],[2, "Work"],[2, "!"],[2, "This"],[2, "Will"],[2, "Work"],[2, "!"]] +SELECT JSON_VALID(JSON_ARRAYAGG(JSON_OBJECT('a', a, 'b', b))) FROM t1; +JSON_VALID(JSON_ARRAYAGG(JSON_OBJECT('a', a, 'b', b))) +1 +SELECT JSON_ARRAYAGG(JSON_OBJECT('a', a, 'b', b)) FROM t1; +JSON_ARRAYAGG(JSON_OBJECT('a', a, 'b', b)) +[{"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}] +SELECT JSON_ARRAYAGG(JSON_OBJECT('a', a, 'b', b)) FROM t1 GROUP BY a; +JSON_ARRAYAGG(JSON_OBJECT('a', a, 'b', b)) +[{"a": 3, "b": null},{"a": 3, "b": null}] +[{"a": 1, "b": "Hello"},{"a": 1, "b": "World"},{"a": 1, "b": "Hello"},{"a": 1, "b": "World"}] +[{"a": 2, "b": "This"},{"a": 2, "b": "Will"},{"a": 2, "b": "Work"},{"a": 2, "b": "!"},{"a": 2, "b": "This"},{"a": 2, "b": "Will"},{"a": 2, "b": "Work"},{"a": 2, "b": "!"}] +# +# Error checks +# +SELECT JSON_ARRAYAGG(a, b) FROM t1; +ERROR 42000: Incorrect parameter count in the call to native function 'JSON_ARRAYAGG' +SELECT JSON_ARRAYAGG(JSON_ARRAYAGG(a, b)) FROM t1; +ERROR 42000: Incorrect parameter count in the call to native function 'JSON_ARRAYAGG' +SELECT JSON_ARRAYAGG(JSON_ARRAYAGG(a)) FROM t1; +ERROR HY000: Invalid use of group function +# +# MDEV-16620 JSON_OBJECTAGG +# +DROP TABLE t1; +# +# End of 10.4 tests +# +# +# MDEV-16620 JSON_ARRAYAGG +# +CREATE TABLE t1 (a INT)ENGINE=COLUMNSTORE; +SELECT JSON_ARRAYAGG(a) FROM t1; +JSON_ARRAYAGG(a) +NULL +DROP TABLE t1; +# +# MDEV-21915 Server crashes in copy_fields,Item_func_group_concat::add +while using json_arrayagg() as a window function +# +select json_arrayagg(a) over () from (select 1 a) t; +ERROR 42000: This version of MariaDB doesn't yet support 'JSON_ARRAYAGG() aggregate as window function' +select json_objectagg(a, b) over () from (select 1 a, 2 b) t; +ERROR 42000: This version of MariaDB doesn't yet support 'JSON_OBJECTAGG() aggregate as window function' +SELECT JSON_ARRAYAGG(NULL) FROM (SELECT 1 AS t) AS A; +JSON_ARRAYAGG(NULL) +[null] +SELECT JSON_ARRAYAGG("null") FROM (SELECT 1 AS t) AS A; +JSON_ARRAYAGG("null") +["null"] +create view v as (select json_arrayagg(json_object("type", "permPeriod", "id", "asd")) as JSON_DATA); +select * from v; +JSON_DATA +[{"type": "permPeriod", "id": "asd"}] +drop view v; +select json_arrayagg(a order by a asc) from (select 1 a union select 2 a) t; +json_arrayagg(a order by a asc) +[1,2] +select json_object('x', json_arrayagg(json_object('a', 1))); +json_object('x', json_arrayagg(json_object('a', 1))) +{"x": [{"a": 1}]} +# +# MDEV-22011: DISTINCT with JSON_ARRAYAGG gives wrong results +# +CREATE TABLE t1(a INT, b INT)ENGINE=COLUMNSTORE; +INSERT INTO t1 VALUES (1,1), (2,2), (3,3); +INSERT INTO t1 VALUES (1,1), (2,2), (3,3); +SELECT JSON_ARRAYAGG(a) FROM t1; +JSON_ARRAYAGG(a) +[1,2,3,1,2,3] +SELECT JSON_ARRAYAGG(DISTINCT a) FROM t1; +JSON_ARRAYAGG(DISTINCT a) +[3,2,1] +INSERT INTO t1 VALUES (NULL,NULL), (NULL,NULL); +SELECT JSON_ARRAYAGG(a) FROM t1; +JSON_ARRAYAGG(a) +[1,2,3,1,2,3] +SELECT JSON_ARRAYAGG(DISTINCT a) FROM t1; +JSON_ARRAYAGG(DISTINCT a) +[3,2,1] +DROP TABLE t1; +CREATE TABLE t1(a VARCHAR(10), b INT)ENGINE=COLUMNSTORE; +INSERT INTO t1 VALUES (1,1), (2,2), (3,3); +INSERT INTO t1 VALUES (1,1), (2,2), (3,3); +SELECT JSON_ARRAYAGG(a) FROM t1; +JSON_ARRAYAGG(a) +[1,2,3,1,2,3] +SELECT JSON_ARRAYAGG(DISTINCT a) FROM t1; +JSON_ARRAYAGG(DISTINCT a) +[3,2,1] +INSERT INTO t1 VALUES (NULL,NULL), (NULL,NULL); +SELECT JSON_ARRAYAGG(a) FROM t1; +JSON_ARRAYAGG(a) +[1,2,3,1,2,3] +SELECT JSON_ARRAYAGG(DISTINCT a) FROM t1; +JSON_ARRAYAGG(DISTINCT a) +[3,2,1] +DROP TABLE t1; +# +# MDEV-22840: JSON_ARRAYAGG gives wrong results with NULL values and ORDER by clause +# +CREATE TABLE t1(a VARCHAR(255))ENGINE=COLUMNSTORE; +INSERT INTO t1 VALUES ('red'),('blue'); +SELECT JSON_ARRAYAGG(a) FROM t1; +JSON_ARRAYAGG(a) +["red","blue"] +SELECT JSON_ARRAYAGG(a ORDER BY a DESC) FROM t1; +JSON_ARRAYAGG(a ORDER BY a DESC) +["red","blue"] +SELECT JSON_ARRAYAGG(a ORDER BY a ASC) FROM t1; +JSON_ARRAYAGG(a ORDER BY a ASC) +["blue","red"] +INSERT INTO t1 VALUES (NULL); +SELECT JSON_ARRAYAGG(a) FROM t1; +JSON_ARRAYAGG(a) +["red","blue"] +SELECT JSON_ARRAYAGG(a ORDER BY a DESC) FROM t1; +JSON_ARRAYAGG(a ORDER BY a DESC) +["red","blue"] +SELECT JSON_ARRAYAGG(a ORDER BY a ASC) FROM t1; +JSON_ARRAYAGG(a ORDER BY a ASC) +["blue","red"] +DROP TABLE t1; +set group_concat_max_len=64; +create table t1 (a varchar(254))ENGINE=COLUMNSTORE; +insert into t1 values (concat('x64-', repeat('a', 60))); +insert into t1 values (concat('x64-', repeat('b', 60))); +insert into t1 values (concat('x64-', repeat('c', 60))); +select json_arrayagg(a) from t1; +json_arrayagg(a) +["x64-aaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaaa +drop table t1; +SET group_concat_max_len= default; +CREATE TABLE t1(id int, name varchar(50))ENGINE=COLUMNSTORE; +CREATE TABLE t2(id int, owner_id int)ENGINE=COLUMNSTORE; +INSERT INTO t1 VALUES (1, "name1"), (2, "name2"), (3, "name3"); +INSERT INTO t2 VALUES (1, 1), (2, 1), (3, 2), (4, 3); +SELECT t1.id, JSON_ARRAYAGG(JSON_OBJECT('id',t2.id) ORDER BY t2.id) as materials +from t1 LEFT JOIN t2 on t1.id = t2.owner_id +GROUP BY t1.id ORDER BY id; +id materials +1 [{"id": 1},{"id": 2}] +2 [{"id": 3}] +3 [{"id": 4}] +DROP TABLE t1; +DROP TABLE t2; +# +# MDEV-27018 IF and COALESCE lose "json" property +# +SELECT json_object('a', if(1, json_object('b', 'c'), json_object('e', 'f'))); +json_object('a', if(1, json_object('b', 'c'), json_object('e', 'f'))) +{"a": {"b": "c"}} +SELECT json_object('a', coalesce(json_object('b', 'c'))); +json_object('a', coalesce(json_object('b', 'c'))) +{"a": {"b": "c"}} +# +# MDEV-26054 Server crashes in Item_func_json_arrayagg::get_str_from_field +# +CREATE TABLE t (a VARCHAR(8))ENGINE=COLUMNSTORE; +CREATE VIEW v AS SELECT * FROM t; +INSERT INTO t VALUES ('foo'),('bar'); +SELECT JSON_ARRAYAGG(a) AS f FROM v; +f +["foo","bar"] +DROP VIEW v; +DROP TABLE t; +DROP DATABASE IF EXISTS json_arrayagg_db; diff --git a/mysql-test/columnstore/basic/t/func_jsonarrayagg.test b/mysql-test/columnstore/basic/t/func_jsonarrayagg.test new file mode 100644 index 000000000..98bf93e36 --- /dev/null +++ b/mysql-test/columnstore/basic/t/func_jsonarrayagg.test @@ -0,0 +1,224 @@ +DROP DATABASE IF EXISTS json_arrayagg_db; +--enable_warnings + +CREATE DATABASE json_arrayagg_db; +USE json_arrayagg_db; + + +CREATE TABLE t1 (a INT, b INT)ENGINE=COLUMNSTORE; +INSERT INTO t1 VALUES (1, 1),(2, 1), (1, 1),(2, 1), (3, 2),(2, 2),(2, 2),(2, 2); +SELECT JSON_VALID(JSON_ARRAYAGG(a)) FROM t1; +SELECT JSON_ARRAYAGG(a), JSON_ARRAYAGG(b) FROM t1; +SELECT JSON_ARRAYAGG(a), JSON_ARRAYAGG(b) FROM t1 GROUP BY b; +DROP TABLE t1; + +-- echo # +-- echo # Real aggregation +-- echo # +CREATE TABLE t1 (a FLOAT, b DOUBLE, c DECIMAL(10, 2))ENGINE=COLUMNSTORE; +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); +SELECT JSON_VALID(JSON_ARRAYAGG(a)) FROM t1; +SELECT JSON_ARRAYAGG(a), JSON_ARRAYAGG(b), JSON_ARRAYAGG(c) FROM t1; +DROP TABLE t1; + +-- echo # +-- echo # Boolean aggregation +-- echo # +CREATE TABLE t1 (a BOOLEAN, b BOOLEAN)ENGINE=COLUMNSTORE; +INSERT INTO t1 VALUES (TRUE, TRUE), (TRUE, FALSE), (FALSE, TRUE), (FALSE, FALSE); +SELECT JSON_VALID(JSON_ARRAYAGG(a)) FROM t1; +SELECT JSON_ARRAYAGG(a), JSON_ARRAYAGG(b) FROM t1; +SELECT JSON_ARRAYAGG(a), JSON_ARRAYAGG(b) FROM t1 GROUP BY b; +SELECT JSON_ARRAYAGG(TRUE), JSON_ARRAYAGG(FALSE) FROM t1; +DROP TABLE t1; + +-- echo # +-- echo # Aggregation of strings with quoted +-- echo # +CREATE TABLE t1 (a VARCHAR(80))ENGINE=COLUMNSTORE; +INSERT INTO t1 VALUES + ('"double_quoted_value"'), ("'single_quoted_value'"), + ('"double_quoted_value"'), ("'single_quoted_value'"); +SELECT JSON_VALID(JSON_ARRAYAGG(a)) FROM t1; +SELECT JSON_ARRAYAGG(a) FROM t1; +DROP TABLE t1; + +-- echo # +-- echo # Strings and NULLs +-- echo # +CREATE TABLE t1 (a INT, b VARCHAR(80))ENGINE=COLUMNSTORE; +INSERT INTO t1 VALUES + (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); +SELECT JSON_VALID(JSON_ARRAYAGG(b)) FROM t1; +SELECT JSON_ARRAYAGG(a), JSON_ARRAYAGG(b) FROM t1; +SELECT JSON_ARRAYAGG(a), JSON_ARRAYAGG(b) FROM t1 GROUP BY a; + +-- echo # +-- echo # DISTINCT and LIMIT +-- echo # +SELECT JSON_ARRAYAGG(b LIMIT 1) FROM t1; +SELECT JSON_ARRAYAGG(b LIMIT 2) FROM t1; +SELECT JSON_ARRAYAGG(b LIMIT 1) FROM t1 GROUP BY b; +SELECT JSON_ARRAYAGG(b LIMIT 2) FROM t1 GROUP BY a; +SELECT JSON_ARRAYAGG(DISTINCT a) FROM t1; +SELECT JSON_ARRAYAGG(DISTINCT b) FROM t1; +SELECT JSON_ARRAYAGG(DISTINCT a LIMIT 2) FROM t1; +SELECT JSON_ARRAYAGG(DISTINCT b LIMIT 2) FROM t1; + +-- echo # +-- echo # JSON aggregation +-- echo # +SELECT JSON_VALID(JSON_ARRAYAGG(JSON_ARRAY(a, b))) FROM t1; +SELECT JSON_ARRAYAGG(JSON_ARRAY(a, b)) FROM t1; +SELECT JSON_ARRAYAGG(JSON_ARRAY(a, b)) FROM t1 GROUP BY a; + +SELECT JSON_VALID(JSON_ARRAYAGG(JSON_OBJECT('a', a, 'b', b))) FROM t1; +SELECT JSON_ARRAYAGG(JSON_OBJECT('a', a, 'b', b)) FROM t1; +SELECT JSON_ARRAYAGG(JSON_OBJECT('a', a, 'b', b)) FROM t1 GROUP BY a; + +-- echo # +-- echo # Error checks +-- echo # +--error ER_WRONG_PARAMCOUNT_TO_NATIVE_FCT +SELECT JSON_ARRAYAGG(a, b) FROM t1; + +--error ER_WRONG_PARAMCOUNT_TO_NATIVE_FCT +SELECT JSON_ARRAYAGG(JSON_ARRAYAGG(a, b)) FROM t1; + +--error ER_INVALID_GROUP_FUNC_USE +SELECT JSON_ARRAYAGG(JSON_ARRAYAGG(a)) FROM t1; + +-- echo # +-- echo # MDEV-16620 JSON_OBJECTAGG +-- echo # + + +DROP TABLE t1; + +--echo # +--echo # End of 10.4 tests +--echo # + +-- echo # +-- echo # MDEV-16620 JSON_ARRAYAGG +-- echo # + +CREATE TABLE t1 (a INT)ENGINE=COLUMNSTORE; +SELECT JSON_ARRAYAGG(a) FROM t1; +DROP TABLE t1; + +-- echo # +-- echo # MDEV-21915 Server crashes in copy_fields,Item_func_group_concat::add +-- echo while using json_arrayagg() as a window function +-- echo # + +--error ER_NOT_SUPPORTED_YET +select json_arrayagg(a) over () from (select 1 a) t; + +--error ER_NOT_SUPPORTED_YET +select json_objectagg(a, b) over () from (select 1 a, 2 b) t; + +SELECT JSON_ARRAYAGG(NULL) FROM (SELECT 1 AS t) AS A; +SELECT JSON_ARRAYAGG("null") FROM (SELECT 1 AS t) AS A; + +create view v as (select json_arrayagg(json_object("type", "permPeriod", "id", "asd")) as JSON_DATA); +select * from v; +drop view v; + +select json_arrayagg(a order by a asc) from (select 1 a union select 2 a) t; + +select json_object('x', json_arrayagg(json_object('a', 1))); + +--echo # +--echo # MDEV-22011: DISTINCT with JSON_ARRAYAGG gives wrong results +--echo # + +CREATE TABLE t1(a INT, b INT)ENGINE=COLUMNSTORE; +INSERT INTO t1 VALUES (1,1), (2,2), (3,3); +INSERT INTO t1 VALUES (1,1), (2,2), (3,3); + +SELECT JSON_ARRAYAGG(a) FROM t1; +SELECT JSON_ARRAYAGG(DISTINCT a) FROM t1; + +INSERT INTO t1 VALUES (NULL,NULL), (NULL,NULL); + +SELECT JSON_ARRAYAGG(a) FROM t1; +SELECT JSON_ARRAYAGG(DISTINCT a) FROM t1; +DROP TABLE t1; + +CREATE TABLE t1(a VARCHAR(10), b INT)ENGINE=COLUMNSTORE; +INSERT INTO t1 VALUES (1,1), (2,2), (3,3); +INSERT INTO t1 VALUES (1,1), (2,2), (3,3); + +SELECT JSON_ARRAYAGG(a) FROM t1; +SELECT JSON_ARRAYAGG(DISTINCT a) FROM t1; + +INSERT INTO t1 VALUES (NULL,NULL), (NULL,NULL); + +SELECT JSON_ARRAYAGG(a) FROM t1; +SELECT JSON_ARRAYAGG(DISTINCT a) FROM t1; + +DROP TABLE t1; + +--echo # +--echo # MDEV-22840: JSON_ARRAYAGG gives wrong results with NULL values and ORDER by clause +--echo # + +CREATE TABLE t1(a VARCHAR(255))ENGINE=COLUMNSTORE; +INSERT INTO t1 VALUES ('red'),('blue'); + +SELECT JSON_ARRAYAGG(a) FROM t1; +SELECT JSON_ARRAYAGG(a ORDER BY a DESC) FROM t1; +SELECT JSON_ARRAYAGG(a ORDER BY a ASC) FROM t1; + +INSERT INTO t1 VALUES (NULL); + +SELECT JSON_ARRAYAGG(a) FROM t1; +SELECT JSON_ARRAYAGG(a ORDER BY a DESC) FROM t1; +SELECT JSON_ARRAYAGG(a ORDER BY a ASC) FROM t1; +DROP TABLE t1; + +set group_concat_max_len=64; +create table t1 (a varchar(254))ENGINE=COLUMNSTORE; +insert into t1 values (concat('x64-', repeat('a', 60))); +insert into t1 values (concat('x64-', repeat('b', 60))); insert into t1 values (concat('x64-', repeat('c', 60))); +select json_arrayagg(a) from t1; +drop table t1; +SET group_concat_max_len= default; + + + +CREATE TABLE t1(id int, name varchar(50))ENGINE=COLUMNSTORE; +CREATE TABLE t2(id int, owner_id int)ENGINE=COLUMNSTORE; + +INSERT INTO t1 VALUES (1, "name1"), (2, "name2"), (3, "name3"); +INSERT INTO t2 VALUES (1, 1), (2, 1), (3, 2), (4, 3); + +SELECT t1.id, JSON_ARRAYAGG(JSON_OBJECT('id',t2.id) ORDER BY t2.id) as materials + from t1 LEFT JOIN t2 on t1.id = t2.owner_id + GROUP BY t1.id ORDER BY id; + +DROP TABLE t1; +DROP TABLE t2; + +--echo # +--echo # MDEV-27018 IF and COALESCE lose "json" property +--echo # + +SELECT json_object('a', if(1, json_object('b', 'c'), json_object('e', 'f'))); +SELECT json_object('a', coalesce(json_object('b', 'c'))); + + +--echo # +--echo # MDEV-26054 Server crashes in Item_func_json_arrayagg::get_str_from_field +--echo # + +CREATE TABLE t (a VARCHAR(8))ENGINE=COLUMNSTORE; +CREATE VIEW v AS SELECT * FROM t; +INSERT INTO t VALUES ('foo'),('bar'); +SELECT JSON_ARRAYAGG(a) AS f FROM v; +DROP VIEW v; +DROP TABLE t; + +DROP DATABASE IF EXISTS json_arrayagg_db; \ No newline at end of file