1 <?xml version="1.0" encoding="UTF-8" standalone="no"?>
2 <!DOCTYPE html PUBLIC "-//W3C//DTD XHTML 1.0 Transitional//EN" "http://www.w3.org/TR/xhtml1/DTD/xhtml1-transitional.dtd"><html xmlns="http://www.w3.org/1999/xhtml"><head><meta http-equiv="Content-Type" content="text/html; charset=UTF-8" /><title>9.16. JSON Functions and Operators</title><link rel="stylesheet" type="text/css" href="stylesheet.css" /><link rev="made" href="pgsql-docs@lists.postgresql.org" /><meta name="generator" content="DocBook XSL Stylesheets Vsnapshot" /><link rel="prev" href="functions-xml.html" title="9.15. XML Functions" /><link rel="next" href="functions-sequence.html" title="9.17. Sequence Manipulation Functions" /></head><body id="docContent" class="container-fluid col-10"><div class="navheader"><table width="100%" summary="Navigation header"><tr><th colspan="5" align="center">9.16. JSON Functions and Operators</th></tr><tr><td width="10%" align="left"><a accesskey="p" href="functions-xml.html" title="9.15. XML Functions">Prev</a> </td><td width="10%" align="left"><a accesskey="u" href="functions.html" title="Chapter 9. Functions and Operators">Up</a></td><th width="60%" align="center">Chapter 9. Functions and Operators</th><td width="10%" align="right"><a accesskey="h" href="index.html" title="PostgreSQL 18.0 Documentation">Home</a></td><td width="10%" align="right"> <a accesskey="n" href="functions-sequence.html" title="9.17. Sequence Manipulation Functions">Next</a></td></tr></table><hr /></div><div class="sect1" id="FUNCTIONS-JSON"><div class="titlepage"><div><div><h2 class="title" style="clear: both">9.16. JSON Functions and Operators <a href="#FUNCTIONS-JSON" class="id_link">#</a></h2></div></div></div><div class="toc"><dl class="toc"><dt><span class="sect2"><a href="functions-json.html#FUNCTIONS-JSON-PROCESSING">9.16.1. Processing and Creating JSON Data</a></span></dt><dt><span class="sect2"><a href="functions-json.html#FUNCTIONS-SQLJSON-PATH">9.16.2. The SQL/JSON Path Language</a></span></dt><dt><span class="sect2"><a href="functions-json.html#SQLJSON-QUERY-FUNCTIONS">9.16.3. SQL/JSON Query Functions</a></span></dt><dt><span class="sect2"><a href="functions-json.html#FUNCTIONS-SQLJSON-TABLE">9.16.4. JSON_TABLE</a></span></dt></dl></div><a id="id-1.5.8.22.2" class="indexterm"></a><a id="id-1.5.8.22.3" class="indexterm"></a><p>
3 This section describes:
5 </p><div class="itemizedlist"><ul class="itemizedlist" style="list-style-type: disc; "><li class="listitem"><p>
6 functions and operators for processing and creating JSON data
7 </p></li><li class="listitem"><p>
8 the SQL/JSON path language
9 </p></li><li class="listitem"><p>
10 the SQL/JSON query functions
11 </p></li></ul></div><p>
13 To provide native support for JSON data types within the SQL environment,
14 <span class="productname">PostgreSQL</span> implements the
15 <em class="firstterm">SQL/JSON data model</em>.
16 This model comprises sequences of items. Each item can hold SQL scalar
17 values, 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 implied
19 data model in the JSON specification
20 <a class="ulink" href="https://datatracker.ietf.org/doc/html/rfc7159" target="_top">RFC 7159</a>.
22 SQL/JSON allows you to handle JSON data alongside regular SQL data,
23 with transaction support, including:
25 </p><div class="itemizedlist"><ul class="itemizedlist" style="list-style-type: disc; "><li class="listitem"><p>
26 Uploading JSON data into the database and storing it in
27 regular SQL columns as character or binary strings.
28 </p></li><li class="listitem"><p>
29 Generating JSON objects and arrays from relational data.
30 </p></li><li class="listitem"><p>
31 Querying JSON data using SQL/JSON query functions and
32 SQL/JSON path language expressions.
33 </p></li></ul></div><p>
35 To learn more about the SQL/JSON standard, see
36 <a class="xref" href="biblio.html#SQLTR-19075-6" title="SQL Technical Report">[sqltr-19075-6]</a>. For details on JSON types
37 supported in <span class="productname">PostgreSQL</span>,
38 see <a class="xref" href="datatype-json.html" title="8.14. JSON Types">Section 8.14</a>.
39 </p><div class="sect2" id="FUNCTIONS-JSON-PROCESSING"><div class="titlepage"><div><div><h3 class="title">9.16.1. Processing and Creating JSON Data <a href="#FUNCTIONS-JSON-PROCESSING" class="id_link">#</a></h3></div></div></div><p>
40 <a class="xref" href="functions-json.html#FUNCTIONS-JSON-OP-TABLE" title="Table 9.47. json and jsonb Operators">Table 9.47</a> shows the operators that
41 are available for use with JSON data types (see <a class="xref" href="datatype-json.html" title="8.14. JSON Types">Section 8.14</a>).
42 In addition, the usual comparison operators shown in <a class="xref" href="functions-comparison.html#FUNCTIONS-COMPARISON-OP-TABLE" title="Table 9.1. Comparison Operators">Table 9.1</a> are available for
43 <code class="type">jsonb</code>, though not for <code class="type">json</code>. The comparison
44 operators follow the ordering rules for B-tree operations outlined in
45 <a class="xref" href="datatype-json.html#JSON-INDEXING" title="8.14.4. jsonb Indexing">Section 8.14.4</a>.
46 See also <a class="xref" href="functions-aggregate.html" title="9.21. Aggregate Functions">Section 9.21</a> for the aggregate
47 function <code class="function">json_agg</code> which aggregates record
48 values as JSON, the aggregate function
49 <code class="function">json_object_agg</code> which aggregates pairs of values
50 into a JSON object, and their <code class="type">jsonb</code> equivalents,
51 <code class="function">jsonb_agg</code> and <code class="function">jsonb_object_agg</code>.
52 </p><div class="table" id="FUNCTIONS-JSON-OP-TABLE"><p class="title"><strong>Table 9.47. <code class="type">json</code> and <code class="type">jsonb</code> Operators</strong></p><div class="table-contents"><table class="table" summary="json and jsonb Operators" border="1"><colgroup><col /></colgroup><thead><tr><th class="func_table_entry"><p class="func_signature">
60 </p></th></tr></thead><tbody><tr><td class="func_table_entry"><p class="func_signature">
61 <code class="type">json</code> <code class="literal">-></code> <code class="type">integer</code>
62 → <code class="returnvalue">json</code>
64 <p class="func_signature">
65 <code class="type">jsonb</code> <code class="literal">-></code> <code class="type">integer</code>
66 → <code class="returnvalue">jsonb</code>
69 Extracts <em class="parameter"><code>n</code></em>'th element of JSON array
70 (array elements are indexed from zero, but negative integers count
74 <code class="literal">'[{"a":"foo"},{"b":"bar"},{"c":"baz"}]'::json -> 2</code>
75 → <code class="returnvalue">{"c":"baz"}</code>
78 <code class="literal">'[{"a":"foo"},{"b":"bar"},{"c":"baz"}]'::json -> -3</code>
79 → <code class="returnvalue">{"a":"foo"}</code>
80 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
81 <code class="type">json</code> <code class="literal">-></code> <code class="type">text</code>
82 → <code class="returnvalue">json</code>
84 <p class="func_signature">
85 <code class="type">jsonb</code> <code class="literal">-></code> <code class="type">text</code>
86 → <code class="returnvalue">jsonb</code>
89 Extracts JSON object field with the given key.
92 <code class="literal">'{"a": {"b":"foo"}}'::json -> 'a'</code>
93 → <code class="returnvalue">{"b":"foo"}</code>
94 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
95 <code class="type">json</code> <code class="literal">->></code> <code class="type">integer</code>
96 → <code class="returnvalue">text</code>
98 <p class="func_signature">
99 <code class="type">jsonb</code> <code class="literal">->></code> <code class="type">integer</code>
100 → <code class="returnvalue">text</code>
103 Extracts <em class="parameter"><code>n</code></em>'th element of JSON array,
104 as <code class="type">text</code>.
107 <code class="literal">'[1,2,3]'::json ->> 2</code>
108 → <code class="returnvalue">3</code>
109 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
110 <code class="type">json</code> <code class="literal">->></code> <code class="type">text</code>
111 → <code class="returnvalue">text</code>
113 <p class="func_signature">
114 <code class="type">jsonb</code> <code class="literal">->></code> <code class="type">text</code>
115 → <code class="returnvalue">text</code>
118 Extracts JSON object field with the given key, as <code class="type">text</code>.
121 <code class="literal">'{"a":1,"b":2}'::json ->> 'b'</code>
122 → <code class="returnvalue">2</code>
123 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
124 <code class="type">json</code> <code class="literal">#></code> <code class="type">text[]</code>
125 → <code class="returnvalue">json</code>
127 <p class="func_signature">
128 <code class="type">jsonb</code> <code class="literal">#></code> <code class="type">text[]</code>
129 → <code class="returnvalue">jsonb</code>
132 Extracts JSON sub-object at the specified path, where path elements
133 can be either field keys or array indexes.
136 <code class="literal">'{"a": {"b": ["foo","bar"]}}'::json #> '{a,b,1}'</code>
137 → <code class="returnvalue">"bar"</code>
138 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
139 <code class="type">json</code> <code class="literal">#>></code> <code class="type">text[]</code>
140 → <code class="returnvalue">text</code>
142 <p class="func_signature">
143 <code class="type">jsonb</code> <code class="literal">#>></code> <code class="type">text[]</code>
144 → <code class="returnvalue">text</code>
147 Extracts JSON sub-object at the specified path as <code class="type">text</code>.
150 <code class="literal">'{"a": {"b": ["foo","bar"]}}'::json #>> '{a,b,1}'</code>
151 → <code class="returnvalue">bar</code>
152 </p></td></tr></tbody></table></div></div><br class="table-break" /><div class="note"><h3 class="title">Note</h3><p>
153 The field/element/path extraction operators return NULL, rather than
154 failing, if the JSON input does not have the right structure to match
155 the request; for example if no such key or array element exists.
157 Some further operators exist only for <code class="type">jsonb</code>, as shown
158 in <a class="xref" href="functions-json.html#FUNCTIONS-JSONB-OP-TABLE" title="Table 9.48. Additional jsonb Operators">Table 9.48</a>.
159 <a class="xref" href="datatype-json.html#JSON-INDEXING" title="8.14.4. jsonb Indexing">Section 8.14.4</a>
160 describes how these operators can be used to effectively search indexed
161 <code class="type">jsonb</code> data.
162 </p><div class="table" id="FUNCTIONS-JSONB-OP-TABLE"><p class="title"><strong>Table 9.48. Additional <code class="type">jsonb</code> Operators</strong></p><div class="table-contents"><table class="table" summary="Additional jsonb Operators" border="1"><colgroup><col /></colgroup><thead><tr><th class="func_table_entry"><p class="func_signature">
170 </p></th></tr></thead><tbody><tr><td class="func_table_entry"><p class="func_signature">
171 <code class="type">jsonb</code> <code class="literal">@></code> <code class="type">jsonb</code>
172 → <code class="returnvalue">boolean</code>
175 Does the first JSON value contain the second?
176 (See <a class="xref" href="datatype-json.html#JSON-CONTAINMENT" title="8.14.3. jsonb Containment and Existence">Section 8.14.3</a> for details about containment.)
179 <code class="literal">'{"a":1, "b":2}'::jsonb @> '{"b":2}'::jsonb</code>
180 → <code class="returnvalue">t</code>
181 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
182 <code class="type">jsonb</code> <code class="literal"><@</code> <code class="type">jsonb</code>
183 → <code class="returnvalue">boolean</code>
186 Is the first JSON value contained in the second?
189 <code class="literal">'{"b":2}'::jsonb <@ '{"a":1, "b":2}'::jsonb</code>
190 → <code class="returnvalue">t</code>
191 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
192 <code class="type">jsonb</code> <code class="literal">?</code> <code class="type">text</code>
193 → <code class="returnvalue">boolean</code>
196 Does the text string exist as a top-level key or array element within
200 <code class="literal">'{"a":1, "b":2}'::jsonb ? 'b'</code>
201 → <code class="returnvalue">t</code>
204 <code class="literal">'["a", "b", "c"]'::jsonb ? 'b'</code>
205 → <code class="returnvalue">t</code>
206 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
207 <code class="type">jsonb</code> <code class="literal">?|</code> <code class="type">text[]</code>
208 → <code class="returnvalue">boolean</code>
211 Do any of the strings in the text array exist as top-level keys or
215 <code class="literal">'{"a":1, "b":2, "c":3}'::jsonb ?| array['b', 'd']</code>
216 → <code class="returnvalue">t</code>
217 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
218 <code class="type">jsonb</code> <code class="literal">?&</code> <code class="type">text[]</code>
219 → <code class="returnvalue">boolean</code>
222 Do all of the strings in the text array exist as top-level keys or
226 <code class="literal">'["a", "b", "c"]'::jsonb ?& array['a', 'b']</code>
227 → <code class="returnvalue">t</code>
228 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
229 <code class="type">jsonb</code> <code class="literal">||</code> <code class="type">jsonb</code>
230 → <code class="returnvalue">jsonb</code>
233 Concatenates two <code class="type">jsonb</code> values.
234 Concatenating two arrays generates an array containing all the
235 elements of each input. Concatenating two objects generates an
236 object containing the union of their
237 keys, taking the second object's value when there are duplicate keys.
238 All other cases are treated by converting a non-array input into a
239 single-element array, and then proceeding as for two arrays.
240 Does not operate recursively: only the top-level array or object
244 <code class="literal">'["a", "b"]'::jsonb || '["a", "d"]'::jsonb</code>
245 → <code class="returnvalue">["a", "b", "a", "d"]</code>
248 <code class="literal">'{"a": "b"}'::jsonb || '{"c": "d"}'::jsonb</code>
249 → <code class="returnvalue">{"a": "b", "c": "d"}</code>
252 <code class="literal">'[1, 2]'::jsonb || '3'::jsonb</code>
253 → <code class="returnvalue">[1, 2, 3]</code>
256 <code class="literal">'{"a": "b"}'::jsonb || '42'::jsonb</code>
257 → <code class="returnvalue">[{"a": "b"}, 42]</code>
260 To append an array to another array as a single entry, wrap it
261 in an additional layer of array, for example:
264 <code class="literal">'[1, 2]'::jsonb || jsonb_build_array('[3, 4]'::jsonb)</code>
265 → <code class="returnvalue">[1, 2, [3, 4]]</code>
266 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
267 <code class="type">jsonb</code> <code class="literal">-</code> <code class="type">text</code>
268 → <code class="returnvalue">jsonb</code>
271 Deletes a key (and its value) from a JSON object, or matching string
272 value(s) from a JSON array.
275 <code class="literal">'{"a": "b", "c": "d"}'::jsonb - 'a'</code>
276 → <code class="returnvalue">{"c": "d"}</code>
279 <code class="literal">'["a", "b", "c", "b"]'::jsonb - 'b'</code>
280 → <code class="returnvalue">["a", "c"]</code>
281 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
282 <code class="type">jsonb</code> <code class="literal">-</code> <code class="type">text[]</code>
283 → <code class="returnvalue">jsonb</code>
286 Deletes all matching keys or array elements from the left operand.
289 <code class="literal">'{"a": "b", "c": "d"}'::jsonb - '{a,c}'::text[]</code>
290 → <code class="returnvalue">{}</code>
291 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
292 <code class="type">jsonb</code> <code class="literal">-</code> <code class="type">integer</code>
293 → <code class="returnvalue">jsonb</code>
296 Deletes the array element with specified index (negative
297 integers count from the end). Throws an error if JSON value
301 <code class="literal">'["a", "b"]'::jsonb - 1 </code>
302 → <code class="returnvalue">["a"]</code>
303 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
304 <code class="type">jsonb</code> <code class="literal">#-</code> <code class="type">text[]</code>
305 → <code class="returnvalue">jsonb</code>
308 Deletes the field or array element at the specified path, where path
309 elements can be either field keys or array indexes.
312 <code class="literal">'["a", {"b":1}]'::jsonb #- '{1,b}'</code>
313 → <code class="returnvalue">["a", {}]</code>
314 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
315 <code class="type">jsonb</code> <code class="literal">@?</code> <code class="type">jsonpath</code>
316 → <code class="returnvalue">boolean</code>
319 Does JSON path return any item for the specified JSON value?
320 (This is useful only with SQL-standard JSON path expressions, not
321 <a class="link" href="functions-json.html#FUNCTIONS-SQLJSON-CHECK-EXPRESSIONS" title="9.16.2.1.1. Boolean Predicate Check Expressions">predicate check
322 expressions</a>, since those always return a value.)
325 <code class="literal">'{"a":[1,2,3,4,5]}'::jsonb @? '$.a[*] ? (@ > 2)'</code>
326 → <code class="returnvalue">t</code>
327 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
328 <code class="type">jsonb</code> <code class="literal">@@</code> <code class="type">jsonpath</code>
329 → <code class="returnvalue">boolean</code>
332 Returns the result of a JSON path predicate check for the
333 specified JSON value.
335 with <a class="link" href="functions-json.html#FUNCTIONS-SQLJSON-CHECK-EXPRESSIONS" title="9.16.2.1.1. Boolean Predicate Check Expressions">predicate
336 check expressions</a>, not SQL-standard JSON path expressions,
337 since it will return <code class="literal">NULL</code> if the path result is
338 not a single boolean value.)
341 <code class="literal">'{"a":[1,2,3,4,5]}'::jsonb @@ '$.a[*] > 2'</code>
342 → <code class="returnvalue">t</code>
343 </p></td></tr></tbody></table></div></div><br class="table-break" /><div class="note"><h3 class="title">Note</h3><p>
344 The <code class="type">jsonpath</code> operators <code class="literal">@?</code>
345 and <code class="literal">@@</code> suppress the following errors: missing object
346 field or array element, unexpected JSON item type, datetime and numeric
347 errors. The <code class="type">jsonpath</code>-related functions described below can
348 also be told to suppress these types of errors. This behavior might be
349 helpful when searching JSON document collections of varying structure.
351 <a class="xref" href="functions-json.html#FUNCTIONS-JSON-CREATION-TABLE" title="Table 9.49. JSON Creation Functions">Table 9.49</a> shows the functions that are
352 available for constructing <code class="type">json</code> and <code class="type">jsonb</code> values.
353 Some functions in this table have a <code class="literal">RETURNING</code> clause,
354 which specifies the data type returned. It must be one of <code class="type">json</code>,
355 <code class="type">jsonb</code>, <code class="type">bytea</code>, a character string type (<code class="type">text</code>,
356 <code class="type">char</code>, or <code class="type">varchar</code>), or a type
357 that can be cast to <code class="type">json</code>.
358 By default, the <code class="type">json</code> type is returned.
359 </p><div class="table" id="FUNCTIONS-JSON-CREATION-TABLE"><p class="title"><strong>Table 9.49. JSON Creation Functions</strong></p><div class="table-contents"><table class="table" summary="JSON Creation Functions" border="1"><colgroup><col /></colgroup><thead><tr><th class="func_table_entry"><p class="func_signature">
367 </p></th></tr></thead><tbody><tr><td class="func_table_entry"><p class="func_signature">
368 <a id="id-1.5.8.22.8.9.2.2.1.1.1.1" class="indexterm"></a>
369 <code class="function">to_json</code> ( <code class="type">anyelement</code> )
370 → <code class="returnvalue">json</code>
372 <p class="func_signature">
373 <a id="id-1.5.8.22.8.9.2.2.1.1.2.1" class="indexterm"></a>
374 <code class="function">to_jsonb</code> ( <code class="type">anyelement</code> )
375 → <code class="returnvalue">jsonb</code>
378 Converts any SQL value to <code class="type">json</code> or <code class="type">jsonb</code>.
379 Arrays and composites are converted recursively to arrays and
380 objects (multidimensional arrays become arrays of arrays in JSON).
381 Otherwise, if there is a cast from the SQL data type
382 to <code class="type">json</code>, the cast function will be used to perform the
383 conversion;<a href="#ftn.id-1.5.8.22.8.9.2.2.1.1.3.4" class="footnote"><sup class="footnote" id="id-1.5.8.22.8.9.2.2.1.1.3.4">[a]</sup></a>
384 otherwise, a scalar JSON value is produced. For any scalar other than
385 a number, a Boolean, or a null value, the text representation will be
386 used, with escaping as necessary to make it a valid JSON string value.
389 <code class="literal">to_json('Fred said "Hi."'::text)</code>
390 → <code class="returnvalue">"Fred said \"Hi.\""</code>
393 <code class="literal">to_jsonb(row(42, 'Fred said "Hi."'::text))</code>
394 → <code class="returnvalue">{"f1": 42, "f2": "Fred said \"Hi.\""}</code>
395 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
396 <a id="id-1.5.8.22.8.9.2.2.2.1.1.1" class="indexterm"></a>
397 <code class="function">array_to_json</code> ( <code class="type">anyarray</code> [<span class="optional">, <code class="type">boolean</code> </span>] )
398 → <code class="returnvalue">json</code>
401 Converts an SQL array to a JSON array. The behavior is the same
402 as <code class="function">to_json</code> except that line feeds will be added
403 between top-level array elements if the optional boolean parameter is
407 <code class="literal">array_to_json('{{1,5},{99,100}}'::int[])</code>
408 → <code class="returnvalue">[[1,5],[99,100]]</code>
409 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
410 <a id="id-1.5.8.22.8.9.2.2.3.1.1.1" class="indexterm"></a>
411 <code class="function">json_array</code> (
412 [<span class="optional"> { <em class="replaceable"><code>value_expression</code></em> [<span class="optional"> <code class="literal">FORMAT JSON</code> </span>] } [<span class="optional">, ...</span>] </span>]
413 [<span class="optional"> { <code class="literal">NULL</code> | <code class="literal">ABSENT</code> } <code class="literal">ON NULL</code> </span>]
414 [<span class="optional"> <code class="literal">RETURNING</code> <em class="replaceable"><code>data_type</code></em> [<span class="optional"> <code class="literal">FORMAT JSON</code> [<span class="optional"> <code class="literal">ENCODING UTF8</code> </span>] </span>] </span>])
416 <p class="func_signature">
417 <code class="function">json_array</code> (
418 [<span class="optional"> <em class="replaceable"><code>query_expression</code></em> </span>]
419 [<span class="optional"> <code class="literal">RETURNING</code> <em class="replaceable"><code>data_type</code></em> [<span class="optional"> <code class="literal">FORMAT JSON</code> [<span class="optional"> <code class="literal">ENCODING UTF8</code> </span>] </span>] </span>])
422 Constructs a JSON array from either a series of
423 <em class="replaceable"><code>value_expression</code></em> parameters or from the results
424 of <em class="replaceable"><code>query_expression</code></em>,
425 which must be a SELECT query returning a single column. If
426 <code class="literal">ABSENT ON NULL</code> is specified, NULL values are ignored.
427 This is always the case if a
428 <em class="replaceable"><code>query_expression</code></em> is used.
431 <code class="literal">json_array(1,true,json '{"a":null}')</code>
432 → <code class="returnvalue">[1, true, {"a":null}]</code>
435 <code class="literal">json_array(SELECT * FROM (VALUES(1),(2)) t)</code>
436 → <code class="returnvalue">[1, 2]</code>
437 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
438 <a id="id-1.5.8.22.8.9.2.2.4.1.1.1" class="indexterm"></a>
439 <code class="function">row_to_json</code> ( <code class="type">record</code> [<span class="optional">, <code class="type">boolean</code> </span>] )
440 → <code class="returnvalue">json</code>
443 Converts an SQL composite value to a JSON object. The behavior is the
444 same as <code class="function">to_json</code> except that line feeds will be
445 added between top-level elements if the optional boolean parameter is
449 <code class="literal">row_to_json(row(1,'foo'))</code>
450 → <code class="returnvalue">{"f1":1,"f2":"foo"}</code>
451 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
452 <a id="id-1.5.8.22.8.9.2.2.5.1.1.1" class="indexterm"></a>
453 <code class="function">json_build_array</code> ( <code class="literal">VARIADIC</code> <code class="type">"any"</code> )
454 → <code class="returnvalue">json</code>
456 <p class="func_signature">
457 <a id="id-1.5.8.22.8.9.2.2.5.1.2.1" class="indexterm"></a>
458 <code class="function">jsonb_build_array</code> ( <code class="literal">VARIADIC</code> <code class="type">"any"</code> )
459 → <code class="returnvalue">jsonb</code>
462 Builds a possibly-heterogeneously-typed JSON array out of a variadic
463 argument list. Each argument is converted as
464 per <code class="function">to_json</code> or <code class="function">to_jsonb</code>.
467 <code class="literal">json_build_array(1, 2, 'foo', 4, 5)</code>
468 → <code class="returnvalue">[1, 2, "foo", 4, 5]</code>
469 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
470 <a id="id-1.5.8.22.8.9.2.2.6.1.1.1" class="indexterm"></a>
471 <code class="function">json_build_object</code> ( <code class="literal">VARIADIC</code> <code class="type">"any"</code> )
472 → <code class="returnvalue">json</code>
474 <p class="func_signature">
475 <a id="id-1.5.8.22.8.9.2.2.6.1.2.1" class="indexterm"></a>
476 <code class="function">jsonb_build_object</code> ( <code class="literal">VARIADIC</code> <code class="type">"any"</code> )
477 → <code class="returnvalue">jsonb</code>
480 Builds a JSON object out of a variadic argument list. By convention,
481 the argument list consists of alternating keys and values. Key
482 arguments are coerced to text; value arguments are converted as
483 per <code class="function">to_json</code> or <code class="function">to_jsonb</code>.
486 <code class="literal">json_build_object('foo', 1, 2, row(3,'bar'))</code>
487 → <code class="returnvalue">{"foo" : 1, "2" : {"f1":3,"f2":"bar"}}</code>
488 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
489 <a id="id-1.5.8.22.8.9.2.2.7.1.1.1" class="indexterm"></a>
490 <code class="function">json_object</code> (
491 [<span class="optional"> { <em class="replaceable"><code>key_expression</code></em> { <code class="literal">VALUE</code> | ':' }
492 <em class="replaceable"><code>value_expression</code></em> [<span class="optional"> <code class="literal">FORMAT JSON</code> [<span class="optional"> <code class="literal">ENCODING UTF8</code> </span>] </span>] }[<span class="optional">, ...</span>] </span>]
493 [<span class="optional"> { <code class="literal">NULL</code> | <code class="literal">ABSENT</code> } <code class="literal">ON NULL</code> </span>]
494 [<span class="optional"> { <code class="literal">WITH</code> | <code class="literal">WITHOUT</code> } <code class="literal">UNIQUE</code> [<span class="optional"> <code class="literal">KEYS</code> </span>] </span>]
495 [<span class="optional"> <code class="literal">RETURNING</code> <em class="replaceable"><code>data_type</code></em> [<span class="optional"> <code class="literal">FORMAT JSON</code> [<span class="optional"> <code class="literal">ENCODING UTF8</code> </span>] </span>] </span>])
498 Constructs a JSON object of all the key/value pairs given,
499 or an empty object if none are given.
500 <em class="replaceable"><code>key_expression</code></em> is a scalar expression
501 defining the <acronym class="acronym">JSON</acronym> key, which is
502 converted to the <code class="type">text</code> type.
503 It cannot be <code class="literal">NULL</code> nor can it
504 belong to a type that has a cast to the <code class="type">json</code> type.
505 If <code class="literal">WITH UNIQUE KEYS</code> is specified, there must not
506 be any duplicate <em class="replaceable"><code>key_expression</code></em>.
507 Any pair for which the <em class="replaceable"><code>value_expression</code></em>
508 evaluates to <code class="literal">NULL</code> is omitted from the output
509 if <code class="literal">ABSENT ON NULL</code> is specified;
510 if <code class="literal">NULL ON NULL</code> is specified or the clause
511 omitted, the key is included with value <code class="literal">NULL</code>.
514 <code class="literal">json_object('code' VALUE 'P123', 'title': 'Jaws')</code>
515 → <code class="returnvalue">{"code" : "P123", "title" : "Jaws"}</code>
516 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
517 <a id="id-1.5.8.22.8.9.2.2.8.1.1.1" class="indexterm"></a>
518 <code class="function">json_object</code> ( <code class="type">text[]</code> )
519 → <code class="returnvalue">json</code>
521 <p class="func_signature">
522 <a id="id-1.5.8.22.8.9.2.2.8.1.2.1" class="indexterm"></a>
523 <code class="function">jsonb_object</code> ( <code class="type">text[]</code> )
524 → <code class="returnvalue">jsonb</code>
527 Builds a JSON object out of a text array. The array must have either
528 exactly one dimension with an even number of members, in which case
529 they are taken as alternating key/value pairs, or two dimensions
530 such that each inner array has exactly two elements, which
531 are taken as a key/value pair. All values are converted to JSON
535 <code class="literal">json_object('{a, 1, b, "def", c, 3.5}')</code>
536 → <code class="returnvalue">{"a" : "1", "b" : "def", "c" : "3.5"}</code>
538 <p><code class="literal">json_object('{{a, 1}, {b, "def"}, {c, 3.5}}')</code>
539 → <code class="returnvalue">{"a" : "1", "b" : "def", "c" : "3.5"}</code>
540 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
541 <code class="function">json_object</code> ( <em class="parameter"><code>keys</code></em> <code class="type">text[]</code>, <em class="parameter"><code>values</code></em> <code class="type">text[]</code> )
542 → <code class="returnvalue">json</code>
544 <p class="func_signature">
545 <code class="function">jsonb_object</code> ( <em class="parameter"><code>keys</code></em> <code class="type">text[]</code>, <em class="parameter"><code>values</code></em> <code class="type">text[]</code> )
546 → <code class="returnvalue">jsonb</code>
549 This form of <code class="function">json_object</code> takes keys and values
550 pairwise from separate text arrays. Otherwise it is identical to
551 the one-argument form.
554 <code class="literal">json_object('{a,b}', '{1,2}')</code>
555 → <code class="returnvalue">{"a": "1", "b": "2"}</code>
556 </p></td></tr><tr><td class="func_table_entry">
557 <p class="func_signature">
558 <a id="id-1.5.8.22.8.9.2.2.10.1.1.1" class="indexterm"></a>
559 <code class="function">json</code> (
560 <em class="replaceable"><code>expression</code></em>
561 [<span class="optional"> <code class="literal">FORMAT JSON</code> [<span class="optional"> <code class="literal">ENCODING UTF8</code> </span>]</span>]
562 [<span class="optional"> { <code class="literal">WITH</code> | <code class="literal">WITHOUT</code> } <code class="literal">UNIQUE</code> [<span class="optional"> <code class="literal">KEYS</code> </span>]</span>] )
563 → <code class="returnvalue">json</code>
566 Converts a given expression specified as <code class="type">text</code> or
567 <code class="type">bytea</code> string (in UTF8 encoding) into a JSON
568 value. If <em class="replaceable"><code>expression</code></em> is NULL, an
569 <acronym class="acronym">SQL</acronym> null value is returned.
570 If <code class="literal">WITH UNIQUE</code> is specified, the
571 <em class="replaceable"><code>expression</code></em> must not contain any duplicate
575 <code class="literal">json('{"a":123, "b":[true,"foo"], "a":"bar"}')</code>
576 → <code class="returnvalue">{"a":123, "b":[true,"foo"], "a":"bar"}</code>
578 </td></tr><tr><td class="func_table_entry">
579 <p class="func_signature">
580 <a id="id-1.5.8.22.8.9.2.2.11.1.1.1" class="indexterm"></a>
581 <code class="function">json_scalar</code> ( <em class="replaceable"><code>expression</code></em> )
584 Converts a given SQL scalar value into a JSON scalar value.
585 If the input is NULL, an <acronym class="acronym">SQL</acronym> null is returned. If
586 the input is number or a boolean value, a corresponding JSON number
587 or boolean value is returned. For any other value, a JSON string is
591 <code class="literal">json_scalar(123.45)</code>
592 → <code class="returnvalue">123.45</code>
595 <code class="literal">json_scalar(CURRENT_TIMESTAMP)</code>
596 → <code class="returnvalue">"2022-05-10T10:51:04.62128-04:00"</code>
597 </p></td></tr><tr><td class="func_table_entry">
598 <p class="func_signature">
599 <code class="function">json_serialize</code> (
600 <em class="replaceable"><code>expression</code></em> [<span class="optional"> <code class="literal">FORMAT JSON</code> [<span class="optional"> <code class="literal">ENCODING UTF8</code> </span>] </span>]
601 [<span class="optional"> <code class="literal">RETURNING</code> <em class="replaceable"><code>data_type</code></em> [<span class="optional"> <code class="literal">FORMAT JSON</code> [<span class="optional"> <code class="literal">ENCODING UTF8</code> </span>] </span>] </span>] )
604 Converts an SQL/JSON expression into a character or binary string. The
605 <em class="replaceable"><code>expression</code></em> can be of any JSON type, any
606 character string type, or <code class="type">bytea</code> in UTF8 encoding.
607 The returned type used in <code class="literal"> RETURNING</code> can be any
608 character string type or <code class="type">bytea</code>. The default is
609 <code class="type">text</code>.
612 <code class="literal">json_serialize('{ "a" : 1 } ' RETURNING bytea)</code>
613 → <code class="returnvalue">\x7b20226122203a2031207d20</code>
614 </p></td></tr></tbody><tbody class="footnotes"><tr><td colspan="1"><div id="ftn.id-1.5.8.22.8.9.2.2.1.1.3.4" class="footnote"><p><a href="#id-1.5.8.22.8.9.2.2.1.1.3.4" class="para"><sup class="para">[a] </sup></a>
615 For example, the <a class="xref" href="hstore.html" title="F.17. hstore — hstore key/value datatype">hstore</a> extension has a cast
616 from <code class="type">hstore</code> to <code class="type">json</code>, so that
617 <code class="type">hstore</code> values converted via the JSON creation functions
618 will be represented as JSON objects, not as primitive string values.
619 </p></div></td></tr></tbody></table></div></div><br class="table-break" /><p>
620 <a class="xref" href="functions-json.html#FUNCTIONS-SQLJSON-MISC" title="Table 9.50. SQL/JSON Testing Functions">Table 9.50</a> details SQL/JSON
621 facilities for testing JSON.
622 </p><div class="table" id="FUNCTIONS-SQLJSON-MISC"><p class="title"><strong>Table 9.50. SQL/JSON Testing Functions</strong></p><div class="table-contents"><table class="table" summary="SQL/JSON Testing Functions" border="1"><colgroup><col /></colgroup><thead><tr><th class="func_table_entry"><p class="func_signature">
630 </p></th></tr></thead><tbody><tr><td class="func_table_entry"><p class="func_signature">
631 <a id="id-1.5.8.22.8.11.2.2.1.1.1.1" class="indexterm"></a>
632 <em class="replaceable"><code>expression</code></em> <code class="literal">IS</code> [<span class="optional"> <code class="literal">NOT</code> </span>] <code class="literal">JSON</code>
633 [<span class="optional"> { <code class="literal">VALUE</code> | <code class="literal">SCALAR</code> | <code class="literal">ARRAY</code> | <code class="literal">OBJECT</code> } </span>]
634 [<span class="optional"> { <code class="literal">WITH</code> | <code class="literal">WITHOUT</code> } <code class="literal">UNIQUE</code> [<span class="optional"> <code class="literal">KEYS</code> </span>] </span>]
637 This predicate tests whether <em class="replaceable"><code>expression</code></em> can be
638 parsed as JSON, possibly of a specified type.
639 If <code class="literal">SCALAR</code> or <code class="literal">ARRAY</code> or
640 <code class="literal">OBJECT</code> is specified, the
641 test is whether or not the JSON is of that particular type. If
642 <code class="literal">WITH UNIQUE KEYS</code> is specified, then any object in the
643 <em class="replaceable"><code>expression</code></em> is also tested to see if it
647 </p><pre class="programlisting">
650 js IS JSON SCALAR "scalar?",
651 js IS JSON OBJECT "object?",
652 js IS JSON ARRAY "array?"
654 ('123'), ('"abc"'), ('{"a": "b"}'), ('[1,2]'),('abc')) foo(js);
655 js | json? | scalar? | object? | array?
656 ------------+-------+---------+---------+--------
658 "abc" | t | t | f | f
659 {"a": "b"} | t | f | t | f
660 [1,2] | t | f | f | t
665 </p><pre class="programlisting">
667 js IS JSON OBJECT "object?",
668 js IS JSON ARRAY "array?",
669 js IS JSON ARRAY WITH UNIQUE KEYS "array w. UK?",
670 js IS JSON ARRAY WITHOUT UNIQUE KEYS "array w/o UK?"
671 FROM (VALUES ('[{"a":"1"},
672 {"b":"2","b":"3"}]')) foo(js);
673 -[ RECORD 1 ]-+--------------------
681 </p></td></tr></tbody></table></div></div><br class="table-break" /><p>
682 <a class="xref" href="functions-json.html#FUNCTIONS-JSON-PROCESSING-TABLE" title="Table 9.51. JSON Processing Functions">Table 9.51</a> shows the functions that
683 are available for processing <code class="type">json</code> and <code class="type">jsonb</code> values.
684 </p><div class="table" id="FUNCTIONS-JSON-PROCESSING-TABLE"><p class="title"><strong>Table 9.51. JSON Processing Functions</strong></p><div class="table-contents"><table class="table" summary="JSON Processing Functions" border="1"><colgroup><col /></colgroup><thead><tr><th class="func_table_entry"><p class="func_signature">
692 </p></th></tr></thead><tbody><tr><td class="func_table_entry"><p class="func_signature">
693 <a id="id-1.5.8.22.8.13.2.2.1.1.1.1" class="indexterm"></a>
694 <code class="function">json_array_elements</code> ( <code class="type">json</code> )
695 → <code class="returnvalue">setof json</code>
697 <p class="func_signature">
698 <a id="id-1.5.8.22.8.13.2.2.1.1.2.1" class="indexterm"></a>
699 <code class="function">jsonb_array_elements</code> ( <code class="type">jsonb</code> )
700 → <code class="returnvalue">setof jsonb</code>
703 Expands the top-level JSON array into a set of JSON values.
706 <code class="literal">select * from json_array_elements('[1,true, [2,false]]')</code>
707 → <code class="returnvalue"></code>
708 </p><pre class="programlisting">
715 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
716 <a id="id-1.5.8.22.8.13.2.2.2.1.1.1" class="indexterm"></a>
717 <code class="function">json_array_elements_text</code> ( <code class="type">json</code> )
718 → <code class="returnvalue">setof text</code>
720 <p class="func_signature">
721 <a id="id-1.5.8.22.8.13.2.2.2.1.2.1" class="indexterm"></a>
722 <code class="function">jsonb_array_elements_text</code> ( <code class="type">jsonb</code> )
723 → <code class="returnvalue">setof text</code>
726 Expands the top-level JSON array into a set of <code class="type">text</code> values.
729 <code class="literal">select * from json_array_elements_text('["foo", "bar"]')</code>
730 → <code class="returnvalue"></code>
731 </p><pre class="programlisting">
737 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
738 <a id="id-1.5.8.22.8.13.2.2.3.1.1.1" class="indexterm"></a>
739 <code class="function">json_array_length</code> ( <code class="type">json</code> )
740 → <code class="returnvalue">integer</code>
742 <p class="func_signature">
743 <a id="id-1.5.8.22.8.13.2.2.3.1.2.1" class="indexterm"></a>
744 <code class="function">jsonb_array_length</code> ( <code class="type">jsonb</code> )
745 → <code class="returnvalue">integer</code>
748 Returns the number of elements in the top-level JSON array.
751 <code class="literal">json_array_length('[1,2,3,{"f1":1,"f2":[5,6]},4]')</code>
752 → <code class="returnvalue">5</code>
755 <code class="literal">jsonb_array_length('[]')</code>
756 → <code class="returnvalue">0</code>
757 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
758 <a id="id-1.5.8.22.8.13.2.2.4.1.1.1" class="indexterm"></a>
759 <code class="function">json_each</code> ( <code class="type">json</code> )
760 → <code class="returnvalue">setof record</code>
761 ( <em class="parameter"><code>key</code></em> <code class="type">text</code>,
762 <em class="parameter"><code>value</code></em> <code class="type">json</code> )
764 <p class="func_signature">
765 <a id="id-1.5.8.22.8.13.2.2.4.1.2.1" class="indexterm"></a>
766 <code class="function">jsonb_each</code> ( <code class="type">jsonb</code> )
767 → <code class="returnvalue">setof record</code>
768 ( <em class="parameter"><code>key</code></em> <code class="type">text</code>,
769 <em class="parameter"><code>value</code></em> <code class="type">jsonb</code> )
772 Expands the top-level JSON object into a set of key/value pairs.
775 <code class="literal">select * from json_each('{"a":"foo", "b":"bar"}')</code>
776 → <code class="returnvalue"></code>
777 </p><pre class="programlisting">
783 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
784 <a id="id-1.5.8.22.8.13.2.2.5.1.1.1" class="indexterm"></a>
785 <code class="function">json_each_text</code> ( <code class="type">json</code> )
786 → <code class="returnvalue">setof record</code>
787 ( <em class="parameter"><code>key</code></em> <code class="type">text</code>,
788 <em class="parameter"><code>value</code></em> <code class="type">text</code> )
790 <p class="func_signature">
791 <a id="id-1.5.8.22.8.13.2.2.5.1.2.1" class="indexterm"></a>
792 <code class="function">jsonb_each_text</code> ( <code class="type">jsonb</code> )
793 → <code class="returnvalue">setof record</code>
794 ( <em class="parameter"><code>key</code></em> <code class="type">text</code>,
795 <em class="parameter"><code>value</code></em> <code class="type">text</code> )
798 Expands the top-level JSON object into a set of key/value pairs.
799 The returned <em class="parameter"><code>value</code></em>s will be of
800 type <code class="type">text</code>.
803 <code class="literal">select * from json_each_text('{"a":"foo", "b":"bar"}')</code>
804 → <code class="returnvalue"></code>
805 </p><pre class="programlisting">
811 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
812 <a id="id-1.5.8.22.8.13.2.2.6.1.1.1" class="indexterm"></a>
813 <code class="function">json_extract_path</code> ( <em class="parameter"><code>from_json</code></em> <code class="type">json</code>, <code class="literal">VARIADIC</code> <em class="parameter"><code>path_elems</code></em> <code class="type">text[]</code> )
814 → <code class="returnvalue">json</code>
816 <p class="func_signature">
817 <a id="id-1.5.8.22.8.13.2.2.6.1.2.1" class="indexterm"></a>
818 <code class="function">jsonb_extract_path</code> ( <em class="parameter"><code>from_json</code></em> <code class="type">jsonb</code>, <code class="literal">VARIADIC</code> <em class="parameter"><code>path_elems</code></em> <code class="type">text[]</code> )
819 → <code class="returnvalue">jsonb</code>
822 Extracts JSON sub-object at the specified path.
823 (This is functionally equivalent to the <code class="literal">#></code>
824 operator, but writing the path out as a variadic list can be more
825 convenient in some cases.)
828 <code class="literal">json_extract_path('{"f2":{"f3":1},"f4":{"f5":99,"f6":"foo"}}', 'f4', 'f6')</code>
829 → <code class="returnvalue">"foo"</code>
830 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
831 <a id="id-1.5.8.22.8.13.2.2.7.1.1.1" class="indexterm"></a>
832 <code class="function">json_extract_path_text</code> ( <em class="parameter"><code>from_json</code></em> <code class="type">json</code>, <code class="literal">VARIADIC</code> <em class="parameter"><code>path_elems</code></em> <code class="type">text[]</code> )
833 → <code class="returnvalue">text</code>
835 <p class="func_signature">
836 <a id="id-1.5.8.22.8.13.2.2.7.1.2.1" class="indexterm"></a>
837 <code class="function">jsonb_extract_path_text</code> ( <em class="parameter"><code>from_json</code></em> <code class="type">jsonb</code>, <code class="literal">VARIADIC</code> <em class="parameter"><code>path_elems</code></em> <code class="type">text[]</code> )
838 → <code class="returnvalue">text</code>
841 Extracts JSON sub-object at the specified path as <code class="type">text</code>.
842 (This is functionally equivalent to the <code class="literal">#>></code>
846 <code class="literal">json_extract_path_text('{"f2":{"f3":1},"f4":{"f5":99,"f6":"foo"}}', 'f4', 'f6')</code>
847 → <code class="returnvalue">foo</code>
848 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
849 <a id="id-1.5.8.22.8.13.2.2.8.1.1.1" class="indexterm"></a>
850 <code class="function">json_object_keys</code> ( <code class="type">json</code> )
851 → <code class="returnvalue">setof text</code>
853 <p class="func_signature">
854 <a id="id-1.5.8.22.8.13.2.2.8.1.2.1" class="indexterm"></a>
855 <code class="function">jsonb_object_keys</code> ( <code class="type">jsonb</code> )
856 → <code class="returnvalue">setof text</code>
859 Returns the set of keys in the top-level JSON object.
862 <code class="literal">select * from json_object_keys('{"f1":"abc","f2":{"f3":"a", "f4":"b"}}')</code>
863 → <code class="returnvalue"></code>
864 </p><pre class="programlisting">
870 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
871 <a id="id-1.5.8.22.8.13.2.2.9.1.1.1" class="indexterm"></a>
872 <code class="function">json_populate_record</code> ( <em class="parameter"><code>base</code></em> <code class="type">anyelement</code>, <em class="parameter"><code>from_json</code></em> <code class="type">json</code> )
873 → <code class="returnvalue">anyelement</code>
875 <p class="func_signature">
876 <a id="id-1.5.8.22.8.13.2.2.9.1.2.1" class="indexterm"></a>
877 <code class="function">jsonb_populate_record</code> ( <em class="parameter"><code>base</code></em> <code class="type">anyelement</code>, <em class="parameter"><code>from_json</code></em> <code class="type">jsonb</code> )
878 → <code class="returnvalue">anyelement</code>
881 Expands the top-level JSON object to a row having the composite type
882 of the <em class="parameter"><code>base</code></em> argument. The JSON object
883 is scanned for fields whose names match column names of the output row
884 type, and their values are inserted into those columns of the output.
885 (Fields that do not correspond to any output column name are ignored.)
886 In typical use, the value of <em class="parameter"><code>base</code></em> is just
887 <code class="literal">NULL</code>, which means that any output columns that do
888 not match any object field will be filled with nulls. However,
889 if <em class="parameter"><code>base</code></em> isn't <code class="literal">NULL</code> then
890 the values it contains will be used for unmatched columns.
893 To convert a JSON value to the SQL type of an output column, the
894 following rules are applied in sequence:
895 </p><div class="itemizedlist"><ul class="itemizedlist compact" style="list-style-type: disc; "><li class="listitem"><p>
896 A JSON null value is converted to an SQL null in all cases.
897 </p></li><li class="listitem"><p>
898 If the output column is of type <code class="type">json</code>
899 or <code class="type">jsonb</code>, the JSON value is just reproduced exactly.
900 </p></li><li class="listitem"><p>
901 If the output column is a composite (row) type, and the JSON value
902 is a JSON object, the fields of the object are converted to columns
903 of the output row type by recursive application of these rules.
904 </p></li><li class="listitem"><p>
905 Likewise, if the output column is an array type and the JSON value
906 is a JSON array, the elements of the JSON array are converted to
907 elements of the output array by recursive application of these
909 </p></li><li class="listitem"><p>
910 Otherwise, if the JSON value is a string, the contents of the
911 string are fed to the input conversion function for the column's
913 </p></li><li class="listitem"><p>
914 Otherwise, the ordinary text representation of the JSON value is
915 fed to the input conversion function for the column's data type.
916 </p></li></ul></div><p>
919 While the example below uses a constant JSON value, typical use would
920 be to reference a <code class="type">json</code> or <code class="type">jsonb</code> column
921 laterally from another table in the query's <code class="literal">FROM</code>
922 clause. Writing <code class="function">json_populate_record</code> in
923 the <code class="literal">FROM</code> clause is good practice, since all of the
924 extracted columns are available for use without duplicate function
928 <code class="literal">create type subrowtype as (d int, e text);</code>
929 <code class="literal">create type myrowtype as (a int, b text[], c subrowtype);</code>
932 <code class="literal">select * from json_populate_record(null::myrowtype,
933 '{"a": 1, "b": ["2", "a b"], "c": {"d": 4, "e": "a b c"}, "x": "foo"}')</code>
934 → <code class="returnvalue"></code>
935 </p><pre class="programlisting">
937 ---+-----------+-------------
938 1 | {2,"a b"} | (4,"a b c")
940 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
941 <a id="id-1.5.8.22.8.13.2.2.10.1.1.1" class="indexterm"></a>
942 <code class="function">jsonb_populate_record_valid</code> ( <em class="parameter"><code>base</code></em> <code class="type">anyelement</code>, <em class="parameter"><code>from_json</code></em> <code class="type">json</code> )
943 → <code class="returnvalue">boolean</code>
946 Function for testing <code class="function">jsonb_populate_record</code>. Returns
947 <code class="literal">true</code> if the input <code class="function">jsonb_populate_record</code>
948 would finish without an error for the given input JSON object; that is, it's
949 valid input, <code class="literal">false</code> otherwise.
952 <code class="literal">create type jsb_char2 as (a char(2));</code>
955 <code class="literal">select jsonb_populate_record_valid(NULL::jsb_char2, '{"a": "aaa"}');</code>
956 → <code class="returnvalue"></code>
957 </p><pre class="programlisting">
958 jsonb_populate_record_valid
959 -----------------------------
964 <code class="literal">select * from jsonb_populate_record(NULL::jsb_char2, '{"a": "aaa"}') q;</code>
965 → <code class="returnvalue"></code>
966 </p><pre class="programlisting">
967 ERROR: value too long for type character(2)
969 <code class="literal">select jsonb_populate_record_valid(NULL::jsb_char2, '{"a": "aa"}');</code>
970 → <code class="returnvalue"></code>
971 </p><pre class="programlisting">
972 jsonb_populate_record_valid
973 -----------------------------
978 <code class="literal">select * from jsonb_populate_record(NULL::jsb_char2, '{"a": "aa"}') q;</code>
979 → <code class="returnvalue"></code>
980 </p><pre class="programlisting">
986 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
987 <a id="id-1.5.8.22.8.13.2.2.11.1.1.1" class="indexterm"></a>
988 <code class="function">json_populate_recordset</code> ( <em class="parameter"><code>base</code></em> <code class="type">anyelement</code>, <em class="parameter"><code>from_json</code></em> <code class="type">json</code> )
989 → <code class="returnvalue">setof anyelement</code>
991 <p class="func_signature">
992 <a id="id-1.5.8.22.8.13.2.2.11.1.2.1" class="indexterm"></a>
993 <code class="function">jsonb_populate_recordset</code> ( <em class="parameter"><code>base</code></em> <code class="type">anyelement</code>, <em class="parameter"><code>from_json</code></em> <code class="type">jsonb</code> )
994 → <code class="returnvalue">setof anyelement</code>
997 Expands the top-level JSON array of objects to a set of rows having
998 the composite type of the <em class="parameter"><code>base</code></em> argument.
999 Each element of the JSON array is processed as described above
1000 for <code class="function">json[b]_populate_record</code>.
1003 <code class="literal">create type twoints as (a int, b int);</code>
1006 <code class="literal">select * from json_populate_recordset(null::twoints, '[{"a":1,"b":2}, {"a":3,"b":4}]')</code>
1007 → <code class="returnvalue"></code>
1008 </p><pre class="programlisting">
1014 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
1015 <a id="id-1.5.8.22.8.13.2.2.12.1.1.1" class="indexterm"></a>
1016 <code class="function">json_to_record</code> ( <code class="type">json</code> )
1017 → <code class="returnvalue">record</code>
1019 <p class="func_signature">
1020 <a id="id-1.5.8.22.8.13.2.2.12.1.2.1" class="indexterm"></a>
1021 <code class="function">jsonb_to_record</code> ( <code class="type">jsonb</code> )
1022 → <code class="returnvalue">record</code>
1025 Expands the top-level JSON object to a row having the composite type
1026 defined by an <code class="literal">AS</code> clause. (As with all functions
1027 returning <code class="type">record</code>, the calling query must explicitly
1028 define the structure of the record with an <code class="literal">AS</code>
1029 clause.) The output record is filled from fields of the JSON object,
1030 in the same way as described above
1031 for <code class="function">json[b]_populate_record</code>. Since there is no
1032 input record value, unmatched columns are always filled with nulls.
1035 <code class="literal">create type myrowtype as (a int, b text);</code>
1038 <code class="literal">select * from json_to_record('{"a":1,"b":[1,2,3],"c":[1,2,3],"e":"bar","r": {"a": 123, "b": "a b c"}}') as x(a int, b text, c int[], d text, r myrowtype)</code>
1039 → <code class="returnvalue"></code>
1040 </p><pre class="programlisting">
1042 ---+---------+---------+---+---------------
1043 1 | [1,2,3] | {1,2,3} | | (123,"a b c")
1045 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
1046 <a id="id-1.5.8.22.8.13.2.2.13.1.1.1" class="indexterm"></a>
1047 <code class="function">json_to_recordset</code> ( <code class="type">json</code> )
1048 → <code class="returnvalue">setof record</code>
1050 <p class="func_signature">
1051 <a id="id-1.5.8.22.8.13.2.2.13.1.2.1" class="indexterm"></a>
1052 <code class="function">jsonb_to_recordset</code> ( <code class="type">jsonb</code> )
1053 → <code class="returnvalue">setof record</code>
1056 Expands the top-level JSON array of objects to a set of rows having
1057 the composite type defined by an <code class="literal">AS</code> clause. (As
1058 with all functions returning <code class="type">record</code>, the calling query
1059 must explicitly define the structure of the record with
1060 an <code class="literal">AS</code> clause.) Each element of the JSON array is
1061 processed as described above
1062 for <code class="function">json[b]_populate_record</code>.
1065 <code class="literal">select * from json_to_recordset('[{"a":1,"b":"foo"}, {"a":"2","c":"bar"}]') as x(a int, b text)</code>
1066 → <code class="returnvalue"></code>
1067 </p><pre class="programlisting">
1073 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
1074 <a id="id-1.5.8.22.8.13.2.2.14.1.1.1" class="indexterm"></a>
1075 <code class="function">jsonb_set</code> ( <em class="parameter"><code>target</code></em> <code class="type">jsonb</code>, <em class="parameter"><code>path</code></em> <code class="type">text[]</code>, <em class="parameter"><code>new_value</code></em> <code class="type">jsonb</code> [<span class="optional">, <em class="parameter"><code>create_if_missing</code></em> <code class="type">boolean</code> </span>] )
1076 → <code class="returnvalue">jsonb</code>
1079 Returns <em class="parameter"><code>target</code></em>
1080 with the item designated by <em class="parameter"><code>path</code></em>
1081 replaced by <em class="parameter"><code>new_value</code></em>, or with
1082 <em class="parameter"><code>new_value</code></em> added if
1083 <em class="parameter"><code>create_if_missing</code></em> is true (which is the
1084 default) and the item designated by <em class="parameter"><code>path</code></em>
1086 All earlier steps in the path must exist, or
1087 the <em class="parameter"><code>target</code></em> is returned unchanged.
1088 As with the path oriented operators, negative integers that
1089 appear in the <em class="parameter"><code>path</code></em> count from the end
1091 If the last path step is an array index that is out of range,
1092 and <em class="parameter"><code>create_if_missing</code></em> is true, the new
1093 value is added at the beginning of the array if the index is negative,
1094 or at the end of the array if it is positive.
1097 <code class="literal">jsonb_set('[{"f1":1,"f2":null},2,null,3]', '{0,f1}', '[2,3,4]', false)</code>
1098 → <code class="returnvalue">[{"f1": [2, 3, 4], "f2": null}, 2, null, 3]</code>
1101 <code class="literal">jsonb_set('[{"f1":1,"f2":null},2]', '{0,f3}', '[2,3,4]')</code>
1102 → <code class="returnvalue">[{"f1": 1, "f2": null, "f3": [2, 3, 4]}, 2]</code>
1103 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
1104 <a id="id-1.5.8.22.8.13.2.2.15.1.1.1" class="indexterm"></a>
1105 <code class="function">jsonb_set_lax</code> ( <em class="parameter"><code>target</code></em> <code class="type">jsonb</code>, <em class="parameter"><code>path</code></em> <code class="type">text[]</code>, <em class="parameter"><code>new_value</code></em> <code class="type">jsonb</code> [<span class="optional">, <em class="parameter"><code>create_if_missing</code></em> <code class="type">boolean</code> [<span class="optional">, <em class="parameter"><code>null_value_treatment</code></em> <code class="type">text</code> </span>]</span>] )
1106 → <code class="returnvalue">jsonb</code>
1109 If <em class="parameter"><code>new_value</code></em> is not <code class="literal">NULL</code>,
1110 behaves identically to <code class="literal">jsonb_set</code>. Otherwise behaves
1111 according to the value
1112 of <em class="parameter"><code>null_value_treatment</code></em> which must be one
1113 of <code class="literal">'raise_exception'</code>,
1114 <code class="literal">'use_json_null'</code>, <code class="literal">'delete_key'</code>, or
1115 <code class="literal">'return_target'</code>. The default is
1116 <code class="literal">'use_json_null'</code>.
1119 <code class="literal">jsonb_set_lax('[{"f1":1,"f2":null},2,null,3]', '{0,f1}', null)</code>
1120 → <code class="returnvalue">[{"f1": null, "f2": null}, 2, null, 3]</code>
1123 <code class="literal">jsonb_set_lax('[{"f1":99,"f2":null},2]', '{0,f3}', null, true, 'return_target')</code>
1124 → <code class="returnvalue">[{"f1": 99, "f2": null}, 2]</code>
1125 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
1126 <a id="id-1.5.8.22.8.13.2.2.16.1.1.1" class="indexterm"></a>
1127 <code class="function">jsonb_insert</code> ( <em class="parameter"><code>target</code></em> <code class="type">jsonb</code>, <em class="parameter"><code>path</code></em> <code class="type">text[]</code>, <em class="parameter"><code>new_value</code></em> <code class="type">jsonb</code> [<span class="optional">, <em class="parameter"><code>insert_after</code></em> <code class="type">boolean</code> </span>] )
1128 → <code class="returnvalue">jsonb</code>
1131 Returns <em class="parameter"><code>target</code></em>
1132 with <em class="parameter"><code>new_value</code></em> inserted. If the item
1133 designated by the <em class="parameter"><code>path</code></em> is an array
1134 element, <em class="parameter"><code>new_value</code></em> will be inserted before
1135 that item if <em class="parameter"><code>insert_after</code></em> is false (which
1136 is the default), or after it
1137 if <em class="parameter"><code>insert_after</code></em> is true. If the item
1138 designated by the <em class="parameter"><code>path</code></em> is an object
1139 field, <em class="parameter"><code>new_value</code></em> will be inserted only if
1140 the object does not already contain that key.
1141 All earlier steps in the path must exist, or
1142 the <em class="parameter"><code>target</code></em> is returned unchanged.
1143 As with the path oriented operators, negative integers that
1144 appear in the <em class="parameter"><code>path</code></em> count from the end
1146 If the last path step is an array index that is out of range, the new
1147 value is added at the beginning of the array if the index is negative,
1148 or at the end of the array if it is positive.
1151 <code class="literal">jsonb_insert('{"a": [0,1,2]}', '{a, 1}', '"new_value"')</code>
1152 → <code class="returnvalue">{"a": [0, "new_value", 1, 2]}</code>
1155 <code class="literal">jsonb_insert('{"a": [0,1,2]}', '{a, 1}', '"new_value"', true)</code>
1156 → <code class="returnvalue">{"a": [0, 1, "new_value", 2]}</code>
1157 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
1158 <a id="id-1.5.8.22.8.13.2.2.17.1.1.1" class="indexterm"></a>
1159 <code class="function">json_strip_nulls</code> ( <em class="parameter"><code>target</code></em> <code class="type">json</code> [<span class="optional">,<em class="parameter"><code>strip_in_arrays</code></em> <code class="type">boolean</code> </span>] )
1160 → <code class="returnvalue">json</code>
1162 <p class="func_signature">
1163 <a id="id-1.5.8.22.8.13.2.2.17.1.2.1" class="indexterm"></a>
1164 <code class="function">jsonb_strip_nulls</code> ( <em class="parameter"><code>target</code></em> <code class="type">jsonb</code> [<span class="optional">,<em class="parameter"><code>strip_in_arrays</code></em> <code class="type">boolean</code> </span>] )
1165 → <code class="returnvalue">jsonb</code>
1168 Deletes all object fields that have null values from the given JSON
1170 If <em class="parameter"><code>strip_in_arrays</code></em> is true (the default is false),
1171 null array elements are also stripped.
1172 Otherwise they are not stripped. Bare null values are never stripped.
1175 <code class="literal">json_strip_nulls('[{"f1":1, "f2":null}, 2, null, 3]')</code>
1176 → <code class="returnvalue">[{"f1":1},2,null,3]</code>
1179 <code class="literal">jsonb_strip_nulls('[1,2,null,3,4]', true);</code>
1180 → <code class="returnvalue">[1,2,3,4]</code>
1182 </td></tr><tr><td class="func_table_entry"><p class="func_signature">
1183 <a id="id-1.5.8.22.8.13.2.2.18.1.1.1" class="indexterm"></a>
1184 <code class="function">jsonb_path_exists</code> ( <em class="parameter"><code>target</code></em> <code class="type">jsonb</code>, <em class="parameter"><code>path</code></em> <code class="type">jsonpath</code> [<span class="optional">, <em class="parameter"><code>vars</code></em> <code class="type">jsonb</code> [<span class="optional">, <em class="parameter"><code>silent</code></em> <code class="type">boolean</code> </span>]</span>] )
1185 → <code class="returnvalue">boolean</code>
1188 Checks whether the JSON path returns any item for the specified JSON
1190 (This is useful only with SQL-standard JSON path expressions, not
1191 <a class="link" href="functions-json.html#FUNCTIONS-SQLJSON-CHECK-EXPRESSIONS" title="9.16.2.1.1. Boolean Predicate Check Expressions">predicate check
1192 expressions</a>, since those always return a value.)
1193 If the <em class="parameter"><code>vars</code></em> argument is specified, it must
1194 be a JSON object, and its fields provide named values to be
1195 substituted into the <code class="type">jsonpath</code> expression.
1196 If the <em class="parameter"><code>silent</code></em> argument is specified and
1197 is <code class="literal">true</code>, the function suppresses the same errors
1198 as the <code class="literal">@?</code> and <code class="literal">@@</code> operators do.
1201 <code class="literal">jsonb_path_exists('{"a":[1,2,3,4,5]}', '$.a[*] ? (@ >= $min && @ <= $max)', '{"min":2, "max":4}')</code>
1202 → <code class="returnvalue">t</code>
1203 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
1204 <a id="id-1.5.8.22.8.13.2.2.19.1.1.1" class="indexterm"></a>
1205 <code class="function">jsonb_path_match</code> ( <em class="parameter"><code>target</code></em> <code class="type">jsonb</code>, <em class="parameter"><code>path</code></em> <code class="type">jsonpath</code> [<span class="optional">, <em class="parameter"><code>vars</code></em> <code class="type">jsonb</code> [<span class="optional">, <em class="parameter"><code>silent</code></em> <code class="type">boolean</code> </span>]</span>] )
1206 → <code class="returnvalue">boolean</code>
1209 Returns the SQL boolean result of a JSON path predicate check
1210 for the specified JSON value.
1211 (This is useful only
1212 with <a class="link" href="functions-json.html#FUNCTIONS-SQLJSON-CHECK-EXPRESSIONS" title="9.16.2.1.1. Boolean Predicate Check Expressions">predicate
1213 check expressions</a>, not SQL-standard JSON path expressions,
1214 since it will either fail or return <code class="literal">NULL</code> if the
1215 path result is not a single boolean value.)
1216 The optional <em class="parameter"><code>vars</code></em>
1217 and <em class="parameter"><code>silent</code></em> arguments act the same as
1218 for <code class="function">jsonb_path_exists</code>.
1221 <code class="literal">jsonb_path_match('{"a":[1,2,3,4,5]}', 'exists($.a[*] ? (@ >= $min && @ <= $max))', '{"min":2, "max":4}')</code>
1222 → <code class="returnvalue">t</code>
1223 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
1224 <a id="id-1.5.8.22.8.13.2.2.20.1.1.1" class="indexterm"></a>
1225 <code class="function">jsonb_path_query</code> ( <em class="parameter"><code>target</code></em> <code class="type">jsonb</code>, <em class="parameter"><code>path</code></em> <code class="type">jsonpath</code> [<span class="optional">, <em class="parameter"><code>vars</code></em> <code class="type">jsonb</code> [<span class="optional">, <em class="parameter"><code>silent</code></em> <code class="type">boolean</code> </span>]</span>] )
1226 → <code class="returnvalue">setof jsonb</code>
1229 Returns all JSON items returned by the JSON path for the specified
1231 For SQL-standard JSON path expressions it returns the JSON
1232 values selected from <em class="parameter"><code>target</code></em>.
1233 For <a class="link" href="functions-json.html#FUNCTIONS-SQLJSON-CHECK-EXPRESSIONS" title="9.16.2.1.1. Boolean Predicate Check Expressions">predicate
1234 check expressions</a> it returns the result of the predicate
1235 check: <code class="literal">true</code>, <code class="literal">false</code>,
1236 or <code class="literal">null</code>.
1237 The optional <em class="parameter"><code>vars</code></em>
1238 and <em class="parameter"><code>silent</code></em> arguments act the same as
1239 for <code class="function">jsonb_path_exists</code>.
1242 <code class="literal">select * from jsonb_path_query('{"a":[1,2,3,4,5]}', '$.a[*] ? (@ >= $min && @ <= $max)', '{"min":2, "max":4}')</code>
1243 → <code class="returnvalue"></code>
1244 </p><pre class="programlisting">
1251 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
1252 <a id="id-1.5.8.22.8.13.2.2.21.1.1.1" class="indexterm"></a>
1253 <code class="function">jsonb_path_query_array</code> ( <em class="parameter"><code>target</code></em> <code class="type">jsonb</code>, <em class="parameter"><code>path</code></em> <code class="type">jsonpath</code> [<span class="optional">, <em class="parameter"><code>vars</code></em> <code class="type">jsonb</code> [<span class="optional">, <em class="parameter"><code>silent</code></em> <code class="type">boolean</code> </span>]</span>] )
1254 → <code class="returnvalue">jsonb</code>
1257 Returns all JSON items returned by the JSON path for the specified
1258 JSON value, as a JSON array.
1259 The parameters are the same as
1260 for <code class="function">jsonb_path_query</code>.
1263 <code class="literal">jsonb_path_query_array('{"a":[1,2,3,4,5]}', '$.a[*] ? (@ >= $min && @ <= $max)', '{"min":2, "max":4}')</code>
1264 → <code class="returnvalue">[2, 3, 4]</code>
1265 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
1266 <a id="id-1.5.8.22.8.13.2.2.22.1.1.1" class="indexterm"></a>
1267 <code class="function">jsonb_path_query_first</code> ( <em class="parameter"><code>target</code></em> <code class="type">jsonb</code>, <em class="parameter"><code>path</code></em> <code class="type">jsonpath</code> [<span class="optional">, <em class="parameter"><code>vars</code></em> <code class="type">jsonb</code> [<span class="optional">, <em class="parameter"><code>silent</code></em> <code class="type">boolean</code> </span>]</span>] )
1268 → <code class="returnvalue">jsonb</code>
1271 Returns the first JSON item returned by the JSON path for the
1272 specified JSON value, or <code class="literal">NULL</code> if there are no
1274 The parameters are the same as
1275 for <code class="function">jsonb_path_query</code>.
1278 <code class="literal">jsonb_path_query_first('{"a":[1,2,3,4,5]}', '$.a[*] ? (@ >= $min && @ <= $max)', '{"min":2, "max":4}')</code>
1279 → <code class="returnvalue">2</code>
1280 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
1281 <a id="id-1.5.8.22.8.13.2.2.23.1.1.1" class="indexterm"></a>
1282 <code class="function">jsonb_path_exists_tz</code> ( <em class="parameter"><code>target</code></em> <code class="type">jsonb</code>, <em class="parameter"><code>path</code></em> <code class="type">jsonpath</code> [<span class="optional">, <em class="parameter"><code>vars</code></em> <code class="type">jsonb</code> [<span class="optional">, <em class="parameter"><code>silent</code></em> <code class="type">boolean</code> </span>]</span>] )
1283 → <code class="returnvalue">boolean</code>
1285 <p class="func_signature">
1286 <a id="id-1.5.8.22.8.13.2.2.23.1.2.1" class="indexterm"></a>
1287 <code class="function">jsonb_path_match_tz</code> ( <em class="parameter"><code>target</code></em> <code class="type">jsonb</code>, <em class="parameter"><code>path</code></em> <code class="type">jsonpath</code> [<span class="optional">, <em class="parameter"><code>vars</code></em> <code class="type">jsonb</code> [<span class="optional">, <em class="parameter"><code>silent</code></em> <code class="type">boolean</code> </span>]</span>] )
1288 → <code class="returnvalue">boolean</code>
1290 <p class="func_signature">
1291 <a id="id-1.5.8.22.8.13.2.2.23.1.3.1" class="indexterm"></a>
1292 <code class="function">jsonb_path_query_tz</code> ( <em class="parameter"><code>target</code></em> <code class="type">jsonb</code>, <em class="parameter"><code>path</code></em> <code class="type">jsonpath</code> [<span class="optional">, <em class="parameter"><code>vars</code></em> <code class="type">jsonb</code> [<span class="optional">, <em class="parameter"><code>silent</code></em> <code class="type">boolean</code> </span>]</span>] )
1293 → <code class="returnvalue">setof jsonb</code>
1295 <p class="func_signature">
1296 <a id="id-1.5.8.22.8.13.2.2.23.1.4.1" class="indexterm"></a>
1297 <code class="function">jsonb_path_query_array_tz</code> ( <em class="parameter"><code>target</code></em> <code class="type">jsonb</code>, <em class="parameter"><code>path</code></em> <code class="type">jsonpath</code> [<span class="optional">, <em class="parameter"><code>vars</code></em> <code class="type">jsonb</code> [<span class="optional">, <em class="parameter"><code>silent</code></em> <code class="type">boolean</code> </span>]</span>] )
1298 → <code class="returnvalue">jsonb</code>
1300 <p class="func_signature">
1301 <a id="id-1.5.8.22.8.13.2.2.23.1.5.1" class="indexterm"></a>
1302 <code class="function">jsonb_path_query_first_tz</code> ( <em class="parameter"><code>target</code></em> <code class="type">jsonb</code>, <em class="parameter"><code>path</code></em> <code class="type">jsonpath</code> [<span class="optional">, <em class="parameter"><code>vars</code></em> <code class="type">jsonb</code> [<span class="optional">, <em class="parameter"><code>silent</code></em> <code class="type">boolean</code> </span>]</span>] )
1303 → <code class="returnvalue">jsonb</code>
1306 These functions act like their counterparts described above without
1307 the <code class="literal">_tz</code> suffix, except that these functions support
1308 comparisons of date/time values that require timezone-aware
1309 conversions. The example below requires interpretation of the
1310 date-only value <code class="literal">2015-08-02</code> as a timestamp with time
1311 zone, so the result depends on the current
1312 <a class="xref" href="runtime-config-client.html#GUC-TIMEZONE">TimeZone</a> setting. Due to this dependency, these
1313 functions are marked as stable, which means these functions cannot be
1314 used in indexes. Their counterparts are immutable, and so can be used
1315 in indexes; but they will throw errors if asked to make such
1319 <code class="literal">jsonb_path_exists_tz('["2015-08-01 12:00:00-05"]', '$[*] ? (@.datetime() < "2015-08-02".datetime())')</code>
1320 → <code class="returnvalue">t</code>
1321 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
1322 <a id="id-1.5.8.22.8.13.2.2.24.1.1.1" class="indexterm"></a>
1323 <code class="function">jsonb_pretty</code> ( <code class="type">jsonb</code> )
1324 → <code class="returnvalue">text</code>
1327 Converts the given JSON value to pretty-printed, indented text.
1330 <code class="literal">jsonb_pretty('[{"f1":1,"f2":null}, 2]')</code>
1331 → <code class="returnvalue"></code>
1332 </p><pre class="programlisting">
1341 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
1342 <a id="id-1.5.8.22.8.13.2.2.25.1.1.1" class="indexterm"></a>
1343 <code class="function">json_typeof</code> ( <code class="type">json</code> )
1344 → <code class="returnvalue">text</code>
1346 <p class="func_signature">
1347 <a id="id-1.5.8.22.8.13.2.2.25.1.2.1" class="indexterm"></a>
1348 <code class="function">jsonb_typeof</code> ( <code class="type">jsonb</code> )
1349 → <code class="returnvalue">text</code>
1352 Returns the type of the top-level JSON value as a text string.
1354 <code class="literal">object</code>, <code class="literal">array</code>,
1355 <code class="literal">string</code>, <code class="literal">number</code>,
1356 <code class="literal">boolean</code>, and <code class="literal">null</code>.
1357 (The <code class="literal">null</code> result should not be confused
1358 with an SQL NULL; see the examples.)
1361 <code class="literal">json_typeof('-123.4')</code>
1362 → <code class="returnvalue">number</code>
1365 <code class="literal">json_typeof('null'::json)</code>
1366 → <code class="returnvalue">null</code>
1369 <code class="literal">json_typeof(NULL::json) IS NULL</code>
1370 → <code class="returnvalue">t</code>
1371 </p></td></tr></tbody></table></div></div><br class="table-break" /></div><div class="sect2" id="FUNCTIONS-SQLJSON-PATH"><div class="titlepage"><div><div><h3 class="title">9.16.2. The SQL/JSON Path Language <a href="#FUNCTIONS-SQLJSON-PATH" class="id_link">#</a></h3></div></div></div><a id="id-1.5.8.22.9.2" class="indexterm"></a><p>
1372 SQL/JSON path expressions specify item(s) to be retrieved
1373 from a JSON value, similarly to XPath expressions used
1374 for access to XML content. In <span class="productname">PostgreSQL</span>,
1375 path expressions are implemented as the <code class="type">jsonpath</code>
1376 data type and can use any elements described in
1377 <a class="xref" href="datatype-json.html#DATATYPE-JSONPATH" title="8.14.7. jsonpath Type">Section 8.14.7</a>.
1379 JSON query functions and operators
1380 pass the provided path expression to the <em class="firstterm">path engine</em>
1381 for evaluation. If the expression matches the queried JSON data,
1382 the corresponding JSON item, or set of items, is returned.
1383 If there is no match, the result will be <code class="literal">NULL</code>,
1384 <code class="literal">false</code>, or an error, depending on the function.
1385 Path expressions are written in the SQL/JSON path language
1386 and can include arithmetic expressions and functions.
1388 A path expression consists of a sequence of elements allowed
1389 by the <code class="type">jsonpath</code> data type.
1390 The path expression is normally evaluated from left to right, but
1391 you can use parentheses to change the order of operations.
1392 If the evaluation is successful, a sequence of JSON items is produced,
1393 and the evaluation result is returned to the JSON query function
1394 that completes the specified computation.
1396 To refer to the JSON value being queried (the
1397 <em class="firstterm">context item</em>), use the <code class="literal">$</code> variable
1398 in the path expression. The first element of a path must always
1399 be <code class="literal">$</code>. It can be followed by one or more
1400 <a class="link" href="datatype-json.html#TYPE-JSONPATH-ACCESSORS" title="Table 8.25. jsonpath Accessors">accessor operators</a>,
1401 which go down the JSON structure level by level to retrieve sub-items
1402 of the context item. Each accessor operator acts on the
1403 result(s) of the previous evaluation step, producing zero, one, or more
1404 output items from each input item.
1406 For example, suppose you have some JSON data from a GPS tracker that you
1407 would like to parse, such as:
1408 </p><pre class="programlisting">
1413 "location": [ 47.763, 13.4034 ],
1414 "start time": "2018-10-14 10:05:14",
1418 "location": [ 47.706, 13.2635 ],
1419 "start time": "2018-10-14 10:39:21",
1426 (The above example can be copied-and-pasted
1427 into <span class="application">psql</span> to set things up for the following
1428 examples. Then <span class="application">psql</span> will
1429 expand <code class="literal">:'json'</code> into a suitably-quoted string
1430 constant containing the JSON value.)
1432 To retrieve the available track segments, you need to use the
1433 <code class="literal">.<em class="replaceable"><code>key</code></em></code> accessor
1434 operator to descend through surrounding JSON objects, for example:
1435 </p><pre class="screen">
1436 <code class="prompt">=></code> <strong class="userinput"><code>select jsonb_path_query(:'json', '$.track.segments');</code></strong>
1438 -------------------------------------------------------------------------------------------------------------------------------------------------------------------
1439 [{"HR": 73, "location": [47.763, 13.4034], "start time": "2018-10-14 10:05:14"}, {"HR": 135, "location": [47.706, 13.2635], "start time": "2018-10-14 10:39:21"}]
1442 To retrieve the contents of an array, you typically use the
1443 <code class="literal">[*]</code> operator.
1444 The following example will return the location coordinates for all
1445 the available track segments:
1446 </p><pre class="screen">
1447 <code class="prompt">=></code> <strong class="userinput"><code>select jsonb_path_query(:'json', '$.track.segments[*].location');</code></strong>
1453 Here we started with the whole JSON input value (<code class="literal">$</code>),
1454 then the <code class="literal">.track</code> accessor selected the JSON object
1455 associated with the <code class="literal">"track"</code> object key, then
1456 the <code class="literal">.segments</code> accessor selected the JSON array
1457 associated with the <code class="literal">"segments"</code> key within that
1458 object, then the <code class="literal">[*]</code> accessor selected each element
1459 of that array (producing a series of items), then
1460 the <code class="literal">.location</code> accessor selected the JSON array
1461 associated with the <code class="literal">"location"</code> key within each of
1462 those objects. In this example, each of those objects had
1463 a <code class="literal">"location"</code> key; but if any of them did not,
1464 the <code class="literal">.location</code> accessor would have simply produced no
1465 output for that input item.
1467 To return the coordinates of the first segment only, you can
1468 specify the corresponding subscript in the <code class="literal">[]</code>
1469 accessor operator. Recall that JSON array indexes are 0-relative:
1470 </p><pre class="screen">
1471 <code class="prompt">=></code> <strong class="userinput"><code>select jsonb_path_query(:'json', '$.track.segments[0].location');</code></strong>
1477 The result of each path evaluation step can be processed
1478 by one or more of the <code class="type">jsonpath</code> operators and methods
1479 listed in <a class="xref" href="functions-json.html#FUNCTIONS-SQLJSON-PATH-OPERATORS" title="9.16.2.3. SQL/JSON Path Operators and Methods">Section 9.16.2.3</a>.
1480 Each method name must be preceded by a dot. For example,
1481 you can get the size of an array:
1482 </p><pre class="screen">
1483 <code class="prompt">=></code> <strong class="userinput"><code>select jsonb_path_query(:'json', '$.track.segments.size()');</code></strong>
1488 More examples of using <code class="type">jsonpath</code> operators
1489 and methods within path expressions appear below in
1490 <a class="xref" href="functions-json.html#FUNCTIONS-SQLJSON-PATH-OPERATORS" title="9.16.2.3. SQL/JSON Path Operators and Methods">Section 9.16.2.3</a>.
1492 A path can also contain
1493 <em class="firstterm">filter expressions</em> that work similarly to the
1494 <code class="literal">WHERE</code> clause in SQL. A filter expression begins with
1495 a question mark and provides a condition in parentheses:
1497 </p><pre class="synopsis">
1498 ? (<em class="replaceable"><code>condition</code></em>)
1501 Filter expressions must be written just after the path evaluation step
1502 to which they should apply. The result of that step is filtered to include
1503 only those items that satisfy the provided condition. SQL/JSON defines
1504 three-valued logic, so the condition can
1505 produce <code class="literal">true</code>, <code class="literal">false</code>,
1506 or <code class="literal">unknown</code>. The <code class="literal">unknown</code> value
1507 plays the same role as SQL <code class="literal">NULL</code> and can be tested
1508 for with the <code class="literal">is unknown</code> predicate. Further path
1509 evaluation steps use only those items for which the filter expression
1510 returned <code class="literal">true</code>.
1512 The functions and operators that can be used in filter expressions are
1513 listed in <a class="xref" href="functions-json.html#FUNCTIONS-SQLJSON-FILTER-EX-TABLE" title="Table 9.53. jsonpath Filter Expression Elements">Table 9.53</a>. Within a
1514 filter expression, the <code class="literal">@</code> variable denotes the value
1515 being considered (i.e., one result of the preceding path step). You can
1516 write accessor operators after <code class="literal">@</code> to retrieve component
1519 For example, suppose you would like to retrieve all heart rate values higher
1520 than 130. You can achieve this as follows:
1521 </p><pre class="screen">
1522 <code class="prompt">=></code> <strong class="userinput"><code>select jsonb_path_query(:'json', '$.track.segments[*].HR ? (@ > 130)');</code></strong>
1528 To get the start times of segments with such values, you have to
1529 filter out irrelevant segments before selecting the start times, so the
1530 filter expression is applied to the previous step, and the path used
1531 in the condition is different:
1532 </p><pre class="screen">
1533 <code class="prompt">=></code> <strong class="userinput"><code>select jsonb_path_query(:'json', '$.track.segments[*] ? (@.HR > 130)."start time"');</code></strong>
1535 -----------------------
1536 "2018-10-14 10:39:21"
1539 You can use several filter expressions in sequence, if required.
1540 The following example selects start times of all segments that
1541 contain locations with relevant coordinates and high heart rate values:
1542 </p><pre class="screen">
1543 <code class="prompt">=></code> <strong class="userinput"><code>select jsonb_path_query(:'json', '$.track.segments[*] ? (@.location[1] < 13.4) ? (@.HR > 130)."start time"');</code></strong>
1545 -----------------------
1546 "2018-10-14 10:39:21"
1549 Using filter expressions at different nesting levels is also allowed.
1550 The following example first filters all segments by location, and then
1551 returns high heart rate values for these segments, if available:
1552 </p><pre class="screen">
1553 <code class="prompt">=></code> <strong class="userinput"><code>select jsonb_path_query(:'json', '$.track.segments[*] ? (@.location[1] < 13.4).HR ? (@ > 130)');</code></strong>
1559 You can also nest filter expressions within each other.
1560 This example returns the size of the track if it contains any
1561 segments with high heart rate values, or an empty sequence otherwise:
1562 </p><pre class="screen">
1563 <code class="prompt">=></code> <strong class="userinput"><code>select jsonb_path_query(:'json', '$.track ? (exists(@.segments[*] ? (@.HR > 130))).segments.size()');</code></strong>
1568 </p><div class="sect3" id="FUNCTIONS-SQLJSON-DEVIATIONS"><div class="titlepage"><div><div><h4 class="title">9.16.2.1. Deviations from the SQL Standard <a href="#FUNCTIONS-SQLJSON-DEVIATIONS" class="id_link">#</a></h4></div></div></div><p>
1569 <span class="productname">PostgreSQL</span>'s implementation of the SQL/JSON path
1570 language has the following deviations from the SQL/JSON standard.
1571 </p><div class="sect4" id="FUNCTIONS-SQLJSON-CHECK-EXPRESSIONS"><div class="titlepage"><div><div><h5 class="title">9.16.2.1.1. Boolean Predicate Check Expressions <a href="#FUNCTIONS-SQLJSON-CHECK-EXPRESSIONS" class="id_link">#</a></h5></div></div></div><p>
1572 As an extension to the SQL standard,
1573 a <span class="productname">PostgreSQL</span> path expression can be a
1574 Boolean predicate, whereas the SQL standard allows predicates only within
1575 filters. While SQL-standard path expressions return the relevant
1576 element(s) of the queried JSON value, predicate check expressions
1577 return the single three-valued <code class="type">jsonb</code> result of the
1578 predicate: <code class="literal">true</code>,
1579 <code class="literal">false</code>, or <code class="literal">null</code>.
1580 For example, we could write this SQL-standard filter expression:
1581 </p><pre class="screen">
1582 <code class="prompt">=></code> <strong class="userinput"><code>select jsonb_path_query(:'json', '$.track.segments ?(@[*].HR > 130)');</code></strong>
1584 ---------------------------------------------------------------------------------
1585 {"HR": 135, "location": [47.706, 13.2635], "start time": "2018-10-14 10:39:21"}
1587 The similar predicate check expression simply
1588 returns <code class="literal">true</code>, indicating that a match exists:
1589 </p><pre class="screen">
1590 <code class="prompt">=></code> <strong class="userinput"><code>select jsonb_path_query(:'json', '$.track.segments[*].HR > 130');</code></strong>
1595 </p><div class="note"><h3 class="title">Note</h3><p>
1596 Predicate check expressions are required in the
1597 <code class="literal">@@</code> operator (and the
1598 <code class="function">jsonb_path_match</code> function), and should not be used
1599 with the <code class="literal">@?</code> operator (or the
1600 <code class="function">jsonb_path_exists</code> function).
1601 </p></div></div><div class="sect4" id="FUNCTIONS-SQLJSON-REGULAR-EXPRESSION-DEVIATION"><div class="titlepage"><div><div><h5 class="title">9.16.2.1.2. Regular Expression Interpretation <a href="#FUNCTIONS-SQLJSON-REGULAR-EXPRESSION-DEVIATION" class="id_link">#</a></h5></div></div></div><p>
1602 There are minor differences in the interpretation of regular
1603 expression patterns used in <code class="literal">like_regex</code> filters, as
1604 described in <a class="xref" href="functions-json.html#JSONPATH-REGULAR-EXPRESSIONS" title="9.16.2.4. SQL/JSON Regular Expressions">Section 9.16.2.4</a>.
1605 </p></div></div><div class="sect3" id="FUNCTIONS-SQLJSON-STRICT-AND-LAX-MODES"><div class="titlepage"><div><div><h4 class="title">9.16.2.2. Strict and Lax Modes <a href="#FUNCTIONS-SQLJSON-STRICT-AND-LAX-MODES" class="id_link">#</a></h4></div></div></div><p>
1606 When you query JSON data, the path expression may not match the
1607 actual JSON data structure. An attempt to access a non-existent
1608 member of an object or element of an array is defined as a
1609 structural error. SQL/JSON path expressions have two modes
1610 of handling structural errors:
1611 </p><div class="itemizedlist"><ul class="itemizedlist" style="list-style-type: disc; "><li class="listitem"><p>
1612 lax (default) — the path engine implicitly adapts
1613 the queried data to the specified path.
1614 Any structural errors that cannot be fixed as described below
1615 are suppressed, producing no match.
1616 </p></li><li class="listitem"><p>
1617 strict — if a structural error occurs, an error is raised.
1618 </p></li></ul></div><p>
1619 Lax mode facilitates matching of a JSON document and path
1620 expression when the JSON data does not conform to the expected schema.
1621 If an operand does not match the requirements of a particular operation,
1622 it can be automatically wrapped as an SQL/JSON array, or unwrapped by
1623 converting its elements into an SQL/JSON sequence before performing
1624 the operation. Also, comparison operators automatically unwrap their
1625 operands in lax mode, so you can compare SQL/JSON arrays
1626 out-of-the-box. An array of size 1 is considered equal to its sole element.
1627 Automatic unwrapping is not performed when:
1628 </p><div class="itemizedlist"><ul class="itemizedlist" style="list-style-type: disc; "><li class="listitem"><p>
1629 The path expression contains <code class="literal">type()</code> or
1630 <code class="literal">size()</code> methods that return the type
1631 and the number of elements in the array, respectively.
1632 </p></li><li class="listitem"><p>
1633 The queried JSON data contain nested arrays. In this case, only
1634 the outermost array is unwrapped, while all the inner arrays
1635 remain unchanged. Thus, implicit unwrapping can only go one
1636 level down within each path evaluation step.
1637 </p></li></ul></div><p>
1639 For example, when querying the GPS data listed above, you can
1640 abstract from the fact that it stores an array of segments
1641 when using lax mode:
1642 </p><pre class="screen">
1643 <code class="prompt">=></code> <strong class="userinput"><code>select jsonb_path_query(:'json', 'lax $.track.segments.location');</code></strong>
1650 In strict mode, the specified path must exactly match the structure of
1651 the queried JSON document, so using this path
1652 expression will cause an error:
1653 </p><pre class="screen">
1654 <code class="prompt">=></code> <strong class="userinput"><code>select jsonb_path_query(:'json', 'strict $.track.segments.location');</code></strong>
1655 ERROR: jsonpath member accessor can only be applied to an object
1657 To get the same result as in lax mode, you have to explicitly unwrap the
1658 <code class="literal">segments</code> array:
1659 </p><pre class="screen">
1660 <code class="prompt">=></code> <strong class="userinput"><code>select jsonb_path_query(:'json', 'strict $.track.segments[*].location');</code></strong>
1667 The unwrapping behavior of lax mode can lead to surprising results. For
1668 instance, the following query using the <code class="literal">.**</code> accessor
1669 selects every <code class="literal">HR</code> value twice:
1670 </p><pre class="screen">
1671 <code class="prompt">=></code> <strong class="userinput"><code>select jsonb_path_query(:'json', 'lax $.**.HR');</code></strong>
1679 This happens because the <code class="literal">.**</code> accessor selects both
1680 the <code class="literal">segments</code> array and each of its elements, while
1681 the <code class="literal">.HR</code> accessor automatically unwraps arrays when
1682 using lax mode. To avoid surprising results, we recommend using
1683 the <code class="literal">.**</code> accessor only in strict mode. The
1684 following query selects each <code class="literal">HR</code> value just once:
1685 </p><pre class="screen">
1686 <code class="prompt">=></code> <strong class="userinput"><code>select jsonb_path_query(:'json', 'strict $.**.HR');</code></strong>
1693 The unwrapping of arrays can also lead to unexpected results. Consider this
1694 example, which selects all the <code class="literal">location</code> arrays:
1695 </p><pre class="screen">
1696 <code class="prompt">=></code> <strong class="userinput"><code>select jsonb_path_query(:'json', 'lax $.track.segments[*].location');</code></strong>
1703 As expected it returns the full arrays. But applying a filter expression
1704 causes the arrays to be unwrapped to evaluate each item, returning only the
1705 items that match the expression:
1706 </p><pre class="screen">
1707 <code class="prompt">=></code> <strong class="userinput"><code>select jsonb_path_query(:'json', 'lax $.track.segments[*].location ?(@[*] > 15)');</code></strong>
1714 This despite the fact that the full arrays are selected by the path
1715 expression. Use strict mode to restore selecting the arrays:
1716 </p><pre class="screen">
1717 <code class="prompt">=></code> <strong class="userinput"><code>select jsonb_path_query(:'json', 'strict $.track.segments[*].location ?(@[*] > 15)');</code></strong>
1724 </p></div><div class="sect3" id="FUNCTIONS-SQLJSON-PATH-OPERATORS"><div class="titlepage"><div><div><h4 class="title">9.16.2.3. SQL/JSON Path Operators and Methods <a href="#FUNCTIONS-SQLJSON-PATH-OPERATORS" class="id_link">#</a></h4></div></div></div><p>
1725 <a class="xref" href="functions-json.html#FUNCTIONS-SQLJSON-OP-TABLE" title="Table 9.52. jsonpath Operators and Methods">Table 9.52</a> shows the operators and
1726 methods available in <code class="type">jsonpath</code>. Note that while the unary
1727 operators and methods can be applied to multiple values resulting from a
1728 preceding path step, the binary operators (addition etc.) can only be
1729 applied to single values. In lax mode, methods applied to an array will be
1730 executed for each value in the array. The exceptions are
1731 <code class="literal">.type()</code> and <code class="literal">.size()</code>, which apply to
1733 </p><div class="table" id="FUNCTIONS-SQLJSON-OP-TABLE"><p class="title"><strong>Table 9.52. <code class="type">jsonpath</code> Operators and Methods</strong></p><div class="table-contents"><table class="table" summary="jsonpath Operators and Methods" border="1"><colgroup><col /></colgroup><thead><tr><th class="func_table_entry"><p class="func_signature">
1741 </p></th></tr></thead><tbody><tr><td class="func_table_entry"><p class="func_signature">
1742 <em class="replaceable"><code>number</code></em> <code class="literal">+</code> <em class="replaceable"><code>number</code></em>
1743 → <code class="returnvalue"><em class="replaceable"><code>number</code></em></code>
1749 <code class="literal">jsonb_path_query('[2]', '$[0] + 3')</code>
1750 → <code class="returnvalue">5</code>
1751 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
1752 <code class="literal">+</code> <em class="replaceable"><code>number</code></em>
1753 → <code class="returnvalue"><em class="replaceable"><code>number</code></em></code>
1756 Unary plus (no operation); unlike addition, this can iterate over
1760 <code class="literal">jsonb_path_query_array('{"x": [2,3,4]}', '+ $.x')</code>
1761 → <code class="returnvalue">[2, 3, 4]</code>
1762 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
1763 <em class="replaceable"><code>number</code></em> <code class="literal">-</code> <em class="replaceable"><code>number</code></em>
1764 → <code class="returnvalue"><em class="replaceable"><code>number</code></em></code>
1770 <code class="literal">jsonb_path_query('[2]', '7 - $[0]')</code>
1771 → <code class="returnvalue">5</code>
1772 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
1773 <code class="literal">-</code> <em class="replaceable"><code>number</code></em>
1774 → <code class="returnvalue"><em class="replaceable"><code>number</code></em></code>
1777 Negation; unlike subtraction, this can iterate over
1781 <code class="literal">jsonb_path_query_array('{"x": [2,3,4]}', '- $.x')</code>
1782 → <code class="returnvalue">[-2, -3, -4]</code>
1783 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
1784 <em class="replaceable"><code>number</code></em> <code class="literal">*</code> <em class="replaceable"><code>number</code></em>
1785 → <code class="returnvalue"><em class="replaceable"><code>number</code></em></code>
1791 <code class="literal">jsonb_path_query('[4]', '2 * $[0]')</code>
1792 → <code class="returnvalue">8</code>
1793 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
1794 <em class="replaceable"><code>number</code></em> <code class="literal">/</code> <em class="replaceable"><code>number</code></em>
1795 → <code class="returnvalue"><em class="replaceable"><code>number</code></em></code>
1801 <code class="literal">jsonb_path_query('[8.5]', '$[0] / 2')</code>
1802 → <code class="returnvalue">4.2500000000000000</code>
1803 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
1804 <em class="replaceable"><code>number</code></em> <code class="literal">%</code> <em class="replaceable"><code>number</code></em>
1805 → <code class="returnvalue"><em class="replaceable"><code>number</code></em></code>
1811 <code class="literal">jsonb_path_query('[32]', '$[0] % 10')</code>
1812 → <code class="returnvalue">2</code>
1813 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
1814 <em class="replaceable"><code>value</code></em> <code class="literal">.</code> <code class="literal">type()</code>
1815 → <code class="returnvalue"><em class="replaceable"><code>string</code></em></code>
1818 Type of the JSON item (see <code class="function">json_typeof</code>)
1821 <code class="literal">jsonb_path_query_array('[1, "2", {}]', '$[*].type()')</code>
1822 → <code class="returnvalue">["number", "string", "object"]</code>
1823 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
1824 <em class="replaceable"><code>value</code></em> <code class="literal">.</code> <code class="literal">size()</code>
1825 → <code class="returnvalue"><em class="replaceable"><code>number</code></em></code>
1828 Size of the JSON item (number of array elements, or 1 if not an
1832 <code class="literal">jsonb_path_query('{"m": [11, 15]}', '$.m.size()')</code>
1833 → <code class="returnvalue">2</code>
1834 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
1835 <em class="replaceable"><code>value</code></em> <code class="literal">.</code> <code class="literal">boolean()</code>
1836 → <code class="returnvalue"><em class="replaceable"><code>boolean</code></em></code>
1839 Boolean value converted from a JSON boolean, number, or string
1842 <code class="literal">jsonb_path_query_array('[1, "yes", false]', '$[*].boolean()')</code>
1843 → <code class="returnvalue">[true, true, false]</code>
1844 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
1845 <em class="replaceable"><code>value</code></em> <code class="literal">.</code> <code class="literal">string()</code>
1846 → <code class="returnvalue"><em class="replaceable"><code>string</code></em></code>
1849 String value converted from a JSON boolean, number, string, or
1853 <code class="literal">jsonb_path_query_array('[1.23, "xyz", false]', '$[*].string()')</code>
1854 → <code class="returnvalue">["1.23", "xyz", "false"]</code>
1857 <code class="literal">jsonb_path_query('"2023-08-15 12:34:56"', '$.timestamp().string()')</code>
1858 → <code class="returnvalue">"2023-08-15T12:34:56"</code>
1859 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
1860 <em class="replaceable"><code>value</code></em> <code class="literal">.</code> <code class="literal">double()</code>
1861 → <code class="returnvalue"><em class="replaceable"><code>number</code></em></code>
1864 Approximate floating-point number converted from a JSON number or
1868 <code class="literal">jsonb_path_query('{"len": "1.9"}', '$.len.double() * 2')</code>
1869 → <code class="returnvalue">3.8</code>
1870 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
1871 <em class="replaceable"><code>number</code></em> <code class="literal">.</code> <code class="literal">ceiling()</code>
1872 → <code class="returnvalue"><em class="replaceable"><code>number</code></em></code>
1875 Nearest integer greater than or equal to the given number
1878 <code class="literal">jsonb_path_query('{"h": 1.3}', '$.h.ceiling()')</code>
1879 → <code class="returnvalue">2</code>
1880 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
1881 <em class="replaceable"><code>number</code></em> <code class="literal">.</code> <code class="literal">floor()</code>
1882 → <code class="returnvalue"><em class="replaceable"><code>number</code></em></code>
1885 Nearest integer less than or equal to the given number
1888 <code class="literal">jsonb_path_query('{"h": 1.7}', '$.h.floor()')</code>
1889 → <code class="returnvalue">1</code>
1890 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
1891 <em class="replaceable"><code>number</code></em> <code class="literal">.</code> <code class="literal">abs()</code>
1892 → <code class="returnvalue"><em class="replaceable"><code>number</code></em></code>
1895 Absolute value of the given number
1898 <code class="literal">jsonb_path_query('{"z": -0.3}', '$.z.abs()')</code>
1899 → <code class="returnvalue">0.3</code>
1900 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
1901 <em class="replaceable"><code>value</code></em> <code class="literal">.</code> <code class="literal">bigint()</code>
1902 → <code class="returnvalue"><em class="replaceable"><code>bigint</code></em></code>
1905 Big integer value converted from a JSON number or string
1908 <code class="literal">jsonb_path_query('{"len": "9876543219"}', '$.len.bigint()')</code>
1909 → <code class="returnvalue">9876543219</code>
1910 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
1911 <em class="replaceable"><code>value</code></em> <code class="literal">.</code> <code class="literal">decimal( [ <em class="replaceable"><code>precision</code></em> [ , <em class="replaceable"><code>scale</code></em> ] ] )</code>
1912 → <code class="returnvalue"><em class="replaceable"><code>decimal</code></em></code>
1915 Rounded decimal value converted from a JSON number or string
1916 (<code class="literal">precision</code> and <code class="literal">scale</code> must be
1920 <code class="literal">jsonb_path_query('1234.5678', '$.decimal(6, 2)')</code>
1921 → <code class="returnvalue">1234.57</code>
1922 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
1923 <em class="replaceable"><code>value</code></em> <code class="literal">.</code> <code class="literal">integer()</code>
1924 → <code class="returnvalue"><em class="replaceable"><code>integer</code></em></code>
1927 Integer value converted from a JSON number or string
1930 <code class="literal">jsonb_path_query('{"len": "12345"}', '$.len.integer()')</code>
1931 → <code class="returnvalue">12345</code>
1932 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
1933 <em class="replaceable"><code>value</code></em> <code class="literal">.</code> <code class="literal">number()</code>
1934 → <code class="returnvalue"><em class="replaceable"><code>numeric</code></em></code>
1937 Numeric value converted from a JSON number or string
1940 <code class="literal">jsonb_path_query('{"len": "123.45"}', '$.len.number()')</code>
1941 → <code class="returnvalue">123.45</code>
1942 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
1943 <em class="replaceable"><code>string</code></em> <code class="literal">.</code> <code class="literal">datetime()</code>
1944 → <code class="returnvalue"><em class="replaceable"><code>datetime_type</code></em></code>
1948 Date/time value converted from a string
1951 <code class="literal">jsonb_path_query('["2015-8-1", "2015-08-12"]', '$[*] ? (@.datetime() < "2015-08-2".datetime())')</code>
1952 → <code class="returnvalue">"2015-8-1"</code>
1953 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
1954 <em class="replaceable"><code>string</code></em> <code class="literal">.</code> <code class="literal">datetime(<em class="replaceable"><code>template</code></em>)</code>
1955 → <code class="returnvalue"><em class="replaceable"><code>datetime_type</code></em></code>
1959 Date/time value converted from a string using the
1960 specified <code class="function">to_timestamp</code> template
1963 <code class="literal">jsonb_path_query_array('["12:30", "18:40"]', '$[*].datetime("HH24:MI")')</code>
1964 → <code class="returnvalue">["12:30:00", "18:40:00"]</code>
1965 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
1966 <em class="replaceable"><code>string</code></em> <code class="literal">.</code> <code class="literal">date()</code>
1967 → <code class="returnvalue"><em class="replaceable"><code>date</code></em></code>
1970 Date value converted from a string
1973 <code class="literal">jsonb_path_query('"2023-08-15"', '$.date()')</code>
1974 → <code class="returnvalue">"2023-08-15"</code>
1975 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
1976 <em class="replaceable"><code>string</code></em> <code class="literal">.</code> <code class="literal">time()</code>
1977 → <code class="returnvalue"><em class="replaceable"><code>time without time zone</code></em></code>
1980 Time without time zone value converted from a string
1983 <code class="literal">jsonb_path_query('"12:34:56"', '$.time()')</code>
1984 → <code class="returnvalue">"12:34:56"</code>
1985 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
1986 <em class="replaceable"><code>string</code></em> <code class="literal">.</code> <code class="literal">time(<em class="replaceable"><code>precision</code></em>)</code>
1987 → <code class="returnvalue"><em class="replaceable"><code>time without time zone</code></em></code>
1990 Time without time zone value converted from a string, with fractional
1991 seconds adjusted to the given precision
1994 <code class="literal">jsonb_path_query('"12:34:56.789"', '$.time(2)')</code>
1995 → <code class="returnvalue">"12:34:56.79"</code>
1996 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
1997 <em class="replaceable"><code>string</code></em> <code class="literal">.</code> <code class="literal">time_tz()</code>
1998 → <code class="returnvalue"><em class="replaceable"><code>time with time zone</code></em></code>
2001 Time with time zone value converted from a string
2004 <code class="literal">jsonb_path_query('"12:34:56 +05:30"', '$.time_tz()')</code>
2005 → <code class="returnvalue">"12:34:56+05:30"</code>
2006 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
2007 <em class="replaceable"><code>string</code></em> <code class="literal">.</code> <code class="literal">time_tz(<em class="replaceable"><code>precision</code></em>)</code>
2008 → <code class="returnvalue"><em class="replaceable"><code>time with time zone</code></em></code>
2011 Time with time zone value converted from a string, with fractional
2012 seconds adjusted to the given precision
2015 <code class="literal">jsonb_path_query('"12:34:56.789 +05:30"', '$.time_tz(2)')</code>
2016 → <code class="returnvalue">"12:34:56.79+05:30"</code>
2017 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
2018 <em class="replaceable"><code>string</code></em> <code class="literal">.</code> <code class="literal">timestamp()</code>
2019 → <code class="returnvalue"><em class="replaceable"><code>timestamp without time zone</code></em></code>
2022 Timestamp without time zone value converted from a string
2025 <code class="literal">jsonb_path_query('"2023-08-15 12:34:56"', '$.timestamp()')</code>
2026 → <code class="returnvalue">"2023-08-15T12:34:56"</code>
2027 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
2028 <em class="replaceable"><code>string</code></em> <code class="literal">.</code> <code class="literal">timestamp(<em class="replaceable"><code>precision</code></em>)</code>
2029 → <code class="returnvalue"><em class="replaceable"><code>timestamp without time zone</code></em></code>
2032 Timestamp without time zone value converted from a string, with
2033 fractional seconds adjusted to the given precision
2036 <code class="literal">jsonb_path_query('"2023-08-15 12:34:56.789"', '$.timestamp(2)')</code>
2037 → <code class="returnvalue">"2023-08-15T12:34:56.79"</code>
2038 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
2039 <em class="replaceable"><code>string</code></em> <code class="literal">.</code> <code class="literal">timestamp_tz()</code>
2040 → <code class="returnvalue"><em class="replaceable"><code>timestamp with time zone</code></em></code>
2043 Timestamp with time zone value converted from a string
2046 <code class="literal">jsonb_path_query('"2023-08-15 12:34:56 +05:30"', '$.timestamp_tz()')</code>
2047 → <code class="returnvalue">"2023-08-15T12:34:56+05:30"</code>
2048 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
2049 <em class="replaceable"><code>string</code></em> <code class="literal">.</code> <code class="literal">timestamp_tz(<em class="replaceable"><code>precision</code></em>)</code>
2050 → <code class="returnvalue"><em class="replaceable"><code>timestamp with time zone</code></em></code>
2053 Timestamp with time zone value converted from a string, with fractional
2054 seconds adjusted to the given precision
2057 <code class="literal">jsonb_path_query('"2023-08-15 12:34:56.789 +05:30"', '$.timestamp_tz(2)')</code>
2058 → <code class="returnvalue">"2023-08-15T12:34:56.79+05:30"</code>
2059 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
2060 <em class="replaceable"><code>object</code></em> <code class="literal">.</code> <code class="literal">keyvalue()</code>
2061 → <code class="returnvalue"><em class="replaceable"><code>array</code></em></code>
2064 The object's key-value pairs, represented as an array of objects
2065 containing three fields: <code class="literal">"key"</code>,
2066 <code class="literal">"value"</code>, and <code class="literal">"id"</code>;
2067 <code class="literal">"id"</code> is a unique identifier of the object the
2068 key-value pair belongs to
2071 <code class="literal">jsonb_path_query_array('{"x": "20", "y": 32}', '$.keyvalue()')</code>
2072 → <code class="returnvalue">[{"id": 0, "key": "x", "value": "20"}, {"id": 0, "key": "y", "value": 32}]</code>
2073 </p></td></tr></tbody></table></div></div><br class="table-break" /><div class="note"><h3 class="title">Note</h3><p>
2074 The result type of the <code class="literal">datetime()</code> and
2075 <code class="literal">datetime(<em class="replaceable"><code>template</code></em>)</code>
2076 methods can be <code class="type">date</code>, <code class="type">timetz</code>, <code class="type">time</code>,
2077 <code class="type">timestamptz</code>, or <code class="type">timestamp</code>.
2078 Both methods determine their result type dynamically.
2080 The <code class="literal">datetime()</code> method sequentially tries to
2081 match its input string to the ISO formats
2082 for <code class="type">date</code>, <code class="type">timetz</code>, <code class="type">time</code>,
2083 <code class="type">timestamptz</code>, and <code class="type">timestamp</code>. It stops on
2084 the first matching format and emits the corresponding data type.
2086 The <code class="literal">datetime(<em class="replaceable"><code>template</code></em>)</code>
2087 method determines the result type according to the fields used in the
2088 provided template string.
2090 The <code class="literal">datetime()</code> and
2091 <code class="literal">datetime(<em class="replaceable"><code>template</code></em>)</code> methods
2092 use the same parsing rules as the <code class="literal">to_timestamp</code> SQL
2093 function does (see <a class="xref" href="functions-formatting.html" title="9.8. Data Type Formatting Functions">Section 9.8</a>), with three
2094 exceptions. First, these methods don't allow unmatched template
2095 patterns. Second, only the following separators are allowed in the
2096 template string: minus sign, period, solidus (slash), comma, apostrophe,
2097 semicolon, colon and space. Third, separators in the template string
2098 must exactly match the input string.
2100 If different date/time types need to be compared, an implicit cast is
2101 applied. A <code class="type">date</code> value can be cast to <code class="type">timestamp</code>
2102 or <code class="type">timestamptz</code>, <code class="type">timestamp</code> can be cast to
2103 <code class="type">timestamptz</code>, and <code class="type">time</code> to <code class="type">timetz</code>.
2104 However, all but the first of these conversions depend on the current
2105 <a class="xref" href="runtime-config-client.html#GUC-TIMEZONE">TimeZone</a> setting, and thus can only be performed
2106 within timezone-aware <code class="type">jsonpath</code> functions. Similarly, other
2107 date/time-related methods that convert strings to date/time types
2108 also do this casting, which may involve the current
2109 <a class="xref" href="runtime-config-client.html#GUC-TIMEZONE">TimeZone</a> setting. Therefore, these conversions can
2110 also only be performed within timezone-aware <code class="type">jsonpath</code>
2113 <a class="xref" href="functions-json.html#FUNCTIONS-SQLJSON-FILTER-EX-TABLE" title="Table 9.53. jsonpath Filter Expression Elements">Table 9.53</a> shows the available
2114 filter expression elements.
2115 </p><div class="table" id="FUNCTIONS-SQLJSON-FILTER-EX-TABLE"><p class="title"><strong>Table 9.53. <code class="type">jsonpath</code> Filter Expression Elements</strong></p><div class="table-contents"><table class="table" summary="jsonpath Filter Expression Elements" border="1"><colgroup><col /></colgroup><thead><tr><th class="func_table_entry"><p class="func_signature">
2123 </p></th></tr></thead><tbody><tr><td class="func_table_entry"><p class="func_signature">
2124 <em class="replaceable"><code>value</code></em> <code class="literal">==</code> <em class="replaceable"><code>value</code></em>
2125 → <code class="returnvalue">boolean</code>
2128 Equality comparison (this, and the other comparison operators, work on
2129 all JSON scalar values)
2132 <code class="literal">jsonb_path_query_array('[1, "a", 1, 3]', '$[*] ? (@ == 1)')</code>
2133 → <code class="returnvalue">[1, 1]</code>
2136 <code class="literal">jsonb_path_query_array('[1, "a", 1, 3]', '$[*] ? (@ == "a")')</code>
2137 → <code class="returnvalue">["a"]</code>
2138 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
2139 <em class="replaceable"><code>value</code></em> <code class="literal">!=</code> <em class="replaceable"><code>value</code></em>
2140 → <code class="returnvalue">boolean</code>
2142 <p class="func_signature">
2143 <em class="replaceable"><code>value</code></em> <code class="literal"><></code> <em class="replaceable"><code>value</code></em>
2144 → <code class="returnvalue">boolean</code>
2147 Non-equality comparison
2150 <code class="literal">jsonb_path_query_array('[1, 2, 1, 3]', '$[*] ? (@ != 1)')</code>
2151 → <code class="returnvalue">[2, 3]</code>
2154 <code class="literal">jsonb_path_query_array('["a", "b", "c"]', '$[*] ? (@ <> "b")')</code>
2155 → <code class="returnvalue">["a", "c"]</code>
2156 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
2157 <em class="replaceable"><code>value</code></em> <code class="literal"><</code> <em class="replaceable"><code>value</code></em>
2158 → <code class="returnvalue">boolean</code>
2161 Less-than comparison
2164 <code class="literal">jsonb_path_query_array('[1, 2, 3]', '$[*] ? (@ < 2)')</code>
2165 → <code class="returnvalue">[1]</code>
2166 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
2167 <em class="replaceable"><code>value</code></em> <code class="literal"><=</code> <em class="replaceable"><code>value</code></em>
2168 → <code class="returnvalue">boolean</code>
2171 Less-than-or-equal-to comparison
2174 <code class="literal">jsonb_path_query_array('["a", "b", "c"]', '$[*] ? (@ <= "b")')</code>
2175 → <code class="returnvalue">["a", "b"]</code>
2176 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
2177 <em class="replaceable"><code>value</code></em> <code class="literal">></code> <em class="replaceable"><code>value</code></em>
2178 → <code class="returnvalue">boolean</code>
2181 Greater-than comparison
2184 <code class="literal">jsonb_path_query_array('[1, 2, 3]', '$[*] ? (@ > 2)')</code>
2185 → <code class="returnvalue">[3]</code>
2186 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
2187 <em class="replaceable"><code>value</code></em> <code class="literal">>=</code> <em class="replaceable"><code>value</code></em>
2188 → <code class="returnvalue">boolean</code>
2191 Greater-than-or-equal-to comparison
2194 <code class="literal">jsonb_path_query_array('[1, 2, 3]', '$[*] ? (@ >= 2)')</code>
2195 → <code class="returnvalue">[2, 3]</code>
2196 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
2197 <code class="literal">true</code>
2198 → <code class="returnvalue">boolean</code>
2201 JSON constant <code class="literal">true</code>
2204 <code class="literal">jsonb_path_query('[{"name": "John", "parent": false}, {"name": "Chris", "parent": true}]', '$[*] ? (@.parent == true)')</code>
2205 → <code class="returnvalue">{"name": "Chris", "parent": true}</code>
2206 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
2207 <code class="literal">false</code>
2208 → <code class="returnvalue">boolean</code>
2211 JSON constant <code class="literal">false</code>
2214 <code class="literal">jsonb_path_query('[{"name": "John", "parent": false}, {"name": "Chris", "parent": true}]', '$[*] ? (@.parent == false)')</code>
2215 → <code class="returnvalue">{"name": "John", "parent": false}</code>
2216 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
2217 <code class="literal">null</code>
2218 → <code class="returnvalue"><em class="replaceable"><code>value</code></em></code>
2221 JSON constant <code class="literal">null</code> (note that, unlike in SQL,
2222 comparison to <code class="literal">null</code> works normally)
2225 <code class="literal">jsonb_path_query('[{"name": "Mary", "job": null}, {"name": "Michael", "job": "driver"}]', '$[*] ? (@.job == null) .name')</code>
2226 → <code class="returnvalue">"Mary"</code>
2227 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
2228 <em class="replaceable"><code>boolean</code></em> <code class="literal">&&</code> <em class="replaceable"><code>boolean</code></em>
2229 → <code class="returnvalue">boolean</code>
2235 <code class="literal">jsonb_path_query('[1, 3, 7]', '$[*] ? (@ > 1 && @ < 5)')</code>
2236 → <code class="returnvalue">3</code>
2237 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
2238 <em class="replaceable"><code>boolean</code></em> <code class="literal">||</code> <em class="replaceable"><code>boolean</code></em>
2239 → <code class="returnvalue">boolean</code>
2245 <code class="literal">jsonb_path_query('[1, 3, 7]', '$[*] ? (@ < 1 || @ > 5)')</code>
2246 → <code class="returnvalue">7</code>
2247 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
2248 <code class="literal">!</code> <em class="replaceable"><code>boolean</code></em>
2249 → <code class="returnvalue">boolean</code>
2255 <code class="literal">jsonb_path_query('[1, 3, 7]', '$[*] ? (!(@ < 5))')</code>
2256 → <code class="returnvalue">7</code>
2257 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
2258 <em class="replaceable"><code>boolean</code></em> <code class="literal">is unknown</code>
2259 → <code class="returnvalue">boolean</code>
2262 Tests whether a Boolean condition is <code class="literal">unknown</code>.
2265 <code class="literal">jsonb_path_query('[-1, 2, 7, "foo"]', '$[*] ? ((@ > 0) is unknown)')</code>
2266 → <code class="returnvalue">"foo"</code>
2267 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
2268 <em class="replaceable"><code>string</code></em> <code class="literal">like_regex</code> <em class="replaceable"><code>string</code></em> [<span class="optional"> <code class="literal">flag</code> <em class="replaceable"><code>string</code></em> </span>]
2269 → <code class="returnvalue">boolean</code>
2272 Tests whether the first operand matches the regular expression
2273 given by the second operand, optionally with modifications
2274 described by a string of <code class="literal">flag</code> characters (see
2275 <a class="xref" href="functions-json.html#JSONPATH-REGULAR-EXPRESSIONS" title="9.16.2.4. SQL/JSON Regular Expressions">Section 9.16.2.4</a>).
2278 <code class="literal">jsonb_path_query_array('["abc", "abd", "aBdC", "abdacb", "babc"]', '$[*] ? (@ like_regex "^ab.*c")')</code>
2279 → <code class="returnvalue">["abc", "abdacb"]</code>
2282 <code class="literal">jsonb_path_query_array('["abc", "abd", "aBdC", "abdacb", "babc"]', '$[*] ? (@ like_regex "^ab.*c" flag "i")')</code>
2283 → <code class="returnvalue">["abc", "aBdC", "abdacb"]</code>
2284 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
2285 <em class="replaceable"><code>string</code></em> <code class="literal">starts with</code> <em class="replaceable"><code>string</code></em>
2286 → <code class="returnvalue">boolean</code>
2289 Tests whether the second operand is an initial substring of the first
2293 <code class="literal">jsonb_path_query('["John Smith", "Mary Stone", "Bob Johnson"]', '$[*] ? (@ starts with "John")')</code>
2294 → <code class="returnvalue">"John Smith"</code>
2295 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
2296 <code class="literal">exists</code> <code class="literal">(</code> <em class="replaceable"><code>path_expression</code></em> <code class="literal">)</code>
2297 → <code class="returnvalue">boolean</code>
2300 Tests whether a path expression matches at least one SQL/JSON item.
2301 Returns <code class="literal">unknown</code> if the path expression would result
2302 in an error; the second example uses this to avoid a no-such-key error
2306 <code class="literal">jsonb_path_query('{"x": [1, 2], "y": [2, 4]}', 'strict $.* ? (exists (@ ? (@[*] > 2)))')</code>
2307 → <code class="returnvalue">[2, 4]</code>
2310 <code class="literal">jsonb_path_query_array('{"value": 41}', 'strict $ ? (exists (@.name)) .name')</code>
2311 → <code class="returnvalue">[]</code>
2312 </p></td></tr></tbody></table></div></div><br class="table-break" /></div><div class="sect3" id="JSONPATH-REGULAR-EXPRESSIONS"><div class="titlepage"><div><div><h4 class="title">9.16.2.4. SQL/JSON Regular Expressions <a href="#JSONPATH-REGULAR-EXPRESSIONS" class="id_link">#</a></h4></div></div></div><a id="id-1.5.8.22.9.23.2" class="indexterm"></a><p>
2313 SQL/JSON path expressions allow matching text to a regular expression
2314 with the <code class="literal">like_regex</code> filter. For example, the
2315 following SQL/JSON path query would case-insensitively match all
2316 strings in an array that start with an English vowel:
2317 </p><pre class="programlisting">
2318 $[*] ? (@ like_regex "^[aeiou]" flag "i")
2321 The optional <code class="literal">flag</code> string may include one or more of
2323 <code class="literal">i</code> for case-insensitive match,
2324 <code class="literal">m</code> to allow <code class="literal">^</code>
2325 and <code class="literal">$</code> to match at newlines,
2326 <code class="literal">s</code> to allow <code class="literal">.</code> to match a newline,
2327 and <code class="literal">q</code> to quote the whole pattern (reducing the
2328 behavior to a simple substring match).
2330 The SQL/JSON standard borrows its definition for regular expressions
2331 from the <code class="literal">LIKE_REGEX</code> operator, which in turn uses the
2332 XQuery standard. PostgreSQL does not currently support the
2333 <code class="literal">LIKE_REGEX</code> operator. Therefore,
2334 the <code class="literal">like_regex</code> filter is implemented using the
2335 POSIX regular expression engine described in
2336 <a class="xref" href="functions-matching.html#FUNCTIONS-POSIX-REGEXP" title="9.7.3. POSIX Regular Expressions">Section 9.7.3</a>. This leads to various minor
2337 discrepancies from standard SQL/JSON behavior, which are cataloged in
2338 <a class="xref" href="functions-matching.html#POSIX-VS-XQUERY" title="9.7.3.8. Differences from SQL Standard and XQuery">Section 9.7.3.8</a>.
2339 Note, however, that the flag-letter incompatibilities described there
2340 do not apply to SQL/JSON, as it translates the XQuery flag letters to
2341 match what the POSIX engine expects.
2343 Keep in mind that the pattern argument of <code class="literal">like_regex</code>
2344 is a JSON path string literal, written according to the rules given in
2345 <a class="xref" href="datatype-json.html#DATATYPE-JSONPATH" title="8.14.7. jsonpath Type">Section 8.14.7</a>. This means in particular that any
2346 backslashes you want to use in the regular expression must be doubled.
2347 For example, to match string values of the root document that contain
2349 </p><pre class="programlisting">
2350 $.* ? (@ like_regex "^\\d+$")
2352 </p></div></div><div class="sect2" id="SQLJSON-QUERY-FUNCTIONS"><div class="titlepage"><div><div><h3 class="title">9.16.3. SQL/JSON Query Functions <a href="#SQLJSON-QUERY-FUNCTIONS" class="id_link">#</a></h3></div></div></div><p>
2353 SQL/JSON functions <code class="literal">JSON_EXISTS()</code>,
2354 <code class="literal">JSON_QUERY()</code>, and <code class="literal">JSON_VALUE()</code>
2355 described in <a class="xref" href="functions-json.html#FUNCTIONS-SQLJSON-QUERYING" title="Table 9.54. SQL/JSON Query Functions">Table 9.54</a> can be used
2356 to query JSON documents. Each of these functions apply a
2357 <em class="replaceable"><code>path_expression</code></em> (an SQL/JSON path query) to a
2358 <em class="replaceable"><code>context_item</code></em> (the document). See
2359 <a class="xref" href="functions-json.html#FUNCTIONS-SQLJSON-PATH" title="9.16.2. The SQL/JSON Path Language">Section 9.16.2</a> for more details on what
2360 the <em class="replaceable"><code>path_expression</code></em> can contain. The
2361 <em class="replaceable"><code>path_expression</code></em> can also reference variables,
2362 whose values are specified with their respective names in the
2363 <code class="literal">PASSING</code> clause that is supported by each function.
2364 <em class="replaceable"><code>context_item</code></em> can be a <code class="type">jsonb</code> value
2365 or a character string that can be successfully cast to <code class="type">jsonb</code>.
2366 </p><div class="table" id="FUNCTIONS-SQLJSON-QUERYING"><p class="title"><strong>Table 9.54. SQL/JSON Query Functions</strong></p><div class="table-contents"><table class="table" summary="SQL/JSON Query Functions" border="1"><colgroup><col /></colgroup><thead><tr><th class="func_table_entry"><p class="func_signature">
2374 </p></th></tr></thead><tbody><tr><td class="func_table_entry"><p class="func_signature">
2375 <a id="id-1.5.8.22.10.3.2.2.1.1.1.1" class="indexterm"></a>
2376 </p><pre class="synopsis">
2377 <code class="function">JSON_EXISTS</code> (
2378 <em class="replaceable"><code>context_item</code></em>, <em class="replaceable"><code>path_expression</code></em>
2379 [<span class="optional"> <code class="literal">PASSING</code> { <em class="replaceable"><code>value</code></em> <code class="literal">AS</code> <em class="replaceable"><code>varname</code></em> } [<span class="optional">, ...</span>]</span>]
2380 [<span class="optional">{ <code class="literal">TRUE</code> | <code class="literal">FALSE</code> |<code class="literal"> UNKNOWN</code> | <code class="literal">ERROR</code> } <code class="literal">ON ERROR</code> </span>]) → <code class="returnvalue">boolean</code>
2381 </pre><p class="func_signature">
2383 <div class="itemizedlist"><ul class="itemizedlist" style="list-style-type: disc; "><li class="listitem"><p>
2384 Returns true if the SQL/JSON <em class="replaceable"><code>path_expression</code></em>
2385 applied to the <em class="replaceable"><code>context_item</code></em> yields any
2386 items, false otherwise.
2387 </p></li><li class="listitem"><p>
2388 The <code class="literal">ON ERROR</code> clause specifies the behavior if
2389 an error occurs during <em class="replaceable"><code>path_expression</code></em>
2390 evaluation. Specifying <code class="literal">ERROR</code> will cause an error to
2391 be thrown with the appropriate message. Other options include
2392 returning <code class="type">boolean</code> values <code class="literal">FALSE</code> or
2393 <code class="literal">TRUE</code> or the value <code class="literal">UNKNOWN</code> which
2394 is actually an SQL NULL. The default when no <code class="literal">ON ERROR</code>
2395 clause is specified is to return the <code class="type">boolean</code> value
2396 <code class="literal">FALSE</code>.
2397 </p></li></ul></div>
2402 <code class="literal">JSON_EXISTS(jsonb '{"key1": [1,2,3]}', 'strict $.key1[*] ? (@ > $x)' PASSING 2 AS x)</code>
2403 → <code class="returnvalue">t</code>
2406 <code class="literal">JSON_EXISTS(jsonb '{"a": [1,2,3]}', 'lax $.a[5]' ERROR ON ERROR)</code>
2407 → <code class="returnvalue">f</code>
2410 <code class="literal">JSON_EXISTS(jsonb '{"a": [1,2,3]}', 'strict $.a[5]' ERROR ON ERROR)</code>
2411 → <code class="returnvalue"></code>
2412 </p><pre class="programlisting">
2413 ERROR: jsonpath array subscript is out of bounds
2415 </p></td></tr><tr><td class="func_table_entry"><p class="func_signature">
2416 <a id="id-1.5.8.22.10.3.2.2.2.1.1.1" class="indexterm"></a>
2417 </p><pre class="synopsis">
2418 <code class="function">JSON_QUERY</code> (
2419 <em class="replaceable"><code>context_item</code></em>, <em class="replaceable"><code>path_expression</code></em>
2420 [<span class="optional"> <code class="literal">PASSING</code> { <em class="replaceable"><code>value</code></em> <code class="literal">AS</code> <em class="replaceable"><code>varname</code></em> } [<span class="optional">, ...</span>]</span>]
2421 [<span class="optional"> <code class="literal">RETURNING</code> <em class="replaceable"><code>data_type</code></em> [<span class="optional"> <code class="literal">FORMAT JSON</code> [<span class="optional"> <code class="literal">ENCODING UTF8</code> </span>] </span>] </span>]
2422 [<span class="optional"> { <code class="literal">WITHOUT</code> | <code class="literal">WITH</code> { <code class="literal">CONDITIONAL</code> | [<span class="optional"><code class="literal">UNCONDITIONAL</code></span>] } } [<span class="optional"> <code class="literal">ARRAY</code> </span>] <code class="literal">WRAPPER</code> </span>]
2423 [<span class="optional"> { <code class="literal">KEEP</code> | <code class="literal">OMIT</code> } <code class="literal">QUOTES</code> [<span class="optional"> <code class="literal">ON SCALAR STRING</code> </span>] </span>]
2424 [<span class="optional"> { <code class="literal">ERROR</code> | <code class="literal">NULL</code> | <code class="literal">EMPTY</code> { [<span class="optional"> <code class="literal">ARRAY</code> </span>] | <code class="literal">OBJECT</code> } | <code class="literal">DEFAULT</code> <em class="replaceable"><code>expression</code></em> } <code class="literal">ON EMPTY</code> </span>]
2425 [<span class="optional"> { <code class="literal">ERROR</code> | <code class="literal">NULL</code> | <code class="literal">EMPTY</code> { [<span class="optional"> <code class="literal">ARRAY</code> </span>] | <code class="literal">OBJECT</code> } | <code class="literal">DEFAULT</code> <em class="replaceable"><code>expression</code></em> } <code class="literal">ON ERROR</code> </span>]) → <code class="returnvalue">jsonb</code>
2426 </pre><p class="func_signature">
2428 <div class="itemizedlist"><ul class="itemizedlist" style="list-style-type: disc; "><li class="listitem"><p>
2429 Returns the result of applying the SQL/JSON
2430 <em class="replaceable"><code>path_expression</code></em> to the
2431 <em class="replaceable"><code>context_item</code></em>.
2432 </p></li><li class="listitem"><p>
2433 By default, the result is returned as a value of type <code class="type">jsonb</code>,
2434 though the <code class="literal">RETURNING</code> clause can be used to return
2435 as some other type to which it can be successfully coerced.
2436 </p></li><li class="listitem"><p>
2437 If the path expression may return multiple values, it might be necessary
2438 to wrap those values using the <code class="literal">WITH WRAPPER</code> clause to
2439 make it a valid JSON string, because the default behavior is to not wrap
2440 them, as if <code class="literal">WITHOUT WRAPPER</code> were specified. The
2441 <code class="literal">WITH WRAPPER</code> clause is by default taken to mean
2442 <code class="literal">WITH UNCONDITIONAL WRAPPER</code>, which means that even a
2443 single result value will be wrapped. To apply the wrapper only when
2444 multiple values are present, specify <code class="literal">WITH CONDITIONAL WRAPPER</code>.
2445 Getting multiple values in result will be treated as an error if
2446 <code class="literal">WITHOUT WRAPPER</code> is specified.
2447 </p></li><li class="listitem"><p>
2448 If the result is a scalar string, by default, the returned value will
2449 be surrounded by quotes, making it a valid JSON value. It can be made
2450 explicit by specifying <code class="literal">KEEP QUOTES</code>. Conversely,
2451 quotes can be omitted by specifying <code class="literal">OMIT QUOTES</code>.
2452 To ensure that the result is a valid JSON value, <code class="literal">OMIT QUOTES</code>
2453 cannot be specified when <code class="literal">WITH WRAPPER</code> is also
2455 </p></li><li class="listitem"><p>
2456 The <code class="literal">ON EMPTY</code> clause specifies the behavior if
2457 evaluating <em class="replaceable"><code>path_expression</code></em> yields an empty
2458 set. The <code class="literal">ON ERROR</code> clause specifies the behavior
2459 if an error occurs when evaluating <em class="replaceable"><code>path_expression</code></em>,
2460 when coercing the result value to the <code class="literal">RETURNING</code> type,
2461 or when evaluating the <code class="literal">ON EMPTY</code> expression if the
2462 <em class="replaceable"><code>path_expression</code></em> evaluation returns an empty
2464 </p></li><li class="listitem"><p>
2465 For both <code class="literal">ON EMPTY</code> and <code class="literal">ON ERROR</code>,
2466 specifying <code class="literal">ERROR</code> will cause an error to be thrown with
2467 the appropriate message. Other options include returning an SQL NULL, an
2468 empty array (<code class="literal">EMPTY [<span class="optional">ARRAY</span>]</code>),
2469 an empty object (<code class="literal">EMPTY OBJECT</code>), or a user-specified
2470 expression (<code class="literal">DEFAULT</code> <em class="replaceable"><code>expression</code></em>)
2471 that can be coerced to jsonb or the type specified in <code class="literal">RETURNING</code>.
2472 The default when <code class="literal">ON EMPTY</code> or <code class="literal">ON ERROR</code>
2473 is not specified is to return an SQL NULL value.
2474 </p></li></ul></div>
2479 <code class="literal">JSON_QUERY(jsonb '[1,[2,3],null]', 'lax $[*][$off]' PASSING 1 AS off WITH CONDITIONAL WRAPPER)</code>
2480 → <code class="returnvalue">3</code>
2483 <code class="literal">JSON_QUERY(jsonb '{"a": "[1, 2]"}', 'lax $.a' OMIT QUOTES)</code>
2484 → <code class="returnvalue">[1, 2]</code>
2487 <code class="literal">JSON_QUERY(jsonb '{"a": "[1, 2]"}', 'lax $.a' RETURNING int[] OMIT QUOTES ERROR ON ERROR)</code>
2488 → <code class="returnvalue"></code>
2489 </p><pre class="programlisting">
2490 ERROR: malformed array literal: "[1, 2]"
2491 DETAIL: Missing "]" after array dimensions.
2494 </td></tr><tr><td class="func_table_entry"><p class="func_signature">
2495 <a id="id-1.5.8.22.10.3.2.2.3.1.1.1" class="indexterm"></a>
2496 </p><pre class="synopsis">
2497 <code class="function">JSON_VALUE</code> (
2498 <em class="replaceable"><code>context_item</code></em>, <em class="replaceable"><code>path_expression</code></em>
2499 [<span class="optional"> <code class="literal">PASSING</code> { <em class="replaceable"><code>value</code></em> <code class="literal">AS</code> <em class="replaceable"><code>varname</code></em> } [<span class="optional">, ...</span>]</span>]
2500 [<span class="optional"> <code class="literal">RETURNING</code> <em class="replaceable"><code>data_type</code></em> </span>]
2501 [<span class="optional"> { <code class="literal">ERROR</code> | <code class="literal">NULL</code> | <code class="literal">DEFAULT</code> <em class="replaceable"><code>expression</code></em> } <code class="literal">ON EMPTY</code> </span>]
2502 [<span class="optional"> { <code class="literal">ERROR</code> | <code class="literal">NULL</code> | <code class="literal">DEFAULT</code> <em class="replaceable"><code>expression</code></em> } <code class="literal">ON ERROR</code> </span>]) → <code class="returnvalue">text</code>
2503 </pre><p class="func_signature">
2505 <div class="itemizedlist"><ul class="itemizedlist" style="list-style-type: disc; "><li class="listitem"><p>
2506 Returns the result of applying the SQL/JSON
2507 <em class="replaceable"><code>path_expression</code></em> to the
2508 <em class="replaceable"><code>context_item</code></em>.
2509 </p></li><li class="listitem"><p>
2510 Only use <code class="function">JSON_VALUE()</code> if the extracted value is
2511 expected to be a single <acronym class="acronym">SQL/JSON</acronym> scalar item;
2512 getting multiple values will be treated as an error. If you expect that
2513 extracted value might be an object or an array, use the
2514 <code class="function">JSON_QUERY</code> function instead.
2515 </p></li><li class="listitem"><p>
2516 By default, the result, which must be a single scalar value, is
2517 returned as a value of type <code class="type">text</code>, though the
2518 <code class="literal">RETURNING</code> clause can be used to return as some
2519 other type to which it can be successfully coerced.
2520 </p></li><li class="listitem"><p>
2521 The <code class="literal">ON ERROR</code> and <code class="literal">ON EMPTY</code>
2522 clauses have similar semantics as mentioned in the description of
2523 <code class="function">JSON_QUERY</code>, except the set of values returned in
2524 lieu of throwing an error is different.
2525 </p></li><li class="listitem"><p>
2526 Note that scalar strings returned by <code class="function">JSON_VALUE</code>
2527 always have their quotes removed, equivalent to specifying
2528 <code class="literal">OMIT QUOTES</code> in <code class="function">JSON_QUERY</code>.
2529 </p></li></ul></div>
2534 <code class="literal">JSON_VALUE(jsonb '"123.45"', '$' RETURNING float)</code>
2535 → <code class="returnvalue">123.45</code>
2538 <code class="literal">JSON_VALUE(jsonb '"03:04 2015-02-01"', '$.datetime("HH24:MI YYYY-MM-DD")' RETURNING date)</code>
2539 → <code class="returnvalue">2015-02-01</code>
2542 <code class="literal">JSON_VALUE(jsonb '[1,2]', 'strict $[$off]' PASSING 1 as off)</code>
2543 → <code class="returnvalue">2</code>
2546 <code class="literal">JSON_VALUE(jsonb '[1,2]', 'strict $[*]' DEFAULT 9 ON ERROR)</code>
2547 → <code class="returnvalue">9</code>
2549 </td></tr></tbody></table></div></div><br class="table-break" /><div class="note"><h3 class="title">Note</h3><p>
2550 The <em class="replaceable"><code>context_item</code></em> expression is converted to
2551 <code class="type">jsonb</code> by an implicit cast if the expression is not already of
2552 type <code class="type">jsonb</code>. Note, however, that any parsing errors that occur
2553 during that conversion are thrown unconditionally, that is, are not
2554 handled according to the (specified or implicit) <code class="literal">ON ERROR</code>
2556 </p></div><div class="note"><h3 class="title">Note</h3><p>
2557 <code class="function">JSON_VALUE()</code> returns an SQL NULL if
2558 <em class="replaceable"><code>path_expression</code></em> returns a JSON
2559 <code class="literal">null</code>, whereas <code class="function">JSON_QUERY()</code> returns
2560 the JSON <code class="literal">null</code> as is.
2561 </p></div></div><div class="sect2" id="FUNCTIONS-SQLJSON-TABLE"><div class="titlepage"><div><div><h3 class="title">9.16.4. JSON_TABLE <a href="#FUNCTIONS-SQLJSON-TABLE" class="id_link">#</a></h3></div></div></div><a id="id-1.5.8.22.11.2" class="indexterm"></a><p>
2562 <code class="function">JSON_TABLE</code> is an SQL/JSON function which
2563 queries <acronym class="acronym">JSON</acronym> data
2564 and presents the results as a relational view, which can be accessed as a
2565 regular SQL table. You can use <code class="function">JSON_TABLE</code> inside
2566 the <code class="literal">FROM</code> clause of a <code class="literal">SELECT</code>,
2567 <code class="literal">UPDATE</code>, or <code class="literal">DELETE</code> and as data source
2568 in a <code class="literal">MERGE</code> statement.
2570 Taking JSON data as input, <code class="function">JSON_TABLE</code> uses a JSON path
2571 expression to extract a part of the provided data to use as a
2572 <em class="firstterm">row pattern</em> for the constructed view. Each SQL/JSON
2573 value given by the row pattern serves as source for a separate row in the
2576 To split the row pattern into columns, <code class="function">JSON_TABLE</code>
2577 provides the <code class="literal">COLUMNS</code> clause that defines the
2578 schema of the created view. For each column, a separate JSON path expression
2579 can be specified to be evaluated against the row pattern to get an SQL/JSON
2580 value that will become the value for the specified column in a given output
2583 JSON data stored at a nested level of the row pattern can be extracted using
2584 the <code class="literal">NESTED PATH</code> clause. Each
2585 <code class="literal">NESTED PATH</code> clause can be used to generate one or more
2586 columns using the data from a nested level of the row pattern. Those
2587 columns can be specified using a <code class="literal">COLUMNS</code> clause that
2588 looks similar to the top-level COLUMNS clause. Rows constructed from
2589 NESTED COLUMNS are called <em class="firstterm">child rows</em> and are joined
2590 against the row constructed from the columns specified in the parent
2591 <code class="literal">COLUMNS</code> clause to get the row in the final view. Child
2592 columns themselves may contain a <code class="literal">NESTED PATH</code>
2593 specification thus allowing to extract data located at arbitrary nesting
2594 levels. Columns produced by multiple <code class="literal">NESTED PATH</code>s at the
2595 same level are considered to be <em class="firstterm">siblings</em> of each
2596 other and their rows after joining with the parent row are combined using
2599 The rows produced by <code class="function">JSON_TABLE</code> are laterally
2600 joined to the row that generated them, so you do not have to explicitly join
2601 the constructed view with the original table holding <acronym class="acronym">JSON</acronym>
2605 </p><pre class="synopsis">
2607 <em class="replaceable"><code>context_item</code></em>, <em class="replaceable"><code>path_expression</code></em> [<span class="optional"> AS <em class="replaceable"><code>json_path_name</code></em> </span>] [<span class="optional"> PASSING { <em class="replaceable"><code>value</code></em> AS <em class="replaceable"><code>varname</code></em> } [<span class="optional">, ...</span>] </span>]
2608 COLUMNS ( <em class="replaceable"><code>json_table_column</code></em> [<span class="optional">, ...</span>] )
2609 [<span class="optional"> { <code class="literal">ERROR</code> | <code class="literal">EMPTY</code> [<span class="optional">ARRAY</span>]} <code class="literal">ON ERROR</code> </span>]
2612 <span class="phrase">
2613 where <em class="replaceable"><code>json_table_column</code></em> is:
2615 <em class="replaceable"><code>name</code></em> FOR ORDINALITY
2616 | <em class="replaceable"><code>name</code></em> <em class="replaceable"><code>type</code></em>
2617 [<span class="optional"> FORMAT JSON [<span class="optional">ENCODING <code class="literal">UTF8</code></span>]</span>]
2618 [<span class="optional"> PATH <em class="replaceable"><code>path_expression</code></em> </span>]
2619 [<span class="optional"> { WITHOUT | WITH { CONDITIONAL | [<span class="optional">UNCONDITIONAL</span>] } } [<span class="optional"> ARRAY </span>] WRAPPER </span>]
2620 [<span class="optional"> { KEEP | OMIT } QUOTES [<span class="optional"> ON SCALAR STRING </span>] </span>]
2621 [<span class="optional"> { ERROR | NULL | EMPTY { [<span class="optional">ARRAY</span>] | OBJECT } | DEFAULT <em class="replaceable"><code>expression</code></em> } ON EMPTY </span>]
2622 [<span class="optional"> { ERROR | NULL | EMPTY { [<span class="optional">ARRAY</span>] | OBJECT } | DEFAULT <em class="replaceable"><code>expression</code></em> } ON ERROR </span>]
2623 | <em class="replaceable"><code>name</code></em> <em class="replaceable"><code>type</code></em> EXISTS [<span class="optional"> PATH <em class="replaceable"><code>path_expression</code></em> </span>]
2624 [<span class="optional"> { ERROR | TRUE | FALSE | UNKNOWN } ON ERROR </span>]
2625 | NESTED [<span class="optional"> PATH </span>] <em class="replaceable"><code>path_expression</code></em> [<span class="optional"> AS <em class="replaceable"><code>json_path_name</code></em> </span>] COLUMNS ( <em class="replaceable"><code>json_table_column</code></em> [<span class="optional">, ...</span>] )
2627 Each syntax element is described below in more detail.
2628 </p><div class="variablelist"><dl class="variablelist"><dt><span class="term">
2629 <code class="literal"><em class="replaceable"><code>context_item</code></em>, <em class="replaceable"><code>path_expression</code></em> [<span class="optional"> <code class="literal">AS</code> <em class="replaceable"><code>json_path_name</code></em> </span>] [<span class="optional"> <code class="literal">PASSING</code> { <em class="replaceable"><code>value</code></em> <code class="literal">AS</code> <em class="replaceable"><code>varname</code></em> } [<span class="optional">, ...</span>]</span>]</code>
2631 The <em class="replaceable"><code>context_item</code></em> specifies the input document
2632 to query, the <em class="replaceable"><code>path_expression</code></em> is an SQL/JSON
2633 path expression defining the query, and <em class="replaceable"><code>json_path_name</code></em>
2634 is an optional name for the <em class="replaceable"><code>path_expression</code></em>.
2635 The optional <code class="literal">PASSING</code> clause provides data values for
2636 the variables mentioned in the <em class="replaceable"><code>path_expression</code></em>.
2637 The result of the input data evaluation using the aforementioned elements
2638 is called the <em class="firstterm">row pattern</em>, which is used as the
2639 source for row values in the constructed view.
2640 </p></dd><dt><span class="term">
2641 <code class="literal">COLUMNS</code> ( <em class="replaceable"><code>json_table_column</code></em> [<span class="optional">, ...</span>] )
2643 The <code class="literal">COLUMNS</code> clause defining the schema of the
2644 constructed view. In this clause, you can specify each column to be
2645 filled with an SQL/JSON value obtained by applying a JSON path expression
2646 against the row pattern. <em class="replaceable"><code>json_table_column</code></em> has
2647 the following variants:
2648 </p><div class="variablelist"><dl class="variablelist"><dt><span class="term">
2649 <em class="replaceable"><code>name</code></em> <code class="literal">FOR ORDINALITY</code>
2651 Adds an ordinality column that provides sequential row numbering starting
2652 from 1. Each <code class="literal">NESTED PATH</code> (see below) gets its own
2653 counter for any nested ordinality columns.
2654 </p></dd><dt><span class="term">
2655 <code class="literal"><em class="replaceable"><code>name</code></em> <em class="replaceable"><code>type</code></em>
2656 [<span class="optional"><code class="literal">FORMAT JSON</code> [<span class="optional">ENCODING <code class="literal">UTF8</code></span>]</span>]
2657 [<span class="optional"> <code class="literal">PATH</code> <em class="replaceable"><code>path_expression</code></em> </span>]</code>
2659 Inserts an SQL/JSON value obtained by applying
2660 <em class="replaceable"><code>path_expression</code></em> against the row pattern into
2661 the view's output row after coercing it to specified
2662 <em class="replaceable"><code>type</code></em>.
2664 Specifying <code class="literal">FORMAT JSON</code> makes it explicit that you
2665 expect the value to be a valid <code class="type">json</code> object. It only
2666 makes sense to specify <code class="literal">FORMAT JSON</code> if
2667 <em class="replaceable"><code>type</code></em> is one of <code class="type">bpchar</code>,
2668 <code class="type">bytea</code>, <code class="type">character varying</code>, <code class="type">name</code>,
2669 <code class="type">json</code>, <code class="type">jsonb</code>, <code class="type">text</code>, or a domain over
2672 Optionally, you can specify <code class="literal">WRAPPER</code> and
2673 <code class="literal">QUOTES</code> clauses to format the output. Note that
2674 specifying <code class="literal">OMIT QUOTES</code> overrides
2675 <code class="literal">FORMAT JSON</code> if also specified, because unquoted
2676 literals do not constitute valid <code class="type">json</code> values.
2678 Optionally, you can use <code class="literal">ON EMPTY</code> and
2679 <code class="literal">ON ERROR</code> clauses to specify whether to throw the error
2680 or return the specified value when the result of JSON path evaluation is
2681 empty and when an error occurs during JSON path evaluation or when
2682 coercing the SQL/JSON value to the specified type, respectively. The
2683 default for both is to return a <code class="literal">NULL</code> value.
2684 </p><div class="note"><h3 class="title">Note</h3><p>
2685 This clause is internally turned into and has the same semantics as
2686 <code class="function">JSON_VALUE</code> or <code class="function">JSON_QUERY</code>.
2687 The latter if the specified type is not a scalar type or if either of
2688 <code class="literal">FORMAT JSON</code>, <code class="literal">WRAPPER</code>, or
2689 <code class="literal">QUOTES</code> clause is present.
2690 </p></div></dd><dt><span class="term">
2691 <em class="replaceable"><code>name</code></em> <em class="replaceable"><code>type</code></em>
2692 <code class="literal">EXISTS</code> [<span class="optional"> <code class="literal">PATH</code> <em class="replaceable"><code>path_expression</code></em> </span>]
2694 Inserts a boolean value obtained by applying
2695 <em class="replaceable"><code>path_expression</code></em> against the row pattern
2696 into the view's output row after coercing it to specified
2697 <em class="replaceable"><code>type</code></em>.
2699 The value corresponds to whether applying the <code class="literal">PATH</code>
2700 expression to the row pattern yields any values.
2702 The specified <em class="replaceable"><code>type</code></em> should have a cast from the
2703 <code class="type">boolean</code> type.
2705 Optionally, you can use <code class="literal">ON ERROR</code> to specify whether to
2706 throw the error or return the specified value when an error occurs during
2707 JSON path evaluation or when coercing SQL/JSON value to the specified
2708 type. The default is to return a boolean value
2709 <code class="literal">FALSE</code>.
2710 </p><div class="note"><h3 class="title">Note</h3><p>
2711 This clause is internally turned into and has the same semantics as
2712 <code class="function">JSON_EXISTS</code>.
2713 </p></div></dd><dt><span class="term">
2714 <code class="literal">NESTED [<span class="optional"> PATH </span>]</code> <em class="replaceable"><code>path_expression</code></em> [<span class="optional"> <code class="literal">AS</code> <em class="replaceable"><code>json_path_name</code></em> </span>]
2715 <code class="literal">COLUMNS</code> ( <em class="replaceable"><code>json_table_column</code></em> [<span class="optional">, ...</span>] )
2717 Extracts SQL/JSON values from nested levels of the row pattern,
2718 generates one or more columns as defined by the <code class="literal">COLUMNS</code>
2719 subclause, and inserts the extracted SQL/JSON values into those
2720 columns. The <em class="replaceable"><code>json_table_column</code></em>
2721 expression in the <code class="literal">COLUMNS</code> subclause uses the same
2722 syntax as in the parent <code class="literal">COLUMNS</code> clause.
2724 The <code class="literal">NESTED PATH</code> syntax is recursive,
2725 so you can go down multiple nested levels by specifying several
2726 <code class="literal">NESTED PATH</code> subclauses within each other.
2727 It allows to unnest the hierarchy of JSON objects and arrays
2728 in a single function invocation rather than chaining several
2729 <code class="function">JSON_TABLE</code> expressions in an SQL statement.
2730 </p></dd></dl></div><div class="note"><h3 class="title">Note</h3><p>
2731 In each variant of <em class="replaceable"><code>json_table_column</code></em> described
2732 above, if the <code class="literal">PATH</code> clause is omitted, path expression
2733 <code class="literal">$.<em class="replaceable"><code>name</code></em></code> is used, where
2734 <em class="replaceable"><code>name</code></em> is the provided column name.
2735 </p></div></dd><dt><span class="term">
2736 <code class="literal">AS</code> <em class="replaceable"><code>json_path_name</code></em>
2738 The optional <em class="replaceable"><code>json_path_name</code></em> serves as an
2739 identifier of the provided <em class="replaceable"><code>path_expression</code></em>.
2740 The name must be unique and distinct from the column names.
2741 </p></dd><dt><span class="term">
2742 { <code class="literal">ERROR</code> | <code class="literal">EMPTY</code> } <code class="literal">ON ERROR</code>
2744 The optional <code class="literal">ON ERROR</code> can be used to specify how to
2745 handle errors when evaluating the top-level
2746 <em class="replaceable"><code>path_expression</code></em>. Use <code class="literal">ERROR</code>
2747 if you want the errors to be thrown and <code class="literal">EMPTY</code> to
2748 return an empty table, that is, a table containing 0 rows. Note that
2749 this clause does not affect the errors that occur when evaluating
2750 columns, for which the behavior depends on whether the
2751 <code class="literal">ON ERROR</code> clause is specified against a given column.
2752 </p></dd></dl></div><p>Examples</p><p>
2753 In the examples that follow, the following table containing JSON data
2756 </p><pre class="programlisting">
2757 CREATE TABLE my_films ( js jsonb );
2759 INSERT INTO my_films VALUES (
2761 { "kind" : "comedy", "films" : [
2762 { "title" : "Bananas",
2763 "director" : "Woody Allen"},
2764 { "title" : "The Dinner Game",
2765 "director" : "Francis Veber" } ] },
2766 { "kind" : "horror", "films" : [
2767 { "title" : "Psycho",
2768 "director" : "Alfred Hitchcock" } ] },
2769 { "kind" : "thriller", "films" : [
2770 { "title" : "Vertigo",
2771 "director" : "Alfred Hitchcock" } ] },
2772 { "kind" : "drama", "films" : [
2773 { "title" : "Yojimbo",
2774 "director" : "Akira Kurosawa" } ] }
2779 The following query shows how to use <code class="function">JSON_TABLE</code> to
2780 turn the JSON objects in the <code class="structname">my_films</code> table
2781 to a view containing columns for the keys <code class="literal">kind</code>,
2782 <code class="literal">title</code>, and <code class="literal">director</code> contained in
2783 the original JSON along with an ordinality column:
2785 </p><pre class="programlisting">
2788 JSON_TABLE (js, '$.favorites[*]' COLUMNS (
2790 kind text PATH '$.kind',
2791 title text PATH '$.films[*].title' WITH WRAPPER,
2792 director text PATH '$.films[*].director' WITH WRAPPER)) AS jt;
2795 </p><pre class="screen">
2796 id | kind | title | director
2797 ----+----------+--------------------------------+----------------------------------
2798 1 | comedy | ["Bananas", "The Dinner Game"] | ["Woody Allen", "Francis Veber"]
2799 2 | horror | ["Psycho"] | ["Alfred Hitchcock"]
2800 3 | thriller | ["Vertigo"] | ["Alfred Hitchcock"]
2801 4 | drama | ["Yojimbo"] | ["Akira Kurosawa"]
2806 The following is a modified version of the above query to show the
2807 usage of <code class="literal">PASSING</code> arguments in the filter specified in
2808 the top-level JSON path expression and the various options for the
2811 </p><pre class="programlisting">
2814 JSON_TABLE (js, '$.favorites[*] ? (@.films[*].director == $filter)'
2815 PASSING 'Alfred Hitchcock' AS filter
2818 kind text PATH '$.kind',
2819 title text FORMAT JSON PATH '$.films[*].title' OMIT QUOTES,
2820 director text PATH '$.films[*].director' KEEP QUOTES)) AS jt;
2823 </p><pre class="screen">
2824 id | kind | title | director
2825 ----+----------+---------+--------------------
2826 1 | horror | Psycho | "Alfred Hitchcock"
2827 2 | thriller | Vertigo | "Alfred Hitchcock"
2832 The following is a modified version of the above query to show the usage
2833 of <code class="literal">NESTED PATH</code> for populating title and director
2834 columns, illustrating how they are joined to the parent columns id and
2837 </p><pre class="programlisting">
2840 JSON_TABLE ( js, '$.favorites[*] ? (@.films[*].director == $filter)'
2841 PASSING 'Alfred Hitchcock' AS filter
2844 kind text PATH '$.kind',
2845 NESTED PATH '$.films[*]' COLUMNS (
2846 title text FORMAT JSON PATH '$.title' OMIT QUOTES,
2847 director text PATH '$.director' KEEP QUOTES))) AS jt;
2850 </p><pre class="screen">
2851 id | kind | title | director
2852 ----+----------+---------+--------------------
2853 1 | horror | Psycho | "Alfred Hitchcock"
2854 2 | thriller | Vertigo | "Alfred Hitchcock"
2859 The following is the same query but without the filter in the root
2862 </p><pre class="programlisting">
2865 JSON_TABLE ( js, '$.favorites[*]'
2868 kind text PATH '$.kind',
2869 NESTED PATH '$.films[*]' COLUMNS (
2870 title text FORMAT JSON PATH '$.title' OMIT QUOTES,
2871 director text PATH '$.director' KEEP QUOTES))) AS jt;
2874 </p><pre class="screen">
2875 id | kind | title | director
2876 ----+----------+-----------------+--------------------
2877 1 | comedy | Bananas | "Woody Allen"
2878 1 | comedy | The Dinner Game | "Francis Veber"
2879 2 | horror | Psycho | "Alfred Hitchcock"
2880 3 | thriller | Vertigo | "Alfred Hitchcock"
2881 4 | drama | Yojimbo | "Akira Kurosawa"
2886 The following shows another query using a different <code class="type">JSON</code>
2887 object as input. It shows the UNION "sibling join" between
2888 <code class="literal">NESTED</code> paths <code class="literal">$.movies[*]</code> and
2889 <code class="literal">$.books[*]</code> and also the usage of
2890 <code class="literal">FOR ORDINALITY</code> column at <code class="literal">NESTED</code>
2891 levels (columns <code class="literal">movie_id</code>, <code class="literal">book_id</code>,
2892 and <code class="literal">author_id</code>):
2894 </p><pre class="programlisting">
2895 SELECT * FROM JSON_TABLE (
2898 [{"name": "One", "director": "John Doe"},
2899 {"name": "Two", "director": "Don Joe"}],
2901 [{"name": "Mystery", "authors": [{"name": "Brown Dan"}]},
2902 {"name": "Wonder", "authors": [{"name": "Jun Murakami"}, {"name":"Craig Doe"}]}]
2903 }]}'::json, '$.favorites[*]'
2905 user_id FOR ORDINALITY,
2906 NESTED '$.movies[*]'
2908 movie_id FOR ORDINALITY,
2909 mname text PATH '$.name',
2913 book_id FOR ORDINALITY,
2914 bname text PATH '$.name',
2915 NESTED '$.authors[*]'
2917 author_id FOR ORDINALITY,
2918 author_name text PATH '$.name'))));
2921 </p><pre class="screen">
2922 user_id | movie_id | mname | director | book_id | bname | author_id | author_name
2923 ---------+----------+-------+----------+---------+---------+-----------+--------------
2924 1 | 1 | One | John Doe | | | |
2925 1 | 2 | Two | Don Joe | | | |
2926 1 | | | | 1 | Mystery | 1 | Brown Dan
2927 1 | | | | 2 | Wonder | 1 | Jun Murakami
2928 1 | | | | 2 | Wonder | 2 | Craig Doe
2932 </p></div></div><div class="navfooter"><hr /><table width="100%" summary="Navigation footer"><tr><td width="40%" align="left"><a accesskey="p" href="functions-xml.html" title="9.15. XML Functions">Prev</a> </td><td width="20%" align="center"><a accesskey="u" href="functions.html" title="Chapter 9. Functions and Operators">Up</a></td><td width="40%" align="right"> <a accesskey="n" href="functions-sequence.html" title="9.17. Sequence Manipulation Functions">Next</a></td></tr><tr><td width="40%" align="left" valign="top">9.15. XML Functions </td><td width="20%" align="center"><a accesskey="h" href="index.html" title="PostgreSQL 18.0 Documentation">Home</a></td><td width="40%" align="right" valign="top"> 9.17. Sequence Manipulation Functions</td></tr></table></div></body></html>