Add new JSON processing functions and parser API.

The JSON parser is converted into a recursive descent parser, and
exposed for use by other modules such as extensions. The API provides
hooks for all the significant parser event such as the beginning and end
of objects and arrays, and providing functions to handle these hooks
allows for fairly simple construction of a wide variety of JSON
processing functions. A set of new basic processing functions and
operators is also added, which use this API, including operations to
extract array elements, object fields, get the length of arrays and the
set of keys of a field, deconstruct an object into a set of key/value
pairs, and create records from JSON objects and arrays of objects.

Catalog version bumped.

Andrew Dunstan, with some documentation assistance from Merlin Moncure.
This commit is contained in:
Andrew Dunstan 2013-03-29 14:12:13 -04:00
parent 9ad27c2153
commit a570c98d7f
12 changed files with 3580 additions and 311 deletions

View File

@ -9846,17 +9846,75 @@ table2-mapping
<secondary>Functions and operators</secondary>
</indexterm>
<para>
<xref linkend="functions-json-op-table"> shows the operators that are
available for use with JSON (see <xref linkend="datatype-json">) data.
</para>
<table id="functions-json-op-table">
<title>JSON 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>-&gt;</literal></entry>
<entry>int</entry>
<entry>Get JSON array element</entry>
<entry><literal>'[1,2,3]'::json-&gt;2</literal></entry>
</row>
<row>
<entry><literal>-&gt;</literal></entry>
<entry>text</entry>
<entry>Get JSON object field</entry>
<entry><literal>'{"a":1,"b":2}'::json-&gt;'b'</literal></entry>
</row>
<row>
<entry><literal>-&gt;&gt;</literal></entry>
<entry>int</entry>
<entry>Get JSON array element as text</entry>
<entry><literal>'[1,2,3]'::json-&gt;&gt;2</literal></entry>
</row>
<row>
<entry><literal>-&gt;&gt;</literal></entry>
<entry>text</entry>
<entry>Get JSON object field as text</entry>
<entry><literal>'{"a":1,"b":2}'::json-&gt;&gt;'b'</literal></entry>
</row>
<row>
<entry><literal>#&gt;</literal></entry>
<entry>array of 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>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>
</tbody>
</tgroup>
</table>
<para>
<xref linkend="functions-json-table"> shows the functions that are available
for creating JSON (see <xref linkend="datatype-json">) data.
for creating and manipulating JSON (see <xref linkend="datatype-json">) data.
</para>
<table id="functions-json-table">
<title>JSON Support Functions</title>
<tgroup cols="4">
<tgroup cols="5">
<thead>
<row>
<entry>Function</entry>
<entry>Return Type</entry>
<entry>Description</entry>
<entry>Example</entry>
<entry>Example Result</entry>
@ -9870,6 +9928,7 @@ table2-mapping
</indexterm>
<literal>array_to_json(anyarray [, pretty_bool])</literal>
</entry>
<entry>json</entry>
<entry>
Returns the array as JSON. A PostgreSQL multidimensional array
becomes a JSON array of arrays. Line feeds will be added between
@ -9885,6 +9944,7 @@ table2-mapping
</indexterm>
<literal>row_to_json(record [, pretty_bool])</literal>
</entry>
<entry>json</entry>
<entry>
Returns the row as JSON. Line feeds will be added between level
1 elements if <parameter>pretty_bool</parameter> is true.
@ -9899,6 +9959,7 @@ table2-mapping
</indexterm>
<literal>to_json(anyelement)</literal>
</entry>
<entry>json</entry>
<entry>
Returns the value as JSON. If the data type is not builtin, and there
is a cast from the type to json, the cast function will be used to
@ -9909,6 +9970,182 @@ table2-mapping
<entry><literal>to_json('Fred said "Hi."'</literal></entry>
<entry><literal>"Fred said \"Hi.\""</literal></entry>
</row>
<row>
<entry>
<indexterm>
<primary>json_array_length</primary>
</indexterm>
<literal>json_array_length(json)</literal>
</entry>
<entry>int</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>SETOF key text, value json</entry>
<entry>
Expands the outermost json object into a set of key/value pairs.
</entry>
<entry><literal>select * from json_each_as_text('{"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>SETOF key text, value text</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_as_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>json</entry>
<entry>
Returns json object 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>text</entry>
<entry>
Returns json object 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>SETOF text</entry>
<entry>
Returns set of keys in the json object. Only the "outer" 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>anyelement</entry>
<entry>
Expands the object in from_json 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 from_json
will be left null. A column may only be specified once.
</entry>
<entry><literal>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>SETOF anyelement</entry>
<entry>
Expands the outermost set of objects in from_json 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 from_json will be left null. A column
may only be specified once.
</entry>
<entry><literal>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>SETOF json</entry>
<entry>
Expands a json array to a set of json elements.
</entry>
<entry><literal>json_array_elements('[1,true, [2,false]]')</literal></entry>
<entry>
<programlisting>
value
-----------
1
true
[2,false]
</programlisting>
</entry>
</row>
</tbody>
</tgroup>
</table>
@ -9926,7 +10163,6 @@ table2-mapping
function <function>json_agg</function> which aggregates record
values as json efficiently.
</para>
</sect1>
<sect1 id="functions-sequence">

View File

@ -787,3 +787,11 @@ COMMENT ON FUNCTION ts_debug(text) IS
CREATE OR REPLACE FUNCTION
pg_start_backup(label text, fast boolean DEFAULT false)
RETURNS text STRICT VOLATILE LANGUAGE internal AS 'pg_start_backup';
CREATE OR REPLACE FUNCTION
json_populate_record(base anyelement, from_json json, use_json_as_text boolean DEFAULT false)
RETURNS anyelement LANGUAGE internal STABLE AS 'json_populate_record';
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';

View File

@ -19,8 +19,8 @@ OBJS = acl.o arrayfuncs.o array_selfuncs.o array_typanalyze.o \
array_userfuncs.o arrayutils.o bool.o \
cash.o char.o date.o datetime.o datum.o domains.o \
enum.o float.o format_type.o \
geo_ops.o geo_selfuncs.o int.o int8.o json.o like.o lockfuncs.o \
misc.o nabstime.o name.o numeric.o numutils.o \
geo_ops.o geo_selfuncs.o int.o int8.o json.o jsonfuncs.o like.o \
lockfuncs.o misc.o nabstime.o name.o numeric.o numutils.o \
oid.o oracle_compat.o pseudotypes.o rangetypes.o rangetypes_gist.o \
rowtypes.o regexp.o regproc.o ruleutils.o selfuncs.o \
tid.o timestamp.o varbit.o varchar.o varlena.o version.o xid.o \

File diff suppressed because it is too large Load Diff

File diff suppressed because it is too large Load Diff

View File

@ -53,6 +53,6 @@
*/
/* yyyymmddN */
#define CATALOG_VERSION_NO 201303271
#define CATALOG_VERSION_NO 201303291
#endif

View File

@ -1724,6 +1724,19 @@ DATA(insert OID = 3899 ( "-" PGNSP PGUID b f f 3831 3831 3831 0 0 range_minu
DESCR("range difference");
DATA(insert OID = 3900 ( "*" PGNSP PGUID b f f 3831 3831 3831 3900 0 range_intersect - - ));
DESCR("range intersection");
DATA(insert OID = 3962 ( "->" PGNSP PGUID b f f 114 25 114 0 0 json_object_field - - ));
DESCR("get json object field");
DATA(insert OID = 3963 ( "->>" PGNSP PGUID b f f 114 25 25 0 0 json_object_field_text - - ));
DESCR("get json object field as text");
DATA(insert OID = 3964 ( "->" PGNSP PGUID b f f 114 23 114 0 0 json_array_element - - ));
DESCR("get json array element");
DATA(insert OID = 3965 ( "->>" PGNSP PGUID b f f 114 23 25 0 0 json_array_element_text - - ));
DESCR("get json array element as text");
DATA(insert OID = 3966 ( "#>" PGNSP PGUID b f f 114 1009 114 0 0 json_extract_path_op - - ));
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");
/*

View File

@ -4118,6 +4118,37 @@ DESCR("aggregate input into json");
DATA(insert OID = 3176 ( to_json PGNSP PGUID 12 1 0 0 0 f f f f t f s 1 0 114 "2283" _null_ _null_ _null_ _null_ to_json _null_ _null_ _null_ ));
DESCR("map input to json");
DATA(insert OID = 3947 ( json_object_field PGNSP PGUID 12 1 0 0 0 f f f f t f s 2 0 114 "114 25" _null_ _null_ "{from_json, field_name}" _null_ json_object_field _null_ _null_ _null_ ));
DESCR("get json object field");
DATA(insert OID = 3948 ( json_object_field_text PGNSP PGUID 12 1 0 0 0 f f f f t f s 2 0 25 "114 25" _null_ _null_ "{from_json, field_name}" _null_ json_object_field_text _null_ _null_ _null_ ));
DESCR("get json object field as text");
DATA(insert OID = 3949 ( json_array_element PGNSP PGUID 12 1 0 0 0 f f f f t f s 2 0 114 "114 23" _null_ _null_ "{from_json, element_index}" _null_ json_array_element _null_ _null_ _null_ ));
DESCR("get json array element");
DATA(insert OID = 3950 ( json_array_element_text PGNSP PGUID 12 1 0 0 0 f f f f t f s 2 0 25 "114 23" _null_ _null_ "{from_json, element_index}" _null_ json_array_element_text _null_ _null_ _null_ ));
DESCR("get json array element as text");
DATA(insert OID = 3951 ( json_extract_path PGNSP PGUID 12 1 0 25 0 f f f f t f s 2 0 114 "114 1009" "{114,1009}" "{i,v}" "{from_json,path_elems}" _null_ json_extract_path _null_ _null_ _null_ ));
DESCR("get value from json with path elements");
DATA(insert OID = 3952 ( json_extract_path_op PGNSP PGUID 12 1 0 0 0 f f f f t f s 2 0 114 "114 1009" _null_ _null_ "{from_json,path_elems}" _null_ json_extract_path _null_ _null_ _null_ ));
DESCR("get value from json with path elements");
DATA(insert OID = 3953 ( json_extract_path_text PGNSP PGUID 12 1 0 25 0 f f f f t f s 2 0 25 "114 1009" "{114,1009}" "{i,v}" "{from_json,path_elems}" _null_ json_extract_path_text _null_ _null_ _null_ ));
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 s 2 0 25 "114 1009" _null_ _null_ "{from_json,path_elems}" _null_ json_extract_path_text _null_ _null_ _null_ ));
DESCR("get value from json as text with path elements");
DATA(insert OID = 3955 ( json_array_elements PGNSP PGUID 12 1 100 0 0 f f f f t t s 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 = 3956 ( json_array_length PGNSP PGUID 12 1 0 0 0 f f f f t f s 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 s 1 0 25 "114" _null_ _null_ _null_ _null_ json_object_keys _null_ _null_ _null_ ));
DESCR("get json object keys");
DATA(insert OID = 3958 ( json_each PGNSP PGUID 12 1 100 0 0 f f f f t t s 1 0 2249 "114" "{114,25,114}" "{i,o,o}" "{from_json,key,value}" _null_ json_each _null_ _null_ _null_ ));
DESCR("key value pairs of a json object");
DATA(insert OID = 3959 ( json_each_text PGNSP PGUID 12 1 100 0 0 f f f f t t s 1 0 2249 "114" "{114,25,25}" "{i,o,o}" "{from_json,key,value}" _null_ json_each_text _null_ _null_ _null_ ));
DESCR("key value pairs of a json object");
DATA(insert OID = 3960 ( json_populate_record PGNSP PGUID 12 1 0 0 0 f f f f f f s 3 0 2283 "2283 114 16" _null_ _null_ _null_ _null_ json_populate_record _null_ _null_ _null_ ));
DESCR("get record fields from a json object");
DATA(insert OID = 3961 ( json_populate_recordset PGNSP PGUID 12 1 100 0 0 f f f f f t s 3 0 2283 "2283 114 16" _null_ _null_ _null_ _null_ json_populate_recordset _null_ _null_ _null_ ));
DESCR("get set of records with fields from a json array of objects");
/* 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_ ));
DESCR("I/O");

View File

@ -17,6 +17,7 @@
#include "fmgr.h"
#include "lib/stringinfo.h"
/* functions in json.c */
extern Datum json_in(PG_FUNCTION_ARGS);
extern Datum json_out(PG_FUNCTION_ARGS);
extern Datum json_recv(PG_FUNCTION_ARGS);
@ -32,4 +33,19 @@ extern Datum json_agg_finalfn(PG_FUNCTION_ARGS);
extern void escape_json(StringInfo buf, const char *str);
/* functions in jsonfuncs.c */
extern Datum json_object_field(PG_FUNCTION_ARGS);
extern Datum json_object_field_text(PG_FUNCTION_ARGS);
extern Datum json_array_element(PG_FUNCTION_ARGS);
extern Datum json_array_element_text(PG_FUNCTION_ARGS);
extern Datum json_extract_path(PG_FUNCTION_ARGS);
extern Datum json_extract_path_text(PG_FUNCTION_ARGS);
extern Datum json_object_keys(PG_FUNCTION_ARGS);
extern Datum json_array_length(PG_FUNCTION_ARGS);
extern Datum json_each(PG_FUNCTION_ARGS);
extern Datum json_each_text(PG_FUNCTION_ARGS);
extern Datum json_array_elements(PG_FUNCTION_ARGS);
extern Datum json_populate_record(PG_FUNCTION_ARGS);
extern Datum json_populate_recordset(PG_FUNCTION_ARGS);
#endif /* JSON_H */

110
src/include/utils/jsonapi.h Normal file
View File

@ -0,0 +1,110 @@
/*-------------------------------------------------------------------------
*
* jsonapi.h
* Declarations for JSON API support.
*
* Portions Copyright (c) 1996-2013, PostgreSQL Global Development Group
* Portions Copyright (c) 1994, Regents of the University of California
*
* src/include/utils/jsonapi.h
*
*-------------------------------------------------------------------------
*/
#ifndef JSONAPI_H
#define JSONAPI_H
#include "lib/stringinfo.h"
typedef enum
{
JSON_TOKEN_INVALID,
JSON_TOKEN_STRING,
JSON_TOKEN_NUMBER,
JSON_TOKEN_OBJECT_START,
JSON_TOKEN_OBJECT_END,
JSON_TOKEN_ARRAY_START,
JSON_TOKEN_ARRAY_END,
JSON_TOKEN_COMMA,
JSON_TOKEN_COLON,
JSON_TOKEN_TRUE,
JSON_TOKEN_FALSE,
JSON_TOKEN_NULL,
JSON_TOKEN_END,
} JsonTokenType;
/*
* All the fields in this structure should be treated as read-only.
*
* If strval is not null, then it should contain the de-escaped value
* of the lexeme if it's a string. Otherwise most of these field names
* should be self-explanatory.
*
* line_number and line_start are principally for use by the parser's
* error reporting routines.
* token_terminator and prev_token_terminator point to the character
* AFTER the end of the token, i.e. where there would be a nul byte
* if we were using nul-terminated strings.
*/
typedef struct JsonLexContext
{
char *input;
int input_length;
char *token_start;
char *token_terminator;
char *prev_token_terminator;
JsonTokenType token_type;
int lex_level;
int line_number;
char *line_start;
StringInfo strval;
} JsonLexContext;
typedef void (*json_struct_action) (void *state);
typedef void (*json_ofield_action) (void *state, char *fname, bool isnull);
typedef void (*json_aelem_action) (void *state, bool isnull);
typedef void (*json_scalar_action) (void *state, char *token, JsonTokenType tokentype);
/*
* Semantic Action structure for use in parsing json.
* Any of these actions can be NULL, in which case nothing is done at that
* point, Likewise, semstate can be NULL. Using an all-NULL structure amounts
* to doing a pure parse with no side-effects, and is therefore exactly
* what the json input routines do.
*/
typedef struct jsonSemAction
{
void *semstate;
json_struct_action object_start;
json_struct_action object_end;
json_struct_action array_start;
json_struct_action array_end;
json_ofield_action object_field_start;
json_ofield_action object_field_end;
json_aelem_action array_element_start;
json_aelem_action array_element_end;
json_scalar_action scalar;
} jsonSemAction, *JsonSemAction;
/*
* parse_json will parse the string in the lex calling the
* action functions in sem at the appropriate points. It is
* up to them to keep what state they need in semstate. If they
* need access to the state of the lexer, then its pointer
* should be passed to them as a member of whatever semstate
* points to. If the action pointers are NULL the parser
* does nothing and just continues.
*/
extern void pg_parse_json(JsonLexContext *lex, JsonSemAction sem);
/*
* constructor 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.
*/
extern JsonLexContext *makeJsonLexContext(text *json, bool need_escapes);
#endif /* JSONAPI_H */

View File

@ -457,3 +457,466 @@ FROM (SELECT '{"a":1,"b": [2,3,4,"d","e","f"],"c":{"p":1,"q":2}}'::json AS "json
{"jsonfield":{"a":1,"b": [2,3,4,"d","e","f"],"c":{"p":1,"q":2}}}
(1 row)
-- json extraction functions
CREATE TEMP TABLE test_json (
json_type text,
test_json json
);
INSERT INTO test_json VALUES
('scalar','"a scalar"'),
('array','["zero", "one","two",null,"four","five"]'),
('object','{"field1":"val1","field2":"val2","field3":null}');
SELECT test_json -> 'x'
FROM test_json
WHERE json_type = 'scalar';
ERROR: cannot extract element from a scalar
SELECT test_json -> 'x'
FROM test_json
WHERE json_type = 'array';
ERROR: cannot extract field from a non-object
SELECT test_json -> 'x'
FROM test_json
WHERE json_type = 'object';
?column?
----------
(1 row)
SELECT test_json->'field2'
FROM test_json
WHERE json_type = 'object';
?column?
----------
"val2"
(1 row)
SELECT test_json->>'field2'
FROM test_json
WHERE json_type = 'object';
?column?
----------
val2
(1 row)
SELECT test_json -> 2
FROM test_json
WHERE json_type = 'scalar';
ERROR: cannot extract element from a scalar
SELECT test_json -> 2
FROM test_json
WHERE json_type = 'array';
?column?
----------
"two"
(1 row)
SELECT test_json -> 2
FROM test_json
WHERE json_type = 'object';
ERROR: cannot extract array element from a non-array
SELECT test_json->>2
FROM test_json
WHERE json_type = 'array';
?column?
----------
two
(1 row)
SELECT json_object_keys(test_json)
FROM test_json
WHERE json_type = 'scalar';
ERROR: cannot call json_object_keys on a scalar
SELECT json_object_keys(test_json)
FROM test_json
WHERE json_type = 'array';
ERROR: cannot call json_object_keys on an array
SELECT json_object_keys(test_json)
FROM test_json
WHERE json_type = 'object';
json_object_keys
------------------
field1
field2
field3
(3 rows)
-- nulls
select (test_json->'field3') is null as expect_false
from test_json
where json_type = 'object';
expect_false
--------------
f
(1 row)
select (test_json->>'field3') is null as expect_true
from test_json
where json_type = 'object';
expect_true
-------------
t
(1 row)
select (test_json->3) is null as expect_false
from test_json
where json_type = 'array';
expect_false
--------------
f
(1 row)
select (test_json->>3) is null as expect_true
from test_json
where json_type = 'array';
expect_true
-------------
t
(1 row)
-- array length
SELECT json_array_length('[1,2,3,{"f1":1,"f2":[5,6]},4]');
json_array_length
-------------------
5
(1 row)
SELECT json_array_length('[]');
json_array_length
-------------------
0
(1 row)
SELECT json_array_length('{"f1":1,"f2":[5,6]}');
ERROR: cannot get array length of a non-array
SELECT json_array_length('4');
ERROR: cannot get array length of a scalar
-- each
select json_each('{"f1":[1,2,3],"f2":{"f3":1},"f4":null}');
json_each
-------------------
(f1,"[1,2,3]")
(f2,"{""f3"":1}")
(f4,null)
(3 rows)
select * from json_each('{"f1":[1,2,3],"f2":{"f3":1},"f4":null,"f5":99,"f6":"stringy"}') q;
key | value
-----+-----------
f1 | [1,2,3]
f2 | {"f3":1}
f4 | null
f5 | 99
f6 | "stringy"
(5 rows)
select json_each_text('{"f1":[1,2,3],"f2":{"f3":1},"f4":null,"f5":"null"}');
json_each_text
-------------------
(f1,"[1,2,3]")
(f2,"{""f3"":1}")
(f4,)
(f5,null)
(4 rows)
select * from json_each_text('{"f1":[1,2,3],"f2":{"f3":1},"f4":null,"f5":99,"f6":"stringy"}') q;
key | value
-----+----------
f1 | [1,2,3]
f2 | {"f3":1}
f4 |
f5 | 99
f6 | stringy
(5 rows)
-- extract_path, extract_path_as_text
select json_extract_path('{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}','f4','f6');
json_extract_path
-------------------
"stringy"
(1 row)
select json_extract_path('{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}','f2');
json_extract_path
-------------------
{"f3":1}
(1 row)
select json_extract_path('{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}','f2',0::text);
json_extract_path
-------------------
"f3"
(1 row)
select json_extract_path('{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}','f2',1::text);
json_extract_path
-------------------
1
(1 row)
select json_extract_path_text('{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}','f4','f6');
json_extract_path_text
------------------------
stringy
(1 row)
select json_extract_path_text('{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}','f2');
json_extract_path_text
------------------------
{"f3":1}
(1 row)
select json_extract_path_text('{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}','f2',0::text);
json_extract_path_text
------------------------
f3
(1 row)
select json_extract_path_text('{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}','f2',1::text);
json_extract_path_text
------------------------
1
(1 row)
-- extract_path nulls
select json_extract_path('{"f2":{"f3":1},"f4":{"f5":null,"f6":"stringy"}}','f4','f5') is null as expect_false;
expect_false
--------------
f
(1 row)
select json_extract_path_text('{"f2":{"f3":1},"f4":{"f5":null,"f6":"stringy"}}','f4','f5') is null as expect_true;
expect_true
-------------
t
(1 row)
select json_extract_path('{"f2":{"f3":1},"f4":[0,1,2,null]}','f4','3') is null as expect_false;
expect_false
--------------
f
(1 row)
select json_extract_path_text('{"f2":{"f3":1},"f4":[0,1,2,null]}','f4','3') is null as expect_true;
expect_true
-------------
t
(1 row)
-- extract_path operators
select '{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}'::json#>array['f4','f6'];
?column?
-----------
"stringy"
(1 row)
select '{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}'::json#>array['f2'];
?column?
----------
{"f3":1}
(1 row)
select '{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}'::json#>array['f2','0'];
?column?
----------
"f3"
(1 row)
select '{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}'::json#>array['f2','1'];
?column?
----------
1
(1 row)
select '{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}'::json#>>array['f4','f6'];
?column?
----------
stringy
(1 row)
select '{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}'::json#>>array['f2'];
?column?
----------
{"f3":1}
(1 row)
select '{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}'::json#>>array['f2','0'];
?column?
----------
f3
(1 row)
select '{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}'::json#>>array['f2','1'];
?column?
----------
1
(1 row)
-- same using array literals
select '{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}'::json#>'{f4,f6}';
?column?
-----------
"stringy"
(1 row)
select '{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}'::json#>'{f2}';
?column?
----------
{"f3":1}
(1 row)
select '{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}'::json#>'{f2,0}';
?column?
----------
"f3"
(1 row)
select '{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}'::json#>'{f2,1}';
?column?
----------
1
(1 row)
select '{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}'::json#>>'{f4,f6}';
?column?
----------
stringy
(1 row)
select '{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}'::json#>>'{f2}';
?column?
----------
{"f3":1}
(1 row)
select '{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}'::json#>>'{f2,0}';
?column?
----------
f3
(1 row)
select '{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}'::json#>>'{f2,1}';
?column?
----------
1
(1 row)
-- array_elements
select json_array_elements('[1,true,[1,[2,3]],null,{"f1":1,"f2":[7,8,9]},false]');
json_array_elements
-----------------------
1
true
[1,[2,3]]
null
{"f1":1,"f2":[7,8,9]}
false
(6 rows)
select * from json_array_elements('[1,true,[1,[2,3]],null,{"f1":1,"f2":[7,8,9]},false]') q;
value
-----------------------
1
true
[1,[2,3]]
null
{"f1":1,"f2":[7,8,9]}
false
(6 rows)
-- populate_record
create type jpop as (a text, b int, c timestamp);
select * from json_populate_record(null::jpop,'{"a":"blurfl","x":43.2}') q;
a | b | c
--------+---+---
blurfl | |
(1 row)
select * from json_populate_record(row('x',3,'2012-12-31 15:30:56')::jpop,'{"a":"blurfl","x":43.2}') q;
a | b | c
--------+---+--------------------------
blurfl | 3 | Mon Dec 31 15:30:56 2012
(1 row)
select * from json_populate_record(null::jpop,'{"a":"blurfl","x":43.2}', true) q;
a | b | c
--------+---+---
blurfl | |
(1 row)
select * from json_populate_record(row('x',3,'2012-12-31 15:30:56')::jpop,'{"a":"blurfl","x":43.2}', true) q;
a | b | c
--------+---+--------------------------
blurfl | 3 | Mon Dec 31 15:30:56 2012
(1 row)
select * from json_populate_record(null::jpop,'{"a":[100,200,false],"x":43.2}', true) q;
a | b | c
-----------------+---+---
[100,200,false] | |
(1 row)
select * from json_populate_record(row('x',3,'2012-12-31 15:30:56')::jpop,'{"a":[100,200,false],"x":43.2}', true) q;
a | b | c
-----------------+---+--------------------------
[100,200,false] | 3 | Mon Dec 31 15:30:56 2012
(1 row)
select * from json_populate_record(row('x',3,'2012-12-31 15:30:56')::jpop,'{"c":[100,200,false],"x":43.2}', true) q;
ERROR: invalid input syntax for type timestamp: "[100,200,false]"
-- populate_recordset
select * from json_populate_recordset(null::jpop,'[{"a":"blurfl","x":43.2},{"b":3,"c":"2012-01-20 10:42:53"}]',false) q;
a | b | c
--------+---+--------------------------
blurfl | |
| 3 | Fri Jan 20 10:42:53 2012
(2 rows)
select * from json_populate_recordset(row('def',99,null)::jpop,'[{"a":"blurfl","x":43.2},{"b":3,"c":"2012-01-20 10:42:53"}]',false) q;
a | b | c
--------+----+--------------------------
blurfl | 99 |
def | 3 | Fri Jan 20 10:42:53 2012
(2 rows)
select * from json_populate_recordset(null::jpop,'[{"a":"blurfl","x":43.2},{"b":3,"c":"2012-01-20 10:42:53"}]',true) q;
a | b | c
--------+---+--------------------------
blurfl | |
| 3 | Fri Jan 20 10:42:53 2012
(2 rows)
select * from json_populate_recordset(row('def',99,null)::jpop,'[{"a":"blurfl","x":43.2},{"b":3,"c":"2012-01-20 10:42:53"}]',true) q;
a | b | c
--------+----+--------------------------
blurfl | 99 |
def | 3 | Fri Jan 20 10:42:53 2012
(2 rows)
select * from json_populate_recordset(row('def',99,null)::jpop,'[{"a":[100,200,300],"x":43.2},{"a":{"z":true},"b":3,"c":"2012-01-20 10:42:53"}]',true) q;
a | b | c
---------------+----+--------------------------
[100,200,300] | 99 |
{"z":true} | 3 | Fri Jan 20 10:42:53 2012
(2 rows)
select * from json_populate_recordset(row('def',99,null)::jpop,'[{"c":[100,200,300],"x":43.2},{"a":{"z":true},"b":3,"c":"2012-01-20 10:42:53"}]',true) q;
ERROR: invalid input syntax for type timestamp: "[100,200,300]"
-- using the default use_json_as_text argument
select * from json_populate_recordset(null::jpop,'[{"a":"blurfl","x":43.2},{"b":3,"c":"2012-01-20 10:42:53"}]') q;
a | b | c
--------+---+--------------------------
blurfl | |
| 3 | Fri Jan 20 10:42:53 2012
(2 rows)
select * from json_populate_recordset(row('def',99,null)::jpop,'[{"a":"blurfl","x":43.2},{"b":3,"c":"2012-01-20 10:42:53"}]') q;
a | b | c
--------+----+--------------------------
blurfl | 99 |
def | 3 | Fri Jan 20 10:42:53 2012
(2 rows)
select * from json_populate_recordset(row('def',99,null)::jpop,'[{"a":[100,200,300],"x":43.2},{"a":{"z":true},"b":3,"c":"2012-01-20 10:42:53"}]') q;
ERROR: cannot call json_populate_recordset on a nested object
select * from json_populate_recordset(row('def',99,null)::jpop,'[{"c":[100,200,300],"x":43.2},{"a":{"z":true},"b":3,"c":"2012-01-20 10:42:53"}]') q;
ERROR: cannot call json_populate_recordset on a nested object

View File

@ -125,3 +125,174 @@ FROM (SELECT '-Infinity'::float8 AS "float8field") q;
-- json input
SELECT row_to_json(q)
FROM (SELECT '{"a":1,"b": [2,3,4,"d","e","f"],"c":{"p":1,"q":2}}'::json AS "jsonfield") q;
-- json extraction functions
CREATE TEMP TABLE test_json (
json_type text,
test_json json
);
INSERT INTO test_json VALUES
('scalar','"a scalar"'),
('array','["zero", "one","two",null,"four","five"]'),
('object','{"field1":"val1","field2":"val2","field3":null}');
SELECT test_json -> 'x'
FROM test_json
WHERE json_type = 'scalar';
SELECT test_json -> 'x'
FROM test_json
WHERE json_type = 'array';
SELECT test_json -> 'x'
FROM test_json
WHERE json_type = 'object';
SELECT test_json->'field2'
FROM test_json
WHERE json_type = 'object';
SELECT test_json->>'field2'
FROM test_json
WHERE json_type = 'object';
SELECT test_json -> 2
FROM test_json
WHERE json_type = 'scalar';
SELECT test_json -> 2
FROM test_json
WHERE json_type = 'array';
SELECT test_json -> 2
FROM test_json
WHERE json_type = 'object';
SELECT test_json->>2
FROM test_json
WHERE json_type = 'array';
SELECT json_object_keys(test_json)
FROM test_json
WHERE json_type = 'scalar';
SELECT json_object_keys(test_json)
FROM test_json
WHERE json_type = 'array';
SELECT json_object_keys(test_json)
FROM test_json
WHERE json_type = 'object';
-- nulls
select (test_json->'field3') is null as expect_false
from test_json
where json_type = 'object';
select (test_json->>'field3') is null as expect_true
from test_json
where json_type = 'object';
select (test_json->3) is null as expect_false
from test_json
where json_type = 'array';
select (test_json->>3) is null as expect_true
from test_json
where json_type = 'array';
-- array length
SELECT json_array_length('[1,2,3,{"f1":1,"f2":[5,6]},4]');
SELECT json_array_length('[]');
SELECT json_array_length('{"f1":1,"f2":[5,6]}');
SELECT json_array_length('4');
-- each
select json_each('{"f1":[1,2,3],"f2":{"f3":1},"f4":null}');
select * from json_each('{"f1":[1,2,3],"f2":{"f3":1},"f4":null,"f5":99,"f6":"stringy"}') q;
select json_each_text('{"f1":[1,2,3],"f2":{"f3":1},"f4":null,"f5":"null"}');
select * from json_each_text('{"f1":[1,2,3],"f2":{"f3":1},"f4":null,"f5":99,"f6":"stringy"}') q;
-- extract_path, extract_path_as_text
select json_extract_path('{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}','f4','f6');
select json_extract_path('{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}','f2');
select json_extract_path('{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}','f2',0::text);
select json_extract_path('{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}','f2',1::text);
select json_extract_path_text('{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}','f4','f6');
select json_extract_path_text('{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}','f2');
select json_extract_path_text('{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}','f2',0::text);
select json_extract_path_text('{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}','f2',1::text);
-- extract_path nulls
select json_extract_path('{"f2":{"f3":1},"f4":{"f5":null,"f6":"stringy"}}','f4','f5') is null as expect_false;
select json_extract_path_text('{"f2":{"f3":1},"f4":{"f5":null,"f6":"stringy"}}','f4','f5') is null as expect_true;
select json_extract_path('{"f2":{"f3":1},"f4":[0,1,2,null]}','f4','3') is null as expect_false;
select json_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"}}'::json#>array['f4','f6'];
select '{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}'::json#>array['f2'];
select '{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}'::json#>array['f2','0'];
select '{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}'::json#>array['f2','1'];
select '{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}'::json#>>array['f4','f6'];
select '{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}'::json#>>array['f2'];
select '{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}'::json#>>array['f2','0'];
select '{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}'::json#>>array['f2','1'];
-- same using array literals
select '{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}'::json#>'{f4,f6}';
select '{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}'::json#>'{f2}';
select '{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}'::json#>'{f2,0}';
select '{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}'::json#>'{f2,1}';
select '{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}'::json#>>'{f4,f6}';
select '{"f2":{"f3":1},"f4":{"f5":99,"f6":"stringy"}}'::json#>>'{f2}';
select '{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}'::json#>>'{f2,0}';
select '{"f2":["f3",1],"f4":{"f5":99,"f6":"stringy"}}'::json#>>'{f2,1}';
-- array_elements
select json_array_elements('[1,true,[1,[2,3]],null,{"f1":1,"f2":[7,8,9]},false]');
select * from json_array_elements('[1,true,[1,[2,3]],null,{"f1":1,"f2":[7,8,9]},false]') q;
-- populate_record
create type jpop as (a text, b int, c timestamp);
select * from json_populate_record(null::jpop,'{"a":"blurfl","x":43.2}') q;
select * from json_populate_record(row('x',3,'2012-12-31 15:30:56')::jpop,'{"a":"blurfl","x":43.2}') q;
select * from json_populate_record(null::jpop,'{"a":"blurfl","x":43.2}', true) q;
select * from json_populate_record(row('x',3,'2012-12-31 15:30:56')::jpop,'{"a":"blurfl","x":43.2}', true) q;
select * from json_populate_record(null::jpop,'{"a":[100,200,false],"x":43.2}', true) q;
select * from json_populate_record(row('x',3,'2012-12-31 15:30:56')::jpop,'{"a":[100,200,false],"x":43.2}', true) q;
select * from json_populate_record(row('x',3,'2012-12-31 15:30:56')::jpop,'{"c":[100,200,false],"x":43.2}', true) q;
-- populate_recordset
select * from json_populate_recordset(null::jpop,'[{"a":"blurfl","x":43.2},{"b":3,"c":"2012-01-20 10:42:53"}]',false) q;
select * from json_populate_recordset(row('def',99,null)::jpop,'[{"a":"blurfl","x":43.2},{"b":3,"c":"2012-01-20 10:42:53"}]',false) q;
select * from json_populate_recordset(null::jpop,'[{"a":"blurfl","x":43.2},{"b":3,"c":"2012-01-20 10:42:53"}]',true) q;
select * from json_populate_recordset(row('def',99,null)::jpop,'[{"a":"blurfl","x":43.2},{"b":3,"c":"2012-01-20 10:42:53"}]',true) q;
select * from json_populate_recordset(row('def',99,null)::jpop,'[{"a":[100,200,300],"x":43.2},{"a":{"z":true},"b":3,"c":"2012-01-20 10:42:53"}]',true) q;
select * from json_populate_recordset(row('def',99,null)::jpop,'[{"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 json_populate_recordset(null::jpop,'[{"a":"blurfl","x":43.2},{"b":3,"c":"2012-01-20 10:42:53"}]') q;
select * from json_populate_recordset(row('def',99,null)::jpop,'[{"a":"blurfl","x":43.2},{"b":3,"c":"2012-01-20 10:42:53"}]') q;
select * from json_populate_recordset(row('def',99,null)::jpop,'[{"a":[100,200,300],"x":43.2},{"a":{"z":true},"b":3,"c":"2012-01-20 10:42:53"}]') q;
select * from json_populate_recordset(row('def',99,null)::jpop,'[{"c":[100,200,300],"x":43.2},{"a":{"z":true},"b":3,"c":"2012-01-20 10:42:53"}]') q;