Add several generator functions for jsonb that exist for json.

The functions are:
    to_jsonb()
    jsonb_object()
    jsonb_build_object()
    jsonb_build_array()
    jsonb_agg()
    jsonb_object_agg()

Also along the way some better logic is implemented in
json_categorize_type() to match that in the newly implemented
jsonb_categorize_type().

Andrew Dunstan, reviewed by Pavel Stehule and Alvaro Herrera.
This commit is contained in:
Andrew Dunstan 2014-12-12 15:31:14 -05:00
parent 8ec8760fc8
commit 7e354ab9fe
11 changed files with 2003 additions and 45 deletions

View File

@ -10245,9 +10245,10 @@ table2-mapping
<para> <para>
<xref linkend="functions-json-creation-table"> shows the functions that are <xref linkend="functions-json-creation-table"> shows the functions that are
available for creating <type>json</type> values. available for creating <type>json</type> and <type>jsonb</type> values.
(Currently, there are no equivalent functions for <type>jsonb</>, but you (There are no equivalent functions for <type>jsonb</>, of the <literal>row_to_json</>
can cast the result of one of these functions to <type>jsonb</>.) and <literal>array_to_json</> functions. However, the <literal>to_jsonb</>
function supplies much the same functionality as these functions would.)
</para> </para>
<indexterm> <indexterm>
@ -10268,6 +10269,18 @@ table2-mapping
<indexterm> <indexterm>
<primary>json_object</primary> <primary>json_object</primary>
</indexterm> </indexterm>
<indexterm>
<primary>to_jsonb</primary>
</indexterm>
<indexterm>
<primary>jsonb_build_array</primary>
</indexterm>
<indexterm>
<primary>jsonb_build_object</primary>
</indexterm>
<indexterm>
<primary>jsonb_object</primary>
</indexterm>
<table id="functions-json-creation-table"> <table id="functions-json-creation-table">
<title>JSON Creation Functions</title> <title>JSON Creation Functions</title>
@ -10282,17 +10295,18 @@ table2-mapping
</thead> </thead>
<tbody> <tbody>
<row> <row>
<entry><para><literal>to_json(anyelement)</literal>
</para><para><literal>to_jsonb(anyelement)</literal>
</para></entry>
<entry> <entry>
<literal>to_json(anyelement)</literal> Returns the value as <type>json</> or <type>jsonb</>.
</entry> Arrays and composites are converted
<entry>
Returns the value as JSON. Arrays and composites are converted
(recursively) to arrays and objects; otherwise, if there is a cast (recursively) to arrays and objects; otherwise, if there is a cast
from the type to <type>json</type>, the cast function will be used to from the type to <type>json</type>, the cast function will be used to
perform the conversion; otherwise, a JSON scalar value is produced. perform the conversion; otherwise, a scalar value is produced.
For any scalar type other than a number, a Boolean, or a null value, For any scalar type other than a number, a Boolean, or a null value,
the text representation will be used, properly quoted and escaped the text representation will be used, in such a fashion that it is a
so that it is a valid JSON string. valid <type>json</> or <type>jsonb</> value.
</entry> </entry>
<entry><literal>to_json('Fred said "Hi."'::text)</literal></entry> <entry><literal>to_json('Fred said "Hi."'::text)</literal></entry>
<entry><literal>"Fred said \"Hi.\""</literal></entry> <entry><literal>"Fred said \"Hi.\""</literal></entry>
@ -10321,9 +10335,9 @@ table2-mapping
<entry><literal>{"f1":1,"f2":"foo"}</literal></entry> <entry><literal>{"f1":1,"f2":"foo"}</literal></entry>
</row> </row>
<row> <row>
<entry> <entry><para><literal>json_build_array(VARIADIC "any")</literal>
<literal>json_build_array(VARIADIC "any")</literal> </para><para><literal>jsonb_build_array(VARIADIC "any")</literal>
</entry> </para></entry>
<entry> <entry>
Builds a possibly-heterogeneously-typed JSON array out of a variadic Builds a possibly-heterogeneously-typed JSON array out of a variadic
argument list. argument list.
@ -10332,9 +10346,9 @@ table2-mapping
<entry><literal>[1, 2, "3", 4, 5]</literal></entry> <entry><literal>[1, 2, "3", 4, 5]</literal></entry>
</row> </row>
<row> <row>
<entry> <entry><para><literal>json_build_object(VARIADIC "any")</literal>
<literal>json_build_object(VARIADIC "any")</literal> </para><para><literal>jsonb_build_object(VARIADIC "any")</literal>
</entry> </para></entry>
<entry> <entry>
Builds a JSON object out of a variadic argument list. By Builds a JSON object out of a variadic argument list. By
convention, the argument list consists of alternating convention, the argument list consists of alternating
@ -10344,9 +10358,9 @@ table2-mapping
<entry><literal>{"foo": 1, "bar": 2}</literal></entry> <entry><literal>{"foo": 1, "bar": 2}</literal></entry>
</row> </row>
<row> <row>
<entry> <entry><para><literal>json_object(text[])</literal>
<literal>json_object(text[])</literal> </para><para><literal>jsonb_object(text[])</literal>
</entry> </para></entry>
<entry> <entry>
Builds a JSON object out of a text array. The array must have either Builds a JSON object out of a text array. The array must have either
exactly one dimension with an even number of members, in which case exactly one dimension with an even number of members, in which case
@ -10359,9 +10373,9 @@ table2-mapping
<entry><literal>{"a": "1", "b": "def", "c": "3.5"}</literal></entry> <entry><literal>{"a": "1", "b": "def", "c": "3.5"}</literal></entry>
</row> </row>
<row> <row>
<entry> <entry><para><literal>json_object(keys text[], values text[])</literal>
<literal>json_object(keys text[], values text[])</literal> </para><para><literal>json_object(keys text[], values text[])</literal>
</entry> </para></entry>
<entry> <entry>
This form of <function>json_object</> takes keys and values pairwise from two separate This form of <function>json_object</> takes keys and values pairwise from two separate
arrays. In all other respects it is identical to the one-argument form. arrays. In all other respects it is identical to the one-argument form.
@ -10780,7 +10794,8 @@ table2-mapping
function <function>json_agg</function> which aggregates record function <function>json_agg</function> which aggregates record
values as JSON, and the aggregate function values as JSON, and the aggregate function
<function>json_object_agg</function> which aggregates pairs of values <function>json_object_agg</function> which aggregates pairs of values
into a JSON object. into a JSON object, and their <type>jsonb</type> equivalents,
<function>jsonb_agg</> and <function>jsonb_object_agg</>.
</para> </para>
</sect1> </sect1>
@ -12224,6 +12239,22 @@ NULL baz</literallayout>(3 rows)</entry>
<entry>aggregates records as a JSON array of objects</entry> <entry>aggregates records as a JSON array of objects</entry>
</row> </row>
<row>
<entry>
<indexterm>
<primary>jsonb_agg</primary>
</indexterm>
<function>jsonb_agg(<replaceable class="parameter">record</replaceable>)</function>
</entry>
<entry>
<type>record</type>
</entry>
<entry>
<type>jsonb</type>
</entry>
<entry>aggregates records as a JSON array of objects</entry>
</row>
<row> <row>
<entry> <entry>
<indexterm> <indexterm>
@ -12240,6 +12271,22 @@ NULL baz</literallayout>(3 rows)</entry>
<entry>aggregates name/value pairs as a JSON object</entry> <entry>aggregates name/value pairs as a JSON object</entry>
</row> </row>
<row>
<entry>
<indexterm>
<primary>jsonb_object_agg</primary>
</indexterm>
<function>jsonb_object_agg(<replaceable class="parameter">name</replaceable>, <replaceable class="parameter">value</replaceable>)</function>
</entry>
<entry>
<type>("any", "any")</type>
</entry>
<entry>
<type>jsonb</type>
</entry>
<entry>aggregates name/value pairs as a JSON object</entry>
</row>
<row> <row>
<entry> <entry>
<indexterm> <indexterm>
@ -12386,8 +12433,8 @@ SELECT count(*) FROM sometable;
<para> <para>
The aggregate functions <function>array_agg</function>, The aggregate functions <function>array_agg</function>,
<function>json_agg</function>, <function>json_agg</function>, <function>jsonb_agg</function>,
<function>json_object_agg</function>, <function>json_object_agg</function>, <function>jsonb_object_agg</function>,
<function>string_agg</function>, <function>string_agg</function>,
and <function>xmlagg</function>, as well as similar user-defined and <function>xmlagg</function>, as well as similar user-defined
aggregate functions, produce meaningfully different result values aggregate functions, produce meaningfully different result values

View File

@ -15,7 +15,6 @@
#include "access/htup_details.h" #include "access/htup_details.h"
#include "access/transam.h" #include "access/transam.h"
#include "catalog/pg_cast.h"
#include "catalog/pg_type.h" #include "catalog/pg_type.h"
#include "executor/spi.h" #include "executor/spi.h"
#include "lib/stringinfo.h" #include "lib/stringinfo.h"
@ -1281,10 +1280,14 @@ json_categorize_type(Oid typoid,
/* Look through any domain */ /* Look through any domain */
typoid = getBaseType(typoid); typoid = getBaseType(typoid);
/* We'll usually need to return the type output function */ *outfuncoid = InvalidOid;
getTypeOutputInfo(typoid, outfuncoid, &typisvarlena);
/*
* We need to get the output function for everything except date and
* timestamp types, array and composite types, booleans,
* and non-builtin types where there's a cast to json.
*/
/* Check for known types */
switch (typoid) switch (typoid)
{ {
case BOOLOID: case BOOLOID:
@ -1297,6 +1300,7 @@ json_categorize_type(Oid typoid,
case FLOAT4OID: case FLOAT4OID:
case FLOAT8OID: case FLOAT8OID:
case NUMERICOID: case NUMERICOID:
getTypeOutputInfo(typoid, outfuncoid, &typisvarlena);
*tcategory = JSONTYPE_NUMERIC; *tcategory = JSONTYPE_NUMERIC;
break; break;
@ -1314,6 +1318,7 @@ json_categorize_type(Oid typoid,
case JSONOID: case JSONOID:
case JSONBOID: case JSONBOID:
getTypeOutputInfo(typoid, outfuncoid, &typisvarlena);
*tcategory = JSONTYPE_JSON; *tcategory = JSONTYPE_JSON;
break; break;
@ -1330,24 +1335,27 @@ json_categorize_type(Oid typoid,
/* but let's look for a cast to json, if it's not built-in */ /* but let's look for a cast to json, if it's not built-in */
if (typoid >= FirstNormalObjectId) if (typoid >= FirstNormalObjectId)
{ {
HeapTuple tuple; Oid castfunc;
CoercionPathType ctype;
tuple = SearchSysCache2(CASTSOURCETARGET, ctype = find_coercion_pathway(JSONOID, typoid,
ObjectIdGetDatum(typoid), COERCION_EXPLICIT, &castfunc);
ObjectIdGetDatum(JSONOID)); if (ctype == COERCION_PATH_FUNC && OidIsValid(castfunc))
if (HeapTupleIsValid(tuple))
{
Form_pg_cast castForm = (Form_pg_cast) GETSTRUCT(tuple);
if (castForm->castmethod == COERCION_METHOD_FUNCTION)
{ {
*tcategory = JSONTYPE_CAST; *tcategory = JSONTYPE_CAST;
*outfuncoid = castForm->castfunc; *outfuncoid = castfunc;
} }
else
ReleaseSysCache(tuple); {
/* non builtin type with no cast */
getTypeOutputInfo(typoid, outfuncoid, &typisvarlena);
} }
} }
else
{
/* any other builtin type */
getTypeOutputInfo(typoid, outfuncoid, &typisvarlena);
}
} }
break; break;
} }

File diff suppressed because it is too large Load Diff

View File

@ -1427,7 +1427,7 @@ convertJsonbValue(StringInfo buffer, JEntry *header, JsonbValue *val, int level)
else if (val->type == jbvObject) else if (val->type == jbvObject)
convertJsonbObject(buffer, header, val, level); convertJsonbObject(buffer, header, val, level);
else else
elog(ERROR, "unknown type of jsonb container"); elog(ERROR, "unknown type of jsonb container to convert");
} }
static void static void

View File

@ -53,6 +53,6 @@
*/ */
/* yyyymmddN */ /* yyyymmddN */
#define CATALOG_VERSION_NO 201412121 #define CATALOG_VERSION_NO 201412122
#endif #endif

View File

@ -287,6 +287,10 @@ DATA(insert ( 3545 n 0 bytea_string_agg_transfn bytea_string_agg_finalfn - -
DATA(insert ( 3175 n 0 json_agg_transfn json_agg_finalfn - - - f f 0 2281 0 0 0 _null_ _null_ )); DATA(insert ( 3175 n 0 json_agg_transfn json_agg_finalfn - - - f f 0 2281 0 0 0 _null_ _null_ ));
DATA(insert ( 3197 n 0 json_object_agg_transfn json_object_agg_finalfn - - - f f 0 2281 0 0 0 _null_ _null_ )); DATA(insert ( 3197 n 0 json_object_agg_transfn json_object_agg_finalfn - - - f f 0 2281 0 0 0 _null_ _null_ ));
/* jsonb */
DATA(insert ( 3267 n 0 jsonb_agg_transfn jsonb_agg_finalfn - - - f f 0 2281 0 0 0 _null_ _null_ ));
DATA(insert ( 3270 n 0 jsonb_object_agg_transfn jsonb_object_agg_finalfn - - - f f 0 2281 0 0 0 _null_ _null_ ));
/* ordered-set and hypothetical-set aggregates */ /* ordered-set and hypothetical-set aggregates */
DATA(insert ( 3972 o 1 ordered_set_transition percentile_disc_final - - - t f 0 2281 0 0 0 _null_ _null_ )); DATA(insert ( 3972 o 1 ordered_set_transition percentile_disc_final - - - t f 0 2281 0 0 0 _null_ _null_ ));
DATA(insert ( 3974 o 1 ordered_set_transition percentile_cont_float8_final - - - f f 0 2281 0 0 0 _null_ _null_ )); DATA(insert ( 3974 o 1 ordered_set_transition percentile_cont_float8_final - - - f f 0 2281 0 0 0 _null_ _null_ ));

View File

@ -4656,6 +4656,32 @@ DESCR("I/O");
DATA(insert OID = 3803 ( jsonb_send PGNSP PGUID 12 1 0 0 0 f f f f t f i 1 0 17 "3802" _null_ _null_ _null_ _null_ jsonb_send _null_ _null_ _null_ )); DATA(insert OID = 3803 ( jsonb_send PGNSP PGUID 12 1 0 0 0 f f f f t f i 1 0 17 "3802" _null_ _null_ _null_ _null_ jsonb_send _null_ _null_ _null_ ));
DESCR("I/O"); DESCR("I/O");
DATA(insert OID = 3263 ( jsonb_object PGNSP PGUID 12 1 0 0 0 f f f f t f i 1 0 3802 "1009" _null_ _null_ _null_ _null_ jsonb_object _null_ _null_ _null_ ));
DESCR("map text array of key value pairs to jsonb object");
DATA(insert OID = 3264 ( jsonb_object PGNSP PGUID 12 1 0 0 0 f f f f t f i 2 0 3802 "1009 1009" _null_ _null_ _null_ _null_ jsonb_object_two_arg _null_ _null_ _null_ ));
DESCR("map text array of key value pairs to jsonb object");
DATA(insert OID = 3787 ( to_jsonb PGNSP PGUID 12 1 0 0 0 f f f f t f s 1 0 3802 "2283" _null_ _null_ _null_ _null_ to_jsonb _null_ _null_ _null_ ));
DESCR("map input to jsonb");
DATA(insert OID = 3265 ( jsonb_agg_transfn PGNSP PGUID 12 1 0 0 0 f f f f f f s 2 0 2281 "2281 2283" _null_ _null_ _null_ _null_ jsonb_agg_transfn _null_ _null_ _null_ ));
DESCR("jsonb aggregate transition function");
DATA(insert OID = 3266 ( jsonb_agg_finalfn PGNSP PGUID 12 1 0 0 0 f f f f f f s 1 0 3802 "2281" _null_ _null_ _null_ _null_ jsonb_agg_finalfn _null_ _null_ _null_ ));
DESCR("jsonb aggregate final function");
DATA(insert OID = 3267 ( jsonb_agg PGNSP PGUID 12 1 0 0 0 t f f f f f s 1 0 3802 "2283" _null_ _null_ _null_ _null_ aggregate_dummy _null_ _null_ _null_ ));
DESCR("aggregate input into jsonb");
DATA(insert OID = 3268 ( jsonb_object_agg_transfn PGNSP PGUID 12 1 0 0 0 f f f f f f s 3 0 2281 "2281 2276 2276" _null_ _null_ _null_ _null_ jsonb_object_agg_transfn _null_ _null_ _null_ ));
DESCR("jsonb object aggregate transition function");
DATA(insert OID = 3269 ( jsonb_object_agg_finalfn PGNSP PGUID 12 1 0 0 0 f f f f f f s 1 0 3802 "2281" _null_ _null_ _null_ _null_ jsonb_object_agg_finalfn _null_ _null_ _null_ ));
DESCR("jsonb object aggregate final function");
DATA(insert OID = 3270 ( jsonb_object_agg PGNSP PGUID 12 1 0 0 0 t f f f f f i 2 0 3802 "2276 2276" _null_ _null_ _null_ _null_ aggregate_dummy _null_ _null_ _null_ ));
DESCR("aggregate inputs into jsonb object");
DATA(insert OID = 3271 ( jsonb_build_array PGNSP PGUID 12 1 0 2276 0 f f f f f f s 1 0 3802 "2276" "{2276}" "{v}" _null_ _null_ jsonb_build_array _null_ _null_ _null_ ));
DESCR("build a jsonb array from any inputs");
DATA(insert OID = 3272 ( jsonb_build_array PGNSP PGUID 12 1 0 0 0 f f f f f f s 0 0 3802 "" _null_ _null_ _null_ _null_ jsonb_build_array_noargs _null_ _null_ _null_ ));
DESCR("build an empty jsonb array");
DATA(insert OID = 3273 ( jsonb_build_object PGNSP PGUID 12 1 0 2276 0 f f f f f f s 1 0 3802 "2276" "{2276}" "{v}" _null_ _null_ jsonb_build_object _null_ _null_ _null_ ));
DESCR("build a jsonb object from pairwise key/value inputs");
DATA(insert OID = 3274 ( jsonb_build_object PGNSP PGUID 12 1 0 0 0 f f f f f f s 0 0 3802 "" _null_ _null_ _null_ _null_ jsonb_build_object_noargs _null_ _null_ _null_ ));
DESCR("build an empty jsonb object");
DATA(insert OID = 3262 ( jsonb_strip_nulls PGNSP PGUID 12 1 0 0 0 f f f f t f i 1 0 3802 "3802" _null_ _null_ _null_ _null_ jsonb_strip_nulls _null_ _null_ _null_ )); DATA(insert OID = 3262 ( jsonb_strip_nulls PGNSP PGUID 12 1 0 0 0 f f f f t f i 1 0 3802 "3802" _null_ _null_ _null_ _null_ jsonb_strip_nulls _null_ _null_ _null_ ));
DESCR("remove object fields with null values from jsonb"); DESCR("remove object fields with null values from jsonb");

View File

@ -350,6 +350,22 @@ extern Datum jsonb_recv(PG_FUNCTION_ARGS);
extern Datum jsonb_send(PG_FUNCTION_ARGS); extern Datum jsonb_send(PG_FUNCTION_ARGS);
extern Datum jsonb_typeof(PG_FUNCTION_ARGS); extern Datum jsonb_typeof(PG_FUNCTION_ARGS);
/* generator routines */
extern Datum to_jsonb(PG_FUNCTION_ARGS);
extern Datum jsonb_build_object(PG_FUNCTION_ARGS);
extern Datum jsonb_build_object_noargs(PG_FUNCTION_ARGS);
extern Datum jsonb_build_array(PG_FUNCTION_ARGS);
extern Datum jsonb_build_array_noargs(PG_FUNCTION_ARGS);
extern Datum jsonb_object(PG_FUNCTION_ARGS);
extern Datum jsonb_object_two_arg(PG_FUNCTION_ARGS);
/* jsonb_agg, json_object_agg functions */
extern Datum jsonb_agg_transfn(PG_FUNCTION_ARGS);
extern Datum jsonb_agg_finalfn(PG_FUNCTION_ARGS);
extern Datum jsonb_object_agg_transfn(PG_FUNCTION_ARGS);
extern Datum jsonb_object_agg_finalfn(PG_FUNCTION_ARGS);
/* Indexing-related ops */ /* Indexing-related ops */
extern Datum jsonb_exists(PG_FUNCTION_ARGS); extern Datum jsonb_exists(PG_FUNCTION_ARGS);
extern Datum jsonb_exists_any(PG_FUNCTION_ARGS); extern Datum jsonb_exists_any(PG_FUNCTION_ARGS);

View File

@ -301,6 +301,65 @@ SELECT array_to_json(ARRAY [jsonb '{"a":1}', jsonb '{"b":[2,3]}']);
[{"a": 1},{"b": [2, 3]}] [{"a": 1},{"b": [2, 3]}]
(1 row) (1 row)
-- to_jsonb, timestamps
select to_jsonb(timestamp '2014-05-28 12:22:35.614298');
to_jsonb
------------------------------
"2014-05-28T12:22:35.614298"
(1 row)
BEGIN;
SET LOCAL TIME ZONE 10.5;
select to_jsonb(timestamptz '2014-05-28 12:22:35.614298-04');
to_jsonb
------------------------------------
"2014-05-29T02:52:35.614298+10:30"
(1 row)
SET LOCAL TIME ZONE -8;
select to_jsonb(timestamptz '2014-05-28 12:22:35.614298-04');
to_jsonb
------------------------------------
"2014-05-28T08:22:35.614298-08:00"
(1 row)
COMMIT;
-- unicode escape - backslash is not escaped
select to_jsonb(text '\uabcd');
to_jsonb
----------
"\uabcd"
(1 row)
-- any other backslash is escaped
select to_jsonb(text '\abcd');
to_jsonb
----------
"\\abcd"
(1 row)
--jsonb_agg
CREATE TEMP TABLE rows AS
SELECT x, 'txt' || x as y
FROM generate_series(1,3) AS x;
SELECT jsonb_agg(q)
FROM ( SELECT $$a$$ || x AS b, y AS c,
ARRAY[ROW(x.*,ARRAY[1,2,3]),
ROW(y.*,ARRAY[4,5,6])] AS z
FROM generate_series(1,2) x,
generate_series(4,5) y) q;
jsonb_agg
--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
[{"b": "a1", "c": 4, "z": [{"f1": 1, "f2": [1, 2, 3]}, {"f1": 4, "f2": [4, 5, 6]}]}, {"b": "a1", "c": 5, "z": [{"f1": 1, "f2": [1, 2, 3]}, {"f1": 5, "f2": [4, 5, 6]}]}, {"b": "a2", "c": 4, "z": [{"f1": 2, "f2": [1, 2, 3]}, {"f1": 4, "f2": [4, 5, 6]}]}, {"b": "a2", "c": 5, "z": [{"f1": 2, "f2": [1, 2, 3]}, {"f1": 5, "f2": [4, 5, 6]}]}]
(1 row)
SELECT jsonb_agg(q)
FROM rows q;
jsonb_agg
-----------------------------------------------------------------------
[{"x": 1, "y": "txt1"}, {"x": 2, "y": "txt2"}, {"x": 3, "y": "txt3"}]
(1 row)
-- jsonb extraction functions -- jsonb extraction functions
CREATE TEMP TABLE test_jsonb ( CREATE TEMP TABLE test_jsonb (
json_type text, json_type text,
@ -1256,6 +1315,120 @@ SELECT jsonb_typeof('"1.0"') AS string;
string string
(1 row) (1 row)
-- jsonb_build_array, jsonb_build_object, jsonb_object_agg
SELECT jsonb_build_array('a',1,'b',1.2,'c',true,'d',null,'e',json '{"x": 3, "y": [1,2,3]}');
jsonb_build_array
-------------------------------------------------------------------------
["a", 1, "b", 1.2, "c", true, "d", null, "e", {"x": 3, "y": [1, 2, 3]}]
(1 row)
SELECT jsonb_build_object('a',1,'b',1.2,'c',true,'d',null,'e',json '{"x": 3, "y": [1,2,3]}');
jsonb_build_object
-------------------------------------------------------------------------
{"a": 1, "b": 1.2, "c": true, "d": null, "e": {"x": 3, "y": [1, 2, 3]}}
(1 row)
SELECT jsonb_build_object(
'a', jsonb_build_object('b',false,'c',99),
'd', jsonb_build_object('e',array[9,8,7]::int[],
'f', (select row_to_json(r) from ( select relkind, oid::regclass as name from pg_class where relname = 'pg_class') r)));
jsonb_build_object
------------------------------------------------------------------------------------------------
{"a": {"b": false, "c": 99}, "d": {"e": [9, 8, 7], "f": {"name": "pg_class", "relkind": "r"}}}
(1 row)
-- empty objects/arrays
SELECT jsonb_build_array();
jsonb_build_array
-------------------
[]
(1 row)
SELECT jsonb_build_object();
jsonb_build_object
--------------------
{}
(1 row)
-- make sure keys are quoted
SELECT jsonb_build_object(1,2);
jsonb_build_object
--------------------
{"1": 2}
(1 row)
-- keys must be scalar and not null
SELECT jsonb_build_object(null,2);
ERROR: arg 1: key cannot be null
SELECT jsonb_build_object(r,2) FROM (SELECT 1 AS a, 2 AS b) r;
ERROR: key value must be scalar, not array, composite or json
SELECT jsonb_build_object(json '{"a":1,"b":2}', 3);
ERROR: key value must be scalar, not array, composite or json
SELECT jsonb_build_object('{1,2,3}'::int[], 3);
ERROR: key value must be scalar, not array, composite or json
CREATE TEMP TABLE foo (serial_num int, name text, type text);
INSERT INTO foo VALUES (847001,'t15','GE1043');
INSERT INTO foo VALUES (847002,'t16','GE1043');
INSERT INTO foo VALUES (847003,'sub-alpha','GESS90');
SELECT jsonb_build_object('turbines',jsonb_object_agg(serial_num,jsonb_build_object('name',name,'type',type)))
FROM foo;
jsonb_build_object
-------------------------------------------------------------------------------------------------------------------------------------------------------------
{"turbines": {"847001": {"name": "t15", "type": "GE1043"}, "847002": {"name": "t16", "type": "GE1043"}, "847003": {"name": "sub-alpha", "type": "GESS90"}}}
(1 row)
-- jsonb_object
-- one dimension
SELECT jsonb_object('{a,1,b,2,3,NULL,"d e f","a b c"}');
jsonb_object
---------------------------------------------------
{"3": null, "a": "1", "b": "2", "d e f": "a b c"}
(1 row)
-- same but with two dimensions
SELECT jsonb_object('{{a,1},{b,2},{3,NULL},{"d e f","a b c"}}');
jsonb_object
---------------------------------------------------
{"3": null, "a": "1", "b": "2", "d e f": "a b c"}
(1 row)
-- odd number error
SELECT jsonb_object('{a,b,c}');
ERROR: array must have even number of elements
-- one column error
SELECT jsonb_object('{{a},{b}}');
ERROR: array must have two columns
-- too many columns error
SELECT jsonb_object('{{a,b,c},{b,c,d}}');
ERROR: array must have two columns
-- too many dimensions error
SELECT jsonb_object('{{{a,b},{c,d}},{{b,c},{d,e}}}');
ERROR: wrong number of array subscripts
--two argument form of jsonb_object
select jsonb_object('{a,b,c,"d e f"}','{1,2,3,"a b c"}');
jsonb_object
--------------------------------------------------
{"a": "1", "b": "2", "c": "3", "d e f": "a b c"}
(1 row)
-- too many dimensions
SELECT jsonb_object('{{a,1},{b,2},{3,NULL},{"d e f","a b c"}}', '{{a,1},{b,2},{3,NULL},{"d e f","a b c"}}');
ERROR: wrong number of array subscripts
-- mismatched dimensions
select jsonb_object('{a,b,c,"d e f",g}','{1,2,3,"a b c"}');
ERROR: mismatched array dimensions
select jsonb_object('{a,b,c,"d e f"}','{1,2,3,"a b c",g}');
ERROR: mismatched array dimensions
-- null key error
select jsonb_object('{a,b,NULL,"d e f"}','{1,2,3,"a b c"}');
ERROR: null value not allowed for object key
-- empty key is allowed
select jsonb_object('{a,b,"","d e f"}','{1,2,3,"a b c"}');
jsonb_object
-------------------------------------------------
{"": "3", "a": "1", "b": "2", "d e f": "a b c"}
(1 row)
-- extract_path, extract_path_as_text -- extract_path, extract_path_as_text
SELECT jsonb_extract_path('{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}','f4','f6'); SELECT jsonb_extract_path('{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}','f4','f6');
jsonb_extract_path jsonb_extract_path

View File

@ -301,6 +301,65 @@ SELECT array_to_json(ARRAY [jsonb '{"a":1}', jsonb '{"b":[2,3]}']);
[{"a": 1},{"b": [2, 3]}] [{"a": 1},{"b": [2, 3]}]
(1 row) (1 row)
-- to_jsonb, timestamps
select to_jsonb(timestamp '2014-05-28 12:22:35.614298');
to_jsonb
------------------------------
"2014-05-28T12:22:35.614298"
(1 row)
BEGIN;
SET LOCAL TIME ZONE 10.5;
select to_jsonb(timestamptz '2014-05-28 12:22:35.614298-04');
to_jsonb
------------------------------------
"2014-05-29T02:52:35.614298+10:30"
(1 row)
SET LOCAL TIME ZONE -8;
select to_jsonb(timestamptz '2014-05-28 12:22:35.614298-04');
to_jsonb
------------------------------------
"2014-05-28T08:22:35.614298-08:00"
(1 row)
COMMIT;
-- unicode escape - backslash is not escaped
select to_jsonb(text '\uabcd');
to_jsonb
----------
"\uabcd"
(1 row)
-- any other backslash is escaped
select to_jsonb(text '\abcd');
to_jsonb
----------
"\\abcd"
(1 row)
--jsonb_agg
CREATE TEMP TABLE rows AS
SELECT x, 'txt' || x as y
FROM generate_series(1,3) AS x;
SELECT jsonb_agg(q)
FROM ( SELECT $$a$$ || x AS b, y AS c,
ARRAY[ROW(x.*,ARRAY[1,2,3]),
ROW(y.*,ARRAY[4,5,6])] AS z
FROM generate_series(1,2) x,
generate_series(4,5) y) q;
jsonb_agg
--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
[{"b": "a1", "c": 4, "z": [{"f1": 1, "f2": [1, 2, 3]}, {"f1": 4, "f2": [4, 5, 6]}]}, {"b": "a1", "c": 5, "z": [{"f1": 1, "f2": [1, 2, 3]}, {"f1": 5, "f2": [4, 5, 6]}]}, {"b": "a2", "c": 4, "z": [{"f1": 2, "f2": [1, 2, 3]}, {"f1": 4, "f2": [4, 5, 6]}]}, {"b": "a2", "c": 5, "z": [{"f1": 2, "f2": [1, 2, 3]}, {"f1": 5, "f2": [4, 5, 6]}]}]
(1 row)
SELECT jsonb_agg(q)
FROM rows q;
jsonb_agg
-----------------------------------------------------------------------
[{"x": 1, "y": "txt1"}, {"x": 2, "y": "txt2"}, {"x": 3, "y": "txt3"}]
(1 row)
-- jsonb extraction functions -- jsonb extraction functions
CREATE TEMP TABLE test_jsonb ( CREATE TEMP TABLE test_jsonb (
json_type text, json_type text,
@ -1256,6 +1315,120 @@ SELECT jsonb_typeof('"1.0"') AS string;
string string
(1 row) (1 row)
-- jsonb_build_array, jsonb_build_object, jsonb_object_agg
SELECT jsonb_build_array('a',1,'b',1.2,'c',true,'d',null,'e',json '{"x": 3, "y": [1,2,3]}');
jsonb_build_array
-------------------------------------------------------------------------
["a", 1, "b", 1.2, "c", true, "d", null, "e", {"x": 3, "y": [1, 2, 3]}]
(1 row)
SELECT jsonb_build_object('a',1,'b',1.2,'c',true,'d',null,'e',json '{"x": 3, "y": [1,2,3]}');
jsonb_build_object
-------------------------------------------------------------------------
{"a": 1, "b": 1.2, "c": true, "d": null, "e": {"x": 3, "y": [1, 2, 3]}}
(1 row)
SELECT jsonb_build_object(
'a', jsonb_build_object('b',false,'c',99),
'd', jsonb_build_object('e',array[9,8,7]::int[],
'f', (select row_to_json(r) from ( select relkind, oid::regclass as name from pg_class where relname = 'pg_class') r)));
jsonb_build_object
------------------------------------------------------------------------------------------------
{"a": {"b": false, "c": 99}, "d": {"e": [9, 8, 7], "f": {"name": "pg_class", "relkind": "r"}}}
(1 row)
-- empty objects/arrays
SELECT jsonb_build_array();
jsonb_build_array
-------------------
[]
(1 row)
SELECT jsonb_build_object();
jsonb_build_object
--------------------
{}
(1 row)
-- make sure keys are quoted
SELECT jsonb_build_object(1,2);
jsonb_build_object
--------------------
{"1": 2}
(1 row)
-- keys must be scalar and not null
SELECT jsonb_build_object(null,2);
ERROR: arg 1: key cannot be null
SELECT jsonb_build_object(r,2) FROM (SELECT 1 AS a, 2 AS b) r;
ERROR: key value must be scalar, not array, composite or json
SELECT jsonb_build_object(json '{"a":1,"b":2}', 3);
ERROR: key value must be scalar, not array, composite or json
SELECT jsonb_build_object('{1,2,3}'::int[], 3);
ERROR: key value must be scalar, not array, composite or json
CREATE TEMP TABLE foo (serial_num int, name text, type text);
INSERT INTO foo VALUES (847001,'t15','GE1043');
INSERT INTO foo VALUES (847002,'t16','GE1043');
INSERT INTO foo VALUES (847003,'sub-alpha','GESS90');
SELECT jsonb_build_object('turbines',jsonb_object_agg(serial_num,jsonb_build_object('name',name,'type',type)))
FROM foo;
jsonb_build_object
-------------------------------------------------------------------------------------------------------------------------------------------------------------
{"turbines": {"847001": {"name": "t15", "type": "GE1043"}, "847002": {"name": "t16", "type": "GE1043"}, "847003": {"name": "sub-alpha", "type": "GESS90"}}}
(1 row)
-- jsonb_object
-- one dimension
SELECT jsonb_object('{a,1,b,2,3,NULL,"d e f","a b c"}');
jsonb_object
---------------------------------------------------
{"3": null, "a": "1", "b": "2", "d e f": "a b c"}
(1 row)
-- same but with two dimensions
SELECT jsonb_object('{{a,1},{b,2},{3,NULL},{"d e f","a b c"}}');
jsonb_object
---------------------------------------------------
{"3": null, "a": "1", "b": "2", "d e f": "a b c"}
(1 row)
-- odd number error
SELECT jsonb_object('{a,b,c}');
ERROR: array must have even number of elements
-- one column error
SELECT jsonb_object('{{a},{b}}');
ERROR: array must have two columns
-- too many columns error
SELECT jsonb_object('{{a,b,c},{b,c,d}}');
ERROR: array must have two columns
-- too many dimensions error
SELECT jsonb_object('{{{a,b},{c,d}},{{b,c},{d,e}}}');
ERROR: wrong number of array subscripts
--two argument form of jsonb_object
select jsonb_object('{a,b,c,"d e f"}','{1,2,3,"a b c"}');
jsonb_object
--------------------------------------------------
{"a": "1", "b": "2", "c": "3", "d e f": "a b c"}
(1 row)
-- too many dimensions
SELECT jsonb_object('{{a,1},{b,2},{3,NULL},{"d e f","a b c"}}', '{{a,1},{b,2},{3,NULL},{"d e f","a b c"}}');
ERROR: wrong number of array subscripts
-- mismatched dimensions
select jsonb_object('{a,b,c,"d e f",g}','{1,2,3,"a b c"}');
ERROR: mismatched array dimensions
select jsonb_object('{a,b,c,"d e f"}','{1,2,3,"a b c",g}');
ERROR: mismatched array dimensions
-- null key error
select jsonb_object('{a,b,NULL,"d e f"}','{1,2,3,"a b c"}');
ERROR: null value not allowed for object key
-- empty key is allowed
select jsonb_object('{a,b,"","d e f"}','{1,2,3,"a b c"}');
jsonb_object
-------------------------------------------------
{"": "3", "a": "1", "b": "2", "d e f": "a b c"}
(1 row)
-- extract_path, extract_path_as_text -- extract_path, extract_path_as_text
SELECT jsonb_extract_path('{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}','f4','f6'); SELECT jsonb_extract_path('{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}','f4','f6');
jsonb_extract_path jsonb_extract_path

View File

@ -62,6 +62,41 @@ SELECT ' '::jsonb; -- ERROR, no value
-- make sure jsonb is passed through json generators without being escaped -- make sure jsonb is passed through json generators without being escaped
SELECT array_to_json(ARRAY [jsonb '{"a":1}', jsonb '{"b":[2,3]}']); SELECT array_to_json(ARRAY [jsonb '{"a":1}', jsonb '{"b":[2,3]}']);
-- to_jsonb, timestamps
select to_jsonb(timestamp '2014-05-28 12:22:35.614298');
BEGIN;
SET LOCAL TIME ZONE 10.5;
select to_jsonb(timestamptz '2014-05-28 12:22:35.614298-04');
SET LOCAL TIME ZONE -8;
select to_jsonb(timestamptz '2014-05-28 12:22:35.614298-04');
COMMIT;
-- unicode escape - backslash is not escaped
select to_jsonb(text '\uabcd');
-- any other backslash is escaped
select to_jsonb(text '\abcd');
--jsonb_agg
CREATE TEMP TABLE rows AS
SELECT x, 'txt' || x as y
FROM generate_series(1,3) AS x;
SELECT jsonb_agg(q)
FROM ( SELECT $$a$$ || x AS b, y AS c,
ARRAY[ROW(x.*,ARRAY[1,2,3]),
ROW(y.*,ARRAY[4,5,6])] AS z
FROM generate_series(1,2) x,
generate_series(4,5) y) q;
SELECT jsonb_agg(q)
FROM rows q;
-- jsonb extraction functions -- jsonb extraction functions
CREATE TEMP TABLE test_jsonb ( CREATE TEMP TABLE test_jsonb (
json_type text, json_type text,
@ -263,6 +298,86 @@ SELECT jsonb_typeof('"hello"') AS string;
SELECT jsonb_typeof('"true"') AS string; SELECT jsonb_typeof('"true"') AS string;
SELECT jsonb_typeof('"1.0"') AS string; SELECT jsonb_typeof('"1.0"') AS string;
-- jsonb_build_array, jsonb_build_object, jsonb_object_agg
SELECT jsonb_build_array('a',1,'b',1.2,'c',true,'d',null,'e',json '{"x": 3, "y": [1,2,3]}');
SELECT jsonb_build_object('a',1,'b',1.2,'c',true,'d',null,'e',json '{"x": 3, "y": [1,2,3]}');
SELECT jsonb_build_object(
'a', jsonb_build_object('b',false,'c',99),
'd', jsonb_build_object('e',array[9,8,7]::int[],
'f', (select row_to_json(r) from ( select relkind, oid::regclass as name from pg_class where relname = 'pg_class') r)));
-- empty objects/arrays
SELECT jsonb_build_array();
SELECT jsonb_build_object();
-- make sure keys are quoted
SELECT jsonb_build_object(1,2);
-- keys must be scalar and not null
SELECT jsonb_build_object(null,2);
SELECT jsonb_build_object(r,2) FROM (SELECT 1 AS a, 2 AS b) r;
SELECT jsonb_build_object(json '{"a":1,"b":2}', 3);
SELECT jsonb_build_object('{1,2,3}'::int[], 3);
CREATE TEMP TABLE foo (serial_num int, name text, type text);
INSERT INTO foo VALUES (847001,'t15','GE1043');
INSERT INTO foo VALUES (847002,'t16','GE1043');
INSERT INTO foo VALUES (847003,'sub-alpha','GESS90');
SELECT jsonb_build_object('turbines',jsonb_object_agg(serial_num,jsonb_build_object('name',name,'type',type)))
FROM foo;
-- jsonb_object
-- one dimension
SELECT jsonb_object('{a,1,b,2,3,NULL,"d e f","a b c"}');
-- same but with two dimensions
SELECT jsonb_object('{{a,1},{b,2},{3,NULL},{"d e f","a b c"}}');
-- odd number error
SELECT jsonb_object('{a,b,c}');
-- one column error
SELECT jsonb_object('{{a},{b}}');
-- too many columns error
SELECT jsonb_object('{{a,b,c},{b,c,d}}');
-- too many dimensions error
SELECT jsonb_object('{{{a,b},{c,d}},{{b,c},{d,e}}}');
--two argument form of jsonb_object
select jsonb_object('{a,b,c,"d e f"}','{1,2,3,"a b c"}');
-- too many dimensions
SELECT jsonb_object('{{a,1},{b,2},{3,NULL},{"d e f","a b c"}}', '{{a,1},{b,2},{3,NULL},{"d e f","a b c"}}');
-- mismatched dimensions
select jsonb_object('{a,b,c,"d e f",g}','{1,2,3,"a b c"}');
select jsonb_object('{a,b,c,"d e f"}','{1,2,3,"a b c",g}');
-- null key error
select jsonb_object('{a,b,NULL,"d e f"}','{1,2,3,"a b c"}');
-- empty key is allowed
select jsonb_object('{a,b,"","d e f"}','{1,2,3,"a b c"}');
-- extract_path, extract_path_as_text -- extract_path, extract_path_as_text
SELECT jsonb_extract_path('{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}','f4','f6'); SELECT jsonb_extract_path('{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}','f4','f6');
SELECT jsonb_extract_path('{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}','f2'); SELECT jsonb_extract_path('{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}','f2');