2 9.16. JSON Functions and Operators #
4 9.16.1. Processing and Creating JSON Data
5 9.16.2. The SQL/JSON Path Language
6 9.16.3. SQL/JSON Query Functions
9 This section describes:
10 * functions and operators for processing and creating JSON data
11 * the SQL/JSON path language
12 * the SQL/JSON query functions
14 To provide native support for JSON data types within the SQL
15 environment, PostgreSQL implements the SQL/JSON data model. This model
16 comprises sequences of items. Each item can hold SQL scalar values,
17 with an additional SQL/JSON null value, and composite data structures
18 that use JSON arrays and objects. The model is a formalization of the
19 implied data model in the JSON specification RFC 7159.
21 SQL/JSON allows you to handle JSON data alongside regular SQL data,
22 with transaction support, including:
23 * Uploading JSON data into the database and storing it in regular SQL
24 columns as character or binary strings.
25 * Generating JSON objects and arrays from relational data.
26 * Querying JSON data using SQL/JSON query functions and SQL/JSON path
29 To learn more about the SQL/JSON standard, see [sqltr-19075-6]. For
30 details on JSON types supported in PostgreSQL, see Section 8.14.
32 9.16.1. Processing and Creating JSON Data #
34 Table 9.47 shows the operators that are available for use with JSON
35 data types (see Section 8.14). In addition, the usual comparison
36 operators shown in Table 9.1 are available for jsonb, though not for
37 json. The comparison operators follow the ordering rules for B-tree
38 operations outlined in Section 8.14.4. See also Section 9.21 for the
39 aggregate function json_agg which aggregates record values as JSON, the
40 aggregate function json_object_agg which aggregates pairs of values
41 into a JSON object, and their jsonb equivalents, jsonb_agg and
44 Table 9.47. json and jsonb Operators
52 json -> integer → json
54 jsonb -> integer → jsonb
56 Extracts n'th element of JSON array (array elements are indexed from
57 zero, but negative integers count from the end).
59 '[{"a":"foo"},{"b":"bar"},{"c":"baz"}]'::json -> 2 → {"c":"baz"}
61 '[{"a":"foo"},{"b":"bar"},{"c":"baz"}]'::json -> -3 → {"a":"foo"}
67 Extracts JSON object field with the given key.
69 '{"a": {"b":"foo"}}'::json -> 'a' → {"b":"foo"}
71 json ->> integer → text
73 jsonb ->> integer → text
75 Extracts n'th element of JSON array, as text.
77 '[1,2,3]'::json ->> 2 → 3
83 Extracts JSON object field with the given key, as text.
85 '{"a":1,"b":2}'::json ->> 'b' → 2
89 jsonb #> text[] → jsonb
91 Extracts JSON sub-object at the specified path, where path elements can
92 be either field keys or array indexes.
94 '{"a": {"b": ["foo","bar"]}}'::json #> '{a,b,1}' → "bar"
96 json #>> text[] → text
98 jsonb #>> text[] → text
100 Extracts JSON sub-object at the specified path as text.
102 '{"a": {"b": ["foo","bar"]}}'::json #>> '{a,b,1}' → bar
106 The field/element/path extraction operators return NULL, rather than
107 failing, if the JSON input does not have the right structure to match
108 the request; for example if no such key or array element exists.
110 Some further operators exist only for jsonb, as shown in Table 9.48.
111 Section 8.14.4 describes how these operators can be used to effectively
112 search indexed jsonb data.
114 Table 9.48. Additional jsonb Operators
122 jsonb @> jsonb → boolean
124 Does the first JSON value contain the second? (See Section 8.14.3 for
125 details about containment.)
127 '{"a":1, "b":2}'::jsonb @> '{"b":2}'::jsonb → t
129 jsonb <@ jsonb → boolean
131 Is the first JSON value contained in the second?
133 '{"b":2}'::jsonb <@ '{"a":1, "b":2}'::jsonb → t
135 jsonb ? text → boolean
137 Does the text string exist as a top-level key or array element within
140 '{"a":1, "b":2}'::jsonb ? 'b' → t
142 '["a", "b", "c"]'::jsonb ? 'b' → t
144 jsonb ?| text[] → boolean
146 Do any of the strings in the text array exist as top-level keys or
149 '{"a":1, "b":2, "c":3}'::jsonb ?| array['b', 'd'] → t
151 jsonb ?& text[] → boolean
153 Do all of the strings in the text array exist as top-level keys or
156 '["a", "b", "c"]'::jsonb ?& array['a', 'b'] → t
158 jsonb || jsonb → jsonb
160 Concatenates two jsonb values. Concatenating two arrays generates an
161 array containing all the elements of each input. Concatenating two
162 objects generates an object containing the union of their keys, taking
163 the second object's value when there are duplicate keys. All other
164 cases are treated by converting a non-array input into a single-element
165 array, and then proceeding as for two arrays. Does not operate
166 recursively: only the top-level array or object structure is merged.
168 '["a", "b"]'::jsonb || '["a", "d"]'::jsonb → ["a", "b", "a", "d"]
170 '{"a": "b"}'::jsonb || '{"c": "d"}'::jsonb → {"a": "b", "c": "d"}
172 '[1, 2]'::jsonb || '3'::jsonb → [1, 2, 3]
174 '{"a": "b"}'::jsonb || '42'::jsonb → [{"a": "b"}, 42]
176 To append an array to another array as a single entry, wrap it in an
177 additional layer of array, for example:
179 '[1, 2]'::jsonb || jsonb_build_array('[3, 4]'::jsonb) → [1, 2, [3, 4]]
183 Deletes a key (and its value) from a JSON object, or matching string
184 value(s) from a JSON array.
186 '{"a": "b", "c": "d"}'::jsonb - 'a' → {"c": "d"}
188 '["a", "b", "c", "b"]'::jsonb - 'b' → ["a", "c"]
190 jsonb - text[] → jsonb
192 Deletes all matching keys or array elements from the left operand.
194 '{"a": "b", "c": "d"}'::jsonb - '{a,c}'::text[] → {}
196 jsonb - integer → jsonb
198 Deletes the array element with specified index (negative integers count
199 from the end). Throws an error if JSON value is not an array.
201 '["a", "b"]'::jsonb - 1 → ["a"]
203 jsonb #- text[] → jsonb
205 Deletes the field or array element at the specified path, where path
206 elements can be either field keys or array indexes.
208 '["a", {"b":1}]'::jsonb #- '{1,b}' → ["a", {}]
210 jsonb @? jsonpath → boolean
212 Does JSON path return any item for the specified JSON value? (This is
213 useful only with SQL-standard JSON path expressions, not predicate
214 check expressions, since those always return a value.)
216 '{"a":[1,2,3,4,5]}'::jsonb @? '$.a[*] ? (@ > 2)' → t
218 jsonb @@ jsonpath → boolean
220 Returns the result of a JSON path predicate check for the specified
221 JSON value. (This is useful only with predicate check expressions, not
222 SQL-standard JSON path expressions, since it will return NULL if the
223 path result is not a single boolean value.)
225 '{"a":[1,2,3,4,5]}'::jsonb @@ '$.a[*] > 2' → t
229 The jsonpath operators @? and @@ suppress the following errors: missing
230 object field or array element, unexpected JSON item type, datetime and
231 numeric errors. The jsonpath-related functions described below can also
232 be told to suppress these types of errors. This behavior might be
233 helpful when searching JSON document collections of varying structure.
235 Table 9.49 shows the functions that are available for constructing json
236 and jsonb values. Some functions in this table have a RETURNING clause,
237 which specifies the data type returned. It must be one of json, jsonb,
238 bytea, a character string type (text, char, or varchar), or a type that
239 can be cast to json. By default, the json type is returned.
241 Table 9.49. JSON Creation Functions
249 to_json ( anyelement ) → json
251 to_jsonb ( anyelement ) → jsonb
253 Converts any SQL value to json or jsonb. Arrays and composites are
254 converted recursively to arrays and objects (multidimensional arrays
255 become arrays of arrays in JSON). Otherwise, if there is a cast from
256 the SQL data type to json, the cast function will be used to perform
257 the conversion;^[a] otherwise, a scalar JSON value is produced. For any
258 scalar other than a number, a Boolean, or a null value, the text
259 representation will be used, with escaping as necessary to make it a
260 valid JSON string value.
262 to_json('Fred said "Hi."'::text) → "Fred said \"Hi.\""
264 to_jsonb(row(42, 'Fred said "Hi."'::text)) → {"f1": 42, "f2": "Fred
267 array_to_json ( anyarray [, boolean ] ) → json
269 Converts an SQL array to a JSON array. The behavior is the same as
270 to_json except that line feeds will be added between top-level array
271 elements if the optional boolean parameter is true.
273 array_to_json('{{1,5},{99,100}}'::int[]) → [[1,5],[99,100]]
275 json_array ( [ { value_expression [ FORMAT JSON ] } [, ...] ] [ { NULL
276 | ABSENT } ON NULL ] [ RETURNING data_type [ FORMAT JSON [ ENCODING
279 json_array ( [ query_expression ] [ RETURNING data_type [ FORMAT JSON [
282 Constructs a JSON array from either a series of value_expression
283 parameters or from the results of query_expression, which must be a
284 SELECT query returning a single column. If ABSENT ON NULL is specified,
285 NULL values are ignored. This is always the case if a query_expression
288 json_array(1,true,json '{"a":null}') → [1, true, {"a":null}]
290 json_array(SELECT * FROM (VALUES(1),(2)) t) → [1, 2]
292 row_to_json ( record [, boolean ] ) → json
294 Converts an SQL composite value to a JSON object. The behavior is the
295 same as to_json except that line feeds will be added between top-level
296 elements if the optional boolean parameter is true.
298 row_to_json(row(1,'foo')) → {"f1":1,"f2":"foo"}
300 json_build_array ( VARIADIC "any" ) → json
302 jsonb_build_array ( VARIADIC "any" ) → jsonb
304 Builds a possibly-heterogeneously-typed JSON array out of a variadic
305 argument list. Each argument is converted as per to_json or to_jsonb.
307 json_build_array(1, 2, 'foo', 4, 5) → [1, 2, "foo", 4, 5]
309 json_build_object ( VARIADIC "any" ) → json
311 jsonb_build_object ( VARIADIC "any" ) → jsonb
313 Builds a JSON object out of a variadic argument list. By convention,
314 the argument list consists of alternating keys and values. Key
315 arguments are coerced to text; value arguments are converted as per
318 json_build_object('foo', 1, 2, row(3,'bar')) → {"foo" : 1, "2" :
321 json_object ( [ { key_expression { VALUE | ':' } value_expression [
322 FORMAT JSON [ ENCODING UTF8 ] ] }[, ...] ] [ { NULL | ABSENT } ON NULL
323 ] [ { WITH | WITHOUT } UNIQUE [ KEYS ] ] [ RETURNING data_type [ FORMAT
324 JSON [ ENCODING UTF8 ] ] ])
326 Constructs a JSON object of all the key/value pairs given, or an empty
327 object if none are given. key_expression is a scalar expression
328 defining the JSON key, which is converted to the text type. It cannot
329 be NULL nor can it belong to a type that has a cast to the json type.
330 If WITH UNIQUE KEYS is specified, there must not be any duplicate
331 key_expression. Any pair for which the value_expression evaluates to
332 NULL is omitted from the output if ABSENT ON NULL is specified; if NULL
333 ON NULL is specified or the clause omitted, the key is included with
336 json_object('code' VALUE 'P123', 'title': 'Jaws') → {"code" : "P123",
339 json_object ( text[] ) → json
341 jsonb_object ( text[] ) → jsonb
343 Builds a JSON object out of a text array. The array must have either
344 exactly one dimension with an even number of members, in which case
345 they are taken as alternating key/value pairs, or two dimensions such
346 that each inner array has exactly two elements, which are taken as a
347 key/value pair. All values are converted to JSON strings.
349 json_object('{a, 1, b, "def", c, 3.5}') → {"a" : "1", "b" : "def", "c"
352 json_object('{{a, 1}, {b, "def"}, {c, 3.5}}') → {"a" : "1", "b" :
355 json_object ( keys text[], values text[] ) → json
357 jsonb_object ( keys text[], values text[] ) → jsonb
359 This form of json_object takes keys and values pairwise from separate
360 text arrays. Otherwise it is identical to the one-argument form.
362 json_object('{a,b}', '{1,2}') → {"a": "1", "b": "2"}
364 json ( expression [ FORMAT JSON [ ENCODING UTF8 ]] [ { WITH | WITHOUT }
365 UNIQUE [ KEYS ]] ) → json
367 Converts a given expression specified as text or bytea string (in UTF8
368 encoding) into a JSON value. If expression is NULL, an SQL null value
369 is returned. If WITH UNIQUE is specified, the expression must not
370 contain any duplicate object keys.
372 json('{"a":123, "b":[true,"foo"], "a":"bar"}') → {"a":123,
373 "b":[true,"foo"], "a":"bar"}
375 json_scalar ( expression )
377 Converts a given SQL scalar value into a JSON scalar value. If the
378 input is NULL, an SQL null is returned. If the input is number or a
379 boolean value, a corresponding JSON number or boolean value is
380 returned. For any other value, a JSON string is returned.
382 json_scalar(123.45) → 123.45
384 json_scalar(CURRENT_TIMESTAMP) → "2022-05-10T10:51:04.62128-04:00"
386 json_serialize ( expression [ FORMAT JSON [ ENCODING UTF8 ] ] [
387 RETURNING data_type [ FORMAT JSON [ ENCODING UTF8 ] ] ] )
389 Converts an SQL/JSON expression into a character or binary string. The
390 expression can be of any JSON type, any character string type, or bytea
391 in UTF8 encoding. The returned type used in RETURNING can be any
392 character string type or bytea. The default is text.
394 json_serialize('{ "a" : 1 } ' RETURNING bytea) →
395 \x7b20226122203a2031207d20
397 ^[a] For example, the hstore extension has a cast from hstore to json,
398 so that hstore values converted via the JSON creation functions will be
399 represented as JSON objects, not as primitive string values.
401 Table 9.50 details SQL/JSON facilities for testing JSON.
403 Table 9.50. SQL/JSON Testing Functions
411 expression IS [ NOT ] JSON [ { VALUE | SCALAR | ARRAY | OBJECT } ] [ {
412 WITH | WITHOUT } UNIQUE [ KEYS ] ]
414 This predicate tests whether expression can be parsed as JSON, possibly
415 of a specified type. If SCALAR or ARRAY or OBJECT is specified, the
416 test is whether or not the JSON is of that particular type. If WITH
417 UNIQUE KEYS is specified, then any object in the expression is also
418 tested to see if it has duplicate keys.
422 js IS JSON SCALAR "scalar?",
423 js IS JSON OBJECT "object?",
424 js IS JSON ARRAY "array?"
426 ('123'), ('"abc"'), ('{"a": "b"}'), ('[1,2]'),('abc')) foo(js);
427 js | json? | scalar? | object? | array?
428 ------------+-------+---------+---------+--------
430 "abc" | t | t | f | f
431 {"a": "b"} | t | f | t | f
432 [1,2] | t | f | f | t
436 js IS JSON OBJECT "object?",
437 js IS JSON ARRAY "array?",
438 js IS JSON ARRAY WITH UNIQUE KEYS "array w. UK?",
439 js IS JSON ARRAY WITHOUT UNIQUE KEYS "array w/o UK?"
440 FROM (VALUES ('[{"a":"1"},
441 {"b":"2","b":"3"}]')) foo(js);
442 -[ RECORD 1 ]-+--------------------
450 Table 9.51 shows the functions that are available for processing json
453 Table 9.51. JSON Processing Functions
461 json_array_elements ( json ) → setof json
463 jsonb_array_elements ( jsonb ) → setof jsonb
465 Expands the top-level JSON array into a set of JSON values.
467 select * from json_array_elements('[1,true, [2,false]]') →
474 json_array_elements_text ( json ) → setof text
476 jsonb_array_elements_text ( jsonb ) → setof text
478 Expands the top-level JSON array into a set of text values.
480 select * from json_array_elements_text('["foo", "bar"]') →
486 json_array_length ( json ) → integer
488 jsonb_array_length ( jsonb ) → integer
490 Returns the number of elements in the top-level JSON array.
492 json_array_length('[1,2,3,{"f1":1,"f2":[5,6]},4]') → 5
494 jsonb_array_length('[]') → 0
496 json_each ( json ) → setof record ( key text, value json )
498 jsonb_each ( jsonb ) → setof record ( key text, value jsonb )
500 Expands the top-level JSON object into a set of key/value pairs.
502 select * from json_each('{"a":"foo", "b":"bar"}') →
508 json_each_text ( json ) → setof record ( key text, value text )
510 jsonb_each_text ( jsonb ) → setof record ( key text, value text )
512 Expands the top-level JSON object into a set of key/value pairs. The
513 returned values will be of type text.
515 select * from json_each_text('{"a":"foo", "b":"bar"}') →
521 json_extract_path ( from_json json, VARIADIC path_elems text[] ) → json
523 jsonb_extract_path ( from_json jsonb, VARIADIC path_elems text[] ) →
526 Extracts JSON sub-object at the specified path. (This is functionally
527 equivalent to the #> operator, but writing the path out as a variadic
528 list can be more convenient in some cases.)
530 json_extract_path('{"f2":{"f3":1},"f4":{"f5":99,"f6":"foo"}}', 'f4',
533 json_extract_path_text ( from_json json, VARIADIC path_elems text[] ) →
536 jsonb_extract_path_text ( from_json jsonb, VARIADIC path_elems text[] )
539 Extracts JSON sub-object at the specified path as text. (This is
540 functionally equivalent to the #>> operator.)
542 json_extract_path_text('{"f2":{"f3":1},"f4":{"f5":99,"f6":"foo"}}',
545 json_object_keys ( json ) → setof text
547 jsonb_object_keys ( jsonb ) → setof text
549 Returns the set of keys in the top-level JSON object.
551 select * from json_object_keys('{"f1":"abc","f2":{"f3":"a",
558 json_populate_record ( base anyelement, from_json json ) → anyelement
560 jsonb_populate_record ( base anyelement, from_json jsonb ) → anyelement
562 Expands the top-level JSON object to a row having the composite type of
563 the base argument. The JSON object is scanned for fields whose names
564 match column names of the output row type, and their values are
565 inserted into those columns of the output. (Fields that do not
566 correspond to any output column name are ignored.) In typical use, the
567 value of base is just NULL, which means that any output columns that do
568 not match any object field will be filled with nulls. However, if base
569 isn't NULL then the values it contains will be used for unmatched
572 To convert a JSON value to the SQL type of an output column, the
573 following rules are applied in sequence:
574 * A JSON null value is converted to an SQL null in all cases.
575 * If the output column is of type json or jsonb, the JSON value is
576 just reproduced exactly.
577 * If the output column is a composite (row) type, and the JSON value
578 is a JSON object, the fields of the object are converted to columns
579 of the output row type by recursive application of these rules.
580 * Likewise, if the output column is an array type and the JSON value
581 is a JSON array, the elements of the JSON array are converted to
582 elements of the output array by recursive application of these
584 * Otherwise, if the JSON value is a string, the contents of the
585 string are fed to the input conversion function for the column's
587 * Otherwise, the ordinary text representation of the JSON value is
588 fed to the input conversion function for the column's data type.
590 While the example below uses a constant JSON value, typical use would
591 be to reference a json or jsonb column laterally from another table in
592 the query's FROM clause. Writing json_populate_record in the FROM
593 clause is good practice, since all of the extracted columns are
594 available for use without duplicate function calls.
596 create type subrowtype as (d int, e text); create type myrowtype as (a
597 int, b text[], c subrowtype);
599 select * from json_populate_record(null::myrowtype, '{"a": 1, "b":
600 ["2", "a b"], "c": {"d": 4, "e": "a b c"}, "x": "foo"}') →
602 ---+-----------+-------------
603 1 | {2,"a b"} | (4,"a b c")
605 jsonb_populate_record_valid ( base anyelement, from_json json ) →
608 Function for testing jsonb_populate_record. Returns true if the input
609 jsonb_populate_record would finish without an error for the given input
610 JSON object; that is, it's valid input, false otherwise.
612 create type jsb_char2 as (a char(2));
614 select jsonb_populate_record_valid(NULL::jsb_char2, '{"a": "aaa"}'); →
615 jsonb_populate_record_valid
616 -----------------------------
620 select * from jsonb_populate_record(NULL::jsb_char2, '{"a": "aaa"}') q;
622 ERROR: value too long for type character(2)
624 select jsonb_populate_record_valid(NULL::jsb_char2, '{"a": "aa"}'); →
625 jsonb_populate_record_valid
626 -----------------------------
630 select * from jsonb_populate_record(NULL::jsb_char2, '{"a": "aa"}') q;
637 json_populate_recordset ( base anyelement, from_json json ) → setof
640 jsonb_populate_recordset ( base anyelement, from_json jsonb ) → setof
643 Expands the top-level JSON array of objects to a set of rows having the
644 composite type of the base argument. Each element of the JSON array is
645 processed as described above for json[b]_populate_record.
647 create type twoints as (a int, b int);
649 select * from json_populate_recordset(null::twoints, '[{"a":1,"b":2},
656 json_to_record ( json ) → record
658 jsonb_to_record ( jsonb ) → record
660 Expands the top-level JSON object to a row having the composite type
661 defined by an AS clause. (As with all functions returning record, the
662 calling query must explicitly define the structure of the record with
663 an AS clause.) The output record is filled from fields of the JSON
664 object, in the same way as described above for json[b]_populate_record.
665 Since there is no input record value, unmatched columns are always
668 create type myrowtype as (a int, b text);
671 json_to_record('{"a":1,"b":[1,2,3],"c":[1,2,3],"e":"bar","r": {"a":
672 123, "b": "a b c"}}') as x(a int, b text, c int[], d text, r myrowtype)
675 ---+---------+---------+---+---------------
676 1 | [1,2,3] | {1,2,3} | | (123,"a b c")
678 json_to_recordset ( json ) → setof record
680 jsonb_to_recordset ( jsonb ) → setof record
682 Expands the top-level JSON array of objects to a set of rows having the
683 composite type defined by an AS clause. (As with all functions
684 returning record, the calling query must explicitly define the
685 structure of the record with an AS clause.) Each element of the JSON
686 array is processed as described above for json[b]_populate_record.
688 select * from json_to_recordset('[{"a":1,"b":"foo"},
689 {"a":"2","c":"bar"}]') as x(a int, b text) →
695 jsonb_set ( target jsonb, path text[], new_value jsonb [,
696 create_if_missing boolean ] ) → jsonb
698 Returns target with the item designated by path replaced by new_value,
699 or with new_value added if create_if_missing is true (which is the
700 default) and the item designated by path does not exist. All earlier
701 steps in the path must exist, or the target is returned unchanged. As
702 with the path oriented operators, negative integers that appear in the
703 path count from the end of JSON arrays. If the last path step is an
704 array index that is out of range, and create_if_missing is true, the
705 new value is added at the beginning of the array if the index is
706 negative, or at the end of the array if it is positive.
708 jsonb_set('[{"f1":1,"f2":null},2,null,3]', '{0,f1}', '[2,3,4]', false)
709 → [{"f1": [2, 3, 4], "f2": null}, 2, null, 3]
711 jsonb_set('[{"f1":1,"f2":null},2]', '{0,f3}', '[2,3,4]') → [{"f1": 1,
712 "f2": null, "f3": [2, 3, 4]}, 2]
714 jsonb_set_lax ( target jsonb, path text[], new_value jsonb [,
715 create_if_missing boolean [, null_value_treatment text ]] ) → jsonb
717 If new_value is not NULL, behaves identically to jsonb_set. Otherwise
718 behaves according to the value of null_value_treatment which must be
719 one of 'raise_exception', 'use_json_null', 'delete_key', or
720 'return_target'. The default is 'use_json_null'.
722 jsonb_set_lax('[{"f1":1,"f2":null},2,null,3]', '{0,f1}', null) →
723 [{"f1": null, "f2": null}, 2, null, 3]
725 jsonb_set_lax('[{"f1":99,"f2":null},2]', '{0,f3}', null, true,
726 'return_target') → [{"f1": 99, "f2": null}, 2]
728 jsonb_insert ( target jsonb, path text[], new_value jsonb [,
729 insert_after boolean ] ) → jsonb
731 Returns target with new_value inserted. If the item designated by the
732 path is an array element, new_value will be inserted before that item
733 if insert_after is false (which is the default), or after it if
734 insert_after is true. If the item designated by the path is an object
735 field, new_value will be inserted only if the object does not already
736 contain that key. All earlier steps in the path must exist, or the
737 target is returned unchanged. As with the path oriented operators,
738 negative integers that appear in the path count from the end of JSON
739 arrays. If the last path step is an array index that is out of range,
740 the new value is added at the beginning of the array if the index is
741 negative, or at the end of the array if it is positive.
743 jsonb_insert('{"a": [0,1,2]}', '{a, 1}', '"new_value"') → {"a": [0,
746 jsonb_insert('{"a": [0,1,2]}', '{a, 1}', '"new_value"', true) → {"a":
747 [0, 1, "new_value", 2]}
749 json_strip_nulls ( target json [,strip_in_arrays boolean ] ) → json
751 jsonb_strip_nulls ( target jsonb [,strip_in_arrays boolean ] ) → jsonb
753 Deletes all object fields that have null values from the given JSON
754 value, recursively. If strip_in_arrays is true (the default is false),
755 null array elements are also stripped. Otherwise they are not stripped.
756 Bare null values are never stripped.
758 json_strip_nulls('[{"f1":1, "f2":null}, 2, null, 3]') →
761 jsonb_strip_nulls('[1,2,null,3,4]', true); → [1,2,3,4]
763 jsonb_path_exists ( target jsonb, path jsonpath [, vars jsonb [, silent
764 boolean ]] ) → boolean
766 Checks whether the JSON path returns any item for the specified JSON
767 value. (This is useful only with SQL-standard JSON path expressions,
768 not predicate check expressions, since those always return a value.) If
769 the vars argument is specified, it must be a JSON object, and its
770 fields provide named values to be substituted into the jsonpath
771 expression. If the silent argument is specified and is true, the
772 function suppresses the same errors as the @? and @@ operators do.
774 jsonb_path_exists('{"a":[1,2,3,4,5]}', '$.a[*] ? (@ >= $min && @ <=
775 $max)', '{"min":2, "max":4}') → t
777 jsonb_path_match ( target jsonb, path jsonpath [, vars jsonb [, silent
778 boolean ]] ) → boolean
780 Returns the SQL boolean result of a JSON path predicate check for the
781 specified JSON value. (This is useful only with predicate check
782 expressions, not SQL-standard JSON path expressions, since it will
783 either fail or return NULL if the path result is not a single boolean
784 value.) The optional vars and silent arguments act the same as for
787 jsonb_path_match('{"a":[1,2,3,4,5]}', 'exists($.a[*] ? (@ >= $min && @
788 <= $max))', '{"min":2, "max":4}') → t
790 jsonb_path_query ( target jsonb, path jsonpath [, vars jsonb [, silent
791 boolean ]] ) → setof jsonb
793 Returns all JSON items returned by the JSON path for the specified JSON
794 value. For SQL-standard JSON path expressions it returns the JSON
795 values selected from target. For predicate check expressions it returns
796 the result of the predicate check: true, false, or null. The optional
797 vars and silent arguments act the same as for jsonb_path_exists.
799 select * from jsonb_path_query('{"a":[1,2,3,4,5]}', '$.a[*] ? (@ >=
800 $min && @ <= $max)', '{"min":2, "max":4}') →
807 jsonb_path_query_array ( target jsonb, path jsonpath [, vars jsonb [,
808 silent boolean ]] ) → jsonb
810 Returns all JSON items returned by the JSON path for the specified JSON
811 value, as a JSON array. The parameters are the same as for
814 jsonb_path_query_array('{"a":[1,2,3,4,5]}', '$.a[*] ? (@ >= $min && @
815 <= $max)', '{"min":2, "max":4}') → [2, 3, 4]
817 jsonb_path_query_first ( target jsonb, path jsonpath [, vars jsonb [,
818 silent boolean ]] ) → jsonb
820 Returns the first JSON item returned by the JSON path for the specified
821 JSON value, or NULL if there are no results. The parameters are the
822 same as for jsonb_path_query.
824 jsonb_path_query_first('{"a":[1,2,3,4,5]}', '$.a[*] ? (@ >= $min && @
825 <= $max)', '{"min":2, "max":4}') → 2
827 jsonb_path_exists_tz ( target jsonb, path jsonpath [, vars jsonb [,
828 silent boolean ]] ) → boolean
830 jsonb_path_match_tz ( target jsonb, path jsonpath [, vars jsonb [,
831 silent boolean ]] ) → boolean
833 jsonb_path_query_tz ( target jsonb, path jsonpath [, vars jsonb [,
834 silent boolean ]] ) → setof jsonb
836 jsonb_path_query_array_tz ( target jsonb, path jsonpath [, vars jsonb
837 [, silent boolean ]] ) → jsonb
839 jsonb_path_query_first_tz ( target jsonb, path jsonpath [, vars jsonb
840 [, silent boolean ]] ) → jsonb
842 These functions act like their counterparts described above without the
843 _tz suffix, except that these functions support comparisons of
844 date/time values that require timezone-aware conversions. The example
845 below requires interpretation of the date-only value 2015-08-02 as a
846 timestamp with time zone, so the result depends on the current TimeZone
847 setting. Due to this dependency, these functions are marked as stable,
848 which means these functions cannot be used in indexes. Their
849 counterparts are immutable, and so can be used in indexes; but they
850 will throw errors if asked to make such comparisons.
852 jsonb_path_exists_tz('["2015-08-01 12:00:00-05"]', '$[*] ?
853 (@.datetime() < "2015-08-02".datetime())') → t
855 jsonb_pretty ( jsonb ) → text
857 Converts the given JSON value to pretty-printed, indented text.
859 jsonb_pretty('[{"f1":1,"f2":null}, 2]') →
868 json_typeof ( json ) → text
870 jsonb_typeof ( jsonb ) → text
872 Returns the type of the top-level JSON value as a text string. Possible
873 types are object, array, string, number, boolean, and null. (The null
874 result should not be confused with an SQL NULL; see the examples.)
876 json_typeof('-123.4') → number
878 json_typeof('null'::json) → null
880 json_typeof(NULL::json) IS NULL → t
882 9.16.2. The SQL/JSON Path Language #
884 SQL/JSON path expressions specify item(s) to be retrieved from a JSON
885 value, similarly to XPath expressions used for access to XML content.
886 In PostgreSQL, path expressions are implemented as the jsonpath data
887 type and can use any elements described in Section 8.14.7.
889 JSON query functions and operators pass the provided path expression to
890 the path engine for evaluation. If the expression matches the queried
891 JSON data, the corresponding JSON item, or set of items, is returned.
892 If there is no match, the result will be NULL, false, or an error,
893 depending on the function. Path expressions are written in the SQL/JSON
894 path language and can include arithmetic expressions and functions.
896 A path expression consists of a sequence of elements allowed by the
897 jsonpath data type. The path expression is normally evaluated from left
898 to right, but you can use parentheses to change the order of
899 operations. If the evaluation is successful, a sequence of JSON items
900 is produced, and the evaluation result is returned to the JSON query
901 function that completes the specified computation.
903 To refer to the JSON value being queried (the context item), use the $
904 variable in the path expression. The first element of a path must
905 always be $. It can be followed by one or more accessor operators,
906 which go down the JSON structure level by level to retrieve sub-items
907 of the context item. Each accessor operator acts on the result(s) of
908 the previous evaluation step, producing zero, one, or more output items
909 from each input item.
911 For example, suppose you have some JSON data from a GPS tracker that
912 you would like to parse, such as:
917 "location": [ 47.763, 13.4034 ],
918 "start time": "2018-10-14 10:05:14",
922 "location": [ 47.706, 13.2635 ],
923 "start time": "2018-10-14 10:39:21",
930 (The above example can be copied-and-pasted into psql to set things up
931 for the following examples. Then psql will expand :'json' into a
932 suitably-quoted string constant containing the JSON value.)
934 To retrieve the available track segments, you need to use the .key
935 accessor operator to descend through surrounding JSON objects, for
937 => select jsonb_path_query(:'json', '$.track.segments');
940 -------------------------------------------------------------------------------
941 -------------------------------------------------------------------------------
943 [{"HR": 73, "location": [47.763, 13.4034], "start time": "2018-10-14 10:05:14"}
944 , {"HR": 135, "location": [47.706, 13.2635], "start time": "2018-10-14 10:39:21"
947 To retrieve the contents of an array, you typically use the [*]
948 operator. The following example will return the location coordinates
949 for all the available track segments:
950 => select jsonb_path_query(:'json', '$.track.segments[*].location');
956 Here we started with the whole JSON input value ($), then the .track
957 accessor selected the JSON object associated with the "track" object
958 key, then the .segments accessor selected the JSON array associated
959 with the "segments" key within that object, then the [*] accessor
960 selected each element of that array (producing a series of items), then
961 the .location accessor selected the JSON array associated with the
962 "location" key within each of those objects. In this example, each of
963 those objects had a "location" key; but if any of them did not, the
964 .location accessor would have simply produced no output for that input
967 To return the coordinates of the first segment only, you can specify
968 the corresponding subscript in the [] accessor operator. Recall that
969 JSON array indexes are 0-relative:
970 => select jsonb_path_query(:'json', '$.track.segments[0].location');
975 The result of each path evaluation step can be processed by one or more
976 of the jsonpath operators and methods listed in Section 9.16.2.3. Each
977 method name must be preceded by a dot. For example, you can get the
979 => select jsonb_path_query(:'json', '$.track.segments.size()');
984 More examples of using jsonpath operators and methods within path
985 expressions appear below in Section 9.16.2.3.
987 A path can also contain filter expressions that work similarly to the
988 WHERE clause in SQL. A filter expression begins with a question mark
989 and provides a condition in parentheses:
992 Filter expressions must be written just after the path evaluation step
993 to which they should apply. The result of that step is filtered to
994 include only those items that satisfy the provided condition. SQL/JSON
995 defines three-valued logic, so the condition can produce true, false,
996 or unknown. The unknown value plays the same role as SQL NULL and can
997 be tested for with the is unknown predicate. Further path evaluation
998 steps use only those items for which the filter expression returned
1001 The functions and operators that can be used in filter expressions are
1002 listed in Table 9.53. Within a filter expression, the @ variable
1003 denotes the value being considered (i.e., one result of the preceding
1004 path step). You can write accessor operators after @ to retrieve
1007 For example, suppose you would like to retrieve all heart rate values
1008 higher than 130. You can achieve this as follows:
1009 => select jsonb_path_query(:'json', '$.track.segments[*].HR ? (@ > 130)');
1014 To get the start times of segments with such values, you have to filter
1015 out irrelevant segments before selecting the start times, so the filter
1016 expression is applied to the previous step, and the path used in the
1017 condition is different:
1018 => select jsonb_path_query(:'json', '$.track.segments[*] ? (@.HR > 130)."start t
1021 -----------------------
1022 "2018-10-14 10:39:21"
1024 You can use several filter expressions in sequence, if required. The
1025 following example selects start times of all segments that contain
1026 locations with relevant coordinates and high heart rate values:
1027 => select jsonb_path_query(:'json', '$.track.segments[*] ? (@.location[1] < 13.4
1028 ) ? (@.HR > 130)."start time"');
1030 -----------------------
1031 "2018-10-14 10:39:21"
1033 Using filter expressions at different nesting levels is also allowed.
1034 The following example first filters all segments by location, and then
1035 returns high heart rate values for these segments, if available:
1036 => select jsonb_path_query(:'json', '$.track.segments[*] ? (@.location[1] < 13.4
1042 You can also nest filter expressions within each other. This example
1043 returns the size of the track if it contains any segments with high
1044 heart rate values, or an empty sequence otherwise:
1045 => select jsonb_path_query(:'json', '$.track ? (exists(@.segments[*] ? (@.HR > 1
1046 30))).segments.size()');
1051 9.16.2.1. Deviations from the SQL Standard #
1053 PostgreSQL's implementation of the SQL/JSON path language has the
1054 following deviations from the SQL/JSON standard.
1056 9.16.2.1.1. Boolean Predicate Check Expressions #
1058 As an extension to the SQL standard, a PostgreSQL path expression can
1059 be a Boolean predicate, whereas the SQL standard allows predicates only
1060 within filters. While SQL-standard path expressions return the relevant
1061 element(s) of the queried JSON value, predicate check expressions
1062 return the single three-valued jsonb result of the predicate: true,
1063 false, or null. For example, we could write this SQL-standard filter
1065 => select jsonb_path_query(:'json', '$.track.segments ?(@[*].HR > 130)');
1067 -------------------------------------------------------------------------------
1069 {"HR": 135, "location": [47.706, 13.2635], "start time": "2018-10-14 10:39:21"}
1071 The similar predicate check expression simply returns true, indicating
1072 that a match exists:
1073 => select jsonb_path_query(:'json', '$.track.segments[*].HR > 130');
1080 Predicate check expressions are required in the @@ operator (and the
1081 jsonb_path_match function), and should not be used with the @? operator
1082 (or the jsonb_path_exists function).
1084 9.16.2.1.2. Regular Expression Interpretation #
1086 There are minor differences in the interpretation of regular expression
1087 patterns used in like_regex filters, as described in Section 9.16.2.4.
1089 9.16.2.2. Strict and Lax Modes #
1091 When you query JSON data, the path expression may not match the actual
1092 JSON data structure. An attempt to access a non-existent member of an
1093 object or element of an array is defined as a structural error.
1094 SQL/JSON path expressions have two modes of handling structural errors:
1095 * lax (default) — the path engine implicitly adapts the queried data
1096 to the specified path. Any structural errors that cannot be fixed
1097 as described below are suppressed, producing no match.
1098 * strict — if a structural error occurs, an error is raised.
1100 Lax mode facilitates matching of a JSON document and path expression
1101 when the JSON data does not conform to the expected schema. If an
1102 operand does not match the requirements of a particular operation, it
1103 can be automatically wrapped as an SQL/JSON array, or unwrapped by
1104 converting its elements into an SQL/JSON sequence before performing the
1105 operation. Also, comparison operators automatically unwrap their
1106 operands in lax mode, so you can compare SQL/JSON arrays
1107 out-of-the-box. An array of size 1 is considered equal to its sole
1108 element. Automatic unwrapping is not performed when:
1109 * The path expression contains type() or size() methods that return
1110 the type and the number of elements in the array, respectively.
1111 * The queried JSON data contain nested arrays. In this case, only the
1112 outermost array is unwrapped, while all the inner arrays remain
1113 unchanged. Thus, implicit unwrapping can only go one level down
1114 within each path evaluation step.
1116 For example, when querying the GPS data listed above, you can abstract
1117 from the fact that it stores an array of segments when using lax mode:
1118 => select jsonb_path_query(:'json', 'lax $.track.segments.location');
1124 In strict mode, the specified path must exactly match the structure of
1125 the queried JSON document, so using this path expression will cause an
1127 => select jsonb_path_query(:'json', 'strict $.track.segments.location');
1128 ERROR: jsonpath member accessor can only be applied to an object
1130 To get the same result as in lax mode, you have to explicitly unwrap
1132 => select jsonb_path_query(:'json', 'strict $.track.segments[*].location');
1138 The unwrapping behavior of lax mode can lead to surprising results. For
1139 instance, the following query using the .** accessor selects every HR
1141 => select jsonb_path_query(:'json', 'lax $.**.HR');
1149 This happens because the .** accessor selects both the segments array
1150 and each of its elements, while the .HR accessor automatically unwraps
1151 arrays when using lax mode. To avoid surprising results, we recommend
1152 using the .** accessor only in strict mode. The following query selects
1153 each HR value just once:
1154 => select jsonb_path_query(:'json', 'strict $.**.HR');
1160 The unwrapping of arrays can also lead to unexpected results. Consider
1161 this example, which selects all the location arrays:
1162 => select jsonb_path_query(:'json', 'lax $.track.segments[*].location');
1169 As expected it returns the full arrays. But applying a filter
1170 expression causes the arrays to be unwrapped to evaluate each item,
1171 returning only the items that match the expression:
1172 => select jsonb_path_query(:'json', 'lax $.track.segments[*].location ?(@[*] > 1
1180 This despite the fact that the full arrays are selected by the path
1181 expression. Use strict mode to restore selecting the arrays:
1182 => select jsonb_path_query(:'json', 'strict $.track.segments[*].location ?(@[*]
1190 9.16.2.3. SQL/JSON Path Operators and Methods #
1192 Table 9.52 shows the operators and methods available in jsonpath. Note
1193 that while the unary operators and methods can be applied to multiple
1194 values resulting from a preceding path step, the binary operators
1195 (addition etc.) can only be applied to single values. In lax mode,
1196 methods applied to an array will be executed for each value in the
1197 array. The exceptions are .type() and .size(), which apply to the array
1200 Table 9.52. jsonpath Operators and Methods
1208 number + number → number
1212 jsonb_path_query('[2]', '$[0] + 3') → 5
1216 Unary plus (no operation); unlike addition, this can iterate over
1219 jsonb_path_query_array('{"x": [2,3,4]}', '+ $.x') → [2, 3, 4]
1221 number - number → number
1225 jsonb_path_query('[2]', '7 - $[0]') → 5
1229 Negation; unlike subtraction, this can iterate over multiple values
1231 jsonb_path_query_array('{"x": [2,3,4]}', '- $.x') → [-2, -3, -4]
1233 number * number → number
1237 jsonb_path_query('[4]', '2 * $[0]') → 8
1239 number / number → number
1243 jsonb_path_query('[8.5]', '$[0] / 2') → 4.2500000000000000
1245 number % number → number
1249 jsonb_path_query('[32]', '$[0] % 10') → 2
1251 value . type() → string
1253 Type of the JSON item (see json_typeof)
1255 jsonb_path_query_array('[1, "2", {}]', '$[*].type()') → ["number",
1258 value . size() → number
1260 Size of the JSON item (number of array elements, or 1 if not an array)
1262 jsonb_path_query('{"m": [11, 15]}', '$.m.size()') → 2
1264 value . boolean() → boolean
1266 Boolean value converted from a JSON boolean, number, or string
1268 jsonb_path_query_array('[1, "yes", false]', '$[*].boolean()') → [true,
1271 value . string() → string
1273 String value converted from a JSON boolean, number, string, or datetime
1275 jsonb_path_query_array('[1.23, "xyz", false]', '$[*].string()') →
1276 ["1.23", "xyz", "false"]
1278 jsonb_path_query('"2023-08-15 12:34:56"', '$.timestamp().string()') →
1279 "2023-08-15T12:34:56"
1281 value . double() → number
1283 Approximate floating-point number converted from a JSON number or
1286 jsonb_path_query('{"len": "1.9"}', '$.len.double() * 2') → 3.8
1288 number . ceiling() → number
1290 Nearest integer greater than or equal to the given number
1292 jsonb_path_query('{"h": 1.3}', '$.h.ceiling()') → 2
1294 number . floor() → number
1296 Nearest integer less than or equal to the given number
1298 jsonb_path_query('{"h": 1.7}', '$.h.floor()') → 1
1300 number . abs() → number
1302 Absolute value of the given number
1304 jsonb_path_query('{"z": -0.3}', '$.z.abs()') → 0.3
1306 value . bigint() → bigint
1308 Big integer value converted from a JSON number or string
1310 jsonb_path_query('{"len": "9876543219"}', '$.len.bigint()') →
1313 value . decimal( [ precision [ , scale ] ] ) → decimal
1315 Rounded decimal value converted from a JSON number or string (precision
1316 and scale must be integer values)
1318 jsonb_path_query('1234.5678', '$.decimal(6, 2)') → 1234.57
1320 value . integer() → integer
1322 Integer value converted from a JSON number or string
1324 jsonb_path_query('{"len": "12345"}', '$.len.integer()') → 12345
1326 value . number() → numeric
1328 Numeric value converted from a JSON number or string
1330 jsonb_path_query('{"len": "123.45"}', '$.len.number()') → 123.45
1332 string . datetime() → datetime_type (see note)
1334 Date/time value converted from a string
1336 jsonb_path_query('["2015-8-1", "2015-08-12"]', '$[*] ? (@.datetime() <
1337 "2015-08-2".datetime())') → "2015-8-1"
1339 string . datetime(template) → datetime_type (see note)
1341 Date/time value converted from a string using the specified
1342 to_timestamp template
1344 jsonb_path_query_array('["12:30", "18:40"]',
1345 '$[*].datetime("HH24:MI")') → ["12:30:00", "18:40:00"]
1347 string . date() → date
1349 Date value converted from a string
1351 jsonb_path_query('"2023-08-15"', '$.date()') → "2023-08-15"
1353 string . time() → time without time zone
1355 Time without time zone value converted from a string
1357 jsonb_path_query('"12:34:56"', '$.time()') → "12:34:56"
1359 string . time(precision) → time without time zone
1361 Time without time zone value converted from a string, with fractional
1362 seconds adjusted to the given precision
1364 jsonb_path_query('"12:34:56.789"', '$.time(2)') → "12:34:56.79"
1366 string . time_tz() → time with time zone
1368 Time with time zone value converted from a string
1370 jsonb_path_query('"12:34:56 +05:30"', '$.time_tz()') → "12:34:56+05:30"
1372 string . time_tz(precision) → time with time zone
1374 Time with time zone value converted from a string, with fractional
1375 seconds adjusted to the given precision
1377 jsonb_path_query('"12:34:56.789 +05:30"', '$.time_tz(2)') →
1380 string . timestamp() → timestamp without time zone
1382 Timestamp without time zone value converted from a string
1384 jsonb_path_query('"2023-08-15 12:34:56"', '$.timestamp()') →
1385 "2023-08-15T12:34:56"
1387 string . timestamp(precision) → timestamp without time zone
1389 Timestamp without time zone value converted from a string, with
1390 fractional seconds adjusted to the given precision
1392 jsonb_path_query('"2023-08-15 12:34:56.789"', '$.timestamp(2)') →
1393 "2023-08-15T12:34:56.79"
1395 string . timestamp_tz() → timestamp with time zone
1397 Timestamp with time zone value converted from a string
1399 jsonb_path_query('"2023-08-15 12:34:56 +05:30"', '$.timestamp_tz()') →
1400 "2023-08-15T12:34:56+05:30"
1402 string . timestamp_tz(precision) → timestamp with time zone
1404 Timestamp with time zone value converted from a string, with fractional
1405 seconds adjusted to the given precision
1407 jsonb_path_query('"2023-08-15 12:34:56.789 +05:30"',
1408 '$.timestamp_tz(2)') → "2023-08-15T12:34:56.79+05:30"
1410 object . keyvalue() → array
1412 The object's key-value pairs, represented as an array of objects
1413 containing three fields: "key", "value", and "id"; "id" is a unique
1414 identifier of the object the key-value pair belongs to
1416 jsonb_path_query_array('{"x": "20", "y": 32}', '$.keyvalue()') →
1417 [{"id": 0, "key": "x", "value": "20"}, {"id": 0, "key": "y", "value":
1422 The result type of the datetime() and datetime(template) methods can be
1423 date, timetz, time, timestamptz, or timestamp. Both methods determine
1424 their result type dynamically.
1426 The datetime() method sequentially tries to match its input string to
1427 the ISO formats for date, timetz, time, timestamptz, and timestamp. It
1428 stops on the first matching format and emits the corresponding data
1431 The datetime(template) method determines the result type according to
1432 the fields used in the provided template string.
1434 The datetime() and datetime(template) methods use the same parsing
1435 rules as the to_timestamp SQL function does (see Section 9.8), with
1436 three exceptions. First, these methods don't allow unmatched template
1437 patterns. Second, only the following separators are allowed in the
1438 template string: minus sign, period, solidus (slash), comma,
1439 apostrophe, semicolon, colon and space. Third, separators in the
1440 template string must exactly match the input string.
1442 If different date/time types need to be compared, an implicit cast is
1443 applied. A date value can be cast to timestamp or timestamptz,
1444 timestamp can be cast to timestamptz, and time to timetz. However, all
1445 but the first of these conversions depend on the current TimeZone
1446 setting, and thus can only be performed within timezone-aware jsonpath
1447 functions. Similarly, other date/time-related methods that convert
1448 strings to date/time types also do this casting, which may involve the
1449 current TimeZone setting. Therefore, these conversions can also only be
1450 performed within timezone-aware jsonpath functions.
1452 Table 9.53 shows the available filter expression elements.
1454 Table 9.53. jsonpath Filter Expression Elements
1462 value == value → boolean
1464 Equality comparison (this, and the other comparison operators, work on
1465 all JSON scalar values)
1467 jsonb_path_query_array('[1, "a", 1, 3]', '$[*] ? (@ == 1)') → [1, 1]
1469 jsonb_path_query_array('[1, "a", 1, 3]', '$[*] ? (@ == "a")') → ["a"]
1471 value != value → boolean
1473 value <> value → boolean
1475 Non-equality comparison
1477 jsonb_path_query_array('[1, 2, 1, 3]', '$[*] ? (@ != 1)') → [2, 3]
1479 jsonb_path_query_array('["a", "b", "c"]', '$[*] ? (@ <> "b")') → ["a",
1482 value < value → boolean
1484 Less-than comparison
1486 jsonb_path_query_array('[1, 2, 3]', '$[*] ? (@ < 2)') → [1]
1488 value <= value → boolean
1490 Less-than-or-equal-to comparison
1492 jsonb_path_query_array('["a", "b", "c"]', '$[*] ? (@ <= "b")') → ["a",
1495 value > value → boolean
1497 Greater-than comparison
1499 jsonb_path_query_array('[1, 2, 3]', '$[*] ? (@ > 2)') → [3]
1501 value >= value → boolean
1503 Greater-than-or-equal-to comparison
1505 jsonb_path_query_array('[1, 2, 3]', '$[*] ? (@ >= 2)') → [2, 3]
1511 jsonb_path_query('[{"name": "John", "parent": false}, {"name": "Chris",
1512 "parent": true}]', '$[*] ? (@.parent == true)') → {"name": "Chris",
1519 jsonb_path_query('[{"name": "John", "parent": false}, {"name": "Chris",
1520 "parent": true}]', '$[*] ? (@.parent == false)') → {"name": "John",
1525 JSON constant null (note that, unlike in SQL, comparison to null works
1528 jsonb_path_query('[{"name": "Mary", "job": null}, {"name": "Michael",
1529 "job": "driver"}]', '$[*] ? (@.job == null) .name') → "Mary"
1531 boolean && boolean → boolean
1535 jsonb_path_query('[1, 3, 7]', '$[*] ? (@ > 1 && @ < 5)') → 3
1537 boolean || boolean → boolean
1541 jsonb_path_query('[1, 3, 7]', '$[*] ? (@ < 1 || @ > 5)') → 7
1547 jsonb_path_query('[1, 3, 7]', '$[*] ? (!(@ < 5))') → 7
1549 boolean is unknown → boolean
1551 Tests whether a Boolean condition is unknown.
1553 jsonb_path_query('[-1, 2, 7, "foo"]', '$[*] ? ((@ > 0) is unknown)') →
1556 string like_regex string [ flag string ] → boolean
1558 Tests whether the first operand matches the regular expression given by
1559 the second operand, optionally with modifications described by a string
1560 of flag characters (see Section 9.16.2.4).
1562 jsonb_path_query_array('["abc", "abd", "aBdC", "abdacb", "babc"]',
1563 '$[*] ? (@ like_regex "^ab.*c")') → ["abc", "abdacb"]
1565 jsonb_path_query_array('["abc", "abd", "aBdC", "abdacb", "babc"]',
1566 '$[*] ? (@ like_regex "^ab.*c" flag "i")') → ["abc", "aBdC", "abdacb"]
1568 string starts with string → boolean
1570 Tests whether the second operand is an initial substring of the first
1573 jsonb_path_query('["John Smith", "Mary Stone", "Bob Johnson"]', '$[*] ?
1574 (@ starts with "John")') → "John Smith"
1576 exists ( path_expression ) → boolean
1578 Tests whether a path expression matches at least one SQL/JSON item.
1579 Returns unknown if the path expression would result in an error; the
1580 second example uses this to avoid a no-such-key error in strict mode.
1582 jsonb_path_query('{"x": [1, 2], "y": [2, 4]}', 'strict $.* ? (exists (@
1583 ? (@[*] > 2)))') → [2, 4]
1585 jsonb_path_query_array('{"value": 41}', 'strict $ ? (exists (@.name))
1588 9.16.2.4. SQL/JSON Regular Expressions #
1590 SQL/JSON path expressions allow matching text to a regular expression
1591 with the like_regex filter. For example, the following SQL/JSON path
1592 query would case-insensitively match all strings in an array that start
1593 with an English vowel:
1594 $[*] ? (@ like_regex "^[aeiou]" flag "i")
1596 The optional flag string may include one or more of the characters i
1597 for case-insensitive match, m to allow ^ and $ to match at newlines, s
1598 to allow . to match a newline, and q to quote the whole pattern
1599 (reducing the behavior to a simple substring match).
1601 The SQL/JSON standard borrows its definition for regular expressions
1602 from the LIKE_REGEX operator, which in turn uses the XQuery standard.
1603 PostgreSQL does not currently support the LIKE_REGEX operator.
1604 Therefore, the like_regex filter is implemented using the POSIX regular
1605 expression engine described in Section 9.7.3. This leads to various
1606 minor discrepancies from standard SQL/JSON behavior, which are
1607 cataloged in Section 9.7.3.8. Note, however, that the flag-letter
1608 incompatibilities described there do not apply to SQL/JSON, as it
1609 translates the XQuery flag letters to match what the POSIX engine
1612 Keep in mind that the pattern argument of like_regex is a JSON path
1613 string literal, written according to the rules given in Section 8.14.7.
1614 This means in particular that any backslashes you want to use in the
1615 regular expression must be doubled. For example, to match string values
1616 of the root document that contain only digits:
1617 $.* ? (@ like_regex "^\\d+$")
1619 9.16.3. SQL/JSON Query Functions #
1621 SQL/JSON functions JSON_EXISTS(), JSON_QUERY(), and JSON_VALUE()
1622 described in Table 9.54 can be used to query JSON documents. Each of
1623 these functions apply a path_expression (an SQL/JSON path query) to a
1624 context_item (the document). See Section 9.16.2 for more details on
1625 what the path_expression can contain. The path_expression can also
1626 reference variables, whose values are specified with their respective
1627 names in the PASSING clause that is supported by each function.
1628 context_item can be a jsonb value or a character string that can be
1629 successfully cast to jsonb.
1631 Table 9.54. SQL/JSON Query Functions
1640 context_item, path_expression
1641 [ PASSING { value AS varname } [, ...]]
1642 [{ TRUE | FALSE | UNKNOWN | ERROR } ON ERROR ]) → boolean
1644 * Returns true if the SQL/JSON path_expression applied to the
1645 context_item yields any items, false otherwise.
1646 * The ON ERROR clause specifies the behavior if an error occurs
1647 during path_expression evaluation. Specifying ERROR will cause an
1648 error to be thrown with the appropriate message. Other options
1649 include returning boolean values FALSE or TRUE or the value UNKNOWN
1650 which is actually an SQL NULL. The default when no ON ERROR clause
1651 is specified is to return the boolean value FALSE.
1655 JSON_EXISTS(jsonb '{"key1": [1,2,3]}', 'strict $.key1[*] ? (@ > $x)'
1658 JSON_EXISTS(jsonb '{"a": [1,2,3]}', 'lax $.a[5]' ERROR ON ERROR) → f
1660 JSON_EXISTS(jsonb '{"a": [1,2,3]}', 'strict $.a[5]' ERROR ON ERROR) →
1661 ERROR: jsonpath array subscript is out of bounds
1664 context_item, path_expression
1665 [ PASSING { value AS varname } [, ...]]
1666 [ RETURNING data_type [ FORMAT JSON [ ENCODING UTF8 ] ] ]
1667 [ { WITHOUT | WITH { CONDITIONAL | [UNCONDITIONAL] } } [ ARRAY ] WRAPPER ]
1668 [ { KEEP | OMIT } QUOTES [ ON SCALAR STRING ] ]
1669 [ { ERROR | NULL | EMPTY { [ ARRAY ] | OBJECT } | DEFAULT expression } ON EMPTY
1671 [ { ERROR | NULL | EMPTY { [ ARRAY ] | OBJECT } | DEFAULT expression } ON ERROR
1674 * Returns the result of applying the SQL/JSON path_expression to the
1676 * By default, the result is returned as a value of type jsonb, though
1677 the RETURNING clause can be used to return as some other type to
1678 which it can be successfully coerced.
1679 * If the path expression may return multiple values, it might be
1680 necessary to wrap those values using the WITH WRAPPER clause to
1681 make it a valid JSON string, because the default behavior is to not
1682 wrap them, as if WITHOUT WRAPPER were specified. The WITH WRAPPER
1683 clause is by default taken to mean WITH UNCONDITIONAL WRAPPER,
1684 which means that even a single result value will be wrapped. To
1685 apply the wrapper only when multiple values are present, specify
1686 WITH CONDITIONAL WRAPPER. Getting multiple values in result will be
1687 treated as an error if WITHOUT WRAPPER is specified.
1688 * If the result is a scalar string, by default, the returned value
1689 will be surrounded by quotes, making it a valid JSON value. It can
1690 be made explicit by specifying KEEP QUOTES. Conversely, quotes can
1691 be omitted by specifying OMIT QUOTES. To ensure that the result is
1692 a valid JSON value, OMIT QUOTES cannot be specified when WITH
1693 WRAPPER is also specified.
1694 * The ON EMPTY clause specifies the behavior if evaluating
1695 path_expression yields an empty set. The ON ERROR clause specifies
1696 the behavior if an error occurs when evaluating path_expression,
1697 when coercing the result value to the RETURNING type, or when
1698 evaluating the ON EMPTY expression if the path_expression
1699 evaluation returns an empty set.
1700 * For both ON EMPTY and ON ERROR, specifying ERROR will cause an
1701 error to be thrown with the appropriate message. Other options
1702 include returning an SQL NULL, an empty array (EMPTY [ARRAY]), an
1703 empty object (EMPTY OBJECT), or a user-specified expression
1704 (DEFAULT expression) that can be coerced to jsonb or the type
1705 specified in RETURNING. The default when ON EMPTY or ON ERROR is
1706 not specified is to return an SQL NULL value.
1710 JSON_QUERY(jsonb '[1,[2,3],null]', 'lax $[*][$off]' PASSING 1 AS off
1711 WITH CONDITIONAL WRAPPER) → 3
1713 JSON_QUERY(jsonb '{"a": "[1, 2]"}', 'lax $.a' OMIT QUOTES) → [1, 2]
1715 JSON_QUERY(jsonb '{"a": "[1, 2]"}', 'lax $.a' RETURNING int[] OMIT
1716 QUOTES ERROR ON ERROR) →
1717 ERROR: malformed array literal: "[1, 2]"
1718 DETAIL: Missing "]" after array dimensions.
1721 context_item, path_expression
1722 [ PASSING { value AS varname } [, ...]]
1723 [ RETURNING data_type ]
1724 [ { ERROR | NULL | DEFAULT expression } ON EMPTY ]
1725 [ { ERROR | NULL | DEFAULT expression } ON ERROR ]) → text
1727 * Returns the result of applying the SQL/JSON path_expression to the
1729 * Only use JSON_VALUE() if the extracted value is expected to be a
1730 single SQL/JSON scalar item; getting multiple values will be
1731 treated as an error. If you expect that extracted value might be an
1732 object or an array, use the JSON_QUERY function instead.
1733 * By default, the result, which must be a single scalar value, is
1734 returned as a value of type text, though the RETURNING clause can
1735 be used to return as some other type to which it can be
1736 successfully coerced.
1737 * The ON ERROR and ON EMPTY clauses have similar semantics as
1738 mentioned in the description of JSON_QUERY, except the set of
1739 values returned in lieu of throwing an error is different.
1740 * Note that scalar strings returned by JSON_VALUE always have their
1741 quotes removed, equivalent to specifying OMIT QUOTES in JSON_QUERY.
1745 JSON_VALUE(jsonb '"123.45"', '$' RETURNING float) → 123.45
1747 JSON_VALUE(jsonb '"03:04 2015-02-01"',
1748 '$.datetime("HH24:MI YYYY-MM-DD")' RETURNING date) → 2015-02-01
1750 JSON_VALUE(jsonb '[1,2]', 'strict $[$off]' PASSING 1 as off) → 2
1752 JSON_VALUE(jsonb '[1,2]', 'strict $[*]' DEFAULT 9 ON ERROR) → 9
1756 The context_item expression is converted to jsonb by an implicit cast
1757 if the expression is not already of type jsonb. Note, however, that any
1758 parsing errors that occur during that conversion are thrown
1759 unconditionally, that is, are not handled according to the (specified
1760 or implicit) ON ERROR clause.
1764 JSON_VALUE() returns an SQL NULL if path_expression returns a JSON
1765 null, whereas JSON_QUERY() returns the JSON null as is.
1767 9.16.4. JSON_TABLE #
1769 JSON_TABLE is an SQL/JSON function which queries JSON data and presents
1770 the results as a relational view, which can be accessed as a regular
1771 SQL table. You can use JSON_TABLE inside the FROM clause of a SELECT,
1772 UPDATE, or DELETE and as data source in a MERGE statement.
1774 Taking JSON data as input, JSON_TABLE uses a JSON path expression to
1775 extract a part of the provided data to use as a row pattern for the
1776 constructed view. Each SQL/JSON value given by the row pattern serves
1777 as source for a separate row in the constructed view.
1779 To split the row pattern into columns, JSON_TABLE provides the COLUMNS
1780 clause that defines the schema of the created view. For each column, a
1781 separate JSON path expression can be specified to be evaluated against
1782 the row pattern to get an SQL/JSON value that will become the value for
1783 the specified column in a given output row.
1785 JSON data stored at a nested level of the row pattern can be extracted
1786 using the NESTED PATH clause. Each NESTED PATH clause can be used to
1787 generate one or more columns using the data from a nested level of the
1788 row pattern. Those columns can be specified using a COLUMNS clause that
1789 looks similar to the top-level COLUMNS clause. Rows constructed from
1790 NESTED COLUMNS are called child rows and are joined against the row
1791 constructed from the columns specified in the parent COLUMNS clause to
1792 get the row in the final view. Child columns themselves may contain a
1793 NESTED PATH specification thus allowing to extract data located at
1794 arbitrary nesting levels. Columns produced by multiple NESTED PATHs at
1795 the same level are considered to be siblings of each other and their
1796 rows after joining with the parent row are combined using UNION.
1798 The rows produced by JSON_TABLE are laterally joined to the row that
1799 generated them, so you do not have to explicitly join the constructed
1800 view with the original table holding JSON data.
1804 context_item, path_expression [ AS json_path_name ] [ PASSING { value AS var
1806 COLUMNS ( json_table_column [, ...] )
1807 [ { ERROR | EMPTY [ARRAY]} ON ERROR ]
1811 where json_table_column is:
1815 [ FORMAT JSON [ENCODING UTF8]]
1816 [ PATH path_expression ]
1817 [ { WITHOUT | WITH { CONDITIONAL | [UNCONDITIONAL] } } [ ARRAY ] WRAPPER
1819 [ { KEEP | OMIT } QUOTES [ ON SCALAR STRING ] ]
1820 [ { ERROR | NULL | EMPTY { [ARRAY] | OBJECT } | DEFAULT expression } ON
1822 [ { ERROR | NULL | EMPTY { [ARRAY] | OBJECT } | DEFAULT expression } ON
1824 | name type EXISTS [ PATH path_expression ]
1825 [ { ERROR | TRUE | FALSE | UNKNOWN } ON ERROR ]
1826 | NESTED [ PATH ] path_expression [ AS json_path_name ] COLUMNS ( json_table_c
1829 Each syntax element is described below in more detail.
1831 context_item, path_expression [ AS json_path_name ] [ PASSING { value
1832 AS varname } [, ...]]
1833 The context_item specifies the input document to query, the
1834 path_expression is an SQL/JSON path expression defining the
1835 query, and json_path_name is an optional name for the
1836 path_expression. The optional PASSING clause provides data
1837 values for the variables mentioned in the path_expression. The
1838 result of the input data evaluation using the aforementioned
1839 elements is called the row pattern, which is used as the source
1840 for row values in the constructed view.
1842 COLUMNS ( json_table_column [, ...] )
1843 The COLUMNS clause defining the schema of the constructed view.
1844 In this clause, you can specify each column to be filled with an
1845 SQL/JSON value obtained by applying a JSON path expression
1846 against the row pattern. json_table_column has the following
1850 Adds an ordinality column that provides sequential row
1851 numbering starting from 1. Each NESTED PATH (see below)
1852 gets its own counter for any nested ordinality columns.
1854 name type [FORMAT JSON [ENCODING UTF8]] [ PATH path_expression ]
1855 Inserts an SQL/JSON value obtained by applying
1856 path_expression against the row pattern into the view's
1857 output row after coercing it to specified type.
1859 Specifying FORMAT JSON makes it explicit that you expect
1860 the value to be a valid json object. It only makes sense
1861 to specify FORMAT JSON if type is one of bpchar, bytea,
1862 character varying, name, json, jsonb, text, or a domain
1865 Optionally, you can specify WRAPPER and QUOTES clauses to
1866 format the output. Note that specifying OMIT QUOTES
1867 overrides FORMAT JSON if also specified, because unquoted
1868 literals do not constitute valid json values.
1870 Optionally, you can use ON EMPTY and ON ERROR clauses to
1871 specify whether to throw the error or return the specified
1872 value when the result of JSON path evaluation is empty and
1873 when an error occurs during JSON path evaluation or when
1874 coercing the SQL/JSON value to the specified type,
1875 respectively. The default for both is to return a NULL
1880 This clause is internally turned into and has the same
1881 semantics as JSON_VALUE or JSON_QUERY. The latter if the
1882 specified type is not a scalar type or if either of FORMAT
1883 JSON, WRAPPER, or QUOTES clause is present.
1885 name type EXISTS [ PATH path_expression ]
1886 Inserts a boolean value obtained by applying
1887 path_expression against the row pattern into the view's
1888 output row after coercing it to specified type.
1890 The value corresponds to whether applying the PATH
1891 expression to the row pattern yields any values.
1893 The specified type should have a cast from the boolean
1896 Optionally, you can use ON ERROR to specify whether to
1897 throw the error or return the specified value when an
1898 error occurs during JSON path evaluation or when coercing
1899 SQL/JSON value to the specified type. The default is to
1900 return a boolean value FALSE.
1904 This clause is internally turned into and has the same
1905 semantics as JSON_EXISTS.
1907 NESTED [ PATH ] path_expression [ AS json_path_name ] COLUMNS (
1908 json_table_column [, ...] )
1909 Extracts SQL/JSON values from nested levels of the row
1910 pattern, generates one or more columns as defined by the
1911 COLUMNS subclause, and inserts the extracted SQL/JSON
1912 values into those columns. The json_table_column
1913 expression in the COLUMNS subclause uses the same syntax
1914 as in the parent COLUMNS clause.
1916 The NESTED PATH syntax is recursive, so you can go down
1917 multiple nested levels by specifying several NESTED PATH
1918 subclauses within each other. It allows to unnest the
1919 hierarchy of JSON objects and arrays in a single function
1920 invocation rather than chaining several JSON_TABLE
1921 expressions in an SQL statement.
1925 In each variant of json_table_column described above, if the
1926 PATH clause is omitted, path expression $.name is used, where
1927 name is the provided column name.
1930 The optional json_path_name serves as an identifier of the
1931 provided path_expression. The name must be unique and distinct
1932 from the column names.
1934 { ERROR | EMPTY } ON ERROR
1935 The optional ON ERROR can be used to specify how to handle
1936 errors when evaluating the top-level path_expression. Use ERROR
1937 if you want the errors to be thrown and EMPTY to return an empty
1938 table, that is, a table containing 0 rows. Note that this clause
1939 does not affect the errors that occur when evaluating columns,
1940 for which the behavior depends on whether the ON ERROR clause is
1941 specified against a given column.
1945 In the examples that follow, the following table containing JSON data
1947 CREATE TABLE my_films ( js jsonb );
1949 INSERT INTO my_films VALUES (
1951 { "kind" : "comedy", "films" : [
1952 { "title" : "Bananas",
1953 "director" : "Woody Allen"},
1954 { "title" : "The Dinner Game",
1955 "director" : "Francis Veber" } ] },
1956 { "kind" : "horror", "films" : [
1957 { "title" : "Psycho",
1958 "director" : "Alfred Hitchcock" } ] },
1959 { "kind" : "thriller", "films" : [
1960 { "title" : "Vertigo",
1961 "director" : "Alfred Hitchcock" } ] },
1962 { "kind" : "drama", "films" : [
1963 { "title" : "Yojimbo",
1964 "director" : "Akira Kurosawa" } ] }
1967 The following query shows how to use JSON_TABLE to turn the JSON
1968 objects in the my_films table to a view containing columns for the keys
1969 kind, title, and director contained in the original JSON along with an
1973 JSON_TABLE (js, '$.favorites[*]' COLUMNS (
1975 kind text PATH '$.kind',
1976 title text PATH '$.films[*].title' WITH WRAPPER,
1977 director text PATH '$.films[*].director' WITH WRAPPER)) AS jt;
1979 id | kind | title | director
1980 ----+----------+--------------------------------+-------------------------------
1982 1 | comedy | ["Bananas", "The Dinner Game"] | ["Woody Allen", "Francis Veber
1984 2 | horror | ["Psycho"] | ["Alfred Hitchcock"]
1985 3 | thriller | ["Vertigo"] | ["Alfred Hitchcock"]
1986 4 | drama | ["Yojimbo"] | ["Akira Kurosawa"]
1989 The following is a modified version of the above query to show the
1990 usage of PASSING arguments in the filter specified in the top-level
1991 JSON path expression and the various options for the individual
1995 JSON_TABLE (js, '$.favorites[*] ? (@.films[*].director == $filter)'
1996 PASSING 'Alfred Hitchcock' AS filter
1999 kind text PATH '$.kind',
2000 title text FORMAT JSON PATH '$.films[*].title' OMIT QUOTES,
2001 director text PATH '$.films[*].director' KEEP QUOTES)) AS jt;
2003 id | kind | title | director
2004 ----+----------+---------+--------------------
2005 1 | horror | Psycho | "Alfred Hitchcock"
2006 2 | thriller | Vertigo | "Alfred Hitchcock"
2009 The following is a modified version of the above query to show the
2010 usage of NESTED PATH for populating title and director columns,
2011 illustrating how they are joined to the parent columns id and kind:
2014 JSON_TABLE ( js, '$.favorites[*] ? (@.films[*].director == $filter)'
2015 PASSING 'Alfred Hitchcock' AS filter
2018 kind text PATH '$.kind',
2019 NESTED PATH '$.films[*]' COLUMNS (
2020 title text FORMAT JSON PATH '$.title' OMIT QUOTES,
2021 director text PATH '$.director' KEEP QUOTES))) AS jt;
2023 id | kind | title | director
2024 ----+----------+---------+--------------------
2025 1 | horror | Psycho | "Alfred Hitchcock"
2026 2 | thriller | Vertigo | "Alfred Hitchcock"
2029 The following is the same query but without the filter in the root
2033 JSON_TABLE ( js, '$.favorites[*]'
2036 kind text PATH '$.kind',
2037 NESTED PATH '$.films[*]' COLUMNS (
2038 title text FORMAT JSON PATH '$.title' OMIT QUOTES,
2039 director text PATH '$.director' KEEP QUOTES))) AS jt;
2041 id | kind | title | director
2042 ----+----------+-----------------+--------------------
2043 1 | comedy | Bananas | "Woody Allen"
2044 1 | comedy | The Dinner Game | "Francis Veber"
2045 2 | horror | Psycho | "Alfred Hitchcock"
2046 3 | thriller | Vertigo | "Alfred Hitchcock"
2047 4 | drama | Yojimbo | "Akira Kurosawa"
2050 The following shows another query using a different JSON object as
2051 input. It shows the UNION "sibling join" between NESTED paths
2052 $.movies[*] and $.books[*] and also the usage of FOR ORDINALITY column
2053 at NESTED levels (columns movie_id, book_id, and author_id):
2054 SELECT * FROM JSON_TABLE (
2057 [{"name": "One", "director": "John Doe"},
2058 {"name": "Two", "director": "Don Joe"}],
2060 [{"name": "Mystery", "authors": [{"name": "Brown Dan"}]},
2061 {"name": "Wonder", "authors": [{"name": "Jun Murakami"}, {"name":"Craig D
2063 }]}'::json, '$.favorites[*]'
2065 user_id FOR ORDINALITY,
2066 NESTED '$.movies[*]'
2068 movie_id FOR ORDINALITY,
2069 mname text PATH '$.name',
2073 book_id FOR ORDINALITY,
2074 bname text PATH '$.name',
2075 NESTED '$.authors[*]'
2077 author_id FOR ORDINALITY,
2078 author_name text PATH '$.name'))));
2080 user_id | movie_id | mname | director | book_id | bname | author_id | author_
2082 ---------+----------+-------+----------+---------+---------+-----------+--------
2084 1 | 1 | One | John Doe | | | |
2085 1 | 2 | Two | Don Joe | | | |
2086 1 | | | | 1 | Mystery | 1 | Brown D
2088 1 | | | | 2 | Wonder | 1 | Jun Mur
2090 1 | | | | 2 | Wonder | 2 | Craig D