mirror of
https://github.com/mariadb-corporation/mariadb-columnstore-engine.git
synced 2025-04-26 11:48:52 +03:00
247 lines
6.6 KiB
Plaintext
247 lines
6.6 KiB
Plaintext
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;
|
|
sorted_result;
|
|
SELECT JSON_ARRAYAGG(a), JSON_ARRAYAGG(b) FROM t1;
|
|
sorted_result;
|
|
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;
|
|
sorted_result;
|
|
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;
|
|
sorted_result;
|
|
SELECT JSON_ARRAYAGG(a), JSON_ARRAYAGG(b) FROM t1;
|
|
sorted_result;
|
|
SELECT JSON_ARRAYAGG(a), JSON_ARRAYAGG(b) FROM t1 GROUP BY b;
|
|
sorted_result;
|
|
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;
|
|
sorted_result;
|
|
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;
|
|
sorted_result;
|
|
SELECT JSON_ARRAYAGG(a), JSON_ARRAYAGG(b) FROM t1;
|
|
sorted_result;
|
|
SELECT JSON_ARRAYAGG(a), JSON_ARRAYAGG(b) FROM t1 GROUP BY a;
|
|
|
|
-- echo #
|
|
-- echo # DISTINCT and LIMIT
|
|
-- echo #
|
|
sorted_result;
|
|
SELECT JSON_ARRAYAGG(b LIMIT 1) FROM t1;
|
|
sorted_result;
|
|
SELECT JSON_ARRAYAGG(b LIMIT 2) FROM t1;
|
|
sorted_result;
|
|
SELECT JSON_ARRAYAGG(b LIMIT 1) FROM t1 GROUP BY b;
|
|
sorted_result;
|
|
SELECT JSON_ARRAYAGG(b LIMIT 2) FROM t1 GROUP BY a;
|
|
sorted_result;
|
|
SELECT JSON_ARRAYAGG(DISTINCT a) FROM t1;
|
|
sorted_result;
|
|
SELECT JSON_ARRAYAGG(DISTINCT b) FROM t1;
|
|
sorted_result;
|
|
SELECT JSON_ARRAYAGG(DISTINCT a LIMIT 2) FROM t1;
|
|
sorted_result;
|
|
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;
|
|
sorted_result;
|
|
SELECT JSON_ARRAYAGG(JSON_ARRAY(a, b)) FROM t1;
|
|
sorted_result;
|
|
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;
|
|
sorted_result;
|
|
SELECT JSON_ARRAYAGG(JSON_OBJECT('a', a, 'b', b)) FROM t1;
|
|
sorted_result;
|
|
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 #
|
|
|
|
|
|
DROP TABLE t1;
|
|
|
|
|
|
-- echo #
|
|
-- echo #
|
|
|
|
CREATE TABLE t1 (a INT)ENGINE=COLUMNSTORE;
|
|
SELECT JSON_ARRAYAGG(a) FROM t1;
|
|
DROP TABLE t1;
|
|
|
|
-- echo #
|
|
-- 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;
|
|
|
|
sorted_result;
|
|
SELECT JSON_ARRAYAGG(NULL) FROM (SELECT 1 AS t) AS A;
|
|
sorted_result;
|
|
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;
|
|
|
|
sorted_result;
|
|
select json_arrayagg(a order by a asc) from (select 1 a union select 2 a) t;
|
|
sorted_result;
|
|
select json_object('x', json_arrayagg(json_object('a', 1)));
|
|
|
|
--echo #
|
|
--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);
|
|
sorted_result;
|
|
SELECT JSON_ARRAYAGG(a) FROM t1;
|
|
sorted_result;
|
|
SELECT JSON_ARRAYAGG(DISTINCT a) FROM t1;
|
|
|
|
INSERT INTO t1 VALUES (NULL,NULL), (NULL,NULL);
|
|
|
|
sorted_result;
|
|
SELECT JSON_ARRAYAGG(a) FROM t1;
|
|
sorted_result;
|
|
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);
|
|
|
|
sorted_result;
|
|
SELECT JSON_ARRAYAGG(a) FROM t1;
|
|
sorted_result;
|
|
SELECT JSON_ARRAYAGG(DISTINCT a) FROM t1;
|
|
|
|
INSERT INTO t1 VALUES (NULL,NULL), (NULL,NULL);
|
|
sorted_result;
|
|
SELECT JSON_ARRAYAGG(a) FROM t1;
|
|
sorted_result;
|
|
SELECT JSON_ARRAYAGG(DISTINCT a) FROM t1;
|
|
|
|
DROP TABLE t1;
|
|
|
|
--echo #
|
|
--echo #
|
|
|
|
CREATE TABLE t1(a VARCHAR(255))ENGINE=COLUMNSTORE;
|
|
INSERT INTO t1 VALUES ('red'),('blue');
|
|
|
|
sorted_result;
|
|
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);
|
|
sorted_result;
|
|
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)));
|
|
sorted_result;
|
|
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 #
|
|
|
|
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 #
|
|
|
|
CREATE TABLE t (a VARCHAR(8))ENGINE=COLUMNSTORE;
|
|
CREATE VIEW v AS SELECT * FROM t;
|
|
INSERT INTO t VALUES ('foo'),('bar');
|
|
sorted_result;
|
|
SELECT JSON_ARRAYAGG(a) AS f FROM v;
|
|
DROP VIEW v;
|
|
DROP TABLE t;
|
|
|
|
DROP DATABASE IF EXISTS json_arrayagg_db;
|