Introduce jsonb, a structured format for storing json.

The new format accepts exactly the same data as the json type. However, it is
stored in a format that does not require reparsing the orgiginal text in order
to process it, making it much more suitable for indexing and other operations.
Insignificant whitespace is discarded, and the order of object keys is not
preserved. Neither are duplicate object keys kept - the later value for a given
key is the only one stored.

The new type has all the functions and operators that the json type has,
with the exception of the json generation functions (to_json, json_agg etc.)
and with identical semantics. In addition, there are operator classes for
hash and btree indexing, and two classes for GIN indexing, that have no
equivalent in the json type.

This feature grew out of previous work by Oleg Bartunov and Teodor Sigaev, which
was intended to provide similar facilities to a nested hstore type, but which
in the end proved to have some significant compatibility issues.

Authors: Oleg Bartunov,  Teodor Sigaev, Peter Geoghegan and Andrew Dunstan.
Review: Andres Freund
This commit is contained in:
Andrew Dunstan 2014-03-23 16:40:19 -04:00
parent b2b2491b06
commit d9134d0a35
43 changed files with 11701 additions and 420 deletions

View File

@ -5,7 +5,8 @@ OBJS = hstore_io.o hstore_op.o hstore_gist.o hstore_gin.o hstore_compat.o \
crc32.o
EXTENSION = hstore
DATA = hstore--1.2.sql hstore--1.1--1.2.sql hstore--1.0--1.1.sql \
DATA = hstore--1.3.sql hstore--1.2--1.3.sql \
hstore--1.1--1.2.sql hstore--1.0--1.1.sql \
hstore--unpackaged--1.0.sql
REGRESS = hstore

View File

@ -1453,7 +1453,7 @@ select count(*) from testhstore where h = 'pos=>98, line=>371, node=>CBA, indexe
1
(1 row)
-- json
-- json and jsonb
select hstore_to_json('"a key" =>1, b => t, c => null, d=> 12345, e => 012345, f=> 1.234, g=> 2.345e+4');
hstore_to_json
-------------------------------------------------------------------------------------------------
@ -1472,6 +1472,24 @@ select hstore_to_json_loose('"a key" =>1, b => t, c => null, d=> 12345, e => 012
{"b": true, "c": null, "d": 12345, "e": "012345", "f": 1.234, "g": 2.345e+4, "a key": 1}
(1 row)
select hstore_to_jsonb('"a key" =>1, b => t, c => null, d=> 12345, e => 012345, f=> 1.234, g=> 2.345e+4');
hstore_to_jsonb
-------------------------------------------------------------------------------------------------
{"b": "t", "c": null, "d": "12345", "e": "012345", "f": "1.234", "g": "2.345e+4", "a key": "1"}
(1 row)
select cast( hstore '"a key" =>1, b => t, c => null, d=> 12345, e => 012345, f=> 1.234, g=> 2.345e+4' as jsonb);
jsonb
-------------------------------------------------------------------------------------------------
{"b": "t", "c": null, "d": "12345", "e": "012345", "f": "1.234", "g": "2.345e+4", "a key": "1"}
(1 row)
select hstore_to_jsonb_loose('"a key" =>1, b => t, c => null, d=> 12345, e => 012345, f=> 1.234, g=> 2.345e+4');
hstore_to_jsonb_loose
---------------------------------------------------------------------------------------
{"b": true, "c": null, "d": 12345, "e": "012345", "f": 1.234, "g": 23450, "a key": 1}
(1 row)
create table test_json_agg (f1 text, f2 hstore);
insert into test_json_agg values ('rec1','"a key" =>1, b => t, c => null, d=> 12345, e => 012345, f=> 1.234, g=> 2.345e+4'),
('rec2','"a key" =>2, b => f, c => "null", d=> -12345, e => 012345.6, f=> -1.234, g=> 0.345e-4');

View File

@ -0,0 +1,17 @@
/* contrib/hstore/hstore--1.2--1.3.sql */
-- complain if script is sourced in psql, rather than via ALTER EXTENSION
\echo Use "ALTER EXTENSION hstore UPDATE TO '1.3'" to load this file. \quit
CREATE FUNCTION hstore_to_jsonb(hstore)
RETURNS jsonb
AS 'MODULE_PATHNAME', 'hstore_to_jsonb'
LANGUAGE C IMMUTABLE STRICT;
CREATE CAST (hstore AS jsonb)
WITH FUNCTION hstore_to_jsonb(hstore);
CREATE FUNCTION hstore_to_jsonb_loose(hstore)
RETURNS jsonb
AS 'MODULE_PATHNAME', 'hstore_to_jsonb_loose'
LANGUAGE C IMMUTABLE STRICT;

View File

@ -1,4 +1,4 @@
/* contrib/hstore/hstore--1.1.sql */
/* contrib/hstore/hstore--1.3.sql */
-- complain if script is sourced in psql, rather than via CREATE EXTENSION
\echo Use "CREATE EXTENSION hstore" to load this file. \quit
@ -247,6 +247,19 @@ RETURNS json
AS 'MODULE_PATHNAME', 'hstore_to_json_loose'
LANGUAGE C IMMUTABLE STRICT;
CREATE FUNCTION hstore_to_jsonb(hstore)
RETURNS jsonb
AS 'MODULE_PATHNAME', 'hstore_to_jsonb'
LANGUAGE C IMMUTABLE STRICT;
CREATE CAST (hstore AS jsonb)
WITH FUNCTION hstore_to_jsonb(hstore);
CREATE FUNCTION hstore_to_jsonb_loose(hstore)
RETURNS jsonb
AS 'MODULE_PATHNAME', 'hstore_to_jsonb_loose'
LANGUAGE C IMMUTABLE STRICT;
CREATE FUNCTION hstore(record)
RETURNS hstore
AS 'MODULE_PATHNAME', 'hstore_from_record'

View File

@ -1,5 +1,5 @@
# hstore extension
comment = 'data type for storing sets of (key, value) pairs'
default_version = '1.2'
default_version = '1.3'
module_pathname = '$libdir/hstore'
relocatable = true

View File

@ -12,6 +12,7 @@
#include "libpq/pqformat.h"
#include "utils/builtins.h"
#include "utils/json.h"
#include "utils/jsonb.h"
#include "utils/lsyscache.h"
#include "utils/memutils.h"
#include "utils/typcache.h"
@ -1374,3 +1375,167 @@ hstore_to_json(PG_FUNCTION_ARGS)
PG_RETURN_TEXT_P(cstring_to_text(dst.data));
}
PG_FUNCTION_INFO_V1(hstore_to_jsonb);
Datum hstore_to_jsonb(PG_FUNCTION_ARGS);
Datum
hstore_to_jsonb(PG_FUNCTION_ARGS)
{
HStore *in = PG_GETARG_HS(0);
int i;
int count = HS_COUNT(in);
char *base = STRPTR(in);
HEntry *entries = ARRPTR(in);
JsonbParseState *state = NULL;
JsonbValue *res;
res = pushJsonbValue(&state, WJB_BEGIN_OBJECT, NULL);
for (i = 0; i < count; i++)
{
JsonbValue key, val;
key.estSize = sizeof(JEntry);
key.type = jbvString;
key.string.len = HS_KEYLEN(entries, i);
key.string.val = pnstrdup(HS_KEY(entries, base, i), key.string.len);
key.estSize += key.string.len;
res = pushJsonbValue(&state, WJB_KEY, &key);
if (HS_VALISNULL(entries, i))
{
val.estSize = sizeof(JEntry);
val.type = jbvNull;
}
else
{
val.estSize = sizeof(JEntry);
val.type = jbvString;
val.string.len = HS_VALLEN(entries, i);
val.string.val = pnstrdup(HS_VAL(entries, base, i), val.string.len);
val.estSize += val.string.len;
}
res = pushJsonbValue(&state, WJB_VALUE, &val);
}
res = pushJsonbValue(&state, WJB_END_OBJECT, NULL);
PG_RETURN_POINTER(JsonbValueToJsonb(res));
}
PG_FUNCTION_INFO_V1(hstore_to_jsonb_loose);
Datum hstore_to_jsonb_loose(PG_FUNCTION_ARGS);
Datum
hstore_to_jsonb_loose(PG_FUNCTION_ARGS)
{
HStore *in = PG_GETARG_HS(0);
int i;
int count = HS_COUNT(in);
char *base = STRPTR(in);
HEntry *entries = ARRPTR(in);
JsonbParseState *state = NULL;
JsonbValue *res;
StringInfoData tmp;
bool is_number;
initStringInfo(&tmp);
res = pushJsonbValue(&state, WJB_BEGIN_OBJECT, NULL);
for (i = 0; i < count; i++)
{
JsonbValue key, val;
key.estSize = sizeof(JEntry);
key.type = jbvString;
key.string.len = HS_KEYLEN(entries, i);
key.string.val = pnstrdup(HS_KEY(entries, base, i), key.string.len);
key.estSize += key.string.len;
res = pushJsonbValue(&state, WJB_KEY, &key);
val.estSize = sizeof(JEntry);
if (HS_VALISNULL(entries, i))
{
val.type = jbvNull;
}
/* guess that values of 't' or 'f' are booleans */
else if (HS_VALLEN(entries, i) == 1 && *(HS_VAL(entries, base, i)) == 't')
{
val.type = jbvBool;
val.boolean = true;
}
else if (HS_VALLEN(entries, i) == 1 && *(HS_VAL(entries, base, i)) == 'f')
{
val.type = jbvBool;
val.boolean = false;
}
else
{
is_number = false;
resetStringInfo(&tmp);
appendBinaryStringInfo(&tmp, HS_VAL(entries, base, i), HS_VALLEN(entries, i));
/*
* don't treat something with a leading zero followed by another
* digit as numeric - could be a zip code or similar
*/
if (tmp.len > 0 &&
!(tmp.data[0] == '0' &&
isdigit((unsigned char) tmp.data[1])) &&
strspn(tmp.data, "+-0123456789Ee.") == tmp.len)
{
/*
* might be a number. See if we can input it as a numeric
* value. Ignore any actual parsed value.
*/
char *endptr = "junk";
long lval;
lval = strtol(tmp.data, &endptr, 10);
(void) lval;
if (*endptr == '\0')
{
/*
* strol man page says this means the whole string is
* valid
*/
is_number = true;
}
else
{
/* not an int - try a double */
double dval;
dval = strtod(tmp.data, &endptr);
(void) dval;
if (*endptr == '\0')
is_number = true;
}
}
if (is_number)
{
val.type = jbvNumeric;
val.numeric = DatumGetNumeric(
DirectFunctionCall3(numeric_in, CStringGetDatum(tmp.data), 0, -1));
val.estSize += VARSIZE_ANY(val.numeric) +sizeof(JEntry);
}
else
{
val.estSize = sizeof(JEntry);
val.type = jbvString;
val.string.len = HS_VALLEN(entries, i);
val.string.val = pnstrdup(HS_VAL(entries, base, i), val.string.len);
val.estSize += val.string.len;
}
}
res = pushJsonbValue(&state, WJB_VALUE, &val);
}
res = pushJsonbValue(&state, WJB_END_OBJECT, NULL);
PG_RETURN_POINTER(JsonbValueToJsonb(res));
}

View File

@ -331,11 +331,15 @@ set enable_seqscan=off;
select count(*) from testhstore where h #># 'p=>1';
select count(*) from testhstore where h = 'pos=>98, line=>371, node=>CBA, indexed=>t';
-- json
-- json and jsonb
select hstore_to_json('"a key" =>1, b => t, c => null, d=> 12345, e => 012345, f=> 1.234, g=> 2.345e+4');
select cast( hstore '"a key" =>1, b => t, c => null, d=> 12345, e => 012345, f=> 1.234, g=> 2.345e+4' as json);
select hstore_to_json_loose('"a key" =>1, b => t, c => null, d=> 12345, e => 012345, f=> 1.234, g=> 2.345e+4');
select hstore_to_jsonb('"a key" =>1, b => t, c => null, d=> 12345, e => 012345, f=> 1.234, g=> 2.345e+4');
select cast( hstore '"a key" =>1, b => t, c => null, d=> 12345, e => 012345, f=> 1.234, g=> 2.345e+4' as jsonb);
select hstore_to_jsonb_loose('"a key" =>1, b => t, c => null, d=> 12345, e => 012345, f=> 1.234, g=> 2.345e+4');
create table test_json_agg (f1 text, f2 hstore);
insert into test_json_agg values ('rec1','"a key" =>1, b => t, c => null, d=> 12345, e => 012345, f=> 1.234, g=> 2.345e+4'),
('rec2','"a key" =>2, b => f, c => "null", d=> -12345, e => 012345.6, f=> -1.234, g=> 0.345e-4');

View File

@ -139,7 +139,13 @@
<row>
<entry><type>json</type></entry>
<entry></entry>
<entry>JSON data</entry>
<entry>textual JSON data</entry>
</row>
<row>
<entry><type>jsonb</type></entry>
<entry></entry>
<entry>binary JSON data, decomposed</entry>
</row>
<row>
@ -4220,34 +4226,7 @@ SET xmloption TO { DOCUMENT | CONTENT };
</sect2>
</sect1>
<sect1 id="datatype-json">
<title><acronym>JSON</> Type</title>
<indexterm zone="datatype-json">
<primary>JSON</primary>
</indexterm>
<para>
The <type>json</type> data type can be used to store JSON (JavaScript
Object Notation) data, as specified in <ulink
url="http://www.ietf.org/rfc/rfc4627.txt">RFC 4627</ulink>. Such
data can also be stored as <type>text</type>, but the
<type>json</type> data type has the advantage of checking that each
stored value is a valid JSON value. There are also related support
functions available; see <xref linkend="functions-json">.
</para>
<para>
<productname>PostgreSQL</productname> allows only one server encoding
per database. It is therefore not possible for JSON to conform rigidly
to the specification unless the server encoding is UTF-8. Attempts to
directly include characters which cannot be represented in the server
encoding will fail; conversely, characters which can be represented in
the server encoding but not in UTF-8 will be allowed.
<literal>\uXXXX</literal> escapes are allowed regardless of the server
encoding, and are checked only for syntactic correctness.
</para>
</sect1>
&json;
&array;

View File

@ -22,6 +22,7 @@
<!ENTITY dml SYSTEM "dml.sgml">
<!ENTITY func SYSTEM "func.sgml">
<!ENTITY indices SYSTEM "indices.sgml">
<!ENTITY json SYSTEM "json.sgml">
<!ENTITY mvcc SYSTEM "mvcc.sgml">
<!ENTITY perform SYSTEM "perform.sgml">
<!ENTITY queries SYSTEM "queries.sgml">

View File

@ -10079,12 +10079,13 @@ table2-mapping
</indexterm>
<para>
<xref linkend="functions-json-op-table"> shows the operators that are
available for use with JSON (see <xref linkend="datatype-json">) data.
<xref linkend="functions-json-op-table"> shows the operators that
are available for use with the two JSON datatypes (see <xref
linkend="datatype-json">).
</para>
<table id="functions-json-op-table">
<title>JSON Operators</title>
<title><type>json</> and <type>jsonb</> Operators</title>
<tgroup cols="4">
<thead>
<row>
@ -10121,13 +10122,13 @@ table2-mapping
</row>
<row>
<entry><literal>#&gt;</literal></entry>
<entry>array of text</entry>
<entry>text[]</entry>
<entry>Get JSON object at specified path</entry>
<entry><literal>'{"a":[1,2,3],"b":[4,5,6]}'::json#&gt;'{a,2}'</literal></entry>
</row>
<row>
<entry><literal>#&gt;&gt;</literal></entry>
<entry>array of text</entry>
<entry>text[]</entry>
<entry>Get JSON object at specified path as text</entry>
<entry><literal>'{"a":[1,2,3],"b":[4,5,6]}'::json#&gt;&gt;'{a,2}'</literal></entry>
</row>
@ -10135,13 +10136,107 @@ table2-mapping
</tgroup>
</table>
<note>
<para>
There are parallel variants of these operators for both the
<type>json</type> and <type>jsonb</type> types. In addition to
those operators common to both types, a further set of operators
exists for <type>jsonb</type> (which comprise the default
<acronym>GIN</acronym> operator class).
</para>
</note>
<para>
<xref linkend="functions-json-table"> shows the functions that are available
for creating and manipulating JSON (see <xref linkend="datatype-json">) data.
The following are <type>jsonb</>-only operators, used by
<type>jsonb</> operator classes. For a full description of
<type>jsonb</> containment semantics and nesting, see <xref
linkend="json-containment">. <xref linkend="json-indexing">
describes how these operators can be used to effectively index
<type>jsonb</>.
</para>
<table id="functions-jsonb-op-table">
<title>Additonal JSONB Operators</title>
<tgroup cols="4">
<thead>
<row>
<entry>Operator</entry>
<entry>Right Operand Type</entry>
<entry>Description</entry>
<entry>Example</entry>
</row>
</thead>
<tbody>
<row>
<entry><literal>=</literal></entry>
<entry>jsonb</entry>
<entry>Is the jsonb equal to this jsonb?</entry>
<entry><literal>'[1,2,3]'::jsonb = '[1,2,3]'::jsonb</literal></entry>
</row>
<row>
<entry><literal>@&gt;</literal></entry>
<entry>jsonb</entry>
<entry>Does the jsonb contain within it this jsonb?</entry>
<entry><literal>'{"a":1, "b":2}'::jsonb &#64;&gt; '{"b":2}'::jsonb</literal></entry>
</row>
<row>
<entry><literal>&lt;@</literal></entry>
<entry>jsonb</entry>
<entry>Does the jsonb have contained within it this jsonb?</entry>
<entry><literal>'{"b":2}'::jsonb &lt;@ '{"a":1, "b":2}'::jsonb</literal></entry>
</row>
<row>
<entry><literal>?</literal></entry>
<entry>text</entry>
<entry>Does this key/element <emphasis>string</emphasis> exist?</entry>
<entry><literal>'{"a":1, "b":2}'::jsonb ? 'b'</literal></entry>
</row>
<row>
<entry><literal>?|</literal></entry>
<entry>text[]</entry>
<entry>Do any of these key/element <emphasis>strings</emphasis> exist?</entry>
<entry><literal>'{"a":1, "b":2, "c":3}'::jsonb ?| array['b', 'c']</literal></entry>
</row>
<row>
<entry><literal>?&amp;</literal></entry>
<entry>text[]</entry>
<entry>Do all of these key/element <emphasis>strings</emphasis> exist?</entry>
<entry><literal>'["a", "b"]'::jsonb ?&amp; array['a', 'b']</literal></entry>
</row>
</tbody>
</tgroup>
</table>
<!--
The release notes contain a reference to "functions-json-table". Since
that table is now split in two, the id has been parked here so we don't
have to change the release notes.
-->
<para id="functions-json-table">
<xref linkend="functions-json-creation-table"> shows the functions that are
available for creating <type>json</type> values.
(see <xref linkend="datatype-json">)
</para>
<table id="functions-json-table">
<title>JSON Support Functions</title>
<indexterm>
<primary>array_to_json</primary>
</indexterm>
<indexterm>
<primary>row_to_json</primary>
</indexterm>
<indexterm>
<primary>to_json</primary>
</indexterm>
<indexterm>
<primary>json_build_array</primary>
</indexterm>
<indexterm>
<primary>json_build_object</primary>
</indexterm>
<indexterm>
<primary>json_object</primary>
</indexterm>
<table id="functions-json-creation-table">
<title>JSON Creation Functions</title>
<tgroup cols="5">
<thead>
<row>
@ -10155,9 +10250,6 @@ table2-mapping
<tbody>
<row>
<entry>
<indexterm>
<primary>array_to_json</primary>
</indexterm>
<literal>array_to_json(anyarray [, pretty_bool])</literal>
</entry>
<entry><type>json</type></entry>
@ -10171,9 +10263,6 @@ table2-mapping
</row>
<row>
<entry>
<indexterm>
<primary>row_to_json</primary>
</indexterm>
<literal>row_to_json(record [, pretty_bool])</literal>
</entry>
<entry><type>json</type></entry>
@ -10186,9 +10275,6 @@ table2-mapping
</row>
<row>
<entry>
<indexterm>
<primary>to_json</primary>
</indexterm>
<literal>to_json(anyelement)</literal>
</entry>
<entry><type>json</type></entry>
@ -10204,223 +10290,6 @@ table2-mapping
</row>
<row>
<entry>
<indexterm>
<primary>json_array_length</primary>
</indexterm>
<literal>json_array_length(json)</literal>
</entry>
<entry><type>int</type></entry>
<entry>
Returns the number of elements in the outermost JSON array.
</entry>
<entry><literal>json_array_length('[1,2,3,{"f1":1,"f2":[5,6]},4]')</literal></entry>
<entry><literal>5</literal></entry>
</row>
<row>
<entry>
<indexterm>
<primary>json_each</primary>
</indexterm>
<literal>json_each(json)</literal>
</entry>
<entry><type>SETOF key text, value json</type></entry>
<entry>
Expands the outermost JSON object into a set of key/value pairs.
</entry>
<entry><literal>select * from json_each('{"a":"foo", "b":"bar"}')</literal></entry>
<entry>
<programlisting>
key | value
-----+-------
a | "foo"
b | "bar"
</programlisting>
</entry>
</row>
<row>
<entry>
<indexterm>
<primary>json_each_text</primary>
</indexterm>
<literal>json_each_text(from_json json)</literal>
</entry>
<entry><type>SETOF key text, value text</type></entry>
<entry>
Expands the outermost JSON object into a set of key/value pairs. The
returned value will be of type text.
</entry>
<entry><literal>select * from json_each_text('{"a":"foo", "b":"bar"}')</literal></entry>
<entry>
<programlisting>
key | value
-----+-------
a | foo
b | bar
</programlisting>
</entry>
</row>
<row>
<entry>
<indexterm>
<primary>json_extract_path</primary>
</indexterm>
<literal>json_extract_path(from_json json, VARIADIC path_elems text[])</literal>
</entry>
<entry><type>json</type></entry>
<entry>
Returns JSON value pointed to by <parameter>path_elems</parameter>.
</entry>
<entry><literal>json_extract_path('{"f2":{"f3":1},"f4":{"f5":99,"f6":"foo"}}','f4')</literal></entry>
<entry><literal>{"f5":99,"f6":"foo"}</literal></entry>
</row>
<row>
<entry>
<indexterm>
<primary>json_extract_path_text</primary>
</indexterm>
<literal>json_extract_path_text(from_json json, VARIADIC path_elems text[])</literal>
</entry>
<entry><type>text</type></entry>
<entry>
Returns JSON value pointed to by <parameter>path_elems</parameter>.
</entry>
<entry><literal>json_extract_path_text('{"f2":{"f3":1},"f4":{"f5":99,"f6":"foo"}}','f4', 'f6')</literal></entry>
<entry><literal>foo</literal></entry>
</row>
<row>
<entry>
<indexterm>
<primary>json_object_keys</primary>
</indexterm>
<literal>json_object_keys(json)</literal>
</entry>
<entry><type>SETOF text</type></entry>
<entry>
Returns set of keys in the JSON object. Only the <quote>outer</quote> object will be displayed.
</entry>
<entry><literal>json_object_keys('{"f1":"abc","f2":{"f3":"a", "f4":"b"}}')</literal></entry>
<entry>
<programlisting>
json_object_keys
------------------
f1
f2
</programlisting>
</entry>
</row>
<row>
<entry>
<indexterm>
<primary>json_populate_record</primary>
</indexterm>
<literal>json_populate_record(base anyelement, from_json json, [, use_json_as_text bool=false]</literal>
</entry>
<entry><type>anyelement</type></entry>
<entry>
Expands the object in <replaceable>from_json</replaceable> to a row whose columns match
the record type defined by base. Conversion will be best
effort; columns in base with no corresponding key in <replaceable>from_json</replaceable>
will be left null. If a column is specified more than once, the last value is used.
</entry>
<entry><literal>select * from json_populate_record(null::x, '{"a":1,"b":2}')</literal></entry>
<entry>
<programlisting>
a | b
---+---
1 | 2
</programlisting>
</entry>
</row>
<row>
<entry>
<indexterm>
<primary>json_populate_recordset</primary>
</indexterm>
<literal>json_populate_recordset(base anyelement, from_json json, [, use_json_as_text bool=false]</literal>
</entry>
<entry><type>SETOF anyelement</type></entry>
<entry>
Expands the outermost set of objects in <replaceable>from_json</replaceable> to a set
whose columns match the record type defined by base.
Conversion will be best effort; columns in base with no
corresponding key in <replaceable>from_json</replaceable> will be left null.
If a column is specified more than once, the last value is used.
</entry>
<entry><literal>select * from json_populate_recordset(null::x, '[{"a":1,"b":2},{"a":3,"b":4}]')</literal></entry>
<entry>
<programlisting>
a | b
---+---
1 | 2
3 | 4
</programlisting>
</entry>
</row>
<row>
<entry>
<indexterm>
<primary>json_array_elements</primary>
</indexterm>
<literal>json_array_elements(json)</literal>
</entry>
<entry><type>SETOF json</type></entry>
<entry>
Expands a JSON array to a set of JSON values.
</entry>
<entry><literal>SELECT * FROM json_array_elements('[1,true, [2,false]]')</literal></entry>
<entry>
<programlisting>
value
-----------
1
true
[2,false]
</programlisting>
</entry>
</row>
<row>
<entry>
<indexterm>
<primary>json_array_elements_text</primary>
</indexterm>
<literal>json_array_elements_text(json)</literal>
</entry>
<entry><type>SETOF text</type></entry>
<entry>
Expands a JSON array to a set of text values.
</entry>
<entry><literal>SELECT * FROM json_array_elements_text('["foo", "bar"]')</literal></entry>
<entry>
<programlisting>
value
-----------
foo
bar
</programlisting>
</entry>
</row>
<row>
<entry>
<indexterm>
<primary>json_typeof</primary>
</indexterm>
<literal>json_typeof(json)</literal>
</entry>
<entry><type>text</type></entry>
<entry>
Returns the type of the outermost JSON value as a text string. The types are
<literal>object</>, <literal>array</>, <literal>string</>, <literal>number</>,
<literal>boolean</>, and <literal>null</>. (See note below regarding the
distinction between a JSON <literal>null</> and a SQL NULL.)
</entry>
<entry><literal>json_typeof('-123.4')</literal></entry>
<entry><literal>number</literal></entry>
</row>
<row>
<entry>
<indexterm>
<primary>json_build_array</primary>
</indexterm>
<literal>json_build_array(VARIADIC "any")</literal>
</entry>
<entry><type>json</type></entry>
@ -10438,16 +10307,13 @@ table2-mapping
</row>
<row>
<entry>
<indexterm>
<primary>json_build_object</primary>
</indexterm>
<literal>json_build_object(VARIADIC "any")</literal>
</entry>
<entry><type>json</type></entry>
<entry>
Builds a JSON array out of a variadic argument list.
By convention, the object is
constructed out of alternating name/value arguments.
Builds a JSON array out of a variadic argument list. By
convention, the object is constructed out of alternating
name/value arguments.
</entry>
<entry><literal>SELECT json_build_object('foo',1,'bar',2);</literal></entry>
<entry>
@ -10460,9 +10326,6 @@ table2-mapping
</row>
<row>
<entry>
<indexterm>
<primary>json_object</primary>
</indexterm>
<literal>json_object(text[])</literal>
</entry>
<entry><type>json</type></entry>
@ -10473,7 +10336,7 @@ table2-mapping
such that each inner array has exactly two elements, which
are taken as a name/value pair.
</entry>
<entry><literal>select * from json_object('{a, 1, b, "def", c, 3.5}') or <literal>select * from json_object('{{a, 1},{b, "def"},{c, 3.5}}')</literal></literal></entry>
<entry><literal>select * from json_object('{a, 1, b, "def", c, 3.5}') or <literal>select json_object('{{a, 1},{b, "def"},{c, 3.5}}')</literal></literal></entry>
<entry>
<programlisting>
json_object
@ -10491,7 +10354,7 @@ table2-mapping
The two-argument form of JSON object takes keys and values pairwise from two separate
arrays. In all other respects it is identical to the one-argument form.
</entry>
<entry><literal>select * from json_object('{a, b}', '{1,2}');</literal></entry>
<entry><literal>select json_object('{a, b}', '{1,2}');</literal></entry>
<entry>
<programlisting>
json_object
@ -10500,16 +10363,298 @@ table2-mapping
</programlisting>
</entry>
</row>
</tbody>
</tgroup>
</table>
<para>
<xref linkend="functions-json-processing-table"> shows the functions that
are available for processing <type>json</type> and <type>jsonb</type> values.
(see <xref linkend="datatype-json">)
</para>
<indexterm>
<primary>json_array_length</primary>
</indexterm>
<indexterm>
<primary>jsonb_array_length</primary>
</indexterm>
<indexterm>
<primary>json_each</primary>
</indexterm>
<indexterm>
<primary>jsonb_each</primary>
</indexterm>
<indexterm>
<primary>json_each_text</primary>
</indexterm>
<indexterm>
<primary>jsonb_each_text</primary>
</indexterm>
<indexterm>
<primary>json_extract_path</primary>
</indexterm>
<indexterm>
<primary>jsonb_extract_path</primary>
</indexterm>
<indexterm>
<primary>json_extract_path_text</primary>
</indexterm>
<indexterm>
<primary>jsonb_extract_path_text</primary>
</indexterm>
<indexterm>
<primary>json_object_keys</primary>
</indexterm>
<indexterm>
<primary>jsonb_object_keys</primary>
</indexterm>
<indexterm>
<primary>json_populate_record</primary>
</indexterm>
<indexterm>
<primary>jsonb_populate_record</primary>
</indexterm>
<indexterm>
<primary>json_populate_recordset</primary>
</indexterm>
<indexterm>
<primary>jsonb_populate_recordset</primary>
</indexterm>
<indexterm>
<primary>json_array_elements</primary>
</indexterm>
<indexterm>
<primary>jsonb_array_elements</primary>
</indexterm>
<indexterm>
<primary>json_array_elements_text</primary>
</indexterm>
<indexterm>
<primary>jsonb_array_elements_text</primary>
</indexterm>
<indexterm>
<primary>json_typeof</primary>
</indexterm>
<indexterm>
<primary>jsonb_typeof</primary>
</indexterm>
<indexterm>
<primary>json_to_record</primary>
</indexterm>
<indexterm>
<primary>json_to_recordset</primary>
</indexterm>
<table id="functions-json-processing-table">
<title>JSON Processing Functions</title>
<tgroup cols="5">
<thead>
<row>
<entry>Function</entry>
<entry>Return Type</entry>
<entry>Description</entry>
<entry>Example</entry>
<entry>Example Result</entry>
</row>
</thead>
<tbody>
<row>
<entry><para><literal>json_array_length(json)</literal>
</para><para><literal>jsonb_array_length(jsonb)</literal>
</para></entry>
<entry><type>int</type></entry>
<entry>
Returns the number of elements in the outermost JSON array.
</entry>
<entry><literal>json_array_length('[1,2,3,{"f1":1,"f2":[5,6]},4]')</literal></entry>
<entry><literal>5</literal></entry>
</row>
<row>
<entry><para><literal>json_each(json)</literal>
</para><para><literal>jsonb_each(jsonb)</literal>
</para></entry>
<entry><para><literal>SETOF key text, value json</literal>
</para><para><literal>SETOF key text, value jsonb</literal>
</para></entry>
<entry>
Expands the outermost JSON object into a set of key/value pairs.
</entry>
<entry><literal>select * from json_each('{"a":"foo", "b":"bar"}')</literal></entry>
<entry>
<programlisting>
key | value
-----+-------
a | "foo"
b | "bar"
</programlisting>
</entry>
</row>
<row>
<entry><para><literal>json_each_text(from_json json)</literal>
</para><para><literal>jsonb_each_text(from_json jsonb)</literal>
</para></entry>
<entry><type>SETOF key text, value text</type></entry>
<entry>
Expands the outermost JSON object into a set of key/value pairs. The
returned value will be of type text.
</entry>
<entry><literal>select * from json_each_text('{"a":"foo", "b":"bar"}')</literal></entry>
<entry>
<programlisting>
key | value
-----+-------
a | foo
b | bar
</programlisting>
</entry>
</row>
<row>
<entry><para><literal>json_extract_path(from_json json, VARIADIC path_elems text[])</literal>
</para><para><literal>jsonb_extract_path(from_jsonb jsonb, VARIADIC path_elems text[])</literal>
</para></entry>
<entry><para><type>json</type></para><para><type>jsonb</type>
</para></entry>
<entry>
Returns JSON value pointed to by <parameter>path_elems</parameter>.
</entry>
<entry><literal>json_extract_path('{"f2":{"f3":1},"f4":{"f5":99,"f6":"foo"}}','f4')</literal></entry>
<entry><literal>{"f5":99,"f6":"foo"}</literal></entry>
</row>
<row>
<entry><para><literal>json_extract_path_text(from_json json, VARIADIC path_elems text[])</literal>
</para><para><literal>json_extract_path_text(from_json json, VARIADIC path_elems text[])</literal>
</para></entry>
<entry><type>text</type></entry>
<entry>
Returns JSON value pointed to by <parameter>path_elems</parameter>.
</entry>
<entry><literal>json_extract_path_text('{"f2":{"f3":1},"f4":{"f5":99,"f6":"foo"}}','f4', 'f6')</literal></entry>
<entry><literal>foo</literal></entry>
</row>
<row>
<entry><para><literal>json_object_keys(json)</literal>
</para><para><literal>jsonb_object_keys(jsonb)</literal>
</para></entry>
<entry><type>SETOF text</type></entry>
<entry>
Returns set of keys in the JSON object. Only the <quote>outer</quote> object will be displayed.
</entry>
<entry><literal>json_object_keys('{"f1":"abc","f2":{"f3":"a", "f4":"b"}}')</literal></entry>
<entry>
<programlisting>
json_object_keys
------------------
f1
f2
</programlisting>
</entry>
</row>
<row>
<entry><para><literal>json_populate_record(base anyelement, from_json json, [, use_json_as_text bool=false])</literal>
</para><para><literal>jsonb_populate_record(base anyelement, from_json jsonb, [, use_json_as_text bool=false])</literal>
</para></entry>
<entry><type>anyelement</type></entry>
<entry>
Expands the object in <replaceable>from_json</replaceable> to a row whose columns match
the record type defined by base. Conversion will be best
effort; columns in base with no corresponding key in <replaceable>from_json</replaceable>
will be left null. When processing <type>json</type>, if a
column is specified more than once, the last value is used.
</entry>
<entry><literal>select * from json_populate_record(null::x, '{"a":1,"b":2}')</literal></entry>
<entry>
<programlisting>
a | b
---+---
1 | 2
</programlisting>
</entry>
</row>
<row>
<entry><para><literal>json_populate_recordset(base anyelement, from_json json, [, use_json_as_text bool=false])</literal>
</para><para><literal>jsonb_populate_recordset(base anyelement, from_json jsonb, [, use_json_as_text bool=false])</literal>
</para></entry>
<entry><type>SETOF anyelement</type></entry>
<entry>
Expands the outermost set of objects in <replaceable>from_json</replaceable> to a set
whose columns match the record type defined by base.
Conversion will be best effort; columns in base with no
corresponding key in <replaceable>from_json</replaceable> will be left null.
When processing <type>json</type>, if a column is specified more
than once, the last value is used.
</entry>
<entry><literal>select * from json_populate_recordset(null::x, '[{"a":1,"b":2},{"a":3,"b":4}]')</literal></entry>
<entry>
<programlisting>
a | b
---+---
1 | 2
3 | 4
</programlisting>
</entry>
</row>
<row>
<entry><para><literal>json_array_elements(json)</literal>
</para><para><literal>jsonb_array_elements(jsonb)</literal>
</para></entry>
<entry><para><type>SETOF json</type>
</para><para><type>SETOF jsonb</type>
</para></entry>
<entry>
Expands a JSON array to a set of JSON values.
</entry>
<entry><literal>SELECT * FROM json_array_elements('[1,true, [2,false]]')</literal></entry>
<entry>
<programlisting>
value
-----------
1
true
[2,false]
</programlisting>
</entry>
</row>
<row>
<entry><para><literal>json_array_elements_text(json)</literal>
</para><para><literal>jsonb_array_elements_text(jsonb)</literal>
</para></entry>
<entry><type>SETOF text</type></entry>
<entry>
Expands a JSON array to a set of text values.
</entry>
<entry><literal>SELECT * FROM json_array_elements_text('["foo", "bar"]')</literal></entry>
<entry>
<programlisting>
value
-----------
foo
bar
</programlisting>
</entry>
</row>
<row>
<entry><para><literal>json_typeof(json)</literal>
</para><para><literal>jsonb_typeof(jsonb)</literal>
</para></entry>
<entry><type>text</type></entry>
<entry>
Returns the type of the outermost JSON value as a text string. The types are
<literal>object</>, <literal>array</>, <literal>string</>, <literal>number</>,
<literal>boolean</>, and <literal>null</>. (See note below regarding the
distinction between a JSON <literal>null</> and a SQL NULL.)
</entry>
<entry><literal>json_typeof('-123.4')</literal></entry>
<entry><literal>number</literal></entry>
</row>
<row>
<entry>
<indexterm>
<primary>json_to_record</primary>
</indexterm>
<literal>json_to_record(json, nested_as_text bool)</literal>
</entry>
<entry><type>record</type></entry>
<entry>
json_to_record returns an arbitrary record from a JSON object. As with all functions
Returns an arbitrary record from a JSON object. As with all functions
returning 'record', the caller must explicitly define the structure of the record
when making the call. The input JSON must be an object, not a scalar or an array.
If nested_as_text is true, the function coerces nested complex elements to text.
@ -10526,14 +10671,11 @@ table2-mapping
</row>
<row>
<entry>
<indexterm>
<primary>json_to_recordset</primary>
</indexterm>
<literal>json_to_recordset(json, nested_as_text bool)</literal>
</entry>
<entry><type>setof record</type></entry>
<entry>
json_to_recordset returns an arbitrary set of records from a JSON object. As with
Returns an arbitrary set of records from a JSON object. As with
json_to_record, the structure of the record must be explicitly defined when making the
call. However, with json_to_recordset the input JSON must be an array containing
objects. nested_as_text works as with json_to_record.

413
doc/src/sgml/json.sgml Normal file
View File

@ -0,0 +1,413 @@
<!-- doc/src/sgml/json.sgml -->
<sect1 id="datatype-json">
<title><acronym>JSON</> Types</title>
<indexterm zone="datatype-json">
<primary>JSON</primary>
</indexterm>
<indexterm zone="datatype-json">
<primary>JSONB</primary>
</indexterm>
<para>
JSON data types are for storing JSON (JavaScript Object Notation)
data, as specified in <ulink url="http://rfc7159.net/rfc7159">RFC
7159</ulink>. Such data can also be stored as <type>text</type>, but
both JSON data types have the advantage of enforcing that each
stored value is a valid JSON value. There are also related support
functions available; see <xref linkend="functions-json">.
</para>
<para>
There are two JSON data types: <type>json</> and <type>jsonb</>.
Both accept <emphasis>almost</emphasis> identical sets of values as
input. The major practical difference is one of efficiency. The
<type>json</> data type stores an exact copy of the the input text,
which processing functions must continually reparse, while
<type>jsonb</> data is stored in a decomposed binary format that
makes it slightly less efficient to input due to added serialization
overhead, but significantly faster to process, since it never needs
reparsing. <type>jsonb</> also supports advanced
<acronym>GIN</acronym> indexing, which is a further significant
advantage.
</para>
<para>
The other difference between the types is that the <type>json</>
type is guaranteed to contain an exact copy of the input, including
preservation of semantically insignificant white space, and the
order of keys within JSON objects (although <type>jsonb</> will
preserve trailing zeros within a JSON number). Also, because the
exact text is kept, if a JSON object within the value contains the
same key more than once, and has been stored using the <type>json</>
type, all the key/value pairs are kept. In that case, the
processing functions consider the last value as the operative one.
By contrast, <type>jsonb</> does not preserve white space, does not
preserve the order of object keys, and does not keep duplicate
object keys. Only the last value for a key specified in the input
is kept.
</para>
<para>
In general, most applications will prefer to store JSON data as
<type>jsonb</>, unless there are quite specialized needs.
</para>
<para>
<productname>PostgreSQL</productname> allows only one server
encoding per database. It is therefore not possible for the JSON
types to conform rigidly to the specification unless the server
encoding is UTF-8. Attempts to directly include characters which
cannot be represented in the server encoding will fail; conversely,
characters which can be represented in the server encoding but not
in UTF-8 will be allowed. <literal>\uXXXX</literal> escapes are
allowed regardless of the server encoding, and are checked only for
syntactic correctness.
</para>
<sect2 id="json-types">
<title>Mapping of RFC-7159/JSON Primitive Types to <productname>PostgreSQL</productname> Types</title>
<table id="json-type-mapping-table">
<title>Mapping of type correspondence, notes</title>
<tgroup cols="3">
<thead>
<row>
<entry><productname>PostgreSQL</productname> type</entry>
<entry>RFC-7159/JSON primitive type</entry>
<entry>Notes</entry>
</row>
</thead>
<tbody>
<row>
<entry><type>text</></entry>
<entry><type>string</></entry>
<entry>See general introductory notes on encoding and JSON</entry>
</row>
<row>
<entry><type>numeric</></entry>
<entry><type>number</></entry>
<entry><literal>NaN</literal> and <literal>infinity</literal> values are disallowed</entry>
</row>
<row>
<entry><type>boolean</></entry>
<entry><type>boolean</></entry>
<entry>Only lowercase <literal>true</literal> and <literal>false</literal> values are accepted</entry>
</row>
<row>
<entry><type>unknown</></entry>
<entry><type>null</></entry>
<entry>SQL <literal>NULL</literal> is orthogonal. NULL semantics do not apply.</entry>
</row>
</tbody>
</tgroup>
</table>
<para>
Primitive types described by <acronym>RFC</> 7159 are effectively
internally mapped onto native
<productname>PostgreSQL</productname> types. Therefore, there are
some very minor additional constraints on what constitutes valid
<type>jsonb</type> that do not apply to the <type>json</type>
type, or to JSON in the abstract, that pertain to limits on what
can be represented by the underlying type system. These
implementation-defined restrictions are permitted by
<acronym>RFC</> 7159. However, in practice problems are far more
likely to occur in other implementations which internally
represent the <type>number</> JSON primitive type as IEEE 754
double precision floating point values, which <acronym>RFC</> 7159
explicitly anticipates and allows for. When using JSON as an
interchange format with such systems, the danger of losing numeric
precision in respect of data originally stored by
<productname>PostgreSQL</productname> should be considered.
</para>
<para>
Conversely, as noted above there are some minor restrictions on
the input format of JSON primitive types that do not apply to
corresponding <productname>PostgreSQL</productname> types.
</para>
</sect2>
<sect2 id="json-querying">
<title>Querying <type>jsonb</type> documents effectively</title>
<para>
Representing data as JSON can be considerably more flexible than
the traditional relational data model, which is compelling in
environments where requirements are fluid. It is quite possible
for both approaches to co-exist and complement each other within
the same application. However, even for applications where maximal
flexibility is desired, it is still recommended that JSON documents
have a somewhat fixed structure. This structure is typically
unenforced (though enforcing some business rules declaratively is
possible), but makes it easier to write queries that usefully
summarize a set of <quote>documents</> (datums) in a table.
</para>
<para>
<type>jsonb</> data is subject to the same concurrency control
considerations as any other datatype when stored in a table.
Although storing large documents is practicable, in order to ensure
correct behavior row-level locks are, quite naturally, aquired as
rows are updated. Consider keeping <type>jsonb</> documents at a
manageable size in order to decrease lock contention among updating
transactions. Ideally, <type>jsonb</> documents should each
represent an atomic datum that business rules dictate cannot
reasonably be further subdivided into smaller atomic datums that
can be independently modified.
</para>
</sect2>
<sect2 id="json-keys-elements">
<title><type>jsonb</> Input and Output Syntax</title>
<para>
In effect, <type>jsonb</> has an internal type system whose
implementation is defined in terms of several particular ordinary
<productname>PostgreSQL</productname> types. The SQL parser does
not have direct knowledge of the internal types that constitute a
<type>jsonb</>.
</para>
<para>
The following are all valid <type>jsonb</> expressions:
<programlisting>
-- Simple scalar/primitive value (explicitly required by RFC-7159)
SELECT '5'::jsonb;
-- Array of heterogeneous, primitive-typed elements
SELECT '[1, 2, "foo", null]'::jsonb;
-- Object of heterogeneous key/value pairs of primitive types
-- Note that key values are always strings
SELECT '{"bar": "baz", "balance": 7.77, "active":false}'::jsonb;
</programlisting>
</para>
<para>
Note the distinction between scalar/primitive values as elements,
keys and values.
</para>
</sect2>
<sect2 id="json-containment">
<title><type>jsonb</> containment</title>
<indexterm>
<primary>jsonb</primary>
<secondary>containment</secondary>
</indexterm>
<para>
Testing <quote>containment</> is an important capability of
<type>jsonb</>. There is no parallel set of facilities for the
<type>json</> type. Containment is the ability to determine if
one <type>jsonb</> document has contained within it another one.
<type>jsonb</> is nested, and so containment semantics are nested;
technically, top-down, unordered <emphasis>subtree isomorphism</>
may be tested. Containment is conventionally tested using the
<literal>@&gt;</> operator, which is made indexable by various
operator classes discussed later in this section.
</para>
<programlisting>
-- Simple scalar/primitive values may contain only each other:
SELECT '"foo"'::jsonb @> '"foo"'::jsonb;
-- The array on the right hand side is contained within the one on the
-- left hand side:
SELECT '[1, 2, 3]'::jsonb @> '[1, 3]'::jsonb;
-- The object with a single pair on the right hand side is contained
-- within the object on the left hand side:
SELECT '{"product": "PostgreSQL", "version": 9.4, "jsonb":true}'::jsonb @> '{"version":9.4}'::jsonb;
-- The array on the right hand side is not contained within the array
-- containing a nested array on the left hand side:
SELECT '[1, 2, [1, 3]]'::jsonb @> '[1, 3]'::jsonb;
-- But with a layer of nesting, it is:
SELECT '[1, 2, [1, 3]]'::jsonb @> '[[1, 3]]'::jsonb;
</programlisting>
<para>
It is both a sufficient and a necessary condition for nesting
levels to <quote>line up</> for one <type>jsonb</> to contain
within it another. Under this definition, objects and arrays
cannot <quote>line up</>, not least because objects contain
key/value pairs, while arrays contain elements.
</para>
<para>
As a special exception to the general principle that nesting
levels should <quote>line up</>, an array may contain a raw scalar:
</para>
<programlisting>
-- This array contains the raw scalar value:
SELECT '["foo", "bar"]'::jsonb @> '"bar"'::jsonb;
-- The special exception is not reciprocated -- non-containment is indicated here:
SELECT '"bar"'::jsonb @> '["bar"]'::jsonb;
</programlisting>
<para>
Objects are better suited for testing containment when there is a
great deal of nesting involved, because unlike arrays they are
internally optimized for searching, and do not need to be searched
linearly within a single <type>jsonb</> document.
</para>
<programlisting>
-- The right-hand side object is contained in this example:
SELECT '{"p":1, "a":{"b":3, "q":11}, "i":77}'::jsonb @> '{"a":{"b":3}}'::jsonb;
</programlisting>
<para>
The various containment operators, along with all other JSON
operators and support functions are documented fully within <xref
linkend="functions-json">, <xref
linkend="functions-jsonb-op-table">.
</para>
</sect2>
<sect2 id="json-indexing">
<title><type>jsonb</> GIN Indexing</title>
<indexterm>
<primary>jsonb</primary>
<secondary>indexes on</secondary>
</indexterm>
<para>
<type>jsonb</> GIN indexes can be used to efficiently search among
more than one possible key/value pair within a single
<type>jsonb</> datum/document, among a large number of such
documents within a column in a table (i.e. among many rows).
</para>
<para>
<type>jsonb</> has GIN index support for the <literal>@&gt;</>,
<literal>?</>, <literal>?&amp;</> and <literal>?|</> operators.
The default GIN operator class makes all these operators
indexable:
</para>
<programlisting>
-- GIN index (default opclass)
CREATE INDEX idxgin ON api USING GIN (jdoc);
-- GIN jsonb_hash_ops index
CREATE INDEX idxginh ON api USING GIN (jdoc jsonb_hash_ops);
</programlisting>
<para>
The non-default GIN operator class <literal>jsonb_hash_ops</>
supports indexing the <literal>@&gt;</> operator only.
</para>
<para>
Consider the example of a table that stores JSON documents
retrieved from a third-party web service, with a documented schema
definition. An example of a document retrieved from this web
service is as follows:
<programlisting>
{
"guid": "9c36adc1-7fb5-4d5b-83b4-90356a46061a",
"name": "Angela Barton",
"is_active": true,
"company": "Magnafone",
"address": "178 Howard Place, Gulf, Washington, 702",
"registered": "2009-11-07T08:53:22 +08:00",
"latitude": 19.793713,
"longitude": 86.513373,
"tags": [
"enim",
"aliquip",
"qui"
]
}
</programlisting>
If a GIN index is created on the table that stores these
documents, <literal>api</literal>, on its <literal>jdoc</>
<type>jsonb</> column, we can expect that queries like the
following may make use of the index:
<programlisting>
-- Note that both key and value have been specified
SELECT jdoc->'guid', jdoc->'name' FROM api WHERE jdoc @&gt; '{"company": "Magnafone"}';
</programlisting>
However, the index could not be used for queries like the
following, due to the aforementioned nesting restriction:
<programlisting>
SELECT jdoc->'guid', jdoc->'name' FROM api WHERE jdoc -> 'tags' ? 'qui';
</programlisting>
Still, with judicious use of expressional indexing, the above
query can use an index scan. If there is a requirement to find
those records with a particular tag quickly, and the tags have a
high cardinality across all documents, defining an index as
follows is an effective approach to indexing:
<programlisting>
-- Note that the "jsonb -> text" operator can only be called on an
-- object, so as a consequence of creating this index the root "jdoc"
-- datum must be an object. This is enforced during insertion.
CREATE INDEX idxgin ON api USING GIN ((jdoc -> 'tags'));
</programlisting>
</para>
<para>
Expressional indexes are discussed in <xref
linkend="indexes-expressional">.
</para>
<para>
For the most flexible approach in terms of what may be indexed,
sophisticated querying on nested structures is possible by
exploiting containment. At the cost of having to create an index
on the entire structure for each row, and not just a nested
subset, we may exploit containment semantics to get an equivalent
result with a non-expressional index on the entire <quote>jdoc</>
column, <emphasis>without</> ever having to create additional
expressional indexes against the document (provided only
containment will be tested). While the index will be considerably
larger than our expression index, it will also be much more
flexible, allowing arbitrary structured searching. Such an index
can generally be expected to help with a query like the following:
</para>
<programlisting>
SELECT jdoc->'guid', jdoc->'name' FROM api WHERE jdoc @&gt; '{"tags": ["qui"]}';
</programlisting>
<para>
For full details of the semantics that these indexable operators
implement, see <xref linkend="functions-json">, <xref
linkend="functions-jsonb-op-table">.
</para>
</sect2>
<sect2 id="json-opclass">
<title><type>jsonb</> non-default GIN operator class</title>
<indexterm>
<primary>jsonb</primary>
<secondary>indexes on</secondary>
</indexterm>
<para>
Although only the <literal>@&gt;</> operator is made indexable, a
<literal>jsonb_hash_ops</literal> operator class GIN index has
some notable advantages over an equivalent GIN index of the
default GIN operator class for <type>jsonb</type>. Search
operations typically perform considerably better, and the on-disk
size of a <literal>jsonb_hash_ops</literal> operator class GIN
index can be much smaller.
</para>
</sect2>
<sect2 id="json-btree-indexing">
<title><type>jsonb</> B-Tree and hash indexing</title>
<para>
<type>jsonb</type> comparisons and related operations are
<emphasis>type-wise</>, in that the underlying
<productname>PostgreSQL</productname> datatype comparators are
invoked recursively, much like a traditional composite type.
</para>
<para>
<type>jsonb</> also supports <type>btree</> and <type>hash</>
indexes. Ordering between <type>jsonb</> datums is:
<synopsis>
<replaceable>Object</replaceable> > <replaceable>Array</replaceable> > <replaceable>Boolean</replaceable> > <replaceable>Number</replaceable> > <replaceable>String</replaceable> > <replaceable>Null</replaceable>
<replaceable>Object with n pairs</replaceable> > <replaceable>object with n - 1 pairs</replaceable>
<replaceable>Array with n elements</replaceable> > <replaceable>array with n - 1 elements</replaceable>
</synopsis>
Subsequently, individual primitive type comparators are invoked.
All comparisons of JSON primitive types occurs using the same
comparison rules as the underlying
<productname>PostgreSQL</productname> types. Strings are
compared lexically, using the default database collation.
Objects with equal numbers of pairs are compared:
<synopsis>
<replaceable>key-1</replaceable>, <replaceable>value-1</replaceable>, <replaceable>key-2</replaceable> ...
</synopsis>
Note however that object keys are compared in their storage order, and in particular,
since shorter keys are stored before longer keys, this can lead to results that might be
unintuitive, such as:
<programlisting>{ "aa": 1, "c": 1} > {"b": 1, "d": 1}</programlisting>
Similarly, arrays with equal numbers of elements are compared:
<synopsis>
<replaceable>element-1</replaceable>, <replaceable>element-2</replaceable> ...
</synopsis>
</para>
</sect2>
</sect1>

View File

@ -825,6 +825,14 @@ CREATE OR REPLACE FUNCTION
json_populate_recordset(base anyelement, from_json json, use_json_as_text boolean DEFAULT false)
RETURNS SETOF anyelement LANGUAGE internal STABLE ROWS 100 AS 'json_populate_recordset';
CREATE OR REPLACE FUNCTION
jsonb_populate_record(base anyelement, from_json jsonb, use_json_as_text boolean DEFAULT false)
RETURNS anyelement LANGUAGE internal STABLE AS 'jsonb_populate_record';
CREATE OR REPLACE FUNCTION
jsonb_populate_recordset(base anyelement, from_json jsonb, use_json_as_text boolean DEFAULT false)
RETURNS SETOF anyelement LANGUAGE internal STABLE ROWS 100 AS 'jsonb_populate_recordset';
CREATE OR REPLACE FUNCTION pg_logical_slot_get_changes(
IN slotname name, IN upto_lsn pg_lsn, IN upto_nchanges int, VARIADIC options text[] DEFAULT '{}',
OUT location pg_lsn, OUT xid xid, OUT data text)

View File

@ -21,11 +21,11 @@ OBJS = acl.o arrayfuncs.o array_selfuncs.o array_typanalyze.o \
cash.o char.o date.o datetime.o datum.o dbsize.o domains.o \
encode.o enum.o float.o format_type.o formatting.o genfile.o \
geo_ops.o geo_selfuncs.o inet_cidr_ntop.o inet_net_pton.o int.o \
int8.o json.o jsonfuncs.o like.o \
lockfuncs.o mac.o misc.o nabstime.o name.o network.o numeric.o \
numutils.o oid.o oracle_compat.o orderedsetaggs.o \
pg_lzcompress.o pg_locale.o pg_lsn.o pgstatfuncs.o \
pseudotypes.o quote.o rangetypes.o rangetypes_gist.o \
int8.o json.o jsonb.o jsonb_gin.o jsonb_op.o jsonb_util.o \
jsonfuncs.o like.o lockfuncs.o mac.o misc.o nabstime.o name.o \
network.o numeric.o numutils.o oid.o oracle_compat.o \
orderedsetaggs.o pg_lzcompress.o pg_locale.o pg_lsn.o \
pgstatfuncs.o pseudotypes.o quote.o rangetypes.o rangetypes_gist.o \
rangetypes_selfuncs.o rangetypes_spgist.o rangetypes_typanalyze.o \
regexp.o regproc.o ri_triggers.o rowtypes.o ruleutils.o \
selfuncs.o tid.o timestamp.o trigfuncs.o \

View File

@ -210,22 +210,17 @@ Datum
json_recv(PG_FUNCTION_ARGS)
{
StringInfo buf = (StringInfo) PG_GETARG_POINTER(0);
text *result;
char *str;
int nbytes;
JsonLexContext *lex;
str = pq_getmsgtext(buf, buf->len - buf->cursor, &nbytes);
result = palloc(nbytes + VARHDRSZ);
SET_VARSIZE(result, nbytes + VARHDRSZ);
memcpy(VARDATA(result), str, nbytes);
/* Validate it. */
lex = makeJsonLexContext(result, false);
lex = makeJsonLexContextCstringLen(str, nbytes, false);
pg_parse_json(lex, &nullSemAction);
PG_RETURN_TEXT_P(result);
PG_RETURN_TEXT_P(cstring_to_text_with_len(str, nbytes));
}
/*
@ -236,15 +231,26 @@ json_recv(PG_FUNCTION_ARGS)
*
* Without is better as it makes the processing faster, so only make one
* if really required.
*
* If you already have the json as a text* value, use the first of these
* functions, otherwise use makeJsonLexContextCstringLen().
*/
JsonLexContext *
makeJsonLexContext(text *json, bool need_escapes)
{
return makeJsonLexContextCstringLen(VARDATA(json),
VARSIZE(json) - VARHDRSZ,
need_escapes);
}
JsonLexContext *
makeJsonLexContextCstringLen(char *json, int len, bool need_escapes)
{
JsonLexContext *lex = palloc0(sizeof(JsonLexContext));
lex->input = lex->token_terminator = lex->line_start = VARDATA(json);
lex->input = lex->token_terminator = lex->line_start = json;
lex->line_number = 1;
lex->input_length = VARSIZE(json) - VARHDRSZ;
lex->input_length = len;
if (need_escapes)
lex->strval = makeStringInfo();
return lex;
@ -1274,7 +1280,7 @@ datum_to_json(Datum val, bool is_null, StringInfo result,
pfree(outputstr);
break;
case TYPCATEGORY_JSON:
/* JSON will already be escaped */
/* JSON and JSONB will already be escaped */
outputstr = OidOutputFunctionCall(typoutputfunc, val);
appendStringInfoString(result, outputstr);
pfree(outputstr);
@ -1406,7 +1412,7 @@ array_to_json_internal(Datum array, StringInfo result, bool use_line_feeds)
tcategory = TYPCATEGORY_JSON_CAST;
else if (element_type == RECORDOID)
tcategory = TYPCATEGORY_COMPOSITE;
else if (element_type == JSONOID)
else if (element_type == JSONOID || element_type == JSONBOID)
tcategory = TYPCATEGORY_JSON;
else
tcategory = TypeCategory(element_type);
@ -1501,7 +1507,8 @@ composite_to_json(Datum composite, StringInfo result, bool use_line_feeds)
tcategory = TYPCATEGORY_ARRAY;
else if (tupdesc->attrs[i]->atttypid == RECORDOID)
tcategory = TYPCATEGORY_COMPOSITE;
else if (tupdesc->attrs[i]->atttypid == JSONOID)
else if (tupdesc->attrs[i]->atttypid == JSONOID ||
tupdesc->attrs[i]->atttypid == JSONBOID)
tcategory = TYPCATEGORY_JSON;
else
tcategory = TypeCategory(tupdesc->attrs[i]->atttypid);
@ -1689,7 +1696,7 @@ to_json(PG_FUNCTION_ARGS)
tcategory = TYPCATEGORY_ARRAY;
else if (val_type == RECORDOID)
tcategory = TYPCATEGORY_COMPOSITE;
else if (val_type == JSONOID)
else if (val_type == JSONOID || val_type == JSONBOID)
tcategory = TYPCATEGORY_JSON;
else
tcategory = TypeCategory(val_type);
@ -1783,7 +1790,7 @@ json_agg_transfn(PG_FUNCTION_ARGS)
tcategory = TYPCATEGORY_ARRAY;
else if (val_type == RECORDOID)
tcategory = TYPCATEGORY_COMPOSITE;
else if (val_type == JSONOID)
else if (val_type == JSONOID || val_type == JSONBOID)
tcategory = TYPCATEGORY_JSON;
else
tcategory = TypeCategory(val_type);
@ -2346,12 +2353,15 @@ escape_json(StringInfo buf, const char *str)
Datum
json_typeof(PG_FUNCTION_ARGS)
{
text *json = PG_GETARG_TEXT_P(0);
text *json;
JsonLexContext *lex = makeJsonLexContext(json, false);
JsonLexContext *lex;
JsonTokenType tok;
char *type;
json = PG_GETARG_TEXT_P(0);
lex = makeJsonLexContext(json, false);
/* Lex exactly one token from the input and check its type. */
json_lex(lex);
tok = lex_peek(lex);

View File

@ -0,0 +1,468 @@
/*-------------------------------------------------------------------------
*
* jsonb.c
* I/O routines for jsonb type
*
* Copyright (c) 2014, PostgreSQL Global Development Group
*
* IDENTIFICATION
* src/backend/utils/adt/jsonb.c
*
*-------------------------------------------------------------------------
*/
#include "postgres.h"
#include "libpq/pqformat.h"
#include "utils/builtins.h"
#include "utils/json.h"
#include "utils/jsonapi.h"
#include "utils/jsonb.h"
typedef struct JsonbInState
{
JsonbParseState *parseState;
JsonbValue *res;
} JsonbInState;
static inline Datum jsonb_from_cstring(char *json, int len);
static size_t checkStringLen(size_t len);
static void jsonb_in_object_start(void *pstate);
static void jsonb_in_object_end(void *pstate);
static void jsonb_in_array_start(void *pstate);
static void jsonb_in_array_end(void *pstate);
static void jsonb_in_object_field_start(void *pstate, char *fname, bool isnull);
static void jsonb_put_escaped_value(StringInfo out, JsonbValue * scalarVal);
static void jsonb_in_scalar(void *pstate, char *token, JsonTokenType tokentype);
char *JsonbToCString(StringInfo out, char *in, int estimated_len);
/*
* jsonb type input function
*/
Datum
jsonb_in(PG_FUNCTION_ARGS)
{
char *json = PG_GETARG_CSTRING(0);
return jsonb_from_cstring(json, strlen(json));
}
/*
* jsonb type recv function
*
* The type is sent as text in binary mode, so this is almost the same
* as the input function, but it's prefixed with a version number so we
* can change the binary format sent in future if necessary. For now,
* only version 1 is supported.
*/
Datum
jsonb_recv(PG_FUNCTION_ARGS)
{
StringInfo buf = (StringInfo) PG_GETARG_POINTER(0);
int version = pq_getmsgint(buf, 1);
char *str;
int nbytes;
if (version == 1)
str = pq_getmsgtext(buf, buf->len - buf->cursor, &nbytes);
else
elog(ERROR, "Unsupported jsonb version number %d", version);
return jsonb_from_cstring(str, nbytes);
}
/*
* jsonb type output function
*/
Datum
jsonb_out(PG_FUNCTION_ARGS)
{
Jsonb *jb = PG_GETARG_JSONB(0);
char *out;
out = JsonbToCString(NULL, VARDATA(jb), VARSIZE(jb));
PG_RETURN_CSTRING(out);
}
/*
* jsonb type send function
*
* Just send jsonb as a version number, then a string of text
*/
Datum
jsonb_send(PG_FUNCTION_ARGS)
{
Jsonb *jb = PG_GETARG_JSONB(0);
StringInfoData buf;
StringInfo jtext = makeStringInfo();
int version = 1;
(void) JsonbToCString(jtext, VARDATA(jb), VARSIZE(jb));
pq_begintypsend(&buf);
pq_sendint(&buf, version, 1);
pq_sendtext(&buf, jtext->data, jtext->len);
pfree(jtext->data);
pfree(jtext);
PG_RETURN_BYTEA_P(pq_endtypsend(&buf));
}
/*
* SQL function jsonb_typeof(jsonb) -> text
*
* This function is here because the analog json function is in json.c, since
* it uses the json parser internals not exposed elsewhere.
*/
Datum
jsonb_typeof(PG_FUNCTION_ARGS)
{
Jsonb *in = PG_GETARG_JSONB(0);
JsonbIterator *it;
JsonbValue v;
char *result;
if (JB_ROOT_IS_OBJECT(in))
result = "object";
else if (JB_ROOT_IS_ARRAY(in) && !JB_ROOT_IS_SCALAR(in))
result = "array";
else
{
Assert(JB_ROOT_IS_SCALAR(in));
it = JsonbIteratorInit(VARDATA_ANY(in));
/*
* A root scalar is stored as an array of one element, so we get the
* array and then its first (and only) member.
*/
(void) JsonbIteratorNext(&it, &v, true);
Assert(v.type == jbvArray);
(void) JsonbIteratorNext(&it, &v, true);
switch (v.type)
{
case jbvNull:
result = "null";
break;
case jbvString:
result = "string";
break;
case jbvNumeric:
result = "number";
break;
case jbvBool:
result = "boolean";
break;
default:
elog(ERROR, "unknown jsonb scalar type");
}
}
PG_RETURN_TEXT_P(cstring_to_text(result));
}
/*
* jsonb_from_cstring
*
* Turns json string into a jsonb Datum.
*
* Uses the json parser (with hooks) to construct a jsonb.
*/
static inline Datum
jsonb_from_cstring(char *json, int len)
{
JsonLexContext *lex;
JsonbInState state;
JsonSemAction sem;
memset(&state, 0, sizeof(state));
memset(&sem, 0, sizeof(sem));
lex = makeJsonLexContextCstringLen(json, len, true);
sem.semstate = (void *) &state;
sem.object_start = jsonb_in_object_start;
sem.array_start = jsonb_in_array_start;
sem.object_end = jsonb_in_object_end;
sem.array_end = jsonb_in_array_end;
sem.scalar = jsonb_in_scalar;
sem.object_field_start = jsonb_in_object_field_start;
pg_parse_json(lex, &sem);
/* after parsing, the item member has the composed jsonb structure */
PG_RETURN_POINTER(JsonbValueToJsonb(state.res));
}
static size_t
checkStringLen(size_t len)
{
if (len > JENTRY_POSMASK)
ereport(ERROR,
(errcode(ERRCODE_PROGRAM_LIMIT_EXCEEDED),
errmsg("string too long to represent as jsonb string"),
errdetail("Due to an implementation restriction, jsonb strings cannot exceed %d bytes.",
JENTRY_POSMASK)));
return len;
}
static void
jsonb_in_object_start(void *pstate)
{
JsonbInState *_state = (JsonbInState *) pstate;
_state->res = pushJsonbValue(&_state->parseState, WJB_BEGIN_OBJECT, NULL);
}
static void
jsonb_in_object_end(void *pstate)
{
JsonbInState *_state = (JsonbInState *) pstate;
_state->res = pushJsonbValue(&_state->parseState, WJB_END_OBJECT, NULL);
}
static void
jsonb_in_array_start(void *pstate)
{
JsonbInState *_state = (JsonbInState *) pstate;
_state->res = pushJsonbValue(&_state->parseState, WJB_BEGIN_ARRAY, NULL);
}
static void
jsonb_in_array_end(void *pstate)
{
JsonbInState *_state = (JsonbInState *) pstate;
_state->res = pushJsonbValue(&_state->parseState, WJB_END_ARRAY, NULL);
}
static void
jsonb_in_object_field_start(void *pstate, char *fname, bool isnull)
{
JsonbInState *_state = (JsonbInState *) pstate;
JsonbValue v;
Assert (fname != NULL);
v.type = jbvString;
v.string.len = checkStringLen(strlen(fname));
v.string.val = pnstrdup(fname, v.string.len);
v.estSize = sizeof(JEntry) + v.string.len;
_state->res = pushJsonbValue(&_state->parseState, WJB_KEY, &v);
}
static void
jsonb_put_escaped_value(StringInfo out, JsonbValue * scalarVal)
{
switch (scalarVal->type)
{
case jbvNull:
appendBinaryStringInfo(out, "null", 4);
break;
case jbvString:
escape_json(out, pnstrdup(scalarVal->string.val, scalarVal->string.len));
break;
case jbvNumeric:
appendStringInfoString(out,
DatumGetCString(DirectFunctionCall1(numeric_out,
PointerGetDatum(scalarVal->numeric))));
break;
case jbvBool:
if (scalarVal->boolean)
appendBinaryStringInfo(out, "true", 4);
else
appendBinaryStringInfo(out, "false", 5);
break;
default:
elog(ERROR, "unknown jsonb scalar type");
}
}
/*
* For jsonb we always want the de-escaped value - that's what's in token
*/
static void
jsonb_in_scalar(void *pstate, char *token, JsonTokenType tokentype)
{
JsonbInState *_state = (JsonbInState *) pstate;
JsonbValue v;
v.estSize = sizeof(JEntry);
switch (tokentype)
{
case JSON_TOKEN_STRING:
Assert (token != NULL);
v.type = jbvString;
v.string.len = checkStringLen(strlen(token));
v.string.val = pnstrdup(token, v.string.len);
v.estSize += v.string.len;
break;
case JSON_TOKEN_NUMBER:
/*
* No need to check size of numeric values, because maximum numeric
* size is well below the JsonbValue restriction
*/
Assert (token != NULL);
v.type = jbvNumeric;
v.numeric = DatumGetNumeric(DirectFunctionCall3(numeric_in, CStringGetDatum(token), 0, -1));
v.estSize += VARSIZE_ANY(v.numeric) + sizeof(JEntry) /* alignment */ ;
break;
case JSON_TOKEN_TRUE:
v.type = jbvBool;
v.boolean = true;
break;
case JSON_TOKEN_FALSE:
v.type = jbvBool;
v.boolean = false;
break;
case JSON_TOKEN_NULL:
v.type = jbvNull;
break;
default:
/* should not be possible */
elog(ERROR, "invalid json token type");
break;
}
if (_state->parseState == NULL)
{
/* single scalar */
JsonbValue va;
va.type = jbvArray;
va.array.rawScalar = true;
va.array.nElems = 1;
_state->res = pushJsonbValue(&_state->parseState, WJB_BEGIN_ARRAY, &va);
_state->res = pushJsonbValue(&_state->parseState, WJB_ELEM, &v);
_state->res = pushJsonbValue(&_state->parseState, WJB_END_ARRAY, NULL);
}
else
{
JsonbValue *o = &_state->parseState->contVal;
switch (o->type)
{
case jbvArray:
_state->res = pushJsonbValue(&_state->parseState, WJB_ELEM, &v);
break;
case jbvObject:
_state->res = pushJsonbValue(&_state->parseState, WJB_VALUE, &v);
break;
default:
elog(ERROR, "unexpected parent of nested structure");
}
}
}
/*
* JsonbToCString
* Converts jsonb value to a C-string.
*
* If 'out' argument is non-null, the resulting C-string is stored inside the
* StringBuffer. The resulting string is always returned.
*
* A typical case for passing the StringInfo in rather than NULL is where the
* caller wants access to the len attribute without having to call strlen, e.g.
* if they are converting it to a text* object.
*/
char *
JsonbToCString(StringInfo out, JsonbSuperHeader in, int estimated_len)
{
bool first = true;
JsonbIterator *it;
int type = 0;
JsonbValue v;
int level = 0;
bool redo_switch = false;
if (out == NULL)
out = makeStringInfo();
enlargeStringInfo(out, (estimated_len >= 0) ? estimated_len : 64);
it = JsonbIteratorInit(in);
while (redo_switch ||
((type = JsonbIteratorNext(&it, &v, false)) != WJB_DONE))
{
redo_switch = false;
switch (type)
{
case WJB_BEGIN_ARRAY:
if (!first)
appendBinaryStringInfo(out, ", ", 2);
first = true;
if (!v.array.rawScalar)
appendStringInfoChar(out, '[');
level++;
break;
case WJB_BEGIN_OBJECT:
if (!first)
appendBinaryStringInfo(out, ", ", 2);
first = true;
appendStringInfoCharMacro(out, '{');
level++;
break;
case WJB_KEY:
if (!first)
appendBinaryStringInfo(out, ", ", 2);
first = true;
/* json rules guarantee this is a string */
jsonb_put_escaped_value(out, &v);
appendBinaryStringInfo(out, ": ", 2);
type = JsonbIteratorNext(&it, &v, false);
if (type == WJB_VALUE)
{
first = false;
jsonb_put_escaped_value(out, &v);
}
else
{
Assert(type == WJB_BEGIN_OBJECT || type == WJB_BEGIN_ARRAY);
/*
* We need to rerun the current switch() since we need to
* output the object which we just got from the iterator
* before calling the iterator again.
*/
redo_switch = true;
}
break;
case WJB_ELEM:
if (!first)
appendBinaryStringInfo(out, ", ", 2);
else
first = false;
jsonb_put_escaped_value(out, &v);
break;
case WJB_END_ARRAY:
level--;
if (!v.array.rawScalar)
appendStringInfoChar(out, ']');
first = false;
break;
case WJB_END_OBJECT:
level--;
appendStringInfoCharMacro(out, '}');
first = false;
break;
default:
elog(ERROR, "unknown flag of jsonb iterator");
}
}
Assert(level == 0);
return out->data;
}

View File

@ -0,0 +1,646 @@
/*-------------------------------------------------------------------------
*
* jsonb_gin.c
* GIN support functions for jsonb
*
* Copyright (c) 2014, PostgreSQL Global Development Group
*
*
* IDENTIFICATION
* src/backend/utils/adt/jsonb_gin.c
*
*-------------------------------------------------------------------------
*/
#include "postgres.h"
#include "access/gin.h"
#include "access/skey.h"
#include "catalog/pg_collation.h"
#include "catalog/pg_type.h"
#include "utils/builtins.h"
#include "utils/jsonb.h"
typedef struct PathHashStack
{
uint32 hash;
struct PathHashStack *parent;
} PathHashStack;
static text *make_text_key(const char *str, int len, char flag);
static text *make_scalar_key(const JsonbValue * scalarVal, char flag);
/*
*
* jsonb_ops GIN opclass support functions
*
*/
Datum
gin_compare_jsonb(PG_FUNCTION_ARGS)
{
text *arg1 = PG_GETARG_TEXT_PP(0);
text *arg2 = PG_GETARG_TEXT_PP(1);
int32 result;
char *a1p,
*a2p;
int len1,
len2;
a1p = VARDATA_ANY(arg1);
a2p = VARDATA_ANY(arg2);
len1 = VARSIZE_ANY_EXHDR(arg1);
len2 = VARSIZE_ANY_EXHDR(arg2);
/* Compare text as bttextcmp does, but always using C collation */
result = varstr_cmp(a1p, len1, a2p, len2, C_COLLATION_OID);
PG_FREE_IF_COPY(arg1, 0);
PG_FREE_IF_COPY(arg2, 1);
PG_RETURN_INT32(result);
}
Datum
gin_extract_jsonb(PG_FUNCTION_ARGS)
{
Jsonb *jb = (Jsonb *) PG_GETARG_JSONB(0);
int32 *nentries = (int32 *) PG_GETARG_POINTER(1);
Datum *entries = NULL;
int total = 2 * JB_ROOT_COUNT(jb);
int i = 0,
r;
JsonbIterator *it;
JsonbValue v;
if (total == 0)
{
*nentries = 0;
PG_RETURN_POINTER(NULL);
}
entries = (Datum *) palloc(sizeof(Datum) * total);
it = JsonbIteratorInit(VARDATA(jb));
while ((r = JsonbIteratorNext(&it, &v, false)) != WJB_DONE)
{
if (i >= total)
{
total *= 2;
entries = (Datum *) repalloc(entries, sizeof(Datum) * total);
}
/*
* Serialize keys and elements equivalently, but only when elements
* are Jsonb strings. Otherwise, serialize elements as values. Array
* elements are indexed as keys, for the benefit of
* JsonbExistsStrategyNumber. Our definition of existence does not
* allow for checking the existence of a non-jbvString element (just
* like the definition of the underlying operator), because the
* operator takes a text rhs argument (which is taken as a proxy for an
* equivalent Jsonb string).
*
* The way existence is represented does not preclude an alternative
* existence operator, that takes as its rhs value an arbitrarily
* internally-typed Jsonb. The only reason that isn't the case here is
* that the existence operator is only really intended to determine if
* an object has a certain key (object pair keys are of course
* invariably strings), which is extended to jsonb arrays. You could
* think of the default Jsonb definition of existence as being
* equivalent to a definition where all types of scalar array elements
* are keys that we can check the existence of, while just forbidding
* non-string notation. This inflexibility prevents the user from
* having to qualify that the rhs string is a raw scalar string (that
* is, naturally no internal string quoting in required for the text
* argument), and allows us to not set the reset flag for
* JsonbExistsStrategyNumber, since we know that keys are strings for
* both objects and arrays, and don't have to further account for type
* mismatch. Not having to set the reset flag makes it less than
* tempting to tighten up the definition of existence to preclude array
* elements entirely, which would arguably be a simpler alternative.
* In any case the infrastructure used to implement the existence
* operator could trivially support this hypothetical, slightly
* distinct definition of existence.
*/
switch (r)
{
case WJB_KEY:
/* Serialize key separately, for existence strategies */
entries[i++] = PointerGetDatum(make_scalar_key(&v, JKEYELEM));
break;
case WJB_ELEM:
if (v.type == jbvString)
entries[i++] = PointerGetDatum(make_scalar_key(&v, JKEYELEM));
else
entries[i++] = PointerGetDatum(make_scalar_key(&v, JVAL));
break;
case WJB_VALUE:
entries[i++] = PointerGetDatum(make_scalar_key(&v, JVAL));
break;
default:
continue;
}
}
*nentries = i;
PG_RETURN_POINTER(entries);
}
Datum
gin_extract_jsonb_query(PG_FUNCTION_ARGS)
{
int32 *nentries = (int32 *) PG_GETARG_POINTER(1);
StrategyNumber strategy = PG_GETARG_UINT16(2);
int32 *searchMode = (int32 *) PG_GETARG_POINTER(6);
Datum *entries;
if (strategy == JsonbContainsStrategyNumber)
{
/* Query is a jsonb, so just apply gin_extract_jsonb... */
entries = (Datum *)
DatumGetPointer(DirectFunctionCall2(gin_extract_jsonb,
PG_GETARG_DATUM(0),
PointerGetDatum(nentries)));
/* ...although "contains {}" requires a full index scan */
if (entries == NULL)
*searchMode = GIN_SEARCH_MODE_ALL;
}
else if (strategy == JsonbExistsStrategyNumber)
{
text *query = PG_GETARG_TEXT_PP(0);
text *item;
*nentries = 1;
entries = (Datum *) palloc(sizeof(Datum));
item = make_text_key(VARDATA_ANY(query), VARSIZE_ANY_EXHDR(query),
JKEYELEM);
entries[0] = PointerGetDatum(item);
}
else if (strategy == JsonbExistsAnyStrategyNumber ||
strategy == JsonbExistsAllStrategyNumber)
{
ArrayType *query = PG_GETARG_ARRAYTYPE_P(0);
Datum *key_datums;
bool *key_nulls;
int key_count;
int i,
j;
text *item;
deconstruct_array(query,
TEXTOID, -1, false, 'i',
&key_datums, &key_nulls, &key_count);
entries = (Datum *) palloc(sizeof(Datum) * key_count);
for (i = 0, j = 0; i < key_count; ++i)
{
/* Nulls in the array are ignored */
if (key_nulls[i])
continue;
item = make_text_key(VARDATA(key_datums[i]),
VARSIZE(key_datums[i]) - VARHDRSZ,
JKEYELEM);
entries[j++] = PointerGetDatum(item);
}
*nentries = j;
/* ExistsAll with no keys should match everything */
if (j == 0 && strategy == JsonbExistsAllStrategyNumber)
*searchMode = GIN_SEARCH_MODE_ALL;
}
else
{
elog(ERROR, "unrecognized strategy number: %d", strategy);
entries = NULL; /* keep compiler quiet */
}
PG_RETURN_POINTER(entries);
}
Datum
gin_consistent_jsonb(PG_FUNCTION_ARGS)
{
bool *check = (bool *) PG_GETARG_POINTER(0);
StrategyNumber strategy = PG_GETARG_UINT16(1);
/* Jsonb *query = PG_GETARG_JSONB(2); */
int32 nkeys = PG_GETARG_INT32(3);
/* Pointer *extra_data = (Pointer *) PG_GETARG_POINTER(4); */
bool *recheck = (bool *) PG_GETARG_POINTER(5);
bool res = true;
int32 i;
if (strategy == JsonbContainsStrategyNumber)
{
/*
* Index doesn't have information about correspondence of Jsonb keys
* and values (as distinct from GIN keys, which a key/value pair is
* stored as), so invariably we recheck. Besides, there are some
* special rules around the containment of raw scalar arrays and
* regular arrays that are not represented here. However, if all of
* the keys are not present, that's sufficient reason to return false
* and finish immediately.
*/
*recheck = true;
for (i = 0; i < nkeys; i++)
{
if (!check[i])
{
res = false;
break;
}
}
}
else if (strategy == JsonbExistsStrategyNumber)
{
/* Existence of key guaranteed in default search mode */
*recheck = false;
res = true;
}
else if (strategy == JsonbExistsAnyStrategyNumber)
{
/* Existence of key guaranteed in default search mode */
*recheck = false;
res = true;
}
else if (strategy == JsonbExistsAllStrategyNumber)
{
/* Testing for the presence of all keys gives an exact result */
*recheck = false;
for (i = 0; i < nkeys; i++)
{
if (!check[i])
{
res = false;
break;
}
}
}
else
elog(ERROR, "unrecognized strategy number: %d", strategy);
PG_RETURN_BOOL(res);
}
Datum
gin_triconsistent_jsonb(PG_FUNCTION_ARGS)
{
GinLogicValue *check = (GinLogicValue *) PG_GETARG_POINTER(0);
StrategyNumber strategy = PG_GETARG_UINT16(1);
/* Jsonb *query = PG_GETARG_JSONB(2); */
int32 nkeys = PG_GETARG_INT32(3);
/* Pointer *extra_data = (Pointer *) PG_GETARG_POINTER(4); */
GinLogicValue res = GIN_TRUE;
int32 i;
if (strategy == JsonbContainsStrategyNumber)
{
bool has_maybe = false;
/*
* All extracted keys must be present. Combination of GIN_MAYBE and
* GIN_TRUE gives GIN_MAYBE result because then all keys may be
* present.
*/
for (i = 0; i < nkeys; i++)
{
if (check[i] == GIN_FALSE)
{
res = GIN_FALSE;
break;
}
if (check[i] == GIN_MAYBE)
{
res = GIN_MAYBE;
has_maybe = true;
}
}
/*
* Index doesn't have information about correspondence of Jsonb keys
* and values (as distinct from GIN keys, which a key/value pair is
* stored as), so invariably we recheck. This is also reflected in how
* GIN_MAYBE is given in response to there being no GIN_MAYBE input.
*/
if (!has_maybe && res == GIN_TRUE)
res = GIN_MAYBE;
}
else if (strategy == JsonbExistsStrategyNumber ||
strategy == JsonbExistsAnyStrategyNumber)
{
/* Existence of key guaranteed in default search mode */
res = GIN_FALSE;
for (i = 0; i < nkeys; i++)
{
if (check[i] == GIN_TRUE)
{
res = GIN_TRUE;
break;
}
if (check[i] == GIN_MAYBE)
{
res = GIN_MAYBE;
}
}
}
else if (strategy == JsonbExistsAllStrategyNumber)
{
/* Testing for the presence of all keys gives an exact result */
for (i = 0; i < nkeys; i++)
{
if (check[i] == GIN_FALSE)
{
res = GIN_FALSE;
break;
}
if (check[i] == GIN_MAYBE)
{
res = GIN_MAYBE;
}
}
}
else
elog(ERROR, "unrecognized strategy number: %d", strategy);
PG_RETURN_GIN_LOGIC_VALUE(res);
}
/*
*
* jsonb_hash_ops GIN opclass support functions
*
*/
Datum
gin_consistent_jsonb_hash(PG_FUNCTION_ARGS)
{
bool *check = (bool *) PG_GETARG_POINTER(0);
StrategyNumber strategy = PG_GETARG_UINT16(1);
/* Jsonb *query = PG_GETARG_JSONB(2); */
int32 nkeys = PG_GETARG_INT32(3);
/* Pointer *extra_data = (Pointer *) PG_GETARG_POINTER(4); */
bool *recheck = (bool *) PG_GETARG_POINTER(5);
bool res = true;
int32 i;
if (strategy != JsonbContainsStrategyNumber)
elog(ERROR, "unrecognized strategy number: %d", strategy);
/*
* jsonb_hash_ops index doesn't have information about correspondence
* of Jsonb keys and values (as distinct from GIN keys, which a
* key/value pair is stored as), so invariably we recheck. Besides,
* there are some special rules around the containment of raw scalar
* arrays and regular arrays that are not represented here. However,
* if all of the keys are not present, that's sufficient reason to
* return false and finish immediately.
*/
*recheck = true;
for (i = 0; i < nkeys; i++)
{
if (!check[i])
{
res = false;
break;
}
}
PG_RETURN_BOOL(res);
}
Datum
gin_triconsistent_jsonb_hash(PG_FUNCTION_ARGS)
{
GinLogicValue *check = (GinLogicValue *) PG_GETARG_POINTER(0);
StrategyNumber strategy = PG_GETARG_UINT16(1);
/* Jsonb *query = PG_GETARG_JSONB(2); */
int32 nkeys = PG_GETARG_INT32(3);
/* Pointer *extra_data = (Pointer *) PG_GETARG_POINTER(4); */
GinLogicValue res = GIN_TRUE;
int32 i;
bool has_maybe = false;
if (strategy != JsonbContainsStrategyNumber)
elog(ERROR, "unrecognized strategy number: %d", strategy);
/*
* All extracted keys must be present. A combination of GIN_MAYBE and
* GIN_TRUE induces a GIN_MAYBE result, because then all keys may be
* present.
*/
for (i = 0; i < nkeys; i++)
{
if (check[i] == GIN_FALSE)
{
res = GIN_FALSE;
break;
}
if (check[i] == GIN_MAYBE)
{
res = GIN_MAYBE;
has_maybe = true;
}
}
/*
* jsonb_hash_ops index doesn't have information about correspondence of
* Jsonb keys and values (as distinct from GIN keys, which for this opclass
* are a hash of a pair, or a hash of just an element), so invariably we
* recheck. This is also reflected in how GIN_MAYBE is given in response
* to there being no GIN_MAYBE input.
*/
if (!has_maybe && res == GIN_TRUE)
res = GIN_MAYBE;
PG_RETURN_GIN_LOGIC_VALUE(res);
}
Datum
gin_extract_jsonb_hash(PG_FUNCTION_ARGS)
{
Jsonb *jb = PG_GETARG_JSONB(0);
int32 *nentries = (int32 *) PG_GETARG_POINTER(1);
int total = 2 * JB_ROOT_COUNT(jb);
JsonbIterator *it;
JsonbValue v;
PathHashStack tail;
PathHashStack *stack;
int i = 0,
r;
Datum *entries = NULL;
if (total == 0)
{
*nentries = 0;
PG_RETURN_POINTER(NULL);
}
entries = (Datum *) palloc(sizeof(Datum) * total);
it = JsonbIteratorInit(VARDATA(jb));
tail.parent = NULL;
tail.hash = 0;
stack = &tail;
while ((r = JsonbIteratorNext(&it, &v, false)) != WJB_DONE)
{
PathHashStack *tmp;
if (i >= total)
{
total *= 2;
entries = (Datum *) repalloc(entries, sizeof(Datum) * total);
}
switch (r)
{
case WJB_BEGIN_ARRAY:
case WJB_BEGIN_OBJECT:
tmp = stack;
stack = (PathHashStack *) palloc(sizeof(PathHashStack));
/*
* Nesting an array within another array will not alter
* innermost scalar element hash values, but that seems
* inconsequential
*/
if (tmp->parent)
{
/*
* We pass forward hashes from previous container nesting
* levels so that nested arrays with an outermost nested
* object will have element hashes mixed with the outermost
* key. It's also somewhat useful to have nested objects
* innermost values have hashes that are a function of not
* just their own key, but outer keys too.
*/
stack->hash = tmp->hash;
}
else
{
/*
* At least nested level, initialize with stable container
* type proxy value
*/
stack->hash = (r == WJB_BEGIN_ARRAY)? JB_FARRAY:JB_FOBJECT;
}
stack->parent = tmp;
break;
case WJB_KEY:
/* Initialize hash from parent */
stack->hash = stack->parent->hash;
JsonbHashScalarValue(&v, &stack->hash);
break;
case WJB_ELEM:
/* Elements have parent hash mixed in separately */
stack->hash = stack->parent->hash;
case WJB_VALUE:
/* Element/value case */
JsonbHashScalarValue(&v, &stack->hash);
entries[i++] = stack->hash;
break;
case WJB_END_ARRAY:
case WJB_END_OBJECT:
/* Pop the stack */
tmp = stack->parent;
pfree(stack);
stack = tmp;
break;
default:
elog(ERROR, "invalid JsonbIteratorNext rc: %d", r);
}
}
*nentries = i;
PG_RETURN_POINTER(entries);
}
Datum
gin_extract_jsonb_query_hash(PG_FUNCTION_ARGS)
{
int32 *nentries = (int32 *) PG_GETARG_POINTER(1);
StrategyNumber strategy = PG_GETARG_UINT16(2);
int32 *searchMode = (int32 *) PG_GETARG_POINTER(6);
Datum *entries;
if (strategy != JsonbContainsStrategyNumber)
elog(ERROR, "unrecognized strategy number: %d", strategy);
/* Query is a jsonb, so just apply gin_extract_jsonb... */
entries = (Datum *)
DatumGetPointer(DirectFunctionCall2(gin_extract_jsonb_hash,
PG_GETARG_DATUM(0),
PointerGetDatum(nentries)));
/* ...although "contains {}" requires a full index scan */
if (entries == NULL)
*searchMode = GIN_SEARCH_MODE_ALL;
PG_RETURN_POINTER(entries);
}
/*
* Build a text value from a cstring and flag suitable for storage as a key
* value
*/
static text *
make_text_key(const char *str, int len, char flag)
{
text *item;
item = (text *) palloc(VARHDRSZ + len + 1);
SET_VARSIZE(item, VARHDRSZ + len + 1);
*VARDATA(item) = flag;
memcpy(VARDATA(item) + 1, str, len);
return item;
}
/*
* Create a textual representation of a jsonbValue for GIN storage.
*/
static text *
make_scalar_key(const JsonbValue * scalarVal, char flag)
{
text *item;
char *cstr;
switch (scalarVal->type)
{
case jbvNull:
item = make_text_key("n", 1, flag);
break;
case jbvBool:
item = make_text_key(scalarVal->boolean ? "t" : "f", 1, flag);
break;
case jbvNumeric:
/*
* A normalized textual representation, free of trailing zeroes is
* is required.
*
* It isn't ideal that numerics are stored in a relatively bulky
* textual format. However, it's a notationally convenient way of
* storing a "union" type in the GIN B-Tree, and indexing Jsonb
* strings takes precedence.
*/
cstr = numeric_normalize(scalarVal->numeric);
item = make_text_key(cstr, strlen(cstr), flag);
pfree(cstr);
break;
case jbvString:
item = make_text_key(scalarVal->string.val, scalarVal->string.len,
flag);
break;
default:
elog(ERROR, "invalid jsonb scalar type");
}
return item;
}

View File

@ -0,0 +1,295 @@
/*-------------------------------------------------------------------------
*
* jsonb_op.c
* Special operators for jsonb only, used by various index access methods
*
* Copyright (c) 2014, PostgreSQL Global Development Group
*
*
* IDENTIFICATION
* src/backend/utils/adt/jsonb_op.c
*
*-------------------------------------------------------------------------
*/
#include "postgres.h"
#include "miscadmin.h"
#include "utils/jsonb.h"
Datum
jsonb_exists(PG_FUNCTION_ARGS)
{
Jsonb *jb = PG_GETARG_JSONB(0);
text *key = PG_GETARG_TEXT_PP(1);
JsonbValue kval;
JsonbValue *v = NULL;
/*
* We only match Object keys (which are naturally always Strings), or
* string elements in arrays. In particular, we do not match non-string
* scalar elements. Existence of a key/element is only considered at the
* top level. No recursion occurs.
*/
kval.type = jbvString;
kval.string.val = VARDATA_ANY(key);
kval.string.len = VARSIZE_ANY_EXHDR(key);
v = findJsonbValueFromSuperHeader(VARDATA(jb),
JB_FOBJECT | JB_FARRAY,
NULL,
&kval);
PG_RETURN_BOOL(v != NULL);
}
Datum
jsonb_exists_any(PG_FUNCTION_ARGS)
{
Jsonb *jb = PG_GETARG_JSONB(0);
ArrayType *keys = PG_GETARG_ARRAYTYPE_P(1);
JsonbValue *arrKey = arrayToJsonbSortedArray(keys);
uint32 *plowbound = NULL,
lowbound = 0;
int i;
if (arrKey == NULL || arrKey->object.nPairs == 0)
PG_RETURN_BOOL(false);
if (JB_ROOT_IS_OBJECT(jb))
plowbound = &lowbound;
/*
* We exploit the fact that the pairs list is already sorted into strictly
* increasing order to narrow the findJsonbValueFromSuperHeader search;
* each search can start one entry past the previous "found" entry, or at
* the lower bound of the last search.
*/
for (i = 0; i < arrKey->array.nElems; i++)
{
if (findJsonbValueFromSuperHeader(VARDATA(jb),
JB_FOBJECT | JB_FARRAY,
plowbound,
arrKey->array.elems + i) != NULL)
PG_RETURN_BOOL(true);
}
PG_RETURN_BOOL(false);
}
Datum
jsonb_exists_all(PG_FUNCTION_ARGS)
{
Jsonb *jb = PG_GETARG_JSONB(0);
ArrayType *keys = PG_GETARG_ARRAYTYPE_P(1);
JsonbValue *arrKey = arrayToJsonbSortedArray(keys);
uint32 *plowbound = NULL;
uint32 lowbound = 0;
int i;
if (arrKey == NULL || arrKey->array.nElems == 0)
PG_RETURN_BOOL(true);
if (JB_ROOT_IS_OBJECT(jb))
plowbound = &lowbound;
/*
* We exploit the fact that the pairs list is already sorted into strictly
* increasing order to narrow the findJsonbValueFromSuperHeader search;
* each search can start one entry past the previous "found" entry, or at
* the lower bound of the last search.
*/
for (i = 0; i < arrKey->array.nElems; i++)
{
if (findJsonbValueFromSuperHeader(VARDATA(jb),
JB_FOBJECT | JB_FARRAY,
plowbound,
arrKey->array.elems + i) == NULL)
PG_RETURN_BOOL(false);
}
PG_RETURN_BOOL(true);
}
Datum
jsonb_contains(PG_FUNCTION_ARGS)
{
Jsonb *val = PG_GETARG_JSONB(0);
Jsonb *tmpl = PG_GETARG_JSONB(1);
JsonbIterator *it1, *it2;
if (JB_ROOT_COUNT(val) < JB_ROOT_COUNT(tmpl) ||
JB_ROOT_IS_OBJECT(val) != JB_ROOT_IS_OBJECT(tmpl))
PG_RETURN_BOOL(false);
it1 = JsonbIteratorInit(VARDATA(val));
it2 = JsonbIteratorInit(VARDATA(tmpl));
PG_RETURN_BOOL(JsonbDeepContains(&it1, &it2));
}
Datum
jsonb_contained(PG_FUNCTION_ARGS)
{
/* Commutator of "contains" */
Jsonb *tmpl = PG_GETARG_JSONB(0);
Jsonb *val = PG_GETARG_JSONB(1);
JsonbIterator *it1, *it2;
if (JB_ROOT_COUNT(val) < JB_ROOT_COUNT(tmpl) ||
JB_ROOT_IS_OBJECT(val) != JB_ROOT_IS_OBJECT(tmpl))
PG_RETURN_BOOL(false);
it1 = JsonbIteratorInit(VARDATA(val));
it2 = JsonbIteratorInit(VARDATA(tmpl));
PG_RETURN_BOOL(JsonbDeepContains(&it1, &it2));
}
Datum
jsonb_ne(PG_FUNCTION_ARGS)
{
Jsonb *jba = PG_GETARG_JSONB(0);
Jsonb *jbb = PG_GETARG_JSONB(1);
bool res;
res = (compareJsonbSuperHeaderValue(VARDATA(jba), VARDATA(jbb)) != 0);
PG_FREE_IF_COPY(jba, 0);
PG_FREE_IF_COPY(jbb, 1);
PG_RETURN_BOOL(res);
}
/*
* B-Tree operator class operators, support function
*/
Datum
jsonb_lt(PG_FUNCTION_ARGS)
{
Jsonb *jba = PG_GETARG_JSONB(0);
Jsonb *jbb = PG_GETARG_JSONB(1);
bool res;
res = (compareJsonbSuperHeaderValue(VARDATA(jba), VARDATA(jbb)) < 0);
PG_FREE_IF_COPY(jba, 0);
PG_FREE_IF_COPY(jbb, 1);
PG_RETURN_BOOL(res);
}
Datum
jsonb_gt(PG_FUNCTION_ARGS)
{
Jsonb *jba = PG_GETARG_JSONB(0);
Jsonb *jbb = PG_GETARG_JSONB(1);
bool res;
res = (compareJsonbSuperHeaderValue(VARDATA(jba), VARDATA(jbb)) > 0);
PG_FREE_IF_COPY(jba, 0);
PG_FREE_IF_COPY(jbb, 1);
PG_RETURN_BOOL(res);
}
Datum
jsonb_le(PG_FUNCTION_ARGS)
{
Jsonb *jba = PG_GETARG_JSONB(0);
Jsonb *jbb = PG_GETARG_JSONB(1);
bool res;
res = (compareJsonbSuperHeaderValue(VARDATA(jba), VARDATA(jbb)) <= 0);
PG_FREE_IF_COPY(jba, 0);
PG_FREE_IF_COPY(jbb, 1);
PG_RETURN_BOOL(res);
}
Datum
jsonb_ge(PG_FUNCTION_ARGS)
{
Jsonb *jba = PG_GETARG_JSONB(0);
Jsonb *jbb = PG_GETARG_JSONB(1);
bool res;
res = (compareJsonbSuperHeaderValue(VARDATA(jba), VARDATA(jbb)) >= 0);
PG_FREE_IF_COPY(jba, 0);
PG_FREE_IF_COPY(jbb, 1);
PG_RETURN_BOOL(res);
}
Datum
jsonb_eq(PG_FUNCTION_ARGS)
{
Jsonb *jba = PG_GETARG_JSONB(0);
Jsonb *jbb = PG_GETARG_JSONB(1);
bool res;
res = (compareJsonbSuperHeaderValue(VARDATA(jba), VARDATA(jbb)) == 0);
PG_FREE_IF_COPY(jba, 0);
PG_FREE_IF_COPY(jbb, 1);
PG_RETURN_BOOL(res);
}
Datum
jsonb_cmp(PG_FUNCTION_ARGS)
{
Jsonb *jba = PG_GETARG_JSONB(0);
Jsonb *jbb = PG_GETARG_JSONB(1);
int res;
res = compareJsonbSuperHeaderValue(VARDATA(jba), VARDATA(jbb));
PG_FREE_IF_COPY(jba, 0);
PG_FREE_IF_COPY(jbb, 1);
PG_RETURN_INT32(res);
}
/*
* Hash operator class jsonb hashing function
*/
Datum
jsonb_hash(PG_FUNCTION_ARGS)
{
Jsonb *jb = PG_GETARG_JSONB(0);
JsonbIterator *it;
int32 r;
JsonbValue v;
uint32 hash = 0;
if (JB_ROOT_COUNT(jb) == 0)
PG_RETURN_INT32(0);
it = JsonbIteratorInit(VARDATA(jb));
while ((r = JsonbIteratorNext(&it, &v, false)) != WJB_DONE)
{
switch (r)
{
/* Rotation is left to JsonbHashScalarValue() */
case WJB_BEGIN_ARRAY:
hash ^= JB_FARRAY;
break;
case WJB_BEGIN_OBJECT:
hash ^= JB_FOBJECT;
break;
case WJB_KEY:
case WJB_VALUE:
case WJB_ELEM:
JsonbHashScalarValue(&v, &hash);
break;
case WJB_END_ARRAY:
case WJB_END_OBJECT:
break;
default:
elog(ERROR, "invalid JsonbIteratorNext rc: %d", r);
}
}
PG_FREE_IF_COPY(jb, 0);
PG_RETURN_INT32(hash);
}

File diff suppressed because it is too large Load Diff

File diff suppressed because it is too large Load Diff

View File

@ -626,6 +626,44 @@ numeric_out_sci(Numeric num, int scale)
return str;
}
/*
* numeric_normalize() -
*
* Output function for numeric data type without trailing zeroes.
*/
char *
numeric_normalize(Numeric num)
{
NumericVar x;
char *str;
int orig, last;
/*
* Handle NaN
*/
if (NUMERIC_IS_NAN(num))
return pstrdup("NaN");
init_var_from_num(num, &x);
str = get_str_from_var(&x);
orig = last = strlen(str) - 1;
for (;;)
{
if (last == 0 || str[last] != '0')
break;
last--;
}
if (last > 0 && last != orig)
str[last] = '\0';
return str;
}
/*
* numeric_recv - converts external binary format to numeric
*

View File

@ -777,6 +777,33 @@ DATA(insert ( 4017 25 25 12 s 665 4000 0 ));
DATA(insert ( 4017 25 25 14 s 667 4000 0 ));
DATA(insert ( 4017 25 25 15 s 666 4000 0 ));
/*
* btree jsonb_ops
*/
DATA(insert ( 4033 3802 3802 1 s 3242 403 0 ));
DATA(insert ( 4033 3802 3802 2 s 3244 403 0 ));
DATA(insert ( 4033 3802 3802 3 s 3240 403 0 ));
DATA(insert ( 4033 3802 3802 4 s 3245 403 0 ));
DATA(insert ( 4033 3802 3802 5 s 3243 403 0 ));
/*
* hash jsonb ops
*/
DATA(insert ( 4034 3802 3802 1 s 3240 405 0 ));
/*
* GIN jsonb ops
*/
DATA(insert ( 4036 3802 3802 7 s 3246 2742 0 ));
DATA(insert ( 4036 3802 25 9 s 3247 2742 0 ));
DATA(insert ( 4036 3802 1009 10 s 3248 2742 0 ));
DATA(insert ( 4036 3802 1009 11 s 3249 2742 0 ));
/*
* GIN jsonb hash ops
*/
DATA(insert ( 4037 3802 3802 7 s 3246 2742 0 ));
/*
* SP-GiST range_ops
*/

View File

@ -138,6 +138,7 @@ DATA(insert ( 3522 3500 3500 1 3514 ));
DATA(insert ( 3626 3614 3614 1 3622 ));
DATA(insert ( 3683 3615 3615 1 3668 ));
DATA(insert ( 3901 3831 3831 1 3870 ));
DATA(insert ( 4033 3802 3802 1 4044 ));
/* hash */
@ -175,6 +176,7 @@ DATA(insert ( 2235 1033 1033 1 329 ));
DATA(insert ( 2969 2950 2950 1 2963 ));
DATA(insert ( 3523 3500 3500 1 3515 ));
DATA(insert ( 3903 3831 3831 1 3902 ));
DATA(insert ( 4034 3802 3802 1 4045 ));
/* gist */
@ -387,7 +389,16 @@ DATA(insert ( 3659 3614 3614 3 3657 ));
DATA(insert ( 3659 3614 3614 4 3658 ));
DATA(insert ( 3659 3614 3614 5 2700 ));
DATA(insert ( 3659 3614 3614 6 3921 ));
DATA(insert ( 4036 3802 3802 1 3480 ));
DATA(insert ( 4036 3802 3802 2 3482 ));
DATA(insert ( 4036 3802 3802 3 3483 ));
DATA(insert ( 4036 3802 3802 4 3484 ));
DATA(insert ( 4036 3802 3802 6 3488 ));
DATA(insert ( 4037 3802 3802 1 351 ));
DATA(insert ( 4037 3802 3802 2 3485 ));
DATA(insert ( 4037 3802 3802 3 3486 ));
DATA(insert ( 4037 3802 3802 4 3487 ));
DATA(insert ( 4037 3802 3802 6 3489 ));
/* sp-gist */
DATA(insert ( 3474 3831 3831 1 3469 ));

View File

@ -359,4 +359,8 @@ DATA(insert ( 1560 1560 1685 i f ));
DATA(insert ( 1562 1562 1687 i f ));
DATA(insert ( 1700 1700 1703 i f ));
/* json to/from jsonb */
DATA(insert ( 114 3802 0 e i ));
DATA(insert ( 3802 114 0 e i ));
#endif /* PG_CAST_H */

View File

@ -228,5 +228,9 @@ DATA(insert ( 4000 range_ops PGNSP PGUID 3474 3831 t 0 ));
DATA(insert ( 4000 quad_point_ops PGNSP PGUID 4015 600 t 0 ));
DATA(insert ( 4000 kd_point_ops PGNSP PGUID 4016 600 f 0 ));
DATA(insert ( 4000 text_ops PGNSP PGUID 4017 25 t 0 ));
DATA(insert ( 403 jsonb_ops PGNSP PGUID 4033 3802 t 0 ));
DATA(insert ( 405 jsonb_ops PGNSP PGUID 4034 3802 t 0 ));
DATA(insert ( 2742 jsonb_ops PGNSP PGUID 4036 3802 t 25 ));
DATA(insert ( 2742 jsonb_hash_ops PGNSP PGUID 4037 3802 f 23 ));
#endif /* PG_OPCLASS_H */

View File

@ -1769,8 +1769,41 @@ DATA(insert OID = 3966 ( "#>" PGNSP PGUID b f f 114 1009 114 0 0 json_extrac
DESCR("get value from json with path elements");
DATA(insert OID = 3967 ( "#>>" PGNSP PGUID b f f 114 1009 25 0 0 json_extract_path_text_op - - ));
DESCR("get value from json as text with path elements");
DATA(insert OID = 3211 ( "->" PGNSP PGUID b f f 3802 25 3802 0 0 jsonb_object_field - - ));
DESCR("get jsonb object field");
DATA(insert OID = 3477 ( "->>" PGNSP PGUID b f f 3802 25 25 0 0 jsonb_object_field_text - - ));
DESCR("get jsonb object field as text");
DATA(insert OID = 3212 ( "->" PGNSP PGUID b f f 3802 23 3802 0 0 jsonb_array_element - - ));
DESCR("get jsonb array element");
DATA(insert OID = 3481 ( "->>" PGNSP PGUID b f f 3802 23 25 0 0 jsonb_array_element_text - - ));
DESCR("get jsonb array element as text");
DATA(insert OID = 3213 ( "#>" PGNSP PGUID b f f 3802 1009 3802 0 0 jsonb_extract_path_op - - ));
DESCR("get value from jsonb with path elements");
DATA(insert OID = 3206 ( "#>>" PGNSP PGUID b f f 3802 1009 25 0 0 jsonb_extract_path_text_op - - ));
DESCR("get value from jsonb as text with path elements");
DATA(insert OID = 3240 ( "=" PGNSP PGUID b t t 3802 3802 16 3240 3241 jsonb_eq eqsel eqjoinsel ));
DESCR("equal");
DATA(insert OID = 3241 ( "<>" PGNSP PGUID b f f 3802 3802 16 3241 3240 jsonb_ne neqsel neqjoinsel ));
DESCR("not equal");
DATA(insert OID = 3242 ( "<" PGNSP PGUID b f f 3802 3802 16 3243 3245 jsonb_lt scalarltsel scalarltjoinsel ));
DESCR("less than");
DATA(insert OID = 3243 ( ">" PGNSP PGUID b f f 3802 3802 16 3242 3244 jsonb_gt scalargtsel scalargtjoinsel ));
DESCR("greater than");
DATA(insert OID = 3244 ( "<=" PGNSP PGUID b f f 3802 3802 16 3245 3243 jsonb_le scalarltsel scalarltjoinsel ));
DESCR("less than or equal to");
DATA(insert OID = 3245 ( ">=" PGNSP PGUID b f f 3802 3802 16 3244 3242 jsonb_ge scalargtsel scalargtjoinsel ));
DESCR("greater than or equal to");
/* No commutator? */
DATA(insert OID = 3246 ( "@>" PGNSP PGUID b f f 3802 3802 16 0 3250 jsonb_contains contsel contjoinsel ));
DESCR("contains");
DATA(insert OID = 3247 ( "?" PGNSP PGUID b f f 3802 25 16 0 0 jsonb_exists contsel contjoinsel ));
DESCR("exists");
DATA(insert OID = 3248 ( "?|" PGNSP PGUID b f f 3802 1009 16 0 0 jsonb_exists_any contsel contjoinsel ));
DESCR("exists any");
DATA(insert OID = 3249 ( "?&" PGNSP PGUID b f f 3802 1009 16 0 0 jsonb_exists_all contsel contjoinsel ));
DESCR("exists all");
DATA(insert OID = 3250 ( "<@" PGNSP PGUID b f f 3802 3802 16 0 3246 jsonb_contained contsel contjoinsel ));
DESCR("contained");
/*
* function prototypes

View File

@ -147,6 +147,11 @@ DATA(insert OID = 3474 ( 4000 range_ops PGNSP PGUID ));
DATA(insert OID = 4015 ( 4000 quad_point_ops PGNSP PGUID ));
DATA(insert OID = 4016 ( 4000 kd_point_ops PGNSP PGUID ));
DATA(insert OID = 4017 ( 4000 text_ops PGNSP PGUID ));
DATA(insert OID = 4033 ( 403 jsonb_ops PGNSP PGUID ));
DATA(insert OID = 4034 ( 405 jsonb_ops PGNSP PGUID ));
DATA(insert OID = 4035 ( 783 jsonb_ops PGNSP PGUID ));
DATA(insert OID = 4036 ( 2742 jsonb_ops PGNSP PGUID ));
DATA(insert OID = 4037 ( 2742 jsonb_hash_ops PGNSP PGUID ));
#define TEXT_SPGIST_FAM_OID 4017
#endif /* PG_OPFAMILY_H */

View File

@ -4173,6 +4173,8 @@ DESCR("get value from json as text with path elements");
DATA(insert OID = 3954 ( json_extract_path_text_op PGNSP PGUID 12 1 0 0 0 f f f f t f i 2 0 25 "114 1009" _null_ _null_ "{from_json,path_elems}" _null_ json_extract_path_text _null_ _null_ _null_ ));
DATA(insert OID = 3955 ( json_array_elements PGNSP PGUID 12 1 100 0 0 f f f f t t i 1 0 114 "114" "{114,114}" "{i,o}" "{from_json,value}" _null_ json_array_elements _null_ _null_ _null_ ));
DESCR("key value pairs of a json object");
DATA(insert OID = 3969 ( json_array_elements_text PGNSP PGUID 12 1 100 0 0 f f f f t t i 1 0 25 "114" "{114,25}" "{i,o}" "{from_json,value}" _null_ json_array_elements_text _null_ _null_ _null_ ));
DESCR("elements of json array");
DATA(insert OID = 3956 ( json_array_length PGNSP PGUID 12 1 0 0 0 f f f f t f i 1 0 23 "114" _null_ _null_ _null_ _null_ json_array_length _null_ _null_ _null_ ));
DESCR("length of json array");
DATA(insert OID = 3957 ( json_object_keys PGNSP PGUID 12 1 100 0 0 f f f f t t i 1 0 25 "114" _null_ _null_ _null_ _null_ json_object_keys _null_ _null_ _null_ ));
@ -4191,8 +4193,6 @@ DATA(insert OID = 3205 ( json_to_recordset PGNSP PGUID 12 1 100 0 0 f f f f f
DESCR("get set of records with fields from a json array of objects");
DATA(insert OID = 3968 ( json_typeof PGNSP PGUID 12 1 0 0 0 f f f f t f i 1 0 25 "114" _null_ _null_ _null_ _null_ json_typeof _null_ _null_ _null_ ));
DESCR("get the type of a json value");
DATA(insert OID = 3969 ( json_array_elements_text PGNSP PGUID 12 1 100 0 0 f f f f t t i 1 0 25 "114" "{114,25}" "{i,o}" "{from_json,value}" _null_ json_array_elements_text _null_ _null_ _null_ ));
DESCR("elements of json array");
/* uuid */
DATA(insert OID = 2952 ( uuid_in PGNSP PGUID 12 1 0 0 0 f f f f t f i 1 0 2950 "2275" _null_ _null_ _null_ _null_ uuid_in _null_ _null_ _null_ ));
@ -4510,6 +4510,83 @@ DESCR("I/O");
DATA(insert OID = 3774 ( regdictionarysend PGNSP PGUID 12 1 0 0 0 f f f f t f i 1 0 17 "3769" _null_ _null_ _null_ _null_ regdictionarysend _null_ _null_ _null_ ));
DESCR("I/O");
/* jsonb */
DATA(insert OID = 3806 ( jsonb_in PGNSP PGUID 12 1 0 0 0 f f f f t f i 1 0 3802 "2275" _null_ _null_ _null_ _null_ jsonb_in _null_ _null_ _null_ ));
DESCR("I/O");
DATA(insert OID = 3805 ( jsonb_recv PGNSP PGUID 12 1 0 0 0 f f f f t f i 1 0 3802 "2281" _null_ _null_ _null_ _null_ jsonb_recv _null_ _null_ _null_ ));
DESCR("I/O");
DATA(insert OID = 3804 ( jsonb_out PGNSP PGUID 12 1 0 0 0 f f f f t f i 1 0 2275 "3802" _null_ _null_ _null_ _null_ jsonb_out _null_ _null_ _null_ ));
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_ ));
DESCR("I/O");
DATA(insert OID = 3478 ( jsonb_object_field PGNSP PGUID 12 1 0 0 0 f f f f t f i 2 0 3802 "3802 25" _null_ _null_ "{from_json, field_name}" _null_ jsonb_object_field _null_ _null_ _null_ ));
DATA(insert OID = 3214 ( jsonb_object_field_text PGNSP PGUID 12 1 0 0 0 f f f f t f i 2 0 25 "3802 25" _null_ _null_ "{from_json, field_name}" _null_ jsonb_object_field_text _null_ _null_ _null_ ));
DATA(insert OID = 3215 ( jsonb_array_element PGNSP PGUID 12 1 0 0 0 f f f f t f i 2 0 3802 "3802 23" _null_ _null_ "{from_json, element_index}" _null_ jsonb_array_element _null_ _null_ _null_ ));
DATA(insert OID = 3216 ( jsonb_array_element_text PGNSP PGUID 12 1 0 0 0 f f f f t f i 2 0 25 "3802 23" _null_ _null_ "{from_json, element_index}" _null_ jsonb_array_element_text _null_ _null_ _null_ ));
DATA(insert OID = 3217 ( jsonb_extract_path PGNSP PGUID 12 1 0 25 0 f f f f t f i 2 0 3802 "3802 1009" "{3802,1009}" "{i,v}" "{from_json,path_elems}" _null_ jsonb_extract_path _null_ _null_ _null_ ));
DESCR("get value from jsonb with path elements");
DATA(insert OID = 3939 ( jsonb_extract_path_op PGNSP PGUID 12 1 0 0 0 f f f f t f i 2 0 3802 "3802 1009" _null_ _null_ "{from_json,path_elems}" _null_ jsonb_extract_path _null_ _null_ _null_ ));
DATA(insert OID = 3940 ( jsonb_extract_path_text PGNSP PGUID 12 1 0 25 0 f f f f t f i 2 0 25 "3802 1009" "{3802,1009}" "{i,v}" "{from_json,path_elems}" _null_ jsonb_extract_path_text _null_ _null_ _null_ ));
DESCR("get value from jsonb as text with path elements");
DATA(insert OID = 3218 ( jsonb_extract_path_text_op PGNSP PGUID 12 1 0 0 0 f f f f t f i 2 0 25 "3802 1009" _null_ _null_ "{from_json,path_elems}" _null_ jsonb_extract_path_text _null_ _null_ _null_ ));
DATA(insert OID = 3219 ( jsonb_array_elements PGNSP PGUID 12 1 100 0 0 f f f f t t i 1 0 3802 "3802" "{3802,3802}" "{i,o}" "{from_json,value}" _null_ jsonb_array_elements _null_ _null_ _null_ ));
DESCR("elements of a jsonb array");
DATA(insert OID = 3465 ( jsonb_array_elements_text PGNSP PGUID 12 1 100 0 0 f f f f t t i 1 0 25 "3802" "{3802,25}" "{i,o}" "{from_json,value}" _null_ jsonb_array_elements_text _null_ _null_ _null_ ));
DESCR("elements of jsonb array");
DATA(insert OID = 3207 ( jsonb_array_length PGNSP PGUID 12 1 0 0 0 f f f f t f i 1 0 23 "3802" _null_ _null_ _null_ _null_ jsonb_array_length _null_ _null_ _null_ ));
DESCR("length of jsonb array");
DATA(insert OID = 3931 ( jsonb_object_keys PGNSP PGUID 12 1 100 0 0 f f f f t t i 1 0 25 "3802" _null_ _null_ _null_ _null_ jsonb_object_keys _null_ _null_ _null_ ));
DESCR("get jsonb object keys");
DATA(insert OID = 3208 ( jsonb_each PGNSP PGUID 12 1 100 0 0 f f f f t t i 1 0 2249 "3802" "{3802,25,3802}" "{i,o,o}" "{from_json,key,value}" _null_ jsonb_each _null_ _null_ _null_ ));
DESCR("key value pairs of a jsonb object");
DATA(insert OID = 3932 ( jsonb_each_text PGNSP PGUID 12 1 100 0 0 f f f f t t i 1 0 2249 "3802" "{3802,25,25}" "{i,o,o}" "{from_json,key,value}" _null_ jsonb_each_text _null_ _null_ _null_ ));
DESCR("key value pairs of a jsonb object");
DATA(insert OID = 3209 ( jsonb_populate_record PGNSP PGUID 12 1 0 0 0 f f f f f f s 3 0 2283 "2283 3802 16" _null_ _null_ _null_ _null_ jsonb_populate_record _null_ _null_ _null_ ));
DESCR("get record fields from a jsonb object");
DATA(insert OID = 3475 ( jsonb_populate_recordset PGNSP PGUID 12 1 100 0 0 f f f f f t s 3 0 2283 "2283 3802 16" _null_ _null_ _null_ _null_ jsonb_populate_recordset _null_ _null_ _null_ ));
DESCR("get set of records with fields from a jsonb array of objects");
DATA(insert OID = 3210 ( jsonb_typeof PGNSP PGUID 12 1 0 0 0 f f f f t f i 1 0 25 "3802" _null_ _null_ _null_ _null_ jsonb_typeof _null_ _null_ _null_ ));
DESCR("get the type of a jsonb value");
DATA(insert OID = 4038 ( jsonb_ne PGNSP PGUID 12 1 0 0 0 f f f f t f i 2 0 16 "3802 3802" _null_ _null_ _null_ _null_ jsonb_ne _null_ _null_ _null_ ));
DATA(insert OID = 4039 ( jsonb_lt PGNSP PGUID 12 1 0 0 0 f f f f t f i 2 0 16 "3802 3802" _null_ _null_ _null_ _null_ jsonb_lt _null_ _null_ _null_ ));
DATA(insert OID = 4040 ( jsonb_gt PGNSP PGUID 12 1 0 0 0 f f f f t f i 2 0 16 "3802 3802" _null_ _null_ _null_ _null_ jsonb_gt _null_ _null_ _null_ ));
DATA(insert OID = 4041 ( jsonb_le PGNSP PGUID 12 1 0 0 0 f f f f t f i 2 0 16 "3802 3802" _null_ _null_ _null_ _null_ jsonb_le _null_ _null_ _null_ ));
DATA(insert OID = 4042 ( jsonb_ge PGNSP PGUID 12 1 0 0 0 f f f f t f i 2 0 16 "3802 3802" _null_ _null_ _null_ _null_ jsonb_ge _null_ _null_ _null_ ));
DATA(insert OID = 4043 ( jsonb_eq PGNSP PGUID 12 1 0 0 0 f f f f t f i 2 0 16 "3802 3802" _null_ _null_ _null_ _null_ jsonb_eq _null_ _null_ _null_ ));
DATA(insert OID = 4044 ( jsonb_cmp PGNSP PGUID 12 1 0 0 0 f f f f t f i 2 0 23 "3802 3802" _null_ _null_ _null_ _null_ jsonb_cmp _null_ _null_ _null_ ));
DESCR("less-equal-greater");
DATA(insert OID = 4045 ( jsonb_hash PGNSP PGUID 12 1 0 0 0 f f f f t f i 1 0 23 "3802" _null_ _null_ _null_ _null_ jsonb_hash _null_ _null_ _null_ ));
DESCR("hash");
DATA(insert OID = 4046 ( jsonb_contains PGNSP PGUID 12 1 0 0 0 f f f f t f i 2 0 16 "3802 3802" _null_ _null_ _null_ _null_ jsonb_contains _null_ _null_ _null_ ));
DESCR("implementation of @> operator");
DATA(insert OID = 4047 ( jsonb_exists PGNSP PGUID 12 1 0 0 0 f f f f t f i 2 0 16 "3802 25" _null_ _null_ _null_ _null_ jsonb_exists _null_ _null_ _null_ ));
DESCR("implementation of ? operator");
DATA(insert OID = 4048 ( jsonb_exists_any PGNSP PGUID 12 1 0 0 0 f f f f t f i 2 0 16 "3802 1009" _null_ _null_ _null_ _null_ jsonb_exists_any _null_ _null_ _null_ ));
DESCR("implementation of ?| operator");
DATA(insert OID = 4049 ( jsonb_exists_all PGNSP PGUID 12 1 0 0 0 f f f f t f i 2 0 16 "3802 1009" _null_ _null_ _null_ _null_ jsonb_exists_all _null_ _null_ _null_ ));
DESCR("implementation of ?& operator");
DATA(insert OID = 4050 ( jsonb_contained PGNSP PGUID 12 1 0 0 0 f f f f t f i 2 0 16 "3802 3802" _null_ _null_ _null_ _null_ jsonb_contained _null_ _null_ _null_ ));
DESCR("implementation of <@ operator");
DATA(insert OID = 3480 ( gin_compare_jsonb PGNSP PGUID 12 1 0 0 0 f f f f t f i 2 0 23 "25 25" _null_ _null_ _null_ _null_ gin_compare_jsonb _null_ _null_ _null_ ));
DESCR("GIN support");
DATA(insert OID = 3482 ( gin_extract_jsonb PGNSP PGUID 12 1 0 0 0 f f f f t f i 3 0 2281 "2281 2281 2281" _null_ _null_ _null_ _null_ gin_extract_jsonb _null_ _null_ _null_ ));
DESCR("GIN support");
DATA(insert OID = 3483 ( gin_extract_jsonb_query PGNSP PGUID 12 1 0 0 0 f f f f t f i 7 0 2281 "2277 2281 21 2281 2281 2281 2281" _null_ _null_ _null_ _null_ gin_extract_jsonb_query _null_ _null_ _null_ ));
DESCR("GIN support");
DATA(insert OID = 3484 ( gin_consistent_jsonb PGNSP PGUID 12 1 0 0 0 f f f f t f i 8 0 16 "2281 21 2277 23 2281 2281 2281 2281" _null_ _null_ _null_ _null_ gin_consistent_jsonb _null_ _null_ _null_ ));
DESCR("GIN support");
DATA(insert OID = 3488 ( gin_triconsistent_jsonb PGNSP PGUID 12 1 0 0 0 f f f f t f i 7 0 16 "2281 21 2277 23 2281 2281 2281" _null_ _null_ _null_ _null_ gin_triconsistent_jsonb _null_ _null_ _null_ ));
DESCR("GIN support");
DATA(insert OID = 3485 ( gin_extract_jsonb_hash PGNSP PGUID 12 1 0 0 0 f f f f t f i 3 0 2281 "2281 2281 2281" _null_ _null_ _null_ _null_ gin_extract_jsonb_hash _null_ _null_ _null_ ));
DESCR("GIN support");
DATA(insert OID = 3486 ( gin_extract_jsonb_query_hash PGNSP PGUID 12 1 0 0 0 f f f f t f i 7 0 2281 "2277 2281 21 2281 2281 2281 2281" _null_ _null_ _null_ _null_ gin_extract_jsonb_query_hash _null_ _null_ _null_ ));
DESCR("GIN support");
DATA(insert OID = 3487 ( gin_consistent_jsonb_hash PGNSP PGUID 12 1 0 0 0 f f f f t f i 8 0 16 "2281 21 2277 23 2281 2281 2281 2281" _null_ _null_ _null_ _null_ gin_consistent_jsonb_hash _null_ _null_ _null_ ));
DESCR("GIN support");
DATA(insert OID = 3489 ( gin_triconsistent_jsonb_hash PGNSP PGUID 12 1 0 0 0 f f f f t f i 7 0 16 "2281 21 2277 23 2281 2281 2281" _null_ _null_ _null_ _null_ gin_triconsistent_jsonb_hash _null_ _null_ _null_ ));
DESCR("GIN support");
/* txid */
DATA(insert OID = 2939 ( txid_snapshot_in PGNSP PGUID 12 1 0 0 0 f f f f t f i 1 0 2970 "2275" _null_ _null_ _null_ _null_ txid_snapshot_in _null_ _null_ _null_ ));
DESCR("I/O");

View File

@ -606,6 +606,12 @@ DATA(insert OID = 3645 ( _tsquery PGNSP PGUID -1 f b A f t \054 0 3615 0 array_
DATA(insert OID = 3735 ( _regconfig PGNSP PGUID -1 f b A f t \054 0 3734 0 array_in array_out array_recv array_send - - array_typanalyze i x f 0 -1 0 0 _null_ _null_ _null_ ));
DATA(insert OID = 3770 ( _regdictionary PGNSP PGUID -1 f b A f t \054 0 3769 0 array_in array_out array_recv array_send - - array_typanalyze i x f 0 -1 0 0 _null_ _null_ _null_ ));
/* jsonb */
DATA(insert OID = 3802 ( jsonb PGNSP PGUID -1 f b C f t \054 0 0 3807 jsonb_in jsonb_out jsonb_recv jsonb_send - - - i x f 0 -1 0 0 _null_ _null_ _null_ ));
DESCR("Binary JSON");
#define JSONBOID 3802
DATA(insert OID = 3807 ( _jsonb PGNSP PGUID -1 f b A f t \054 0 3802 0 array_in array_out array_recv array_send - - array_typanalyze i x f 0 -1 0 0 _null_ _null_ _null_ ));
DATA(insert OID = 2970 ( txid_snapshot PGNSP PGUID -1 f b U f t \054 0 0 2949 txid_snapshot_in txid_snapshot_out txid_snapshot_recv txid_snapshot_send - - - d x f 0 -1 0 0 _null_ _null_ _null_ ));
DESCR("txid snapshot");
DATA(insert OID = 2949 ( _txid_snapshot PGNSP PGUID -1 f b A f t \054 0 2970 0 array_in array_out array_recv array_send - - array_typanalyze d x f 0 -1 0 0 _null_ _null_ _null_ ));

View File

@ -293,6 +293,15 @@ extern void end_MultiFuncCall(PG_FUNCTION_ARGS, FuncCallContext *funcctx);
PG_RETURN_DATUM(_result); \
} while (0)
#define SRF_RETURN_NEXT_NULL(_funcctx) \
do { \
ReturnSetInfo *rsi; \
(_funcctx)->call_cntr++; \
rsi = (ReturnSetInfo *) fcinfo->resultinfo; \
rsi->isDone = ExprMultipleResult; \
PG_RETURN_NULL(); \
} while (0)
#define SRF_RETURN_DONE(_funcctx) \
do { \
ReturnSetInfo *rsi; \

View File

@ -64,4 +64,19 @@ extern Datum json_populate_recordset(PG_FUNCTION_ARGS);
extern Datum json_to_record(PG_FUNCTION_ARGS);
extern Datum json_to_recordset(PG_FUNCTION_ARGS);
extern Datum jsonb_object_field(PG_FUNCTION_ARGS);
extern Datum jsonb_object_field_text(PG_FUNCTION_ARGS);
extern Datum jsonb_array_element(PG_FUNCTION_ARGS);
extern Datum jsonb_array_element_text(PG_FUNCTION_ARGS);
extern Datum jsonb_extract_path(PG_FUNCTION_ARGS);
extern Datum jsonb_extract_path_text(PG_FUNCTION_ARGS);
extern Datum jsonb_object_keys(PG_FUNCTION_ARGS);
extern Datum jsonb_array_length(PG_FUNCTION_ARGS);
extern Datum jsonb_each(PG_FUNCTION_ARGS);
extern Datum jsonb_each_text(PG_FUNCTION_ARGS);
extern Datum jsonb_array_elements_text(PG_FUNCTION_ARGS);
extern Datum jsonb_array_elements(PG_FUNCTION_ARGS);
extern Datum jsonb_populate_record(PG_FUNCTION_ARGS);
extern Datum jsonb_populate_recordset(PG_FUNCTION_ARGS);
#endif /* JSON_H */

View File

@ -100,11 +100,17 @@ typedef struct JsonSemAction
extern void pg_parse_json(JsonLexContext *lex, JsonSemAction *sem);
/*
* constructor for JsonLexContext, with or without strval element.
* constructors for JsonLexContext, with or without strval element.
* If supplied, the strval element will contain a de-escaped version of
* the lexeme. However, doing this imposes a performance penalty, so
* it should be avoided if the de-escaped lexeme is not required.
*
* If you already have the json as a text* value, use the first of these
* functions, otherwise use makeJsonLexContextCstringLen().
*/
extern JsonLexContext *makeJsonLexContext(text *json, bool need_escapes);
extern JsonLexContext *makeJsonLexContextCstringLen(char *json,
int len,
bool need_escapes);
#endif /* JSONAPI_H */

320
src/include/utils/jsonb.h Normal file
View File

@ -0,0 +1,320 @@
/*-------------------------------------------------------------------------
*
* jsonb.h
* Declarations for jsonb data type support.
*
* Copyright (c) 1996-2014, PostgreSQL Global Development Group
*
* src/include/utils/jsonb.h
*
*-------------------------------------------------------------------------
*/
#ifndef __JSONB_H__
#define __JSONB_H__
#include "lib/stringinfo.h"
#include "utils/array.h"
#include "utils/numeric.h"
/*
* JB_CMASK is used to extract count of items
*
* It's not possible to get more than 2^28 items into an Jsonb.
*/
#define JB_CMASK 0x0FFFFFFF
#define JB_FSCALAR 0x10000000
#define JB_FOBJECT 0x20000000
#define JB_FARRAY 0x40000000
/* Get information on varlena Jsonb */
#define JB_ROOT_COUNT(jbp_) ( *(uint32*) VARDATA(jbp_) & JB_CMASK)
#define JB_ROOT_IS_SCALAR(jbp_) ( *(uint32*) VARDATA(jbp_) & JB_FSCALAR)
#define JB_ROOT_IS_OBJECT(jbp_) ( *(uint32*) VARDATA(jbp_) & JB_FOBJECT)
#define JB_ROOT_IS_ARRAY(jbp_) ( *(uint32*) VARDATA(jbp_) & JB_FARRAY)
/* Jentry macros */
#define JENTRY_POSMASK 0x0FFFFFFF
#define JENTRY_ISFIRST 0x80000000
#define JENTRY_TYPEMASK (~(JENTRY_POSMASK | JENTRY_ISFIRST))
#define JENTRY_ISSTRING 0x00000000
#define JENTRY_ISNUMERIC 0x10000000
#define JENTRY_ISNEST 0x20000000
#define JENTRY_ISNULL 0x40000000
#define JENTRY_ISBOOL (JENTRY_ISNUMERIC | JENTRY_ISNEST)
#define JENTRY_ISFALSE JENTRY_ISBOOL
#define JENTRY_ISTRUE (JENTRY_ISBOOL | 0x40000000)
/* Note possible multiple evaluations, also access to prior array element */
#define JBE_ISFIRST(je_) (((je_).header & JENTRY_ISFIRST) != 0)
#define JBE_ISSTRING(je_) (((je_).header & JENTRY_TYPEMASK) == JENTRY_ISSTRING)
#define JBE_ISNUMERIC(je_) (((je_).header & JENTRY_TYPEMASK) == JENTRY_ISNUMERIC)
#define JBE_ISNEST(je_) (((je_).header & JENTRY_TYPEMASK) == JENTRY_ISNEST)
#define JBE_ISNULL(je_) (((je_).header & JENTRY_TYPEMASK) == JENTRY_ISNULL)
#define JBE_ISBOOL(je_) (((je_).header & JENTRY_TYPEMASK & JENTRY_ISBOOL) == JENTRY_ISBOOL)
#define JBE_ISBOOL_TRUE(je_) (((je_).header & JENTRY_TYPEMASK) == JENTRY_ISTRUE)
#define JBE_ISBOOL_FALSE(je_) (JBE_ISBOOL(je_) && !JBE_ISBOOL_TRUE(je_))
/* Get offset for Jentry */
#define JBE_ENDPOS(je_) ((je_).header & JENTRY_POSMASK)
#define JBE_OFF(je_) (JBE_ISFIRST(je_) ? 0 : JBE_ENDPOS((&(je_))[-1]))
#define JBE_LEN(je_) (JBE_ISFIRST(je_) ? \
JBE_ENDPOS(je_) \
: JBE_ENDPOS(je_) - JBE_ENDPOS((&(je_))[-1]))
/* Flags indicating a stage of sequential Jsonb processing */
#define WJB_DONE 0x000
#define WJB_KEY 0x001
#define WJB_VALUE 0x002
#define WJB_ELEM 0x004
#define WJB_BEGIN_ARRAY 0x008
#define WJB_END_ARRAY 0x010
#define WJB_BEGIN_OBJECT 0x020
#define WJB_END_OBJECT 0x040
/*
* When using a GIN index for jsonb, we choose to index both keys and values.
* The storage format is text, with K, or V prepended to the string to indicate
* key/element or value/element.
*
* Jsonb Keys and string array elements are treated equivalently when
* serialized to text index storage. One day we may wish to create an opclass
* that only indexes values, but for now keys and values are stored in GIN
* indexes in a way that doesn't really consider their relationship to each
* other.
*/
#define JKEYELEM 'K'
#define JVAL 'V'
#define JsonbContainsStrategyNumber 7
#define JsonbExistsStrategyNumber 9
#define JsonbExistsAnyStrategyNumber 10
#define JsonbExistsAllStrategyNumber 11
/* Convenience macros */
#define DatumGetJsonb(d) ((Jsonb *) PG_DETOAST_DATUM(d))
#define JsonbGetDatum(p) PointerGetDatum(p)
#define PG_GETARG_JSONB(x) DatumGetJsonb(PG_GETARG_DATUM(x))
#define PG_RETURN_JSONB(x) PG_RETURN_POINTER(x)
typedef struct JsonbPair JsonbPair;
typedef struct JsonbValue JsonbValue;
typedef char* JsonbSuperHeader;
/*
* Jsonbs are varlena objects, so must meet the varlena convention that the
* first int32 of the object contains the total object size in bytes. Be sure
* to use VARSIZE() and SET_VARSIZE() to access it, though!
*
* Jsonb is the on-disk representation, in contrast to the in-memory JsonbValue
* representation. Often, JsonbValues are just shims through which a Jsonb
* buffer is accessed, but they can also be deep copied and passed around.
*
* We have an abstraction called a "superheader". This is a pointer that
* conventionally points to the first item after our 4-byte uncompressed
* varlena header, from which we can read flags using bitwise operations.
*
* Frequently, we pass a superheader reference to a function, and it doesn't
* matter if it points to just after the start of a Jsonb, or to a temp buffer.
*/
typedef struct
{
int32 vl_len_; /* varlena header (do not touch directly!) */
uint32 superheader;
/* (array of JEntry follows, size determined using uint32 superheader) */
} Jsonb;
/*
* JEntry: there is one of these for each key _and_ value for objects. Arrays
* have one per element.
*
* The position offset points to the _end_ so that we can get the length by
* subtraction from the previous entry. The JENTRY_ISFIRST flag indicates if
* there is a previous entry.
*/
typedef struct
{
uint32 header; /* Shares some flags with superheader */
} JEntry;
#define IsAJsonbScalar(jsonbval) ((jsonbval)->type >= jbvNull && \
(jsonbval)->type <= jbvBool)
/*
* JsonbValue: In-memory representation of Jsonb. This is a convenient
* deserialized representation, that can easily support using the anonymous
* union across underlying types during manipulation. The Jsonb on-disk
* representation has various alignment considerations.
*/
struct JsonbValue
{
enum
{
/* Scalar types */
jbvNull = 0x0,
jbvString,
jbvNumeric,
jbvBool,
/* Composite types */
jbvArray = 0x10,
jbvObject,
/* Binary (i.e. struct Jsonb) jbvArray/jbvObject */
jbvBinary
} type; /* Influences sort order */
int estSize; /* Estimated size of node (including
* subnodes) */
union
{
Numeric numeric;
bool boolean;
struct
{
int len;
char *val; /* Not necessarily null-terminated */
} string; /* String primitive type */
struct
{
int nElems;
JsonbValue *elems;
bool rawScalar; /* Top-level "raw scalar" array? */
} array; /* Array container type */
struct
{
int nPairs; /* 1 pair, 2 elements */
JsonbPair *pairs;
} object; /* Associative container type */
struct
{
int len;
char *data;
} binary;
};
};
/*
* Pair within an Object.
*
* Pairs with duplicate keys are de-duplicated. We store the order for the
* benefit of doing so in a well-defined way with respect to the original
* observed order (which is "last observed wins"). This is only used briefly
* when originally constructing a Jsonb.
*/
struct JsonbPair
{
JsonbValue key; /* Must be a jbvString */
JsonbValue value; /* May be of any type */
uint32 order; /* preserves order of pairs with equal keys */
};
/* Conversion state used when parsing Jsonb from text, or for type coercion */
typedef struct JsonbParseState
{
JsonbValue contVal;
Size size;
struct JsonbParseState *next;
} JsonbParseState;
/*
* JsonbIterator holds details of the type for each iteration. It also stores a
* Jsonb varlena buffer, which can be directly accessed in some contexts.
*/
typedef enum
{
jbi_start = 0x0,
jbi_key,
jbi_value,
jbi_elem
} JsonbIterState;
typedef struct JsonbIterator
{
/* Jsonb varlena buffer (may or may not be root) */
char *buffer;
/* Current value */
uint32 containerType; /* Never of value JB_FSCALAR, since
* scalars will appear in pseudo-arrays */
uint32 nElems; /* Number of elements in metaArray
* (will be nPairs for objects) */
bool isScalar; /* Pseudo-array scalar value? */
JEntry *meta;
/* Current item in buffer (up to nElems, but must * 2 for objects) */
int i;
/*
* Data proper. Note that this points just past end of "meta" array. We
* use its metadata (Jentrys) with JBE_OFF() macro to find appropriate
* offsets into this array.
*/
char *dataProper;
/* Private state */
JsonbIterState state;
struct JsonbIterator *parent;
} JsonbIterator;
/* I/O routines */
extern Datum jsonb_in(PG_FUNCTION_ARGS);
extern Datum jsonb_out(PG_FUNCTION_ARGS);
extern Datum jsonb_recv(PG_FUNCTION_ARGS);
extern Datum jsonb_send(PG_FUNCTION_ARGS);
extern Datum jsonb_typeof(PG_FUNCTION_ARGS);
/* Indexing-related ops */
extern Datum jsonb_exists(PG_FUNCTION_ARGS);
extern Datum jsonb_exists_any(PG_FUNCTION_ARGS);
extern Datum jsonb_exists_all(PG_FUNCTION_ARGS);
extern Datum jsonb_contains(PG_FUNCTION_ARGS);
extern Datum jsonb_contained(PG_FUNCTION_ARGS);
extern Datum jsonb_ne(PG_FUNCTION_ARGS);
extern Datum jsonb_lt(PG_FUNCTION_ARGS);
extern Datum jsonb_gt(PG_FUNCTION_ARGS);
extern Datum jsonb_le(PG_FUNCTION_ARGS);
extern Datum jsonb_ge(PG_FUNCTION_ARGS);
extern Datum jsonb_eq(PG_FUNCTION_ARGS);
extern Datum jsonb_cmp(PG_FUNCTION_ARGS);
extern Datum jsonb_hash(PG_FUNCTION_ARGS);
/* GIN support functions */
extern Datum gin_compare_jsonb(PG_FUNCTION_ARGS);
extern Datum gin_extract_jsonb(PG_FUNCTION_ARGS);
extern Datum gin_extract_jsonb_query(PG_FUNCTION_ARGS);
extern Datum gin_consistent_jsonb(PG_FUNCTION_ARGS);
extern Datum gin_triconsistent_jsonb(PG_FUNCTION_ARGS);
/* GIN hash opclass functions */
extern Datum gin_extract_jsonb_hash(PG_FUNCTION_ARGS);
extern Datum gin_extract_jsonb_query_hash(PG_FUNCTION_ARGS);
extern Datum gin_consistent_jsonb_hash(PG_FUNCTION_ARGS);
extern Datum gin_triconsistent_jsonb_hash(PG_FUNCTION_ARGS);
/* Support functions */
extern int compareJsonbSuperHeaderValue(JsonbSuperHeader a,
JsonbSuperHeader b);
extern JsonbValue *findJsonbValueFromSuperHeader(JsonbSuperHeader sheader,
uint32 flags,
uint32 *lowbound,
JsonbValue *key);
extern JsonbValue *getIthJsonbValueFromSuperHeader(JsonbSuperHeader sheader,
uint32 i);
extern JsonbValue *pushJsonbValue(JsonbParseState ** pstate, int seq,
JsonbValue *scalarVal);
extern JsonbIterator *JsonbIteratorInit(JsonbSuperHeader buffer);
extern int JsonbIteratorNext(JsonbIterator **it, JsonbValue *val,
bool skipNested);
extern Jsonb *JsonbValueToJsonb(JsonbValue *val);
extern bool JsonbDeepContains(JsonbIterator ** val,
JsonbIterator ** mContained);
extern JsonbValue *arrayToJsonbSortedArray(ArrayType *a);
extern void JsonbHashScalarValue(const JsonbValue * scalarVal, uint32 * hash);
/* jsonb.c support function */
extern char *JsonbToCString(StringInfo out, JsonbSuperHeader in,
int estimated_len);
#endif /* __JSONB_H__ */

View File

@ -58,5 +58,6 @@ typedef struct NumericData *Numeric;
extern bool numeric_is_nan(Numeric num);
int32 numeric_maximum_size(int32 typmod);
extern char *numeric_out_sci(Numeric num, int scale);
extern char *numeric_normalize(Numeric num);
#endif /* _PG_NUMERIC_H_ */

File diff suppressed because it is too large Load Diff

View File

@ -464,8 +464,8 @@ CREATE TEMP TABLE test_json (
);
INSERT INTO test_json VALUES
('scalar','"a scalar"'),
('array','["zero", "one","two",null,"four","five"]'),
('object','{"field1":"val1","field2":"val2","field3":null}');
('array','["zero", "one","two",null,"four","five", [1,2,3],{"f1":9}]'),
('object','{"field1":"val1","field2":"val2","field3":null, "field4": 4, "field5": [1,2,3], "field6": {"f1":9}}');
SELECT test_json -> 'x'
FROM test_json
WHERE json_type = 'scalar';
@ -522,6 +522,36 @@ WHERE json_type = 'array';
two
(1 row)
SELECT test_json ->> 6 FROM test_json WHERE json_type = 'array';
?column?
----------
[1,2,3]
(1 row)
SELECT test_json ->> 7 FROM test_json WHERE json_type = 'array';
?column?
----------
{"f1":9}
(1 row)
SELECT test_json ->> 'field4' FROM test_json WHERE json_type = 'object';
?column?
----------
4
(1 row)
SELECT test_json ->> 'field5' FROM test_json WHERE json_type = 'object';
?column?
----------
[1,2,3]
(1 row)
SELECT test_json ->> 'field6' FROM test_json WHERE json_type = 'object';
?column?
----------
{"f1":9}
(1 row)
SELECT json_object_keys(test_json)
FROM test_json
WHERE json_type = 'scalar';
@ -538,7 +568,20 @@ WHERE json_type = 'object';
field1
field2
field3
(3 rows)
field4
field5
field6
(6 rows)
-- test extending object_keys resultset - initial resultset size is 256
select count(*) from
(select json_object_keys(json_object(array_agg(g)))
from (select unnest(array['f'||n,n::text])as g
from generate_series(1,300) as n) x ) y;
count
-------
300
(1 row)
-- nulls
select (test_json->'field3') is null as expect_false

View File

@ -464,8 +464,8 @@ CREATE TEMP TABLE test_json (
);
INSERT INTO test_json VALUES
('scalar','"a scalar"'),
('array','["zero", "one","two",null,"four","five"]'),
('object','{"field1":"val1","field2":"val2","field3":null}');
('array','["zero", "one","two",null,"four","five", [1,2,3],{"f1":9}]'),
('object','{"field1":"val1","field2":"val2","field3":null, "field4": 4, "field5": [1,2,3], "field6": {"f1":9}}');
SELECT test_json -> 'x'
FROM test_json
WHERE json_type = 'scalar';
@ -522,6 +522,36 @@ WHERE json_type = 'array';
two
(1 row)
SELECT test_json ->> 6 FROM test_json WHERE json_type = 'array';
?column?
----------
[1,2,3]
(1 row)
SELECT test_json ->> 7 FROM test_json WHERE json_type = 'array';
?column?
----------
{"f1":9}
(1 row)
SELECT test_json ->> 'field4' FROM test_json WHERE json_type = 'object';
?column?
----------
4
(1 row)
SELECT test_json ->> 'field5' FROM test_json WHERE json_type = 'object';
?column?
----------
[1,2,3]
(1 row)
SELECT test_json ->> 'field6' FROM test_json WHERE json_type = 'object';
?column?
----------
{"f1":9}
(1 row)
SELECT json_object_keys(test_json)
FROM test_json
WHERE json_type = 'scalar';
@ -538,7 +568,20 @@ WHERE json_type = 'object';
field1
field2
field3
(3 rows)
field4
field5
field6
(6 rows)
-- test extending object_keys resultset - initial resultset size is 256
select count(*) from
(select json_object_keys(json_object(array_agg(g)))
from (select unnest(array['f'||n,n::text])as g
from generate_series(1,300) as n) x ) y;
count
-------
300
(1 row)
-- nulls
select (test_json->'field3') is null as expect_false

File diff suppressed because it is too large Load Diff

File diff suppressed because it is too large Load Diff

View File

@ -1127,6 +1127,10 @@ ORDER BY 1, 2, 3;
2742 | 2 | @@@
2742 | 3 | <@
2742 | 4 | =
2742 | 7 | @>
2742 | 9 | ?
2742 | 10 | ?|
2742 | 11 | ?&
4000 | 1 | <<
4000 | 1 | ~<~
4000 | 2 | &<
@ -1149,7 +1153,7 @@ ORDER BY 1, 2, 3;
4000 | 15 | >
4000 | 16 | @>
4000 | 18 | =
(67 rows)
(71 rows)
-- Check that all opclass search operators have selectivity estimators.
-- This is not absolutely required, but it seems a reasonable thing

View File

@ -98,8 +98,7 @@ test: event_trigger
# ----------
# Another group of parallel tests
# ----------
test: select_views portals_p2 foreign_key cluster dependency guc bitmapops combocid tsearch tsdicts foreign_data window xmlmap functional_deps advisory_lock json indirect_toast
test: select_views portals_p2 foreign_key cluster dependency guc bitmapops combocid tsearch tsdicts foreign_data window xmlmap functional_deps advisory_lock json jsonb indirect_toast
# ----------
# Another group of parallel tests
# NB: temp.sql does a reconnect which transiently uses 2 connections,

View File

@ -122,6 +122,7 @@ test: xmlmap
test: functional_deps
test: advisory_lock
test: json
test: jsonb
test: indirect_toast
test: plancache
test: limit

View File

@ -136,8 +136,8 @@ CREATE TEMP TABLE test_json (
INSERT INTO test_json VALUES
('scalar','"a scalar"'),
('array','["zero", "one","two",null,"four","five"]'),
('object','{"field1":"val1","field2":"val2","field3":null}');
('array','["zero", "one","two",null,"four","five", [1,2,3],{"f1":9}]'),
('object','{"field1":"val1","field2":"val2","field3":null, "field4": 4, "field5": [1,2,3], "field6": {"f1":9}}');
SELECT test_json -> 'x'
FROM test_json
@ -175,6 +175,13 @@ SELECT test_json->>2
FROM test_json
WHERE json_type = 'array';
SELECT test_json ->> 6 FROM test_json WHERE json_type = 'array';
SELECT test_json ->> 7 FROM test_json WHERE json_type = 'array';
SELECT test_json ->> 'field4' FROM test_json WHERE json_type = 'object';
SELECT test_json ->> 'field5' FROM test_json WHERE json_type = 'object';
SELECT test_json ->> 'field6' FROM test_json WHERE json_type = 'object';
SELECT json_object_keys(test_json)
FROM test_json
WHERE json_type = 'scalar';
@ -187,6 +194,13 @@ SELECT json_object_keys(test_json)
FROM test_json
WHERE json_type = 'object';
-- test extending object_keys resultset - initial resultset size is 256
select count(*) from
(select json_object_keys(json_object(array_agg(g)))
from (select unnest(array['f'||n,n::text])as g
from generate_series(1,300) as n) x ) y;
-- nulls
select (test_json->'field3') is null as expect_false

View File

@ -0,0 +1,479 @@
-- Strings.
SELECT '""'::jsonb; -- OK.
SELECT $$''$$::jsonb; -- ERROR, single quotes are not allowed
SELECT '"abc"'::jsonb; -- OK
SELECT '"abc'::jsonb; -- ERROR, quotes not closed
SELECT '"abc
def"'::jsonb; -- ERROR, unescaped newline in string constant
SELECT '"\n\"\\"'::jsonb; -- OK, legal escapes
SELECT '"\v"'::jsonb; -- ERROR, not a valid JSON escape
SELECT '"\u"'::jsonb; -- ERROR, incomplete escape
SELECT '"\u00"'::jsonb; -- ERROR, incomplete escape
SELECT '"\u000g"'::jsonb; -- ERROR, g is not a hex digit
SELECT '"\u0000"'::jsonb; -- OK, legal escape
-- use octet_length here so we don't get an odd unicode char in the
-- output
SELECT octet_length('"\uaBcD"'::jsonb::text); -- OK, uppercase and lower case both OK
-- Numbers.
SELECT '1'::jsonb; -- OK
SELECT '0'::jsonb; -- OK
SELECT '01'::jsonb; -- ERROR, not valid according to JSON spec
SELECT '0.1'::jsonb; -- OK
SELECT '9223372036854775808'::jsonb; -- OK, even though it's too large for int8
SELECT '1e100'::jsonb; -- OK
SELECT '1.3e100'::jsonb; -- OK
SELECT '1f2'::jsonb; -- ERROR
SELECT '0.x1'::jsonb; -- ERROR
SELECT '1.3ex100'::jsonb; -- ERROR
-- Arrays.
SELECT '[]'::jsonb; -- OK
SELECT '[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[[]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]]'::jsonb; -- OK
SELECT '[1,2]'::jsonb; -- OK
SELECT '[1,2,]'::jsonb; -- ERROR, trailing comma
SELECT '[1,2'::jsonb; -- ERROR, no closing bracket
SELECT '[1,[2]'::jsonb; -- ERROR, no closing bracket
-- Objects.
SELECT '{}'::jsonb; -- OK
SELECT '{"abc"}'::jsonb; -- ERROR, no value
SELECT '{"abc":1}'::jsonb; -- OK
SELECT '{1:"abc"}'::jsonb; -- ERROR, keys must be strings
SELECT '{"abc",1}'::jsonb; -- ERROR, wrong separator
SELECT '{"abc"=1}'::jsonb; -- ERROR, totally wrong separator
SELECT '{"abc"::1}'::jsonb; -- ERROR, another wrong separator
SELECT '{"abc":1,"def":2,"ghi":[3,4],"hij":{"klm":5,"nop":[6]}}'::jsonb; -- OK
SELECT '{"abc":1:2}'::jsonb; -- ERROR, colon in wrong spot
SELECT '{"abc":1,3}'::jsonb; -- ERROR, no value
-- Miscellaneous stuff.
SELECT 'true'::jsonb; -- OK
SELECT 'false'::jsonb; -- OK
SELECT 'null'::jsonb; -- OK
SELECT ' true '::jsonb; -- OK, even with extra whitespace
SELECT 'true false'::jsonb; -- ERROR, too many values
SELECT 'true, false'::jsonb; -- ERROR, too many values
SELECT 'truf'::jsonb; -- ERROR, not a keyword
SELECT 'trues'::jsonb; -- ERROR, not a keyword
SELECT ''::jsonb; -- ERROR, no value
SELECT ' '::jsonb; -- ERROR, no value
-- make sure jsonb is passed through json generators without being escaped
SELECT array_to_json(ARRAY [jsonb '{"a":1}', jsonb '{"b":[2,3]}']);
-- jsonb extraction functions
CREATE TEMP TABLE test_jsonb (
json_type text,
test_json jsonb
);
INSERT INTO test_jsonb VALUES
('scalar','"a scalar"'),
('array','["zero", "one","two",null,"four","five", [1,2,3],{"f1":9}]'),
('object','{"field1":"val1","field2":"val2","field3":null, "field4": 4, "field5": [1,2,3], "field6": {"f1":9}}');
SELECT test_json -> 'x' FROM test_jsonb WHERE json_type = 'scalar';
SELECT test_json -> 'x' FROM test_jsonb WHERE json_type = 'array';
SELECT test_json -> 'x' FROM test_jsonb WHERE json_type = 'object';
SELECT test_json -> 'field2' FROM test_jsonb WHERE json_type = 'object';
SELECT test_json ->> 'field2' FROM test_jsonb WHERE json_type = 'scalar';
SELECT test_json ->> 'field2' FROM test_jsonb WHERE json_type = 'array';
SELECT test_json ->> 'field2' FROM test_jsonb WHERE json_type = 'object';
SELECT test_json -> 2 FROM test_jsonb WHERE json_type = 'scalar';
SELECT test_json -> 2 FROM test_jsonb WHERE json_type = 'array';
SELECT test_json -> 9 FROM test_jsonb WHERE json_type = 'array';
SELECT test_json -> 2 FROM test_jsonb WHERE json_type = 'object';
SELECT test_json ->> 6 FROM test_jsonb WHERE json_type = 'array';
SELECT test_json ->> 7 FROM test_jsonb WHERE json_type = 'array';
SELECT test_json ->> 'field4' FROM test_jsonb WHERE json_type = 'object';
SELECT test_json ->> 'field5' FROM test_jsonb WHERE json_type = 'object';
SELECT test_json ->> 'field6' FROM test_jsonb WHERE json_type = 'object';
SELECT test_json ->> 2 FROM test_jsonb WHERE json_type = 'scalar';
SELECT test_json ->> 2 FROM test_jsonb WHERE json_type = 'array';
SELECT test_json ->> 2 FROM test_jsonb WHERE json_type = 'object';
SELECT jsonb_object_keys(test_json) FROM test_jsonb WHERE json_type = 'scalar';
SELECT jsonb_object_keys(test_json) FROM test_jsonb WHERE json_type = 'array';
SELECT jsonb_object_keys(test_json) FROM test_jsonb WHERE json_type = 'object';
-- nulls
SELECT (test_json->'field3') IS NULL AS expect_false FROM test_jsonb WHERE json_type = 'object';
SELECT (test_json->>'field3') IS NULL AS expect_true FROM test_jsonb WHERE json_type = 'object';
SELECT (test_json->3) IS NULL AS expect_false FROM test_jsonb WHERE json_type = 'array';
SELECT (test_json->>3) IS NULL AS expect_true FROM test_jsonb WHERE json_type = 'array';
-- equality and inequality
SELECT '{"x":"y"}'::jsonb = '{"x":"y"}'::jsonb;
SELECT '{"x":"y"}'::jsonb = '{"x":"z"}'::jsonb;
SELECT '{"x":"y"}'::jsonb <> '{"x":"y"}'::jsonb;
SELECT '{"x":"y"}'::jsonb <> '{"x":"z"}'::jsonb;
CREATE TABLE testjsonb (j jsonb);
\copy testjsonb FROM 'data/jsonb.data'
-- containment
SELECT jsonb_contains('{"a":"b", "b":1, "c":null}', '{"a":"b"}');
SELECT jsonb_contains('{"a":"b", "b":1, "c":null}', '{"a":"b", "c":null}');
SELECT jsonb_contains('{"a":"b", "b":1, "c":null}', '{"a":"b", "g":null}');
SELECT jsonb_contains('{"a":"b", "b":1, "c":null}', '{"g":null}');
SELECT jsonb_contains('{"a":"b", "b":1, "c":null}', '{"a":"c"}');
SELECT jsonb_contains('{"a":"b", "b":1, "c":null}', '{"a":"b"}');
SELECT jsonb_contains('{"a":"b", "b":1, "c":null}', '{"a":"b", "c":"q"}');
SELECT '{"a":"b", "b":1, "c":null}'::jsonb @> '{"a":"b"}';
SELECT '{"a":"b", "b":1, "c":null}'::jsonb @> '{"a":"b", "c":null}';
SELECT '{"a":"b", "b":1, "c":null}'::jsonb @> '{"a":"b", "g":null}';
SELECT '{"a":"b", "b":1, "c":null}'::jsonb @> '{"g":null}';
SELECT '{"a":"b", "b":1, "c":null}'::jsonb @> '{"a":"c"}';
SELECT '{"a":"b", "b":1, "c":null}'::jsonb @> '{"a":"b"}';
SELECT '{"a":"b", "b":1, "c":null}'::jsonb @> '{"a":"b", "c":"q"}';
SELECT jsonb_contained('{"a":"b"}', '{"a":"b", "b":1, "c":null}');
SELECT jsonb_contained('{"a":"b", "c":null}', '{"a":"b", "b":1, "c":null}');
SELECT jsonb_contained('{"a":"b", "g":null}', '{"a":"b", "b":1, "c":null}');
SELECT jsonb_contained('{"g":null}', '{"a":"b", "b":1, "c":null}');
SELECT jsonb_contained('{"a":"c"}', '{"a":"b", "b":1, "c":null}');
SELECT jsonb_contained('{"a":"b"}', '{"a":"b", "b":1, "c":null}');
SELECT jsonb_contained('{"a":"b", "c":"q"}', '{"a":"b", "b":1, "c":null}');
SELECT '{"a":"b"}'::jsonb <@ '{"a":"b", "b":1, "c":null}';
SELECT '{"a":"b", "c":null}'::jsonb <@ '{"a":"b", "b":1, "c":null}';
SELECT '{"a":"b", "g":null}'::jsonb <@ '{"a":"b", "b":1, "c":null}';
SELECT '{"g":null}'::jsonb <@ '{"a":"b", "b":1, "c":null}';
SELECT '{"a":"c"}'::jsonb <@ '{"a":"b", "b":1, "c":null}';
SELECT '{"a":"b"}'::jsonb <@ '{"a":"b", "b":1, "c":null}';
SELECT '{"a":"b", "c":"q"}'::jsonb <@ '{"a":"b", "b":1, "c":null}';
-- Raw scalar may contain another raw scalar, array may contain a raw scalar
SELECT '[5]'::jsonb @> '[5]';
SELECT '5'::jsonb @> '5';
SELECT '[5]'::jsonb @> '5';
-- But a raw scalar cannot contain an array
SELECT '5'::jsonb @> '[5]';
-- In general, one thing should always contain itself. Test array containment:
SELECT '["9", ["7", "3"], 1]'::jsonb @> '["9", ["7", "3"], 1]'::jsonb;
SELECT '["9", ["7", "3"], ["1"]]'::jsonb @> '["9", ["7", "3"], ["1"]]'::jsonb;
-- array containment string matching confusion bug
SELECT '{ "name": "Bob", "tags": [ "enim", "qui"]}'::jsonb @> '{"tags":["qu"]}';
-- array length
SELECT jsonb_array_length('[1,2,3,{"f1":1,"f2":[5,6]},4]');
SELECT jsonb_array_length('[]');
SELECT jsonb_array_length('{"f1":1,"f2":[5,6]}');
SELECT jsonb_array_length('4');
-- each
SELECT jsonb_each('{"f1":[1,2,3],"f2":{"f3":1},"f4":null}');
SELECT jsonb_each('{"a":{"b":"c","c":"b","1":"first"},"b":[1,2],"c":"cc","1":"first","n":null}'::jsonb) AS q;
SELECT * FROM jsonb_each('{"f1":[1,2,3],"f2":{"f3":1},"f4":null,"f5":99,"f6":"stringy"}') q;
SELECT * FROM jsonb_each('{"a":{"b":"c","c":"b","1":"first"},"b":[1,2],"c":"cc","1":"first","n":null}'::jsonb) AS q;
SELECT jsonb_each_text('{"f1":[1,2,3],"f2":{"f3":1},"f4":null,"f5":"null"}');
SELECT jsonb_each_text('{"a":{"b":"c","c":"b","1":"first"},"b":[1,2],"c":"cc","1":"first","n":null}'::jsonb) AS q;
SELECT * FROM jsonb_each_text('{"f1":[1,2,3],"f2":{"f3":1},"f4":null,"f5":99,"f6":"stringy"}') q;
SELECT * FROM jsonb_each_text('{"a":{"b":"c","c":"b","1":"first"},"b":[1,2],"c":"cc","1":"first","n":null}'::jsonb) AS q;
-- exists
SELECT jsonb_exists('{"a":null, "b":"qq"}', 'a');
SELECT jsonb_exists('{"a":null, "b":"qq"}', 'b');
SELECT jsonb_exists('{"a":null, "b":"qq"}', 'c');
SELECT jsonb_exists('{"a":"null", "b":"qq"}', 'a');
SELECT jsonb '{"a":null, "b":"qq"}' ? 'a';
SELECT jsonb '{"a":null, "b":"qq"}' ? 'b';
SELECT jsonb '{"a":null, "b":"qq"}' ? 'c';
SELECT jsonb '{"a":"null", "b":"qq"}' ? 'a';
-- array exists - array elements should behave as keys
SELECT count(*) from testjsonb WHERE j->'array' ? 'bar';
-- type sensitive array exists - should return no rows (since "exists" only
-- matches strings that are either object keys or array elements)
SELECT count(*) from testjsonb WHERE j->'array' ? '5'::text;
-- However, a raw scalar is *contained* within the array
SELECT count(*) from testjsonb WHERE j->'array' @> '5'::jsonb;
SELECT jsonb_exists_any('{"a":null, "b":"qq"}', ARRAY['a','b']);
SELECT jsonb_exists_any('{"a":null, "b":"qq"}', ARRAY['b','a']);
SELECT jsonb_exists_any('{"a":null, "b":"qq"}', ARRAY['c','a']);
SELECT jsonb_exists_any('{"a":null, "b":"qq"}', ARRAY['c','d']);
SELECT jsonb_exists_any('{"a":null, "b":"qq"}', '{}'::text[]);
SELECT jsonb '{"a":null, "b":"qq"}' ?| ARRAY['a','b'];
SELECT jsonb '{"a":null, "b":"qq"}' ?| ARRAY['b','a'];
SELECT jsonb '{"a":null, "b":"qq"}' ?| ARRAY['c','a'];
SELECT jsonb '{"a":null, "b":"qq"}' ?| ARRAY['c','d'];
SELECT jsonb '{"a":null, "b":"qq"}' ?| '{}'::text[];
SELECT jsonb_exists_all('{"a":null, "b":"qq"}', ARRAY['a','b']);
SELECT jsonb_exists_all('{"a":null, "b":"qq"}', ARRAY['b','a']);
SELECT jsonb_exists_all('{"a":null, "b":"qq"}', ARRAY['c','a']);
SELECT jsonb_exists_all('{"a":null, "b":"qq"}', ARRAY['c','d']);
SELECT jsonb_exists_all('{"a":null, "b":"qq"}', '{}'::text[]);
SELECT jsonb '{"a":null, "b":"qq"}' ?& ARRAY['a','b'];
SELECT jsonb '{"a":null, "b":"qq"}' ?& ARRAY['b','a'];
SELECT jsonb '{"a":null, "b":"qq"}' ?& ARRAY['c','a'];
SELECT jsonb '{"a":null, "b":"qq"}' ?& ARRAY['c','d'];
SELECT jsonb '{"a":null, "b":"qq"}' ?& ARRAY['a','a', 'b', 'b', 'b'];
SELECT jsonb '{"a":null, "b":"qq"}' ?& '{}'::text[];
-- typeof
SELECT jsonb_typeof('{}') AS object;
SELECT jsonb_typeof('{"c":3,"p":"o"}') AS object;
SELECT jsonb_typeof('[]') AS array;
SELECT jsonb_typeof('["a", 1]') AS array;
SELECT jsonb_typeof('null') AS "null";
SELECT jsonb_typeof('1') AS number;
SELECT jsonb_typeof('-1') AS number;
SELECT jsonb_typeof('1.0') AS number;
SELECT jsonb_typeof('1e2') AS number;
SELECT jsonb_typeof('-1.0') AS number;
SELECT jsonb_typeof('true') AS boolean;
SELECT jsonb_typeof('false') AS boolean;
SELECT jsonb_typeof('"hello"') AS string;
SELECT jsonb_typeof('"true"') AS string;
SELECT jsonb_typeof('"1.0"') AS string;
-- 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"}}','f2');
SELECT jsonb_extract_path('{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}','f2',0::text);
SELECT jsonb_extract_path('{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}','f2',1::text);
SELECT jsonb_extract_path_text('{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}','f4','f6');
SELECT jsonb_extract_path_text('{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}','f2');
SELECT jsonb_extract_path_text('{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}','f2',0::text);
SELECT jsonb_extract_path_text('{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}','f2',1::text);
-- extract_path nulls
SELECT jsonb_extract_path('{"f2":{"f3":1},"f4":{"f5":null,"f6":"stringy"}}','f4','f5') IS NULL AS expect_false;
SELECT jsonb_extract_path_text('{"f2":{"f3":1},"f4":{"f5":null,"f6":"stringy"}}','f4','f5') IS NULL AS expect_true;
SELECT jsonb_extract_path('{"f2":{"f3":1},"f4":[0,1,2,null]}','f4','3') IS NULL AS expect_false;
SELECT jsonb_extract_path_text('{"f2":{"f3":1},"f4":[0,1,2,null]}','f4','3') IS NULL AS expect_true;
-- extract_path operators
SELECT '{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}'::jsonb#>array['f4','f6'];
SELECT '{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}'::jsonb#>array['f2'];
SELECT '{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}'::jsonb#>array['f2','0'];
SELECT '{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}'::jsonb#>array['f2','1'];
SELECT '{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}'::jsonb#>>array['f4','f6'];
SELECT '{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}'::jsonb#>>array['f2'];
SELECT '{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}'::jsonb#>>array['f2','0'];
SELECT '{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}'::jsonb#>>array['f2','1'];
-- same using array literals
SELECT '{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}'::jsonb#>'{f4,f6}';
SELECT '{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}'::jsonb#>'{f2}';
SELECT '{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}'::jsonb#>'{f2,0}';
SELECT '{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}'::jsonb#>'{f2,1}';
SELECT '{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}'::jsonb#>>'{f4,f6}';
SELECT '{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}'::jsonb#>>'{f2}';
SELECT '{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}'::jsonb#>>'{f2,0}';
SELECT '{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}'::jsonb#>>'{f2,1}';
-- same on jsonb scalars (expecting errors)
SELECT '42'::jsonb#>array['f2'];
SELECT '42'::jsonb#>array['0'];
SELECT '42'::jsonb#>>array['f2'];
SELECT '42'::jsonb#>>array['0'];
-- array_elements
SELECT jsonb_array_elements('[1,true,[1,[2,3]],null,{"f1":1,"f2":[7,8,9]},false]');
SELECT * FROM jsonb_array_elements('[1,true,[1,[2,3]],null,{"f1":1,"f2":[7,8,9]},false]') q;
SELECT jsonb_array_elements_text('[1,true,[1,[2,3]],null,{"f1":1,"f2":[7,8,9]},false,"stringy"]');
SELECT * FROM jsonb_array_elements_text('[1,true,[1,[2,3]],null,{"f1":1,"f2":[7,8,9]},false,"stringy"]') q;
-- populate_record
CREATE TYPE jbpop AS (a text, b int, c timestamp);
SELECT * FROM jsonb_populate_record(NULL::jbpop,'{"a":"blurfl","x":43.2}') q;
SELECT * FROM jsonb_populate_record(row('x',3,'2012-12-31 15:30:56')::jbpop,'{"a":"blurfl","x":43.2}') q;
SELECT * FROM jsonb_populate_record(NULL::jbpop,'{"a":"blurfl","x":43.2}', true) q;
SELECT * FROM jsonb_populate_record(row('x',3,'2012-12-31 15:30:56')::jbpop,'{"a":"blurfl","x":43.2}', true) q;
SELECT * FROM jsonb_populate_record(NULL::jbpop,'{"a":[100,200,false],"x":43.2}', true) q;
SELECT * FROM jsonb_populate_record(row('x',3,'2012-12-31 15:30:56')::jbpop,'{"a":[100,200,false],"x":43.2}', true) q;
SELECT * FROM jsonb_populate_record(row('x',3,'2012-12-31 15:30:56')::jbpop,'{"c":[100,200,false],"x":43.2}', true) q;
-- populate_recordset
SELECT * FROM jsonb_populate_recordset(NULL::jbpop,'[{"a":"blurfl","x":43.2},{"b":3,"c":"2012-01-20 10:42:53"}]',false) q;
SELECT * FROM jsonb_populate_recordset(row('def',99,NULL)::jbpop,'[{"a":"blurfl","x":43.2},{"b":3,"c":"2012-01-20 10:42:53"}]',false) q;
SELECT * FROM jsonb_populate_recordset(NULL::jbpop,'[{"a":"blurfl","x":43.2},{"b":3,"c":"2012-01-20 10:42:53"}]',true) q;
SELECT * FROM jsonb_populate_recordset(row('def',99,NULL)::jbpop,'[{"a":"blurfl","x":43.2},{"b":3,"c":"2012-01-20 10:42:53"}]',true) q;
SELECT * FROM jsonb_populate_recordset(row('def',99,NULL)::jbpop,'[{"a":[100,200,300],"x":43.2},{"a":{"z":true},"b":3,"c":"2012-01-20 10:42:53"}]',true) q;
SELECT * FROM jsonb_populate_recordset(row('def',99,NULL)::jbpop,'[{"c":[100,200,300],"x":43.2},{"a":{"z":true},"b":3,"c":"2012-01-20 10:42:53"}]',true) q;
-- using the default use_json_as_text argument
SELECT * FROM jsonb_populate_recordset(NULL::jbpop,'[{"a":"blurfl","x":43.2},{"b":3,"c":"2012-01-20 10:42:53"}]') q;
SELECT * FROM jsonb_populate_recordset(row('def',99,NULL)::jbpop,'[{"a":"blurfl","x":43.2},{"b":3,"c":"2012-01-20 10:42:53"}]') q;
SELECT * FROM jsonb_populate_recordset(row('def',99,NULL)::jbpop,'[{"a":[100,200,300],"x":43.2},{"a":{"z":true},"b":3,"c":"2012-01-20 10:42:53"}]') q;
SELECT * FROM jsonb_populate_recordset(row('def',99,NULL)::jbpop,'[{"c":[100,200,300],"x":43.2},{"a":{"z":true},"b":3,"c":"2012-01-20 10:42:53"}]') q;
-- handling of unicode surrogate pairs
SELECT octet_length((jsonb '{ "a": "\ud83d\ude04\ud83d\udc36" }' -> 'a')::text) AS correct_in_utf8;
SELECT jsonb '{ "a": "\ud83d\ud83d" }' -> 'a'; -- 2 high surrogates in a row
SELECT jsonb '{ "a": "\ude04\ud83d" }' -> 'a'; -- surrogates in wrong order
SELECT jsonb '{ "a": "\ud83dX" }' -> 'a'; -- orphan high surrogate
SELECT jsonb '{ "a": "\ude04X" }' -> 'a'; -- orphan low surrogate
-- handling of simple unicode escapes
SELECT jsonb '{ "a": "the Copyright \u00a9 sign" }' ->> 'a' AS correct_in_utf8;
SELECT jsonb '{ "a": "dollar \u0024 character" }' ->> 'a' AS correct_everyWHERE;
SELECT jsonb '{ "a": "null \u0000 escape" }' ->> 'a' AS not_unescaped;
-- indexing
SELECT count(*) FROM testjsonb WHERE j @> '{"wait":null}';
SELECT count(*) FROM testjsonb WHERE j @> '{"wait":"CC"}';
SELECT count(*) FROM testjsonb WHERE j @> '{"wait":"CC", "public":true}';
SELECT count(*) FROM testjsonb WHERE j @> '{"age":25}';
SELECT count(*) FROM testjsonb WHERE j @> '{"age":25.0}';
SELECT count(*) FROM testjsonb WHERE j ? 'public';
SELECT count(*) FROM testjsonb WHERE j ?| ARRAY['public','disabled'];
SELECT count(*) FROM testjsonb WHERE j ?& ARRAY['public','disabled'];
CREATE INDEX jidx ON testjsonb USING gin (j);
SET enable_seqscan = off;
SELECT count(*) FROM testjsonb WHERE j @> '{"wait":null}';
SELECT count(*) FROM testjsonb WHERE j @> '{"wait":"CC"}';
SELECT count(*) FROM testjsonb WHERE j @> '{"wait":"CC", "public":true}';
SELECT count(*) FROM testjsonb WHERE j @> '{"age":25}';
SELECT count(*) FROM testjsonb WHERE j @> '{"age":25.0}';
SELECT count(*) FROM testjsonb WHERE j @> '{"array":["foo"]}';
SELECT count(*) FROM testjsonb WHERE j @> '{"array":["bar"]}';
-- excercise GIN_SEARCH_MODE_ALL
SELECT count(*) FROM testjsonb WHERE j @> '{}';
SELECT count(*) FROM testjsonb WHERE j ? 'public';
SELECT count(*) FROM testjsonb WHERE j ?| ARRAY['public','disabled'];
SELECT count(*) FROM testjsonb WHERE j ?& ARRAY['public','disabled'];
-- array exists - array elements should behave as keys (for GIN index scans too)
CREATE INDEX jidx_array ON testjsonb USING gin((j->'array'));
SELECT count(*) from testjsonb WHERE j->'array' ? 'bar';
-- type sensitive array exists - should return no rows (since "exists" only
-- matches strings that are either object keys or array elements)
SELECT count(*) from testjsonb WHERE j->'array' ? '5'::text;
-- However, a raw scalar is *contained* within the array
SELECT count(*) from testjsonb WHERE j->'array' @> '5'::jsonb;
RESET enable_seqscan;
SELECT count(*) FROM (SELECT (jsonb_each(j)).key FROM testjsonb) AS wow;
SELECT key, count(*) FROM (SELECT (jsonb_each(j)).key FROM testjsonb) AS wow GROUP BY key ORDER BY count DESC, key;
-- sort/hash
SELECT count(distinct j) FROM testjsonb;
SET enable_hashagg = off;
SELECT count(*) FROM (SELECT j FROM (SELECT * FROM testjsonb UNION ALL SELECT * FROM testjsonb) js GROUP BY j) js2;
SET enable_hashagg = on;
SET enable_sort = off;
SELECT count(*) FROM (SELECT j FROM (SELECT * FROM testjsonb UNION ALL SELECT * FROM testjsonb) js GROUP BY j) js2;
SELECT distinct * FROM (values (jsonb '{}' || ''),('{}')) v(j);
SET enable_sort = on;
RESET enable_hashagg;
RESET enable_sort;
DROP INDEX jidx;
DROP INDEX jidx_array;
-- btree
CREATE INDEX jidx ON testjsonb USING btree (j);
SET enable_seqscan = off;
SELECT count(*) FROM testjsonb WHERE j > '{"p":1}';
SELECT count(*) FROM testjsonb WHERE j = '{"pos":98, "line":371, "node":"CBA", "indexed":true}';
--gin hash
DROP INDEX jidx;
CREATE INDEX jidx ON testjsonb USING gin (j jsonb_hash_ops);
SET enable_seqscan = off;
SELECT count(*) FROM testjsonb WHERE j @> '{"wait":null}';
SELECT count(*) FROM testjsonb WHERE j @> '{"wait":"CC"}';
SELECT count(*) FROM testjsonb WHERE j @> '{"wait":"CC", "public":true}';
SELECT count(*) FROM testjsonb WHERE j @> '{"age":25}';
SELECT count(*) FROM testjsonb WHERE j @> '{"age":25.0}';
-- excercise GIN_SEARCH_MODE_ALL
SELECT count(*) FROM testjsonb WHERE j @> '{}';
RESET enable_seqscan;
DROP INDEX jidx;
-- nested tests
SELECT '{"ff":{"a":12,"b":16}}'::jsonb;
SELECT '{"ff":{"a":12,"b":16},"qq":123}'::jsonb;
SELECT '{"aa":["a","aaa"],"qq":{"a":12,"b":16,"c":["c1","c2"],"d":{"d1":"d1","d2":"d2","d1":"d3"}}}'::jsonb;
SELECT '{"aa":["a","aaa"],"qq":{"a":"12","b":"16","c":["c1","c2"],"d":{"d1":"d1","d2":"d2"}}}'::jsonb;
SELECT '{"aa":["a","aaa"],"qq":{"a":"12","b":"16","c":["c1","c2",["c3"],{"c4":4}],"d":{"d1":"d1","d2":"d2"}}}'::jsonb;
SELECT '{"ff":["a","aaa"]}'::jsonb;
SELECT
'{"ff":{"a":12,"b":16},"qq":123,"x":[1,2],"Y":null}'::jsonb -> 'ff',
'{"ff":{"a":12,"b":16},"qq":123,"x":[1,2],"Y":null}'::jsonb -> 'qq',
('{"ff":{"a":12,"b":16},"qq":123,"x":[1,2],"Y":null}'::jsonb -> 'Y') IS NULL AS f,
('{"ff":{"a":12,"b":16},"qq":123,"x":[1,2],"Y":null}'::jsonb ->> 'Y') IS NULL AS t,
'{"ff":{"a":12,"b":16},"qq":123,"x":[1,2],"Y":null}'::jsonb -> 'x';
-- nested containment
SELECT '{"a":[1,2],"c":"b"}'::jsonb @> '{"a":[1,2]}';
SELECT '{"a":[2,1],"c":"b"}'::jsonb @> '{"a":[1,2]}';
SELECT '{"a":{"1":2},"c":"b"}'::jsonb @> '{"a":[1,2]}';
SELECT '{"a":{"2":1},"c":"b"}'::jsonb @> '{"a":[1,2]}';
SELECT '{"a":{"1":2},"c":"b"}'::jsonb @> '{"a":{"1":2}}';
SELECT '{"a":{"2":1},"c":"b"}'::jsonb @> '{"a":{"1":2}}';
SELECT '["a","b"]'::jsonb @> '["a","b","c","b"]';
SELECT '["a","b","c","b"]'::jsonb @> '["a","b"]';
SELECT '["a","b","c",[1,2]]'::jsonb @> '["a",[1,2]]';
SELECT '["a","b","c",[1,2]]'::jsonb @> '["b",[1,2]]';
SELECT '{"a":[1,2],"c":"b"}'::jsonb @> '{"a":[1]}';
SELECT '{"a":[1,2],"c":"b"}'::jsonb @> '{"a":[2]}';
SELECT '{"a":[1,2],"c":"b"}'::jsonb @> '{"a":[3]}';
SELECT '{"a":[1,2,{"c":3,"x":4}],"c":"b"}'::jsonb @> '{"a":[{"c":3}]}';
SELECT '{"a":[1,2,{"c":3,"x":4}],"c":"b"}'::jsonb @> '{"a":[{"x":4}]}';
SELECT '{"a":[1,2,{"c":3,"x":4}],"c":"b"}'::jsonb @> '{"a":[{"x":4},3]}';
SELECT '{"a":[1,2,{"c":3,"x":4}],"c":"b"}'::jsonb @> '{"a":[{"x":4},1]}';
-- nested object field / array index lookup
SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb -> 'n';
SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb -> 'a';
SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb -> 'b';
SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb -> 'c';
SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb -> 'd';
SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb -> 'd' -> '1';
SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb -> 'e';
SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb -> 0; --expecting error
SELECT '["a","b","c",[1,2],null]'::jsonb -> 0;
SELECT '["a","b","c",[1,2],null]'::jsonb -> 1;
SELECT '["a","b","c",[1,2],null]'::jsonb -> 2;
SELECT '["a","b","c",[1,2],null]'::jsonb -> 3;
SELECT '["a","b","c",[1,2],null]'::jsonb -> 3 -> 1;
SELECT '["a","b","c",[1,2],null]'::jsonb -> 4;
SELECT '["a","b","c",[1,2],null]'::jsonb -> 5;
SELECT '["a","b","c",[1,2],null]'::jsonb -> -1;
--nested path extraction
SELECT '{"a":"b","c":[1,2,3]}'::jsonb #> '{0}';
SELECT '{"a":"b","c":[1,2,3]}'::jsonb #> '{a}';
SELECT '{"a":"b","c":[1,2,3]}'::jsonb #> '{c}';
SELECT '{"a":"b","c":[1,2,3]}'::jsonb #> '{c,0}';
SELECT '{"a":"b","c":[1,2,3]}'::jsonb #> '{c,1}';
SELECT '{"a":"b","c":[1,2,3]}'::jsonb #> '{c,2}';
SELECT '{"a":"b","c":[1,2,3]}'::jsonb #> '{c,3}';
SELECT '{"a":"b","c":[1,2,3]}'::jsonb #> '{c,-1}';
SELECT '[0,1,2,[3,4],{"5":"five"}]'::jsonb #> '{0}';
SELECT '[0,1,2,[3,4],{"5":"five"}]'::jsonb #> '{3}';
SELECT '[0,1,2,[3,4],{"5":"five"}]'::jsonb #> '{4}';
SELECT '[0,1,2,[3,4],{"5":"five"}]'::jsonb #> '{4,5}';
--nested exists
SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb ? 'n';
SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb ? 'a';
SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb ? 'b';
SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb ? 'c';
SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb ? 'd';
SELECT '{"n":null,"a":1,"b":[1,2],"c":{"1":2},"d":{"1":[2,3]}}'::jsonb ? 'e';