mirror of https://github.com/citusdata/citus.git
Implemented jsonb_agg, json_agg, jsonb_object_agg, json_object_agg
parent
62237c40a7
commit
6202e80d06
|
@ -14,7 +14,7 @@ EXTVERSIONS = 5.0 5.0-1 5.0-2 \
|
|||
7.0-1 7.0-2 7.0-3 7.0-4 7.0-5 7.0-6 7.0-7 7.0-8 7.0-9 7.0-10 7.0-11 7.0-12 7.0-13 7.0-14 7.0-15 \
|
||||
7.1-1 7.1-2 7.1-3 7.1-4 \
|
||||
7.2-1 7.2-2 7.2-3 \
|
||||
7.3-1 7.3-2
|
||||
7.3-1 7.3-2 7.3-3
|
||||
|
||||
# All citus--*.sql files in the source directory
|
||||
DATA = $(patsubst $(citus_abs_srcdir)/%.sql,%.sql,$(wildcard $(citus_abs_srcdir)/$(EXTENSION)--*--*.sql))
|
||||
|
@ -190,6 +190,8 @@ $(EXTENSION)--7.3-1.sql: $(EXTENSION)--7.2-3.sql $(EXTENSION)--7.2-3--7.3-1.sql
|
|||
cat $^ > $@
|
||||
$(EXTENSION)--7.3-2.sql: $(EXTENSION)--7.3-1.sql $(EXTENSION)--7.3-1--7.3-2.sql
|
||||
cat $^ > $@
|
||||
$(EXTENSION)--7.3-3.sql: $(EXTENSION)--7.3-2.sql $(EXTENSION)--7.3-2--7.3-3.sql
|
||||
cat $^ > $@
|
||||
|
||||
NO_PGXS = 1
|
||||
|
||||
|
|
|
@ -0,0 +1,75 @@
|
|||
/* citus--7.3-2--7.3-3 */
|
||||
|
||||
/*****************************************************************************
|
||||
* Citus json aggregate helpers
|
||||
*****************************************************************************/
|
||||
|
||||
CREATE FUNCTION pg_catalog.citus_jsonb_concatenate(state jsonb, val jsonb)
|
||||
RETURNS jsonb
|
||||
LANGUAGE SQL
|
||||
AS $function$
|
||||
SELECT CASE
|
||||
WHEN val IS NULL THEN state
|
||||
WHEN jsonb_typeof(state) = 'null' THEN val
|
||||
ELSE state || val
|
||||
END;
|
||||
$function$;
|
||||
|
||||
CREATE FUNCTION pg_catalog.citus_jsonb_concatenate_final(state jsonb)
|
||||
RETURNS jsonb
|
||||
LANGUAGE SQL
|
||||
AS $function$
|
||||
SELECT CASE WHEN jsonb_typeof(state) = 'null' THEN NULL ELSE state END;
|
||||
$function$;
|
||||
|
||||
CREATE FUNCTION pg_catalog.citus_json_concatenate(state json, val json)
|
||||
RETURNS json
|
||||
LANGUAGE SQL
|
||||
AS $function$
|
||||
SELECT CASE
|
||||
WHEN val IS NULL THEN state
|
||||
WHEN json_typeof(state) = 'null' THEN val
|
||||
WHEN json_typeof(state) = 'object' THEN
|
||||
(SELECT json_object_agg(key, value) FROM (
|
||||
SELECT * FROM json_each(state)
|
||||
UNION ALL
|
||||
SELECT * FROM json_each(val)
|
||||
) t)
|
||||
ELSE
|
||||
(SELECT json_agg(a) FROM (
|
||||
SELECT json_array_elements(state) AS a
|
||||
UNION ALL
|
||||
SELECT json_array_elements(val) AS a
|
||||
) t)
|
||||
END;
|
||||
$function$;
|
||||
|
||||
CREATE FUNCTION pg_catalog.citus_json_concatenate_final(state json)
|
||||
RETURNS json
|
||||
LANGUAGE SQL
|
||||
AS $function$
|
||||
SELECT CASE WHEN json_typeof(state) = 'null' THEN NULL ELSE state END;
|
||||
$function$;
|
||||
|
||||
|
||||
/*****************************************************************************
|
||||
* Citus json aggregates
|
||||
*****************************************************************************/
|
||||
|
||||
CREATE AGGREGATE pg_catalog.jsonb_cat_agg(jsonb) (
|
||||
SFUNC = citus_jsonb_concatenate,
|
||||
FINALFUNC = citus_jsonb_concatenate_final,
|
||||
STYPE = jsonb,
|
||||
INITCOND = 'null'
|
||||
);
|
||||
COMMENT ON AGGREGATE pg_catalog.jsonb_cat_agg(jsonb)
|
||||
IS 'concatenate input jsonbs into a single jsonb';
|
||||
|
||||
CREATE AGGREGATE pg_catalog.json_cat_agg(json) (
|
||||
SFUNC = citus_json_concatenate,
|
||||
FINALFUNC = citus_json_concatenate_final,
|
||||
STYPE = json,
|
||||
INITCOND = 'null'
|
||||
);
|
||||
COMMENT ON AGGREGATE pg_catalog.json_cat_agg(json)
|
||||
IS 'concatenate input jsons into a single json';
|
|
@ -1,6 +1,6 @@
|
|||
# Citus extension
|
||||
comment = 'Citus distributed database'
|
||||
default_version = '7.3-2'
|
||||
default_version = '7.3-3'
|
||||
module_pathname = '$libdir/citus'
|
||||
relocatable = false
|
||||
schema = pg_catalog
|
||||
|
|
|
@ -155,6 +155,10 @@ static Const * MakeIntegerConstInt64(int64 integerValue);
|
|||
/* Local functions forward declarations for aggregate expression checks */
|
||||
static void ErrorIfContainsUnsupportedAggregate(MultiNode *logicalPlanNode);
|
||||
static void ErrorIfUnsupportedArrayAggregate(Aggref *arrayAggregateExpression);
|
||||
static void ErrorIfUnsupportedJsonAggregate(AggregateType type,
|
||||
Aggref *aggregateExpression);
|
||||
static void ErrorIfUnsupportedJsonObjectAggregate(AggregateType type,
|
||||
Aggref *aggregateExpression);
|
||||
static void ErrorIfUnsupportedAggregateDistinct(Aggref *aggregateExpression,
|
||||
MultiNode *logicalPlanNode);
|
||||
static Var * AggregateDistinctColumn(Aggref *aggregateExpression);
|
||||
|
@ -1585,41 +1589,71 @@ MasterAggregateExpression(Aggref *originalAggregate,
|
|||
|
||||
newMasterExpression = (Expr *) coalesceExpr;
|
||||
}
|
||||
else if (aggregateType == AGGREGATE_ARRAY_AGG)
|
||||
else if (aggregateType == AGGREGATE_ARRAY_AGG ||
|
||||
aggregateType == AGGREGATE_JSONB_AGG ||
|
||||
aggregateType == AGGREGATE_JSONB_OBJECT_AGG ||
|
||||
aggregateType == AGGREGATE_JSON_AGG ||
|
||||
aggregateType == AGGREGATE_JSON_OBJECT_AGG)
|
||||
{
|
||||
/*
|
||||
* Array aggregates are handled in two steps. First, we compute array_agg()
|
||||
* on the worker nodes. Then, we gather the arrays on the master and
|
||||
* compute the array_cat_agg() aggregate on them to get the final array.
|
||||
* Array and json aggregates are handled in two steps. First, we compute
|
||||
* array_agg() or json aggregate on the worker nodes. Then, we gather
|
||||
* the arrays or jsons on the master and compute the array_cat_agg()
|
||||
* or jsonb_cat_agg() aggregate on them to get the final array or json.
|
||||
*/
|
||||
Var *column = NULL;
|
||||
TargetEntry *arrayCatAggArgument = NULL;
|
||||
TargetEntry *catAggArgument = NULL;
|
||||
Aggref *newMasterAggregate = NULL;
|
||||
Oid aggregateFunctionId = InvalidOid;
|
||||
const char *catAggregateName = NULL;
|
||||
Oid catInputType = InvalidOid;
|
||||
|
||||
/* worker aggregate and original aggregate have same return type */
|
||||
Oid workerReturnType = exprType((Node *) originalAggregate);
|
||||
int32 workerReturnTypeMod = exprTypmod((Node *) originalAggregate);
|
||||
Oid workerCollationId = exprCollation((Node *) originalAggregate);
|
||||
|
||||
/* assert that we do not support array_agg() with distinct or order by */
|
||||
/* assert that we do not support array or json aggregation with
|
||||
* distinct or order by */
|
||||
Assert(!originalAggregate->aggorder);
|
||||
Assert(!originalAggregate->aggdistinct);
|
||||
|
||||
/* array_cat_agg() takes anyarray as input */
|
||||
aggregateFunctionId = AggregateFunctionOid(ARRAY_CAT_AGGREGATE_NAME,
|
||||
ANYARRAYOID);
|
||||
if (aggregateType == AGGREGATE_ARRAY_AGG)
|
||||
{
|
||||
/* array_cat_agg() takes anyarray as input */
|
||||
catAggregateName = ARRAY_CAT_AGGREGATE_NAME;
|
||||
catInputType = ANYARRAYOID;
|
||||
}
|
||||
else if (aggregateType == AGGREGATE_JSONB_AGG ||
|
||||
aggregateType == AGGREGATE_JSONB_OBJECT_AGG)
|
||||
{
|
||||
/* jsonb_cat_agg() takes jsonb as input */
|
||||
catAggregateName = JSONB_CAT_AGGREGATE_NAME;
|
||||
catInputType = JSONBOID;
|
||||
}
|
||||
else
|
||||
{
|
||||
/* json_cat_agg() takes json as input */
|
||||
catAggregateName = JSON_CAT_AGGREGATE_NAME;
|
||||
catInputType = JSONOID;
|
||||
}
|
||||
|
||||
/* create argument for the array_cat_agg() aggregate */
|
||||
Assert(catAggregateName != NULL);
|
||||
Assert(catInputType != InvalidOid);
|
||||
|
||||
aggregateFunctionId = AggregateFunctionOid(catAggregateName,
|
||||
catInputType);
|
||||
|
||||
/* create argument for the array_cat_agg() or jsonb_cat_agg() aggregate */
|
||||
column = makeVar(masterTableId, walkerContext->columnId, workerReturnType,
|
||||
workerReturnTypeMod, workerCollationId, columnLevelsUp);
|
||||
arrayCatAggArgument = makeTargetEntry((Expr *) column, argumentId, NULL, false);
|
||||
catAggArgument = makeTargetEntry((Expr *) column, argumentId, NULL, false);
|
||||
walkerContext->columnId++;
|
||||
|
||||
/* construct the master array_cat_agg() expression */
|
||||
/* construct the master array_cat_agg() or jsonb_cat_agg() expression */
|
||||
newMasterAggregate = copyObject(originalAggregate);
|
||||
newMasterAggregate->aggfnoid = aggregateFunctionId;
|
||||
newMasterAggregate->args = list_make1(arrayCatAggArgument);
|
||||
newMasterAggregate->args = list_make1(catAggArgument);
|
||||
newMasterAggregate->aggfilter = NULL;
|
||||
newMasterAggregate->aggtranstype = InvalidOid;
|
||||
newMasterAggregate->aggargtypes = list_make1_oid(ANYARRAYOID);
|
||||
|
@ -2367,7 +2401,7 @@ AggregateArgumentType(Aggref *aggregate)
|
|||
TargetEntry *argument = (TargetEntry *) linitial(argumentList);
|
||||
Oid returnTypeId = exprType((Node *) argument->expr);
|
||||
|
||||
/* We currently support aggregates with only one argument; assert that. */
|
||||
/* Here we currently support aggregates with only one argument; assert that. */
|
||||
Assert(list_length(argumentList) == 1);
|
||||
|
||||
return returnTypeId;
|
||||
|
@ -2702,6 +2736,16 @@ ErrorIfContainsUnsupportedAggregate(MultiNode *logicalPlanNode)
|
|||
{
|
||||
ErrorIfUnsupportedArrayAggregate(aggregateExpression);
|
||||
}
|
||||
else if (aggregateType == AGGREGATE_JSONB_AGG ||
|
||||
aggregateType == AGGREGATE_JSON_AGG)
|
||||
{
|
||||
ErrorIfUnsupportedJsonAggregate(aggregateType, aggregateExpression);
|
||||
}
|
||||
else if (aggregateType == AGGREGATE_JSONB_OBJECT_AGG ||
|
||||
aggregateType == AGGREGATE_JSON_OBJECT_AGG)
|
||||
{
|
||||
ErrorIfUnsupportedJsonObjectAggregate(aggregateType, aggregateExpression);
|
||||
}
|
||||
else if (aggregateExpression->aggdistinct)
|
||||
{
|
||||
ErrorIfUnsupportedAggregateDistinct(aggregateExpression, logicalPlanNode);
|
||||
|
@ -2734,6 +2778,60 @@ ErrorIfUnsupportedArrayAggregate(Aggref *arrayAggregateExpression)
|
|||
}
|
||||
|
||||
|
||||
/*
|
||||
* ErrorIfUnsupportedJsonAggregate checks if we can transform the json
|
||||
* aggregate expression and push it down to the worker node. If we cannot
|
||||
* transform the aggregate, this function errors.
|
||||
*/
|
||||
static void
|
||||
ErrorIfUnsupportedJsonAggregate(AggregateType type,
|
||||
Aggref *aggregateExpression)
|
||||
{
|
||||
/* if json aggregate has order by, we error out */
|
||||
if (aggregateExpression->aggorder)
|
||||
{
|
||||
const char *name = AggregateNames[type];
|
||||
ereport(ERROR, (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
|
||||
errmsg("%s with order by is unsupported", name)));
|
||||
}
|
||||
|
||||
/* if json aggregate has distinct, we error out */
|
||||
if (aggregateExpression->aggdistinct)
|
||||
{
|
||||
const char *name = AggregateNames[type];
|
||||
ereport(ERROR, (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
|
||||
errmsg("%s (distinct) is unsupported", name)));
|
||||
}
|
||||
}
|
||||
|
||||
|
||||
/*
|
||||
* ErrorIfUnsupportedJsonObjectAggregate checks if we can transform the
|
||||
* json object aggregate expression and push it down to the worker node.
|
||||
* If we cannot transform the aggregate, this function errors.
|
||||
*/
|
||||
static void
|
||||
ErrorIfUnsupportedJsonObjectAggregate(AggregateType type,
|
||||
Aggref *aggregateExpression)
|
||||
{
|
||||
/* if json object aggregate has order by, we error out */
|
||||
if (aggregateExpression->aggorder)
|
||||
{
|
||||
const char *name = AggregateNames[type];
|
||||
ereport(ERROR, (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
|
||||
errmsg("%s with order by is unsupported", name)));
|
||||
}
|
||||
|
||||
/* if json object aggregate has distinct, we error out */
|
||||
if (aggregateExpression->aggdistinct)
|
||||
{
|
||||
const char *name = AggregateNames[type];
|
||||
ereport(ERROR, (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
|
||||
errmsg("%s (distinct) is unsupported", name)));
|
||||
}
|
||||
}
|
||||
|
||||
|
||||
/*
|
||||
* ErrorIfUnsupportedAggregateDistinct checks if we can transform the aggregate
|
||||
* (distinct expression) and push it down to the worker node. It handles count
|
||||
|
|
|
@ -24,6 +24,8 @@
|
|||
#define DISABLE_LIMIT_APPROXIMATION -1
|
||||
#define DISABLE_DISTINCT_APPROXIMATION 0.0
|
||||
#define ARRAY_CAT_AGGREGATE_NAME "array_cat_agg"
|
||||
#define JSONB_CAT_AGGREGATE_NAME "jsonb_cat_agg"
|
||||
#define JSON_CAT_AGGREGATE_NAME "json_cat_agg"
|
||||
#define WORKER_COLUMN_FORMAT "worker_column_%d"
|
||||
|
||||
/* Definitions related to count(distinct) approximations */
|
||||
|
@ -55,7 +57,11 @@ typedef enum
|
|||
AGGREGATE_MAX = 3,
|
||||
AGGREGATE_SUM = 4,
|
||||
AGGREGATE_COUNT = 5,
|
||||
AGGREGATE_ARRAY_AGG = 6
|
||||
AGGREGATE_ARRAY_AGG = 6,
|
||||
AGGREGATE_JSONB_AGG = 7,
|
||||
AGGREGATE_JSONB_OBJECT_AGG = 8,
|
||||
AGGREGATE_JSON_AGG = 9,
|
||||
AGGREGATE_JSON_OBJECT_AGG = 10
|
||||
} AggregateType;
|
||||
|
||||
|
||||
|
@ -96,8 +102,10 @@ typedef enum
|
|||
* values in the preceding AggregateType enum. This order needs to be preserved.
|
||||
*/
|
||||
static const char *const AggregateNames[] = {
|
||||
"invalid", "avg", "min", "max", "sum",
|
||||
"count", "array_agg"
|
||||
"invalid", "avg", "min", "max",
|
||||
"sum", "count", "array_agg",
|
||||
"jsonb_agg", "jsonb_object_agg",
|
||||
"json_agg", "json_object_agg"
|
||||
};
|
||||
|
||||
|
||||
|
|
|
@ -132,6 +132,7 @@ ALTER EXTENSION citus UPDATE TO '7.1-4';
|
|||
ALTER EXTENSION citus UPDATE TO '7.2-1';
|
||||
ALTER EXTENSION citus UPDATE TO '7.2-2';
|
||||
ALTER EXTENSION citus UPDATE TO '7.2-3';
|
||||
ALTER EXTENSION citus UPDATE TO '7.3-3';
|
||||
-- show running version
|
||||
SHOW citus.version;
|
||||
citus.version
|
||||
|
|
|
@ -0,0 +1,183 @@
|
|||
--
|
||||
-- MULTI_JSON_AGG
|
||||
--
|
||||
SET citus.next_shard_id TO 520000;
|
||||
CREATE OR REPLACE FUNCTION array_sort (json)
|
||||
RETURNS json LANGUAGE SQL
|
||||
AS $$
|
||||
SELECT json_agg(value) FROM (
|
||||
SELECT value FROM json_array_elements($1) ORDER BY value::jsonb
|
||||
) t
|
||||
$$;
|
||||
-- Check multi_cat_agg() aggregate which is used to implement json_agg()
|
||||
SELECT json_cat_agg(i) FROM
|
||||
(VALUES ('[1,{"a":2}]'::json), ('[null]'::json), (NULL), ('["3",5,4]'::json)) AS t(i);
|
||||
json_cat_agg
|
||||
-------------------------------
|
||||
[1, {"a":2}, null, "3", 5, 4]
|
||||
(1 row)
|
||||
|
||||
-- Check that we don't support distinct and order by with json_agg()
|
||||
SELECT json_agg(distinct l_orderkey) FROM lineitem;
|
||||
ERROR: json_agg (distinct) is unsupported
|
||||
SELECT json_agg(l_orderkey ORDER BY l_partkey) FROM lineitem;
|
||||
ERROR: json_agg with order by is unsupported
|
||||
SELECT json_agg(distinct l_orderkey ORDER BY l_orderkey) FROM lineitem;
|
||||
ERROR: json_agg with order by is unsupported
|
||||
-- Check json_agg() for different data types and LIMIT clauses
|
||||
SELECT array_sort(json_agg(l_partkey)) FROM lineitem GROUP BY l_orderkey
|
||||
ORDER BY l_orderkey LIMIT 10;
|
||||
array_sort
|
||||
--------------------------------------------------------
|
||||
[2132, 15635, 24027, 63700, 67310, 155190]
|
||||
[106170]
|
||||
[4297, 19036, 29380, 62143, 128449, 183095]
|
||||
[88035]
|
||||
[37531, 108570, 123927]
|
||||
[139636]
|
||||
[79251, 94780, 145243, 151894, 157238, 163073, 182052]
|
||||
[2743, 11615, 44161, 82704, 85811, 197921]
|
||||
[33918, 60519, 61336, 137469]
|
||||
[88362, 89414, 169544]
|
||||
(10 rows)
|
||||
|
||||
SELECT array_sort(json_agg(l_extendedprice)) FROM lineitem GROUP BY l_orderkey
|
||||
ORDER BY l_orderkey LIMIT 10;
|
||||
array_sort
|
||||
-----------------------------------------------------------------------
|
||||
[13309.60, 21168.23, 22824.48, 28955.64, 45983.16, 49620.16]
|
||||
[44694.46]
|
||||
[2618.76, 28733.64, 32986.52, 39890.88, 46796.47, 54058.05]
|
||||
[30690.90]
|
||||
[23678.55, 50723.92, 73426.50]
|
||||
[61998.31]
|
||||
[6476.15, 11594.16, 13608.60, 31809.96, 43058.75, 73943.82, 81639.88]
|
||||
[2210.32, 6582.96, 9159.66, 47227.60, 64605.44, 79059.64]
|
||||
[7532.30, 40217.23, 47344.32, 75928.31]
|
||||
[9681.24, 17554.68, 30875.02]
|
||||
(10 rows)
|
||||
|
||||
SELECT array_sort(json_agg(l_shipdate)) FROM lineitem GROUP BY l_orderkey
|
||||
ORDER BY l_orderkey LIMIT 10;
|
||||
array_sort
|
||||
----------------------------------------------------------------------------------------------------
|
||||
["1996-01-29", "1996-01-30", "1996-03-13", "1996-03-30", "1996-04-12", "1996-04-21"]
|
||||
["1997-01-28"]
|
||||
["1993-10-29", "1993-11-09", "1993-12-04", "1993-12-14", "1994-01-16", "1994-02-02"]
|
||||
["1996-01-10"]
|
||||
["1994-08-08", "1994-10-16", "1994-10-31"]
|
||||
["1992-04-27"]
|
||||
["1996-01-15", "1996-01-16", "1996-02-01", "1996-02-10", "1996-02-11", "1996-03-21", "1996-05-07"]
|
||||
["1995-07-21", "1995-08-04", "1995-08-07", "1995-08-14", "1995-08-28", "1995-10-23"]
|
||||
["1993-10-29", "1993-11-09", "1993-12-09", "1993-12-09"]
|
||||
["1998-10-09", "1998-10-23", "1998-10-30"]
|
||||
(10 rows)
|
||||
|
||||
SELECT array_sort(json_agg(l_shipmode)) FROM lineitem GROUP BY l_orderkey
|
||||
ORDER BY l_orderkey LIMIT 10;
|
||||
array_sort
|
||||
----------------------------------------------------------------------------------------------------
|
||||
["AIR ", "FOB ", "MAIL ", "MAIL ", "REG AIR ", "TRUCK "]
|
||||
["RAIL "]
|
||||
["AIR ", "FOB ", "RAIL ", "RAIL ", "SHIP ", "TRUCK "]
|
||||
["REG AIR "]
|
||||
["AIR ", "AIR ", "FOB "]
|
||||
["TRUCK "]
|
||||
["FOB ", "FOB ", "FOB ", "FOB ", "MAIL ", "SHIP ", "TRUCK "]
|
||||
["AIR ", "AIR ", "AIR ", "RAIL ", "REG AIR ", "TRUCK "]
|
||||
["AIR ", "MAIL ", "MAIL ", "TRUCK "]
|
||||
["FOB ", "FOB ", "REG AIR "]
|
||||
(10 rows)
|
||||
|
||||
-- Check that we can execute json_agg() within other functions
|
||||
SELECT json_array_length(json_agg(l_orderkey)) FROM lineitem;
|
||||
json_array_length
|
||||
-------------------
|
||||
12000
|
||||
(1 row)
|
||||
|
||||
-- Check that we can execute json_agg() on select queries that hit multiple
|
||||
-- shards and contain different aggregates, filter clauses and other complex
|
||||
-- expressions. Note that the l_orderkey ranges are such that the matching rows
|
||||
-- lie in different shards.
|
||||
SELECT l_quantity, count(*), avg(l_extendedprice), array_sort(json_agg(l_orderkey)) FROM lineitem
|
||||
WHERE l_quantity < 5 AND l_orderkey > 5500 AND l_orderkey < 9500
|
||||
GROUP BY l_quantity ORDER BY l_quantity;
|
||||
l_quantity | count | avg | array_sort
|
||||
------------+-------+-----------------------+--------------------------------------------------------------------------------------------------------------------
|
||||
1.00 | 17 | 1477.1258823529411765 | [5543, 5633, 5634, 5698, 5766, 5856, 5857, 5986, 8997, 9026, 9158, 9184, 9220, 9222, 9348, 9383, 9476]
|
||||
2.00 | 19 | 3078.4242105263157895 | [5506, 5540, 5573, 5669, 5703, 5730, 5798, 5831, 5893, 5920, 5923, 9030, 9058, 9123, 9124, 9188, 9344, 9441, 9476]
|
||||
3.00 | 14 | 4714.0392857142857143 | [5509, 5543, 5605, 5606, 5827, 9124, 9157, 9184, 9223, 9254, 9349, 9414, 9475, 9477]
|
||||
4.00 | 19 | 5929.7136842105263158 | [5504, 5507, 5508, 5511, 5538, 5764, 5766, 5826, 5829, 5862, 5959, 5985, 9091, 9120, 9281, 9347, 9382, 9440, 9473]
|
||||
(4 rows)
|
||||
|
||||
SELECT l_quantity, array_sort(json_agg(extract (month FROM o_orderdate))) AS my_month
|
||||
FROM lineitem, orders WHERE l_orderkey = o_orderkey AND l_quantity < 5
|
||||
AND l_orderkey > 5500 AND l_orderkey < 9500 GROUP BY l_quantity ORDER BY l_quantity;
|
||||
l_quantity | my_month
|
||||
------------+------------------------------------------------------------------
|
||||
1.00 | [2, 3, 4, 4, 4, 5, 5, 5, 6, 7, 7, 7, 7, 9, 9, 11, 11]
|
||||
2.00 | [1, 3, 5, 5, 5, 5, 6, 6, 6, 7, 7, 8, 10, 10, 11, 11, 11, 12, 12]
|
||||
3.00 | [3, 4, 5, 6, 7, 7, 8, 8, 8, 9, 9, 10, 11, 11]
|
||||
4.00 | [1, 1, 1, 2, 2, 2, 5, 5, 6, 6, 6, 6, 8, 9, 10, 10, 11, 11, 12]
|
||||
(4 rows)
|
||||
|
||||
SELECT l_quantity, array_sort(json_agg(l_orderkey * 2 + 1)) FROM lineitem WHERE l_quantity < 5
|
||||
AND octet_length(l_comment) + octet_length('randomtext'::text) > 40
|
||||
AND l_orderkey > 5500 AND l_orderkey < 9500 GROUP BY l_quantity ORDER BY l_quantity;
|
||||
l_quantity | array_sort
|
||||
------------+---------------------------------------------------
|
||||
1.00 | [11269, 11397, 11713, 11715, 11973, 18317, 18445]
|
||||
2.00 | [11847, 18061, 18247, 18953]
|
||||
3.00 | [18249, 18315, 18699, 18951, 18955]
|
||||
4.00 | [11653, 11659, 18241, 18765]
|
||||
(4 rows)
|
||||
|
||||
-- Check that we can execute json_agg() with an expression containing NULL values
|
||||
SELECT json_agg(case when l_quantity > 20 then l_quantity else NULL end)
|
||||
FROM lineitem WHERE l_orderkey < 5;
|
||||
json_agg
|
||||
-------------------------------------------------------------------------------------------------
|
||||
[null, 36.00, null, 28.00, 24.00, 32.00, 38.00, 45.00, 49.00, 27.00, null, 28.00, 26.00, 30.00]
|
||||
(1 row)
|
||||
|
||||
|
||||
-- Check that we can execute json_agg() with an expression containing different types
|
||||
SELECT json_agg(case when l_quantity > 20 then to_json(l_quantity) else '"f"'::json end)
|
||||
FROM lineitem WHERE l_orderkey < 5;
|
||||
json_agg
|
||||
----------------------------------------------------------------------------------------------
|
||||
["f", 36.00, "f", 28.00, 24.00, 32.00, 38.00, 45.00, 49.00, 27.00, "f", 28.00, 26.00, 30.00]
|
||||
(1 row)
|
||||
|
||||
|
||||
-- Check that we can execute json_agg() with an expression containing json arrays
|
||||
SELECT json_agg(json_build_array(l_quantity, l_shipdate))
|
||||
FROM lineitem WHERE l_orderkey < 3;
|
||||
json_agg
|
||||
------------------------------------------------------------------------------------------------------------------------------------------------------------------
|
||||
[[17.00, "1996-03-13"], [36.00, "1996-04-12"], [8.00, "1996-01-29"], [28.00, "1996-04-21"], [24.00, "1996-03-30"], [32.00, "1996-01-30"], [38.00, "1997-01-28"]]
|
||||
(1 row)
|
||||
|
||||
|
||||
-- Check that we can execute json_agg() with an expression containing arrays
|
||||
SELECT json_agg(ARRAY[l_quantity, l_orderkey])
|
||||
FROM lineitem WHERE l_orderkey < 3;
|
||||
json_agg
|
||||
--------------
|
||||
[[17.00,1], +
|
||||
[36.00,1], +
|
||||
[8.00,1], +
|
||||
[28.00,1], +
|
||||
[24.00,1], +
|
||||
[32.00,1], +
|
||||
[38.00,2]]
|
||||
(1 row)
|
||||
|
||||
-- Check that we return NULL in case there are no input rows to json_agg()
|
||||
SELECT json_agg(l_orderkey) FROM lineitem WHERE l_quantity < 0;
|
||||
json_agg
|
||||
----------
|
||||
|
||||
(1 row)
|
||||
|
|
@ -0,0 +1,192 @@
|
|||
--
|
||||
-- MULTI_JSON_OBJECT_AGG
|
||||
--
|
||||
SET citus.next_shard_id TO 520000;
|
||||
CREATE OR REPLACE FUNCTION count_keys (json)
|
||||
RETURNS bigint LANGUAGE SQL
|
||||
AS $$
|
||||
SELECT count(*) FROM (SELECT * FROM json_object_keys($1)) t
|
||||
$$;
|
||||
CREATE OR REPLACE FUNCTION keys_sort (json)
|
||||
RETURNS json LANGUAGE SQL
|
||||
AS $$
|
||||
SELECT json_object_agg(key, value) FROM (
|
||||
SELECT * FROM json_each($1) ORDER BY key
|
||||
) t
|
||||
$$;
|
||||
-- Check multi_cat_agg() aggregate which is used to implement json_object_agg()
|
||||
SELECT json_cat_agg(i) FROM
|
||||
(VALUES ('{"c":[], "b":2}'::json), (NULL), ('{"d":null, "a":{"b":3}, "b":2}'::json)) AS t(i);
|
||||
json_cat_agg
|
||||
-----------------------------------------------------------
|
||||
{ "c" : [], "b" : 2, "d" : null, "a" : {"b":3}, "b" : 2 }
|
||||
(1 row)
|
||||
|
||||
-- Check that we don't support distinct and order by with json_object_agg()
|
||||
SELECT json_object_agg(distinct l_shipmode, l_orderkey) FROM lineitem;
|
||||
ERROR: json_object_agg (distinct) is unsupported
|
||||
SELECT json_object_agg(l_shipmode, l_orderkey ORDER BY l_shipmode) FROM lineitem;
|
||||
ERROR: json_object_agg with order by is unsupported
|
||||
SELECT json_object_agg(distinct l_orderkey, l_shipmode ORDER BY l_orderkey) FROM lineitem;
|
||||
ERROR: json_object_agg with order by is unsupported
|
||||
-- Check json_object_agg() for different data types and LIMIT clauses
|
||||
SELECT keys_sort(json_object_agg(l_orderkey::text || l_linenumber::text, l_partkey))
|
||||
FROM lineitem GROUP BY l_orderkey
|
||||
ORDER BY l_orderkey LIMIT 10;
|
||||
keys_sort
|
||||
-----------------------------------------------------------------------------------------------------------
|
||||
{ "11" : 155190, "12" : 67310, "13" : 63700, "14" : 2132, "15" : 24027, "16" : 15635 }
|
||||
{ "21" : 106170 }
|
||||
{ "31" : 4297, "32" : 19036, "33" : 128449, "34" : 29380, "35" : 183095, "36" : 62143 }
|
||||
{ "41" : 88035 }
|
||||
{ "51" : 108570, "52" : 123927, "53" : 37531 }
|
||||
{ "61" : 139636 }
|
||||
{ "71" : 182052, "72" : 145243, "73" : 94780, "74" : 163073, "75" : 151894, "76" : 79251, "77" : 157238 }
|
||||
{ "321" : 82704, "322" : 197921, "323" : 44161, "324" : 2743, "325" : 85811, "326" : 11615 }
|
||||
{ "331" : 61336, "332" : 60519, "333" : 137469, "334" : 33918 }
|
||||
{ "341" : 88362, "342" : 89414, "343" : 169544 }
|
||||
(10 rows)
|
||||
|
||||
SELECT keys_sort(json_object_agg(l_orderkey::text || l_linenumber::text, l_extendedprice))
|
||||
FROM lineitem GROUP BY l_orderkey
|
||||
ORDER BY l_orderkey LIMIT 10;
|
||||
keys_sort
|
||||
--------------------------------------------------------------------------------------------------------------------------
|
||||
{ "11" : 21168.23, "12" : 45983.16, "13" : 13309.60, "14" : 28955.64, "15" : 22824.48, "16" : 49620.16 }
|
||||
{ "21" : 44694.46 }
|
||||
{ "31" : 54058.05, "32" : 46796.47, "33" : 39890.88, "34" : 2618.76, "35" : 32986.52, "36" : 28733.64 }
|
||||
{ "41" : 30690.90 }
|
||||
{ "51" : 23678.55, "52" : 50723.92, "53" : 73426.50 }
|
||||
{ "61" : 61998.31 }
|
||||
{ "71" : 13608.60, "72" : 11594.16, "73" : 81639.88, "74" : 31809.96, "75" : 73943.82, "76" : 43058.75, "77" : 6476.15 }
|
||||
{ "321" : 47227.60, "322" : 64605.44, "323" : 2210.32, "324" : 6582.96, "325" : 79059.64, "326" : 9159.66 }
|
||||
{ "331" : 40217.23, "332" : 47344.32, "333" : 7532.30, "334" : 75928.31 }
|
||||
{ "341" : 17554.68, "342" : 30875.02, "343" : 9681.24 }
|
||||
(10 rows)
|
||||
|
||||
SELECT keys_sort(json_object_agg(l_orderkey::text || l_linenumber::text, l_shipmode))
|
||||
FROM lineitem GROUP BY l_orderkey
|
||||
ORDER BY l_orderkey LIMIT 10;
|
||||
keys_sort
|
||||
-------------------------------------------------------------------------------------------------------------------------------------------------------
|
||||
{ "11" : "TRUCK ", "12" : "MAIL ", "13" : "REG AIR ", "14" : "AIR ", "15" : "FOB ", "16" : "MAIL " }
|
||||
{ "21" : "RAIL " }
|
||||
{ "31" : "AIR ", "32" : "RAIL ", "33" : "SHIP ", "34" : "TRUCK ", "35" : "FOB ", "36" : "RAIL " }
|
||||
{ "41" : "REG AIR " }
|
||||
{ "51" : "AIR ", "52" : "FOB ", "53" : "AIR " }
|
||||
{ "61" : "TRUCK " }
|
||||
{ "71" : "FOB ", "72" : "SHIP ", "73" : "MAIL ", "74" : "FOB ", "75" : "TRUCK ", "76" : "FOB ", "77" : "FOB " }
|
||||
{ "321" : "TRUCK ", "322" : "AIR ", "323" : "AIR ", "324" : "REG AIR ", "325" : "AIR ", "326" : "RAIL " }
|
||||
{ "331" : "TRUCK ", "332" : "MAIL ", "333" : "AIR ", "334" : "MAIL " }
|
||||
{ "341" : "REG AIR ", "342" : "FOB ", "343" : "FOB " }
|
||||
(10 rows)
|
||||
|
||||
SELECT keys_sort(json_object_agg(l_orderkey::text || l_linenumber::text, l_shipdate))
|
||||
FROM lineitem GROUP BY l_orderkey
|
||||
ORDER BY l_orderkey LIMIT 10;
|
||||
keys_sort
|
||||
-------------------------------------------------------------------------------------------------------------------------------------------------------
|
||||
{ "11" : "1996-03-13", "12" : "1996-04-12", "13" : "1996-01-29", "14" : "1996-04-21", "15" : "1996-03-30", "16" : "1996-01-30" }
|
||||
{ "21" : "1997-01-28" }
|
||||
{ "31" : "1994-02-02", "32" : "1993-11-09", "33" : "1994-01-16", "34" : "1993-12-04", "35" : "1993-12-14", "36" : "1993-10-29" }
|
||||
{ "41" : "1996-01-10" }
|
||||
{ "51" : "1994-10-31", "52" : "1994-10-16", "53" : "1994-08-08" }
|
||||
{ "61" : "1992-04-27" }
|
||||
{ "71" : "1996-05-07", "72" : "1996-02-01", "73" : "1996-01-15", "74" : "1996-03-21", "75" : "1996-02-11", "76" : "1996-01-16", "77" : "1996-02-10" }
|
||||
{ "321" : "1995-10-23", "322" : "1995-08-14", "323" : "1995-08-07", "324" : "1995-08-04", "325" : "1995-08-28", "326" : "1995-07-21" }
|
||||
{ "331" : "1993-10-29", "332" : "1993-12-09", "333" : "1993-12-09", "334" : "1993-11-09" }
|
||||
{ "341" : "1998-10-23", "342" : "1998-10-09", "343" : "1998-10-30" }
|
||||
(10 rows)
|
||||
|
||||
-- Check that we can execute json_object_agg() within other functions
|
||||
SELECT count_keys(json_object_agg(l_shipdate, l_orderkey)) FROM lineitem;
|
||||
count_keys
|
||||
------------
|
||||
12000
|
||||
(1 row)
|
||||
|
||||
-- Check that we can execute json_object_agg() on select queries that hit multiple
|
||||
-- shards and contain different aggregates, filter clauses and other complex
|
||||
-- expressions. Note that the l_orderkey ranges are such that the matching rows
|
||||
-- lie in different shards.
|
||||
SELECT l_quantity, count(*), avg(l_extendedprice),
|
||||
keys_sort(json_object_agg(l_orderkey::text || l_linenumber::text, l_shipdate))
|
||||
FROM lineitem
|
||||
WHERE l_quantity < 5 AND l_orderkey > 5000 AND l_orderkey < 5300
|
||||
GROUP BY l_quantity ORDER BY l_quantity;
|
||||
l_quantity | count | avg | keys_sort
|
||||
------------+-------+-----------------------+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
|
||||
1.00 | 8 | 1748.3387500000000000 | { "50635" : "1997-09-03", "51551" : "1994-07-03", "51872" : "1997-08-08", "52221" : "1994-08-19", "52832" : "1994-06-20", "52855" : "1994-03-14", "52856" : "1994-02-08", "52861" : "1997-11-25" }
|
||||
2.00 | 8 | 2990.9825000000000000 | { "50292" : "1992-11-25", "50633" : "1997-06-17", "50904" : "1997-04-07", "50952" : "1992-07-09", "51216" : "1992-08-10", "52191" : "1997-06-26", "52501" : "1995-08-09", "52551" : "1996-09-27" }
|
||||
3.00 | 2 | 4744.8000000000000000 | { "50275" : "1997-09-30", "52863" : "1997-12-04" }
|
||||
4.00 | 4 | 5795.6800000000000000 | { "50313" : "1994-12-26", "50622" : "1993-02-06", "50891" : "1992-09-18", "51893" : "1993-12-21" }
|
||||
(4 rows)
|
||||
|
||||
SELECT l_quantity, keys_sort(json_object_agg(l_orderkey::text || l_linenumber::text,
|
||||
extract (month FROM o_orderdate)))
|
||||
FROM lineitem, orders WHERE l_orderkey = o_orderkey AND l_quantity < 5
|
||||
AND l_orderkey > 5000 AND l_orderkey < 5300 GROUP BY l_quantity ORDER BY l_quantity;
|
||||
l_quantity | keys_sort
|
||||
------------+-------------------------------------------------------------------------------------------------------------
|
||||
1.00 | { "50635" : 5, "51551" : 6, "51872" : 7, "52221" : 5, "52832" : 6, "52855" : 1, "52856" : 1, "52861" : 9 }
|
||||
2.00 | { "50292" : 11, "50633" : 5, "50904" : 3, "50952" : 4, "51216" : 5, "52191" : 2, "52501" : 7, "52551" : 7 }
|
||||
3.00 | { "50275" : 8, "52863" : 9 }
|
||||
4.00 | { "50313" : 12, "50622" : 10, "50891" : 7, "51893" : 11 }
|
||||
(4 rows)
|
||||
|
||||
SELECT l_quantity, keys_sort(json_object_agg(l_orderkey::text || l_linenumber::text, l_orderkey * 2 + 1))
|
||||
FROM lineitem WHERE l_quantity < 5
|
||||
AND octet_length(l_comment) + octet_length('randomtext'::text) > 40
|
||||
AND l_orderkey > 5000 AND l_orderkey < 6000 GROUP BY l_quantity ORDER BY l_quantity;
|
||||
l_quantity | keys_sort
|
||||
------------+--------------------------------------------------------------------------------------------------------------------------------------------
|
||||
1.00 | { "51551" : 10311, "52221" : 10445, "52855" : 10571, "56345" : 11269, "56986" : 11397, "58561" : 11713, "58573" : 11715, "59863" : 11973 }
|
||||
2.00 | { "52191" : 10439, "53513" : 10703, "59233" : 11847 }
|
||||
3.00 | { "54401" : 10881 }
|
||||
4.00 | { "50313" : 10063, "50622" : 10125, "58261" : 11653, "58291" : 11659 }
|
||||
(4 rows)
|
||||
|
||||
-- Check that we can execute json_object_agg() with an expression containing NULL values
|
||||
SELECT keys_sort(json_object_agg(l_orderkey::text || l_linenumber::text,
|
||||
case when l_quantity > 20 then l_quantity else NULL end))
|
||||
FROM lineitem WHERE l_orderkey < 5;
|
||||
keys_sort
|
||||
-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
|
||||
{ "11" : null, "12" : 36.00, "13" : null, "14" : 28.00, "15" : 24.00, "16" : 32.00, "21" : 38.00, "31" : 45.00, "32" : 49.00, "33" : 27.00, "34" : null, "35" : 28.00, "36" : 26.00, "41" : 30.00 }
|
||||
(1 row)
|
||||
|
||||
|
||||
-- Check that we can execute json_object_agg() with an expression containing different types
|
||||
SELECT keys_sort(json_object_agg(l_orderkey::text || l_linenumber::text,
|
||||
case when l_quantity > 20 then to_json(l_quantity) else '"f"'::json end))
|
||||
FROM lineitem WHERE l_orderkey < 5;
|
||||
keys_sort
|
||||
--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
|
||||
{ "11" : "f", "12" : 36.00, "13" : "f", "14" : 28.00, "15" : 24.00, "16" : 32.00, "21" : 38.00, "31" : 45.00, "32" : 49.00, "33" : 27.00, "34" : "f", "35" : 28.00, "36" : 26.00, "41" : 30.00 }
|
||||
(1 row)
|
||||
|
||||
|
||||
-- Check that we can execute json_object_agg() with an expression containing json arrays
|
||||
SELECT keys_sort(json_object_agg(l_orderkey::text || l_linenumber::text, json_build_array(l_quantity, l_shipdate)))
|
||||
FROM lineitem WHERE l_orderkey < 3;
|
||||
keys_sort
|
||||
---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
|
||||
{ "11" : [17.00, "1996-03-13"], "12" : [36.00, "1996-04-12"], "13" : [8.00, "1996-01-29"], "14" : [28.00, "1996-04-21"], "15" : [24.00, "1996-03-30"], "16" : [32.00, "1996-01-30"], "21" : [38.00, "1997-01-28"] }
|
||||
(1 row)
|
||||
|
||||
|
||||
-- Check that we can execute json_object_agg() with an expression containing arrays
|
||||
SELECT keys_sort(json_object_agg(l_orderkey::text || l_linenumber::text, ARRAY[l_quantity, l_orderkey]))
|
||||
FROM lineitem WHERE l_orderkey < 3;
|
||||
keys_sort
|
||||
---------------------------------------------------------------------------------------------------------------------------------
|
||||
{ "11" : [17.00,1], "12" : [36.00,1], "13" : [8.00,1], "14" : [28.00,1], "15" : [24.00,1], "16" : [32.00,1], "21" : [38.00,2] }
|
||||
(1 row)
|
||||
|
||||
-- Check that we return NULL in case there are no input rows to json_object_agg()
|
||||
SELECT json_object_agg(l_shipdate, l_orderkey) FROM lineitem WHERE l_quantity < 0;
|
||||
json_object_agg
|
||||
-----------------
|
||||
|
||||
(1 row)
|
||||
|
|
@ -0,0 +1,177 @@
|
|||
--
|
||||
-- MULTI_JSONB_AGG
|
||||
--
|
||||
SET citus.next_shard_id TO 520000;
|
||||
CREATE OR REPLACE FUNCTION array_sort (jsonb)
|
||||
RETURNS jsonb LANGUAGE SQL
|
||||
AS $$
|
||||
SELECT jsonb_agg(value) FROM (
|
||||
SELECT * FROM jsonb_array_elements($1) ORDER BY 1
|
||||
) t
|
||||
$$;
|
||||
-- Check multi_cat_agg() aggregate which is used to implement jsonb_agg()
|
||||
SELECT jsonb_cat_agg(i) FROM
|
||||
(VALUES ('[1,{"a":2}]'::jsonb), ('[null]'::jsonb), (NULL), ('["3",5,4]'::jsonb)) AS t(i);
|
||||
jsonb_cat_agg
|
||||
--------------------------------
|
||||
[1, {"a": 2}, null, "3", 5, 4]
|
||||
(1 row)
|
||||
|
||||
-- Check that we don't support distinct and order by with jsonb_agg()
|
||||
SELECT jsonb_agg(distinct l_orderkey) FROM lineitem;
|
||||
ERROR: jsonb_agg (distinct) is unsupported
|
||||
SELECT jsonb_agg(l_orderkey ORDER BY l_partkey) FROM lineitem;
|
||||
ERROR: jsonb_agg with order by is unsupported
|
||||
SELECT jsonb_agg(distinct l_orderkey ORDER BY l_orderkey) FROM lineitem;
|
||||
ERROR: jsonb_agg with order by is unsupported
|
||||
-- Check jsonb_agg() for different data types and LIMIT clauses
|
||||
SELECT array_sort(jsonb_agg(l_partkey)) FROM lineitem GROUP BY l_orderkey
|
||||
ORDER BY l_orderkey LIMIT 10;
|
||||
array_sort
|
||||
--------------------------------------------------------
|
||||
[2132, 15635, 24027, 63700, 67310, 155190]
|
||||
[106170]
|
||||
[4297, 19036, 29380, 62143, 128449, 183095]
|
||||
[88035]
|
||||
[37531, 108570, 123927]
|
||||
[139636]
|
||||
[79251, 94780, 145243, 151894, 157238, 163073, 182052]
|
||||
[2743, 11615, 44161, 82704, 85811, 197921]
|
||||
[33918, 60519, 61336, 137469]
|
||||
[88362, 89414, 169544]
|
||||
(10 rows)
|
||||
|
||||
SELECT array_sort(jsonb_agg(l_extendedprice)) FROM lineitem GROUP BY l_orderkey
|
||||
ORDER BY l_orderkey LIMIT 10;
|
||||
array_sort
|
||||
-----------------------------------------------------------------------
|
||||
[13309.60, 21168.23, 22824.48, 28955.64, 45983.16, 49620.16]
|
||||
[44694.46]
|
||||
[2618.76, 28733.64, 32986.52, 39890.88, 46796.47, 54058.05]
|
||||
[30690.90]
|
||||
[23678.55, 50723.92, 73426.50]
|
||||
[61998.31]
|
||||
[6476.15, 11594.16, 13608.60, 31809.96, 43058.75, 73943.82, 81639.88]
|
||||
[2210.32, 6582.96, 9159.66, 47227.60, 64605.44, 79059.64]
|
||||
[7532.30, 40217.23, 47344.32, 75928.31]
|
||||
[9681.24, 17554.68, 30875.02]
|
||||
(10 rows)
|
||||
|
||||
SELECT array_sort(jsonb_agg(l_shipdate)) FROM lineitem GROUP BY l_orderkey
|
||||
ORDER BY l_orderkey LIMIT 10;
|
||||
array_sort
|
||||
----------------------------------------------------------------------------------------------------
|
||||
["1996-01-29", "1996-01-30", "1996-03-13", "1996-03-30", "1996-04-12", "1996-04-21"]
|
||||
["1997-01-28"]
|
||||
["1993-10-29", "1993-11-09", "1993-12-04", "1993-12-14", "1994-01-16", "1994-02-02"]
|
||||
["1996-01-10"]
|
||||
["1994-08-08", "1994-10-16", "1994-10-31"]
|
||||
["1992-04-27"]
|
||||
["1996-01-15", "1996-01-16", "1996-02-01", "1996-02-10", "1996-02-11", "1996-03-21", "1996-05-07"]
|
||||
["1995-07-21", "1995-08-04", "1995-08-07", "1995-08-14", "1995-08-28", "1995-10-23"]
|
||||
["1993-10-29", "1993-11-09", "1993-12-09", "1993-12-09"]
|
||||
["1998-10-09", "1998-10-23", "1998-10-30"]
|
||||
(10 rows)
|
||||
|
||||
SELECT array_sort(jsonb_agg(l_shipmode)) FROM lineitem GROUP BY l_orderkey
|
||||
ORDER BY l_orderkey LIMIT 10;
|
||||
array_sort
|
||||
----------------------------------------------------------------------------------------------------
|
||||
["AIR ", "FOB ", "MAIL ", "MAIL ", "REG AIR ", "TRUCK "]
|
||||
["RAIL "]
|
||||
["AIR ", "FOB ", "RAIL ", "RAIL ", "SHIP ", "TRUCK "]
|
||||
["REG AIR "]
|
||||
["AIR ", "AIR ", "FOB "]
|
||||
["TRUCK "]
|
||||
["FOB ", "FOB ", "FOB ", "FOB ", "MAIL ", "SHIP ", "TRUCK "]
|
||||
["AIR ", "AIR ", "AIR ", "RAIL ", "REG AIR ", "TRUCK "]
|
||||
["AIR ", "MAIL ", "MAIL ", "TRUCK "]
|
||||
["FOB ", "FOB ", "REG AIR "]
|
||||
(10 rows)
|
||||
|
||||
-- Check that we can execute jsonb_agg() within other functions
|
||||
SELECT jsonb_array_length(jsonb_agg(l_orderkey)) FROM lineitem;
|
||||
jsonb_array_length
|
||||
--------------------
|
||||
12000
|
||||
(1 row)
|
||||
|
||||
-- Check that we can execute jsonb_agg() on select queries that hit multiple
|
||||
-- shards and contain different aggregates, filter clauses and other complex
|
||||
-- expressions. Note that the l_orderkey ranges are such that the matching rows
|
||||
-- lie in different shards.
|
||||
SELECT l_quantity, count(*), avg(l_extendedprice), array_sort(jsonb_agg(l_orderkey)) FROM lineitem
|
||||
WHERE l_quantity < 5 AND l_orderkey > 5500 AND l_orderkey < 9500
|
||||
GROUP BY l_quantity ORDER BY l_quantity;
|
||||
l_quantity | count | avg | array_sort
|
||||
------------+-------+-----------------------+--------------------------------------------------------------------------------------------------------------------
|
||||
1.00 | 17 | 1477.1258823529411765 | [5543, 5633, 5634, 5698, 5766, 5856, 5857, 5986, 8997, 9026, 9158, 9184, 9220, 9222, 9348, 9383, 9476]
|
||||
2.00 | 19 | 3078.4242105263157895 | [5506, 5540, 5573, 5669, 5703, 5730, 5798, 5831, 5893, 5920, 5923, 9030, 9058, 9123, 9124, 9188, 9344, 9441, 9476]
|
||||
3.00 | 14 | 4714.0392857142857143 | [5509, 5543, 5605, 5606, 5827, 9124, 9157, 9184, 9223, 9254, 9349, 9414, 9475, 9477]
|
||||
4.00 | 19 | 5929.7136842105263158 | [5504, 5507, 5508, 5511, 5538, 5764, 5766, 5826, 5829, 5862, 5959, 5985, 9091, 9120, 9281, 9347, 9382, 9440, 9473]
|
||||
(4 rows)
|
||||
|
||||
SELECT l_quantity, array_sort(jsonb_agg(extract (month FROM o_orderdate))) AS my_month
|
||||
FROM lineitem, orders WHERE l_orderkey = o_orderkey AND l_quantity < 5
|
||||
AND l_orderkey > 5500 AND l_orderkey < 9500 GROUP BY l_quantity ORDER BY l_quantity;
|
||||
l_quantity | my_month
|
||||
------------+------------------------------------------------------------------
|
||||
1.00 | [2, 3, 4, 4, 4, 5, 5, 5, 6, 7, 7, 7, 7, 9, 9, 11, 11]
|
||||
2.00 | [1, 3, 5, 5, 5, 5, 6, 6, 6, 7, 7, 8, 10, 10, 11, 11, 11, 12, 12]
|
||||
3.00 | [3, 4, 5, 6, 7, 7, 8, 8, 8, 9, 9, 10, 11, 11]
|
||||
4.00 | [1, 1, 1, 2, 2, 2, 5, 5, 6, 6, 6, 6, 8, 9, 10, 10, 11, 11, 12]
|
||||
(4 rows)
|
||||
|
||||
SELECT l_quantity, array_sort(jsonb_agg(l_orderkey * 2 + 1)) FROM lineitem WHERE l_quantity < 5
|
||||
AND octet_length(l_comment) + octet_length('randomtext'::text) > 40
|
||||
AND l_orderkey > 5500 AND l_orderkey < 9500 GROUP BY l_quantity ORDER BY l_quantity;
|
||||
l_quantity | array_sort
|
||||
------------+---------------------------------------------------
|
||||
1.00 | [11269, 11397, 11713, 11715, 11973, 18317, 18445]
|
||||
2.00 | [11847, 18061, 18247, 18953]
|
||||
3.00 | [18249, 18315, 18699, 18951, 18955]
|
||||
4.00 | [11653, 11659, 18241, 18765]
|
||||
(4 rows)
|
||||
|
||||
-- Check that we can execute jsonb_agg() with an expression containing NULL values
|
||||
SELECT jsonb_agg(case when l_quantity > 20 then l_quantity else NULL end)
|
||||
FROM lineitem WHERE l_orderkey < 5;
|
||||
jsonb_agg
|
||||
-------------------------------------------------------------------------------------------------
|
||||
[null, 36.00, null, 28.00, 24.00, 32.00, 38.00, 45.00, 49.00, 27.00, null, 28.00, 26.00, 30.00]
|
||||
(1 row)
|
||||
|
||||
|
||||
-- Check that we can execute jsonb_agg() with an expression containing different types
|
||||
SELECT jsonb_agg(case when l_quantity > 20 then to_jsonb(l_quantity) else '"f"'::jsonb end)
|
||||
FROM lineitem WHERE l_orderkey < 5;
|
||||
jsonb_agg
|
||||
----------------------------------------------------------------------------------------------
|
||||
["f", 36.00, "f", 28.00, 24.00, 32.00, 38.00, 45.00, 49.00, 27.00, "f", 28.00, 26.00, 30.00]
|
||||
(1 row)
|
||||
|
||||
|
||||
-- Check that we can execute jsonb_agg() with an expression containing jsonb arrays
|
||||
SELECT jsonb_agg(jsonb_build_array(l_quantity, l_shipdate))
|
||||
FROM lineitem WHERE l_orderkey < 3;
|
||||
jsonb_agg
|
||||
------------------------------------------------------------------------------------------------------------------------------------------------------------------
|
||||
[[17.00, "1996-03-13"], [36.00, "1996-04-12"], [8.00, "1996-01-29"], [28.00, "1996-04-21"], [24.00, "1996-03-30"], [32.00, "1996-01-30"], [38.00, "1997-01-28"]]
|
||||
(1 row)
|
||||
|
||||
|
||||
-- Check that we can execute jsonb_agg() with an expression containing arrays
|
||||
SELECT jsonb_agg(ARRAY[l_quantity, l_orderkey])
|
||||
FROM lineitem WHERE l_orderkey < 3;
|
||||
jsonb_agg
|
||||
-------------------------------------------------------------------------------------
|
||||
[[17.00, 1], [36.00, 1], [8.00, 1], [28.00, 1], [24.00, 1], [32.00, 1], [38.00, 2]]
|
||||
(1 row)
|
||||
|
||||
-- Check that we return NULL in case there are no input rows to jsonb_agg()
|
||||
SELECT jsonb_agg(l_orderkey) FROM lineitem WHERE l_quantity < 0;
|
||||
jsonb_agg
|
||||
-----------
|
||||
|
||||
(1 row)
|
||||
|
|
@ -0,0 +1,185 @@
|
|||
--
|
||||
-- MULTI_JSONB_OBJECT_AGG
|
||||
--
|
||||
SET citus.next_shard_id TO 520000;
|
||||
CREATE OR REPLACE FUNCTION count_keys (jsonb)
|
||||
RETURNS bigint LANGUAGE SQL
|
||||
AS $$
|
||||
SELECT count(*) FROM (SELECT * FROM jsonb_object_keys($1)) t
|
||||
$$;
|
||||
-- Check multi_cat_agg() aggregate which is used to implement jsonb_object_agg()
|
||||
SELECT jsonb_cat_agg(i) FROM
|
||||
(VALUES ('{"c":[], "b":2}'::jsonb), (NULL), ('{"d":null, "a":{"b":3}, "b":2}'::jsonb)) AS t(i);
|
||||
jsonb_cat_agg
|
||||
---------------------------------------------
|
||||
{"a": {"b": 3}, "b": 2, "c": [], "d": null}
|
||||
(1 row)
|
||||
|
||||
-- Check that we don't support distinct and order by with jsonb_object_agg()
|
||||
SELECT jsonb_object_agg(distinct l_shipmode, l_orderkey) FROM lineitem;
|
||||
ERROR: jsonb_object_agg (distinct) is unsupported
|
||||
SELECT jsonb_object_agg(l_shipmode, l_orderkey ORDER BY l_shipmode) FROM lineitem;
|
||||
ERROR: jsonb_object_agg with order by is unsupported
|
||||
SELECT jsonb_object_agg(distinct l_orderkey, l_shipmode ORDER BY l_orderkey) FROM lineitem;
|
||||
ERROR: jsonb_object_agg with order by is unsupported
|
||||
-- Check jsonb_object_agg() for different data types and LIMIT clauses
|
||||
SELECT jsonb_object_agg(l_orderkey::text || l_linenumber::text, l_partkey)
|
||||
FROM lineitem GROUP BY l_orderkey
|
||||
ORDER BY l_orderkey LIMIT 10;
|
||||
jsonb_object_agg
|
||||
--------------------------------------------------------------------------------------------------
|
||||
{"11": 155190, "12": 67310, "13": 63700, "14": 2132, "15": 24027, "16": 15635}
|
||||
{"21": 106170}
|
||||
{"31": 4297, "32": 19036, "33": 128449, "34": 29380, "35": 183095, "36": 62143}
|
||||
{"41": 88035}
|
||||
{"51": 108570, "52": 123927, "53": 37531}
|
||||
{"61": 139636}
|
||||
{"71": 182052, "72": 145243, "73": 94780, "74": 163073, "75": 151894, "76": 79251, "77": 157238}
|
||||
{"321": 82704, "322": 197921, "323": 44161, "324": 2743, "325": 85811, "326": 11615}
|
||||
{"331": 61336, "332": 60519, "333": 137469, "334": 33918}
|
||||
{"341": 88362, "342": 89414, "343": 169544}
|
||||
(10 rows)
|
||||
|
||||
SELECT jsonb_object_agg(l_orderkey::text || l_linenumber::text, l_extendedprice)
|
||||
FROM lineitem GROUP BY l_orderkey
|
||||
ORDER BY l_orderkey LIMIT 10;
|
||||
jsonb_object_agg
|
||||
-----------------------------------------------------------------------------------------------------------------
|
||||
{"11": 21168.23, "12": 45983.16, "13": 13309.60, "14": 28955.64, "15": 22824.48, "16": 49620.16}
|
||||
{"21": 44694.46}
|
||||
{"31": 54058.05, "32": 46796.47, "33": 39890.88, "34": 2618.76, "35": 32986.52, "36": 28733.64}
|
||||
{"41": 30690.90}
|
||||
{"51": 23678.55, "52": 50723.92, "53": 73426.50}
|
||||
{"61": 61998.31}
|
||||
{"71": 13608.60, "72": 11594.16, "73": 81639.88, "74": 31809.96, "75": 73943.82, "76": 43058.75, "77": 6476.15}
|
||||
{"321": 47227.60, "322": 64605.44, "323": 2210.32, "324": 6582.96, "325": 79059.64, "326": 9159.66}
|
||||
{"331": 40217.23, "332": 47344.32, "333": 7532.30, "334": 75928.31}
|
||||
{"341": 17554.68, "342": 30875.02, "343": 9681.24}
|
||||
(10 rows)
|
||||
|
||||
SELECT jsonb_object_agg(l_orderkey::text || l_linenumber::text, l_shipmode)
|
||||
FROM lineitem GROUP BY l_orderkey
|
||||
ORDER BY l_orderkey LIMIT 10;
|
||||
jsonb_object_agg
|
||||
----------------------------------------------------------------------------------------------------------------------------------------------
|
||||
{"11": "TRUCK ", "12": "MAIL ", "13": "REG AIR ", "14": "AIR ", "15": "FOB ", "16": "MAIL "}
|
||||
{"21": "RAIL "}
|
||||
{"31": "AIR ", "32": "RAIL ", "33": "SHIP ", "34": "TRUCK ", "35": "FOB ", "36": "RAIL "}
|
||||
{"41": "REG AIR "}
|
||||
{"51": "AIR ", "52": "FOB ", "53": "AIR "}
|
||||
{"61": "TRUCK "}
|
||||
{"71": "FOB ", "72": "SHIP ", "73": "MAIL ", "74": "FOB ", "75": "TRUCK ", "76": "FOB ", "77": "FOB "}
|
||||
{"321": "TRUCK ", "322": "AIR ", "323": "AIR ", "324": "REG AIR ", "325": "AIR ", "326": "RAIL "}
|
||||
{"331": "TRUCK ", "332": "MAIL ", "333": "AIR ", "334": "MAIL "}
|
||||
{"341": "REG AIR ", "342": "FOB ", "343": "FOB "}
|
||||
(10 rows)
|
||||
|
||||
SELECT jsonb_object_agg(l_orderkey::text || l_linenumber::text, l_shipdate)
|
||||
FROM lineitem GROUP BY l_orderkey
|
||||
ORDER BY l_orderkey LIMIT 10;
|
||||
jsonb_object_agg
|
||||
----------------------------------------------------------------------------------------------------------------------------------------------
|
||||
{"11": "1996-03-13", "12": "1996-04-12", "13": "1996-01-29", "14": "1996-04-21", "15": "1996-03-30", "16": "1996-01-30"}
|
||||
{"21": "1997-01-28"}
|
||||
{"31": "1994-02-02", "32": "1993-11-09", "33": "1994-01-16", "34": "1993-12-04", "35": "1993-12-14", "36": "1993-10-29"}
|
||||
{"41": "1996-01-10"}
|
||||
{"51": "1994-10-31", "52": "1994-10-16", "53": "1994-08-08"}
|
||||
{"61": "1992-04-27"}
|
||||
{"71": "1996-05-07", "72": "1996-02-01", "73": "1996-01-15", "74": "1996-03-21", "75": "1996-02-11", "76": "1996-01-16", "77": "1996-02-10"}
|
||||
{"321": "1995-10-23", "322": "1995-08-14", "323": "1995-08-07", "324": "1995-08-04", "325": "1995-08-28", "326": "1995-07-21"}
|
||||
{"331": "1993-10-29", "332": "1993-12-09", "333": "1993-12-09", "334": "1993-11-09"}
|
||||
{"341": "1998-10-23", "342": "1998-10-09", "343": "1998-10-30"}
|
||||
(10 rows)
|
||||
|
||||
-- Check that we can execute jsonb_object_agg() within other functions
|
||||
SELECT count_keys(jsonb_object_agg(l_shipdate, l_orderkey)) FROM lineitem;
|
||||
count_keys
|
||||
------------
|
||||
2470
|
||||
(1 row)
|
||||
|
||||
-- Check that we can execute jsonb_object_agg() on select queries that hit multiple
|
||||
-- shards and contain different aggregates, filter clauses and other complex
|
||||
-- expressions. Note that the l_orderkey ranges are such that the matching rows
|
||||
-- lie in different shards.
|
||||
SELECT l_quantity, count(*), avg(l_extendedprice),
|
||||
jsonb_object_agg(l_orderkey::text || l_linenumber::text, l_shipdate)
|
||||
FROM lineitem
|
||||
WHERE l_quantity < 5 AND l_orderkey > 5000 AND l_orderkey < 5300
|
||||
GROUP BY l_quantity ORDER BY l_quantity;
|
||||
l_quantity | count | avg | jsonb_object_agg
|
||||
------------+-------+-----------------------+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
|
||||
1.00 | 8 | 1748.3387500000000000 | {"50635": "1997-09-03", "51551": "1994-07-03", "51872": "1997-08-08", "52221": "1994-08-19", "52832": "1994-06-20", "52855": "1994-03-14", "52856": "1994-02-08", "52861": "1997-11-25"}
|
||||
2.00 | 8 | 2990.9825000000000000 | {"50292": "1992-11-25", "50633": "1997-06-17", "50904": "1997-04-07", "50952": "1992-07-09", "51216": "1992-08-10", "52191": "1997-06-26", "52501": "1995-08-09", "52551": "1996-09-27"}
|
||||
3.00 | 2 | 4744.8000000000000000 | {"50275": "1997-09-30", "52863": "1997-12-04"}
|
||||
4.00 | 4 | 5795.6800000000000000 | {"50313": "1994-12-26", "50622": "1993-02-06", "50891": "1992-09-18", "51893": "1993-12-21"}
|
||||
(4 rows)
|
||||
|
||||
SELECT l_quantity, jsonb_object_agg(l_orderkey::text || l_linenumber::text,
|
||||
extract (month FROM o_orderdate))
|
||||
FROM lineitem, orders WHERE l_orderkey = o_orderkey AND l_quantity < 5
|
||||
AND l_orderkey > 5000 AND l_orderkey < 5300 GROUP BY l_quantity ORDER BY l_quantity;
|
||||
l_quantity | jsonb_object_agg
|
||||
------------+---------------------------------------------------------------------------------------------------
|
||||
1.00 | {"50635": 5, "51551": 6, "51872": 7, "52221": 5, "52832": 6, "52855": 1, "52856": 1, "52861": 9}
|
||||
2.00 | {"50292": 11, "50633": 5, "50904": 3, "50952": 4, "51216": 5, "52191": 2, "52501": 7, "52551": 7}
|
||||
3.00 | {"50275": 8, "52863": 9}
|
||||
4.00 | {"50313": 12, "50622": 10, "50891": 7, "51893": 11}
|
||||
(4 rows)
|
||||
|
||||
SELECT l_quantity, jsonb_object_agg(l_orderkey::text || l_linenumber::text, l_orderkey * 2 + 1)
|
||||
FROM lineitem WHERE l_quantity < 5
|
||||
AND octet_length(l_comment) + octet_length('randomtext'::text) > 40
|
||||
AND l_orderkey > 5000 AND l_orderkey < 6000 GROUP BY l_quantity ORDER BY l_quantity;
|
||||
l_quantity | jsonb_object_agg
|
||||
------------+----------------------------------------------------------------------------------------------------------------------------------
|
||||
1.00 | {"51551": 10311, "52221": 10445, "52855": 10571, "56345": 11269, "56986": 11397, "58561": 11713, "58573": 11715, "59863": 11973}
|
||||
2.00 | {"52191": 10439, "53513": 10703, "59233": 11847}
|
||||
3.00 | {"54401": 10881}
|
||||
4.00 | {"50313": 10063, "50622": 10125, "58261": 11653, "58291": 11659}
|
||||
(4 rows)
|
||||
|
||||
-- Check that we can execute jsonb_object_agg() with an expression containing NULL values
|
||||
SELECT jsonb_object_agg(l_orderkey::text || l_linenumber::text,
|
||||
case when l_quantity > 20 then l_quantity else NULL end)
|
||||
FROM lineitem WHERE l_orderkey < 5;
|
||||
jsonb_object_agg
|
||||
-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
|
||||
{"11": null, "12": 36.00, "13": null, "14": 28.00, "15": 24.00, "16": 32.00, "21": 38.00, "31": 45.00, "32": 49.00, "33": 27.00, "34": null, "35": 28.00, "36": 26.00, "41": 30.00}
|
||||
(1 row)
|
||||
|
||||
|
||||
-- Check that we can execute jsonb_object_agg() with an expression containing different types
|
||||
SELECT jsonb_object_agg(l_orderkey::text || l_linenumber::text,
|
||||
case when l_quantity > 20 then to_jsonb(l_quantity) else '"f"'::jsonb end)
|
||||
FROM lineitem WHERE l_orderkey < 5;
|
||||
jsonb_object_agg
|
||||
----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
|
||||
{"11": "f", "12": 36.00, "13": "f", "14": 28.00, "15": 24.00, "16": 32.00, "21": 38.00, "31": 45.00, "32": 49.00, "33": 27.00, "34": "f", "35": 28.00, "36": 26.00, "41": 30.00}
|
||||
(1 row)
|
||||
|
||||
|
||||
-- Check that we can execute jsonb_object_agg() with an expression containing jsonb arrays
|
||||
SELECT jsonb_object_agg(l_orderkey::text || l_linenumber::text, jsonb_build_array(l_quantity, l_shipdate))
|
||||
FROM lineitem WHERE l_orderkey < 3;
|
||||
jsonb_object_agg
|
||||
------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
|
||||
{"11": [17.00, "1996-03-13"], "12": [36.00, "1996-04-12"], "13": [8.00, "1996-01-29"], "14": [28.00, "1996-04-21"], "15": [24.00, "1996-03-30"], "16": [32.00, "1996-01-30"], "21": [38.00, "1997-01-28"]}
|
||||
(1 row)
|
||||
|
||||
|
||||
-- Check that we can execute jsonb_object_agg() with an expression containing arrays
|
||||
SELECT jsonb_object_agg(l_orderkey::text || l_linenumber::text, ARRAY[l_quantity, l_orderkey])
|
||||
FROM lineitem WHERE l_orderkey < 3;
|
||||
jsonb_object_agg
|
||||
-------------------------------------------------------------------------------------------------------------------------------
|
||||
{"11": [17.00, 1], "12": [36.00, 1], "13": [8.00, 1], "14": [28.00, 1], "15": [24.00, 1], "16": [32.00, 1], "21": [38.00, 2]}
|
||||
(1 row)
|
||||
|
||||
-- Check that we return NULL in case there are no input rows to jsonb_object_agg()
|
||||
SELECT jsonb_object_agg(l_shipdate, l_orderkey) FROM lineitem WHERE l_quantity < 0;
|
||||
jsonb_object_agg
|
||||
------------------
|
||||
|
||||
(1 row)
|
||||
|
|
@ -685,7 +685,7 @@ DEBUG: Plan 69 query after replacing subqueries and CTEs: SELECT count(*) AS co
|
|||
(1 row)
|
||||
|
||||
DROP TABLE local_table;
|
||||
DEBUG: EventTriggerInvoke 19921
|
||||
DEBUG: EventTriggerInvoke 19977
|
||||
SET client_min_messages TO DEFAULT;
|
||||
DROP SCHEMA subquery_in_where CASCADE;
|
||||
SET search_path TO public;
|
||||
|
|
|
@ -59,6 +59,10 @@ test: multi_agg_distinct multi_agg_approximate_distinct multi_limit_clause_appro
|
|||
test: multi_reference_table
|
||||
test: multi_average_expression multi_working_columns multi_having_pushdown
|
||||
test: multi_array_agg multi_limit_clause
|
||||
test: multi_jsonb_agg
|
||||
test: multi_jsonb_object_agg
|
||||
test: multi_json_agg
|
||||
test: multi_json_object_agg
|
||||
test: multi_agg_type_conversion multi_count_type_conversion
|
||||
test: multi_partition_pruning
|
||||
test: multi_join_pruning multi_hash_pruning
|
||||
|
|
|
@ -132,6 +132,7 @@ ALTER EXTENSION citus UPDATE TO '7.1-4';
|
|||
ALTER EXTENSION citus UPDATE TO '7.2-1';
|
||||
ALTER EXTENSION citus UPDATE TO '7.2-2';
|
||||
ALTER EXTENSION citus UPDATE TO '7.2-3';
|
||||
ALTER EXTENSION citus UPDATE TO '7.3-3';
|
||||
|
||||
-- show running version
|
||||
SHOW citus.version;
|
||||
|
|
|
@ -0,0 +1,86 @@
|
|||
--
|
||||
-- MULTI_JSON_AGG
|
||||
--
|
||||
|
||||
|
||||
SET citus.next_shard_id TO 520000;
|
||||
|
||||
CREATE OR REPLACE FUNCTION array_sort (json)
|
||||
RETURNS json LANGUAGE SQL
|
||||
AS $$
|
||||
SELECT json_agg(value) FROM (
|
||||
SELECT value FROM json_array_elements($1) ORDER BY value::jsonb
|
||||
) t
|
||||
$$;
|
||||
|
||||
-- Check multi_cat_agg() aggregate which is used to implement json_agg()
|
||||
|
||||
SELECT json_cat_agg(i) FROM
|
||||
(VALUES ('[1,{"a":2}]'::json), ('[null]'::json), (NULL), ('["3",5,4]'::json)) AS t(i);
|
||||
|
||||
-- Check that we don't support distinct and order by with json_agg()
|
||||
|
||||
SELECT json_agg(distinct l_orderkey) FROM lineitem;
|
||||
|
||||
SELECT json_agg(l_orderkey ORDER BY l_partkey) FROM lineitem;
|
||||
|
||||
SELECT json_agg(distinct l_orderkey ORDER BY l_orderkey) FROM lineitem;
|
||||
|
||||
-- Check json_agg() for different data types and LIMIT clauses
|
||||
|
||||
SELECT array_sort(json_agg(l_partkey)) FROM lineitem GROUP BY l_orderkey
|
||||
ORDER BY l_orderkey LIMIT 10;
|
||||
|
||||
SELECT array_sort(json_agg(l_extendedprice)) FROM lineitem GROUP BY l_orderkey
|
||||
ORDER BY l_orderkey LIMIT 10;
|
||||
|
||||
SELECT array_sort(json_agg(l_shipdate)) FROM lineitem GROUP BY l_orderkey
|
||||
ORDER BY l_orderkey LIMIT 10;
|
||||
|
||||
SELECT array_sort(json_agg(l_shipmode)) FROM lineitem GROUP BY l_orderkey
|
||||
ORDER BY l_orderkey LIMIT 10;
|
||||
|
||||
-- Check that we can execute json_agg() within other functions
|
||||
|
||||
SELECT json_array_length(json_agg(l_orderkey)) FROM lineitem;
|
||||
|
||||
-- Check that we can execute json_agg() on select queries that hit multiple
|
||||
-- shards and contain different aggregates, filter clauses and other complex
|
||||
-- expressions. Note that the l_orderkey ranges are such that the matching rows
|
||||
-- lie in different shards.
|
||||
|
||||
SELECT l_quantity, count(*), avg(l_extendedprice), array_sort(json_agg(l_orderkey)) FROM lineitem
|
||||
WHERE l_quantity < 5 AND l_orderkey > 5500 AND l_orderkey < 9500
|
||||
GROUP BY l_quantity ORDER BY l_quantity;
|
||||
|
||||
SELECT l_quantity, array_sort(json_agg(extract (month FROM o_orderdate))) AS my_month
|
||||
FROM lineitem, orders WHERE l_orderkey = o_orderkey AND l_quantity < 5
|
||||
AND l_orderkey > 5500 AND l_orderkey < 9500 GROUP BY l_quantity ORDER BY l_quantity;
|
||||
|
||||
SELECT l_quantity, array_sort(json_agg(l_orderkey * 2 + 1)) FROM lineitem WHERE l_quantity < 5
|
||||
AND octet_length(l_comment) + octet_length('randomtext'::text) > 40
|
||||
AND l_orderkey > 5500 AND l_orderkey < 9500 GROUP BY l_quantity ORDER BY l_quantity;
|
||||
|
||||
-- Check that we can execute json_agg() with an expression containing NULL values
|
||||
|
||||
SELECT json_agg(case when l_quantity > 20 then l_quantity else NULL end)
|
||||
FROM lineitem WHERE l_orderkey < 5;
|
||||
|
||||
-- Check that we can execute json_agg() with an expression containing different types
|
||||
|
||||
SELECT json_agg(case when l_quantity > 20 then to_json(l_quantity) else '"f"'::json end)
|
||||
FROM lineitem WHERE l_orderkey < 5;
|
||||
|
||||
-- Check that we can execute json_agg() with an expression containing json arrays
|
||||
|
||||
SELECT json_agg(json_build_array(l_quantity, l_shipdate))
|
||||
FROM lineitem WHERE l_orderkey < 3;
|
||||
|
||||
-- Check that we can execute json_agg() with an expression containing arrays
|
||||
|
||||
SELECT json_agg(ARRAY[l_quantity, l_orderkey])
|
||||
FROM lineitem WHERE l_orderkey < 3;
|
||||
|
||||
-- Check that we return NULL in case there are no input rows to json_agg()
|
||||
|
||||
SELECT json_agg(l_orderkey) FROM lineitem WHERE l_quantity < 0;
|
|
@ -0,0 +1,102 @@
|
|||
--
|
||||
-- MULTI_JSON_OBJECT_AGG
|
||||
--
|
||||
|
||||
|
||||
SET citus.next_shard_id TO 520000;
|
||||
|
||||
CREATE OR REPLACE FUNCTION count_keys (json)
|
||||
RETURNS bigint LANGUAGE SQL
|
||||
AS $$
|
||||
SELECT count(*) FROM (SELECT * FROM json_object_keys($1)) t
|
||||
$$;
|
||||
|
||||
CREATE OR REPLACE FUNCTION keys_sort (json)
|
||||
RETURNS json LANGUAGE SQL
|
||||
AS $$
|
||||
SELECT json_object_agg(key, value) FROM (
|
||||
SELECT * FROM json_each($1) ORDER BY key
|
||||
) t
|
||||
$$;
|
||||
|
||||
-- Check multi_cat_agg() aggregate which is used to implement json_object_agg()
|
||||
|
||||
SELECT json_cat_agg(i) FROM
|
||||
(VALUES ('{"c":[], "b":2}'::json), (NULL), ('{"d":null, "a":{"b":3}, "b":2}'::json)) AS t(i);
|
||||
|
||||
-- Check that we don't support distinct and order by with json_object_agg()
|
||||
|
||||
SELECT json_object_agg(distinct l_shipmode, l_orderkey) FROM lineitem;
|
||||
|
||||
SELECT json_object_agg(l_shipmode, l_orderkey ORDER BY l_shipmode) FROM lineitem;
|
||||
|
||||
SELECT json_object_agg(distinct l_orderkey, l_shipmode ORDER BY l_orderkey) FROM lineitem;
|
||||
|
||||
-- Check json_object_agg() for different data types and LIMIT clauses
|
||||
|
||||
SELECT keys_sort(json_object_agg(l_orderkey::text || l_linenumber::text, l_partkey))
|
||||
FROM lineitem GROUP BY l_orderkey
|
||||
ORDER BY l_orderkey LIMIT 10;
|
||||
|
||||
SELECT keys_sort(json_object_agg(l_orderkey::text || l_linenumber::text, l_extendedprice))
|
||||
FROM lineitem GROUP BY l_orderkey
|
||||
ORDER BY l_orderkey LIMIT 10;
|
||||
|
||||
SELECT keys_sort(json_object_agg(l_orderkey::text || l_linenumber::text, l_shipmode))
|
||||
FROM lineitem GROUP BY l_orderkey
|
||||
ORDER BY l_orderkey LIMIT 10;
|
||||
|
||||
SELECT keys_sort(json_object_agg(l_orderkey::text || l_linenumber::text, l_shipdate))
|
||||
FROM lineitem GROUP BY l_orderkey
|
||||
ORDER BY l_orderkey LIMIT 10;
|
||||
|
||||
-- Check that we can execute json_object_agg() within other functions
|
||||
|
||||
SELECT count_keys(json_object_agg(l_shipdate, l_orderkey)) FROM lineitem;
|
||||
|
||||
-- Check that we can execute json_object_agg() on select queries that hit multiple
|
||||
-- shards and contain different aggregates, filter clauses and other complex
|
||||
-- expressions. Note that the l_orderkey ranges are such that the matching rows
|
||||
-- lie in different shards.
|
||||
|
||||
SELECT l_quantity, count(*), avg(l_extendedprice),
|
||||
keys_sort(json_object_agg(l_orderkey::text || l_linenumber::text, l_shipdate))
|
||||
FROM lineitem
|
||||
WHERE l_quantity < 5 AND l_orderkey > 5000 AND l_orderkey < 5300
|
||||
GROUP BY l_quantity ORDER BY l_quantity;
|
||||
|
||||
SELECT l_quantity, keys_sort(json_object_agg(l_orderkey::text || l_linenumber::text,
|
||||
extract (month FROM o_orderdate)))
|
||||
FROM lineitem, orders WHERE l_orderkey = o_orderkey AND l_quantity < 5
|
||||
AND l_orderkey > 5000 AND l_orderkey < 5300 GROUP BY l_quantity ORDER BY l_quantity;
|
||||
|
||||
SELECT l_quantity, keys_sort(json_object_agg(l_orderkey::text || l_linenumber::text, l_orderkey * 2 + 1))
|
||||
FROM lineitem WHERE l_quantity < 5
|
||||
AND octet_length(l_comment) + octet_length('randomtext'::text) > 40
|
||||
AND l_orderkey > 5000 AND l_orderkey < 6000 GROUP BY l_quantity ORDER BY l_quantity;
|
||||
|
||||
-- Check that we can execute json_object_agg() with an expression containing NULL values
|
||||
|
||||
SELECT keys_sort(json_object_agg(l_orderkey::text || l_linenumber::text,
|
||||
case when l_quantity > 20 then l_quantity else NULL end))
|
||||
FROM lineitem WHERE l_orderkey < 5;
|
||||
|
||||
-- Check that we can execute json_object_agg() with an expression containing different types
|
||||
|
||||
SELECT keys_sort(json_object_agg(l_orderkey::text || l_linenumber::text,
|
||||
case when l_quantity > 20 then to_json(l_quantity) else '"f"'::json end))
|
||||
FROM lineitem WHERE l_orderkey < 5;
|
||||
|
||||
-- Check that we can execute json_object_agg() with an expression containing json arrays
|
||||
|
||||
SELECT keys_sort(json_object_agg(l_orderkey::text || l_linenumber::text, json_build_array(l_quantity, l_shipdate)))
|
||||
FROM lineitem WHERE l_orderkey < 3;
|
||||
|
||||
-- Check that we can execute json_object_agg() with an expression containing arrays
|
||||
|
||||
SELECT keys_sort(json_object_agg(l_orderkey::text || l_linenumber::text, ARRAY[l_quantity, l_orderkey]))
|
||||
FROM lineitem WHERE l_orderkey < 3;
|
||||
|
||||
-- Check that we return NULL in case there are no input rows to json_object_agg()
|
||||
|
||||
SELECT json_object_agg(l_shipdate, l_orderkey) FROM lineitem WHERE l_quantity < 0;
|
|
@ -0,0 +1,86 @@
|
|||
--
|
||||
-- MULTI_JSONB_AGG
|
||||
--
|
||||
|
||||
|
||||
SET citus.next_shard_id TO 520000;
|
||||
|
||||
CREATE OR REPLACE FUNCTION array_sort (jsonb)
|
||||
RETURNS jsonb LANGUAGE SQL
|
||||
AS $$
|
||||
SELECT jsonb_agg(value) FROM (
|
||||
SELECT * FROM jsonb_array_elements($1) ORDER BY 1
|
||||
) t
|
||||
$$;
|
||||
|
||||
-- Check multi_cat_agg() aggregate which is used to implement jsonb_agg()
|
||||
|
||||
SELECT jsonb_cat_agg(i) FROM
|
||||
(VALUES ('[1,{"a":2}]'::jsonb), ('[null]'::jsonb), (NULL), ('["3",5,4]'::jsonb)) AS t(i);
|
||||
|
||||
-- Check that we don't support distinct and order by with jsonb_agg()
|
||||
|
||||
SELECT jsonb_agg(distinct l_orderkey) FROM lineitem;
|
||||
|
||||
SELECT jsonb_agg(l_orderkey ORDER BY l_partkey) FROM lineitem;
|
||||
|
||||
SELECT jsonb_agg(distinct l_orderkey ORDER BY l_orderkey) FROM lineitem;
|
||||
|
||||
-- Check jsonb_agg() for different data types and LIMIT clauses
|
||||
|
||||
SELECT array_sort(jsonb_agg(l_partkey)) FROM lineitem GROUP BY l_orderkey
|
||||
ORDER BY l_orderkey LIMIT 10;
|
||||
|
||||
SELECT array_sort(jsonb_agg(l_extendedprice)) FROM lineitem GROUP BY l_orderkey
|
||||
ORDER BY l_orderkey LIMIT 10;
|
||||
|
||||
SELECT array_sort(jsonb_agg(l_shipdate)) FROM lineitem GROUP BY l_orderkey
|
||||
ORDER BY l_orderkey LIMIT 10;
|
||||
|
||||
SELECT array_sort(jsonb_agg(l_shipmode)) FROM lineitem GROUP BY l_orderkey
|
||||
ORDER BY l_orderkey LIMIT 10;
|
||||
|
||||
-- Check that we can execute jsonb_agg() within other functions
|
||||
|
||||
SELECT jsonb_array_length(jsonb_agg(l_orderkey)) FROM lineitem;
|
||||
|
||||
-- Check that we can execute jsonb_agg() on select queries that hit multiple
|
||||
-- shards and contain different aggregates, filter clauses and other complex
|
||||
-- expressions. Note that the l_orderkey ranges are such that the matching rows
|
||||
-- lie in different shards.
|
||||
|
||||
SELECT l_quantity, count(*), avg(l_extendedprice), array_sort(jsonb_agg(l_orderkey)) FROM lineitem
|
||||
WHERE l_quantity < 5 AND l_orderkey > 5500 AND l_orderkey < 9500
|
||||
GROUP BY l_quantity ORDER BY l_quantity;
|
||||
|
||||
SELECT l_quantity, array_sort(jsonb_agg(extract (month FROM o_orderdate))) AS my_month
|
||||
FROM lineitem, orders WHERE l_orderkey = o_orderkey AND l_quantity < 5
|
||||
AND l_orderkey > 5500 AND l_orderkey < 9500 GROUP BY l_quantity ORDER BY l_quantity;
|
||||
|
||||
SELECT l_quantity, array_sort(jsonb_agg(l_orderkey * 2 + 1)) FROM lineitem WHERE l_quantity < 5
|
||||
AND octet_length(l_comment) + octet_length('randomtext'::text) > 40
|
||||
AND l_orderkey > 5500 AND l_orderkey < 9500 GROUP BY l_quantity ORDER BY l_quantity;
|
||||
|
||||
-- Check that we can execute jsonb_agg() with an expression containing NULL values
|
||||
|
||||
SELECT jsonb_agg(case when l_quantity > 20 then l_quantity else NULL end)
|
||||
FROM lineitem WHERE l_orderkey < 5;
|
||||
|
||||
-- Check that we can execute jsonb_agg() with an expression containing different types
|
||||
|
||||
SELECT jsonb_agg(case when l_quantity > 20 then to_jsonb(l_quantity) else '"f"'::jsonb end)
|
||||
FROM lineitem WHERE l_orderkey < 5;
|
||||
|
||||
-- Check that we can execute jsonb_agg() with an expression containing jsonb arrays
|
||||
|
||||
SELECT jsonb_agg(jsonb_build_array(l_quantity, l_shipdate))
|
||||
FROM lineitem WHERE l_orderkey < 3;
|
||||
|
||||
-- Check that we can execute jsonb_agg() with an expression containing arrays
|
||||
|
||||
SELECT jsonb_agg(ARRAY[l_quantity, l_orderkey])
|
||||
FROM lineitem WHERE l_orderkey < 3;
|
||||
|
||||
-- Check that we return NULL in case there are no input rows to jsonb_agg()
|
||||
|
||||
SELECT jsonb_agg(l_orderkey) FROM lineitem WHERE l_quantity < 0;
|
|
@ -0,0 +1,94 @@
|
|||
--
|
||||
-- MULTI_JSONB_OBJECT_AGG
|
||||
--
|
||||
|
||||
|
||||
SET citus.next_shard_id TO 520000;
|
||||
|
||||
CREATE OR REPLACE FUNCTION count_keys (jsonb)
|
||||
RETURNS bigint LANGUAGE SQL
|
||||
AS $$
|
||||
SELECT count(*) FROM (SELECT * FROM jsonb_object_keys($1)) t
|
||||
$$;
|
||||
|
||||
-- Check multi_cat_agg() aggregate which is used to implement jsonb_object_agg()
|
||||
|
||||
SELECT jsonb_cat_agg(i) FROM
|
||||
(VALUES ('{"c":[], "b":2}'::jsonb), (NULL), ('{"d":null, "a":{"b":3}, "b":2}'::jsonb)) AS t(i);
|
||||
|
||||
-- Check that we don't support distinct and order by with jsonb_object_agg()
|
||||
|
||||
SELECT jsonb_object_agg(distinct l_shipmode, l_orderkey) FROM lineitem;
|
||||
|
||||
SELECT jsonb_object_agg(l_shipmode, l_orderkey ORDER BY l_shipmode) FROM lineitem;
|
||||
|
||||
SELECT jsonb_object_agg(distinct l_orderkey, l_shipmode ORDER BY l_orderkey) FROM lineitem;
|
||||
|
||||
-- Check jsonb_object_agg() for different data types and LIMIT clauses
|
||||
|
||||
SELECT jsonb_object_agg(l_orderkey::text || l_linenumber::text, l_partkey)
|
||||
FROM lineitem GROUP BY l_orderkey
|
||||
ORDER BY l_orderkey LIMIT 10;
|
||||
|
||||
SELECT jsonb_object_agg(l_orderkey::text || l_linenumber::text, l_extendedprice)
|
||||
FROM lineitem GROUP BY l_orderkey
|
||||
ORDER BY l_orderkey LIMIT 10;
|
||||
|
||||
SELECT jsonb_object_agg(l_orderkey::text || l_linenumber::text, l_shipmode)
|
||||
FROM lineitem GROUP BY l_orderkey
|
||||
ORDER BY l_orderkey LIMIT 10;
|
||||
|
||||
SELECT jsonb_object_agg(l_orderkey::text || l_linenumber::text, l_shipdate)
|
||||
FROM lineitem GROUP BY l_orderkey
|
||||
ORDER BY l_orderkey LIMIT 10;
|
||||
|
||||
-- Check that we can execute jsonb_object_agg() within other functions
|
||||
|
||||
SELECT count_keys(jsonb_object_agg(l_shipdate, l_orderkey)) FROM lineitem;
|
||||
|
||||
-- Check that we can execute jsonb_object_agg() on select queries that hit multiple
|
||||
-- shards and contain different aggregates, filter clauses and other complex
|
||||
-- expressions. Note that the l_orderkey ranges are such that the matching rows
|
||||
-- lie in different shards.
|
||||
|
||||
SELECT l_quantity, count(*), avg(l_extendedprice),
|
||||
jsonb_object_agg(l_orderkey::text || l_linenumber::text, l_shipdate)
|
||||
FROM lineitem
|
||||
WHERE l_quantity < 5 AND l_orderkey > 5000 AND l_orderkey < 5300
|
||||
GROUP BY l_quantity ORDER BY l_quantity;
|
||||
|
||||
SELECT l_quantity, jsonb_object_agg(l_orderkey::text || l_linenumber::text,
|
||||
extract (month FROM o_orderdate))
|
||||
FROM lineitem, orders WHERE l_orderkey = o_orderkey AND l_quantity < 5
|
||||
AND l_orderkey > 5000 AND l_orderkey < 5300 GROUP BY l_quantity ORDER BY l_quantity;
|
||||
|
||||
SELECT l_quantity, jsonb_object_agg(l_orderkey::text || l_linenumber::text, l_orderkey * 2 + 1)
|
||||
FROM lineitem WHERE l_quantity < 5
|
||||
AND octet_length(l_comment) + octet_length('randomtext'::text) > 40
|
||||
AND l_orderkey > 5000 AND l_orderkey < 6000 GROUP BY l_quantity ORDER BY l_quantity;
|
||||
|
||||
-- Check that we can execute jsonb_object_agg() with an expression containing NULL values
|
||||
|
||||
SELECT jsonb_object_agg(l_orderkey::text || l_linenumber::text,
|
||||
case when l_quantity > 20 then l_quantity else NULL end)
|
||||
FROM lineitem WHERE l_orderkey < 5;
|
||||
|
||||
-- Check that we can execute jsonb_object_agg() with an expression containing different types
|
||||
|
||||
SELECT jsonb_object_agg(l_orderkey::text || l_linenumber::text,
|
||||
case when l_quantity > 20 then to_jsonb(l_quantity) else '"f"'::jsonb end)
|
||||
FROM lineitem WHERE l_orderkey < 5;
|
||||
|
||||
-- Check that we can execute jsonb_object_agg() with an expression containing jsonb arrays
|
||||
|
||||
SELECT jsonb_object_agg(l_orderkey::text || l_linenumber::text, jsonb_build_array(l_quantity, l_shipdate))
|
||||
FROM lineitem WHERE l_orderkey < 3;
|
||||
|
||||
-- Check that we can execute jsonb_object_agg() with an expression containing arrays
|
||||
|
||||
SELECT jsonb_object_agg(l_orderkey::text || l_linenumber::text, ARRAY[l_quantity, l_orderkey])
|
||||
FROM lineitem WHERE l_orderkey < 3;
|
||||
|
||||
-- Check that we return NULL in case there are no input rows to jsonb_object_agg()
|
||||
|
||||
SELECT jsonb_object_agg(l_shipdate, l_orderkey) FROM lineitem WHERE l_quantity < 0;
|
Loading…
Reference in New Issue