|  | <?xml version="1.0" encoding="UTF-8" standalone="no"?>
<!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.15. 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 V1.79.1" /><link rel="prev" href="functions-xml.html" title="9.14. XML Functions" /><link rel="next" href="functions-sequence.html" title="9.16. Sequence Manipulation Functions" /></head><body><div xmlns="http://www.w3.org/TR/xhtml1/transitional" class="navheader"><table width="100%" summary="Navigation header"><tr><th colspan="5" align="center">9.15. JSON Functions and Operators</th></tr><tr><td width="10%" align="left"><a accesskey="p" href="functions-xml.html" title="9.14. 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 12.4 Documentation">Home</a></td><td width="10%" align="right"> <a accesskey="n" href="functions-sequence.html" title="9.16. Sequence Manipulation Functions">Next</a></td></tr></table><hr></hr></div><div class="sect1" id="FUNCTIONS-JSON"><div class="titlepage"><div><div><h2 class="title" style="clear: both">9.15. JSON Functions and Operators</h2></div></div></div><div class="toc"><dl class="toc"><dt><span class="sect2"><a href="functions-json.html#FUNCTIONS-JSON-PROCESSING">9.15.1. Processing and Creating JSON Data</a></span></dt><dt><span class="sect2"><a href="functions-json.html#FUNCTIONS-SQLJSON-PATH">9.15.2. The SQL/JSON Path Language</a></span></dt></dl></div><a id="id-1.5.8.20.2" class="indexterm"></a><p>
   This section describes:
   </p><div class="itemizedlist"><ul class="itemizedlist" style="list-style-type: disc; "><li class="listitem"><p>
      functions and operators for processing and creating JSON data
     </p></li><li class="listitem"><p>
      the SQL/JSON path language
     </p></li></ul></div><p>
  </p><p>
   To learn more about the SQL/JSON standard, see
   <a class="xref" href="biblio.html#SQLTR-19075-6" title="SQL Technical Report">[sqltr-19075-6]</a>. For details on JSON types
   supported in <span class="productname">PostgreSQL</span>,
   see <a class="xref" href="datatype-json.html" title="8.14. JSON Types">Section 8.14</a>.
  </p><div class="sect2" id="FUNCTIONS-JSON-PROCESSING"><div class="titlepage"><div><div><h3 class="title">9.15.1. Processing and Creating JSON Data</h3></div></div></div><p>
   <a class="xref" href="functions-json.html#FUNCTIONS-JSON-OP-TABLE" title="Table 9.44. json and jsonb Operators">Table 9.44</a> shows the operators that
   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>).
  </p><div class="table" id="FUNCTIONS-JSON-OP-TABLE"><p class="title"><strong>Table 9.44. <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 /><col /><col /><col /><col /><col /></colgroup><thead><tr><th>Operator</th><th>Right Operand Type</th><th>Return type</th><th>Description</th><th>Example</th><th>Example Result</th></tr></thead><tbody><tr><td><code class="literal">-></code></td><td><code class="type">int</code></td><td><code class="type">json</code> or <code class="type">jsonb</code></td><td>Get JSON array element (indexed from zero, negative
        integers count from the end)</td><td><code class="literal">'[{"a":"foo"},{"b":"bar"},{"c":"baz"}]'::json->2</code></td><td><code class="literal">{"c":"baz"}</code></td></tr><tr><td><code class="literal">-></code></td><td><code class="type">text</code></td><td><code class="type">json</code> or <code class="type">jsonb</code></td><td>Get JSON object field by key</td><td><code class="literal">'{"a": {"b":"foo"}}'::json->'a'</code></td><td><code class="literal">{"b":"foo"}</code></td></tr><tr><td><code class="literal">->></code></td><td><code class="type">int</code></td><td><code class="type">text</code></td><td>Get JSON array element as <code class="type">text</code></td><td><code class="literal">'[1,2,3]'::json->>2</code></td><td><code class="literal">3</code></td></tr><tr><td><code class="literal">->></code></td><td><code class="type">text</code></td><td><code class="type">text</code></td><td>Get JSON object field as <code class="type">text</code></td><td><code class="literal">'{"a":1,"b":2}'::json->>'b'</code></td><td><code class="literal">2</code></td></tr><tr><td><code class="literal">#></code></td><td><code class="type">text[]</code></td><td><code class="type">json</code> or <code class="type">jsonb</code></td><td>Get JSON object at the specified path</td><td><code class="literal">'{"a": {"b":{"c": "foo"}}}'::json#>'{a,b}'</code></td><td><code class="literal">{"c": "foo"}</code></td></tr><tr><td><code class="literal">#>></code></td><td><code class="type">text[]</code></td><td><code class="type">text</code></td><td>Get JSON object at the specified path as <code class="type">text</code></td><td><code class="literal">'{"a":[1,2,3],"b":[4,5,6]}'::json#>>'{a,2}'</code></td><td><code class="literal">3</code></td></tr></tbody></table></div></div><br class="table-break" /><div class="note"><h3 class="title">Note</h3><p>
    There are parallel variants of these operators for both the
    <code class="type">json</code> and <code class="type">jsonb</code> types.
    The field/element/path extraction operators
    return the same type as their left-hand input (either <code class="type">json</code>
    or <code class="type">jsonb</code>), except for those specified as
    returning <code class="type">text</code>, which coerce the value to text.
    The field/element/path extraction operators return NULL, rather than
    failing, if the JSON input does not have the right structure to match
    the request; for example if no such element exists.  The
    field/element/path extraction operators that accept integer JSON
    array subscripts all support negative subscripting from the end of
    arrays.
   </p></div><p>
   The standard 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
   <code class="type">jsonb</code>, but not for <code class="type">json</code>. They follow the
   ordering rules for B-tree operations outlined at <a class="xref" href="datatype-json.html#JSON-INDEXING" title="8.14.4. jsonb Indexing">Section 8.14.4</a>.
  </p><p>
   Some further operators also exist only for <code class="type">jsonb</code>, as shown
   in <a class="xref" href="functions-json.html#FUNCTIONS-JSONB-OP-TABLE" title="Table 9.45. Additional jsonb Operators">Table 9.45</a>.
   Many of these operators can be indexed by
   <code class="type">jsonb</code> operator classes.  For a full description of
   <code class="type">jsonb</code> containment and existence semantics, see <a class="xref" href="datatype-json.html#JSON-CONTAINMENT" title="8.14.3. jsonb Containment and Existence">Section 8.14.3</a>.  <a class="xref" href="datatype-json.html#JSON-INDEXING" title="8.14.4. jsonb Indexing">Section 8.14.4</a>
   describes how these operators can be used to effectively index
   <code class="type">jsonb</code> data.
  </p><div class="table" id="FUNCTIONS-JSONB-OP-TABLE"><p class="title"><strong>Table 9.45. Additional <code class="type">jsonb</code> Operators</strong></p><div class="table-contents"><table class="table" summary="Additional jsonb Operators" border="1"><colgroup><col /><col /><col /><col /></colgroup><thead><tr><th>Operator</th><th>Right Operand Type</th><th>Description</th><th>Example</th></tr></thead><tbody><tr><td><code class="literal">@></code></td><td><code class="type">jsonb</code></td><td>Does the left JSON value contain the right JSON
        path/value entries at the top level?</td><td><code class="literal">'{"a":1, "b":2}'::jsonb @> '{"b":2}'::jsonb</code></td></tr><tr><td><code class="literal"><@</code></td><td><code class="type">jsonb</code></td><td>Are the left JSON path/value entries contained at the top level within
        the right JSON value?</td><td><code class="literal">'{"b":2}'::jsonb <@ '{"a":1, "b":2}'::jsonb</code></td></tr><tr><td><code class="literal">?</code></td><td><code class="type">text</code></td><td>Does the <span class="emphasis"><em>string</em></span> exist as a top-level
        key within the JSON value?</td><td><code class="literal">'{"a":1, "b":2}'::jsonb ? 'b'</code></td></tr><tr><td><code class="literal">?|</code></td><td><code class="type">text[]</code></td><td>Do any of these array <span class="emphasis"><em>strings</em></span>
        exist as top-level keys?</td><td><code class="literal">'{"a":1, "b":2, "c":3}'::jsonb ?| array['b', 'c']</code></td></tr><tr><td><code class="literal">?&</code></td><td><code class="type">text[]</code></td><td>Do all of these array <span class="emphasis"><em>strings</em></span> exist
        as top-level keys?</td><td><code class="literal">'["a", "b"]'::jsonb ?& array['a', 'b']</code></td></tr><tr><td><code class="literal">||</code></td><td><code class="type">jsonb</code></td><td>Concatenate two <code class="type">jsonb</code> values into a new <code class="type">jsonb</code> value</td><td><code class="literal">'["a", "b"]'::jsonb || '["c", "d"]'::jsonb</code></td></tr><tr><td><code class="literal">-</code></td><td><code class="type">text</code></td><td>Delete key/value pair or <span class="emphasis"><em>string</em></span>
        element from left operand.  Key/value pairs are matched based
        on their key value.</td><td><code class="literal">'{"a": "b"}'::jsonb - 'a' </code></td></tr><tr><td><code class="literal">-</code></td><td><code class="type">text[]</code></td><td>Delete multiple key/value pairs or <span class="emphasis"><em>string</em></span>
        elements from left operand.  Key/value pairs are matched based
        on their key value.</td><td><code class="literal">'{"a": "b", "c": "d"}'::jsonb - '{a,c}'::text[] </code></td></tr><tr><td><code class="literal">-</code></td><td><code class="type">integer</code></td><td>Delete the array element with specified index (Negative
        integers count from the end).  Throws an error if top level
        container is not an array.</td><td><code class="literal">'["a", "b"]'::jsonb - 1 </code></td></tr><tr><td><code class="literal">#-</code></td><td><code class="type">text[]</code></td><td>Delete the field or element with specified path (for
        JSON arrays, negative integers count from the end)</td><td><code class="literal">'["a", {"b":1}]'::jsonb #- '{1,b}'</code></td></tr><tr><td><code class="literal">@?</code></td><td><code class="type">jsonpath</code></td><td>Does JSON path return any item for the specified JSON value?</td><td><code class="literal">'{"a":[1,2,3,4,5]}'::jsonb @? '$.a[*] ? (@ > 2)'</code></td></tr><tr><td><code class="literal">@@</code></td><td><code class="type">jsonpath</code></td><td>Returns the result of JSON path predicate check for the specified JSON value.
        Only the first item of the result is taken into account.  If the
        result is not Boolean, then <code class="literal">null</code> is returned.</td><td><code class="literal">'{"a":[1,2,3,4,5]}'::jsonb @@ '$.a[*] > 2'</code></td></tr></tbody></table></div></div><br class="table-break" /><div class="note"><h3 class="title">Note</h3><p>
    The <code class="literal">||</code> operator concatenates the elements at the top level of
    each of its operands. It does not operate recursively. For example, if
    both operands are objects with a common key field name, the value of the
    field in the result will just be the value from the right hand operand.
   </p></div><div class="note"><h3 class="title">Note</h3><p>
    The <code class="literal">@?</code> and <code class="literal">@@</code> operators suppress
    the following errors: lacking object field or array element, unexpected
    JSON item type, and numeric errors.
    This behavior might be helpful while searching over JSON document
    collections of varying structure.
   </p></div><p>
   <a class="xref" href="functions-json.html#FUNCTIONS-JSON-CREATION-TABLE" title="Table 9.46. JSON Creation Functions">Table 9.46</a> shows the functions that are
   available for creating <code class="type">json</code> and <code class="type">jsonb</code> values.
   (There are no equivalent functions for <code class="type">jsonb</code>, of the <code class="literal">row_to_json</code>
   and <code class="literal">array_to_json</code> functions. However, the <code class="literal">to_jsonb</code>
   function supplies much the same functionality as these functions would.)
  </p><a id="id-1.5.8.20.5.11" class="indexterm"></a><a id="id-1.5.8.20.5.12" class="indexterm"></a><a id="id-1.5.8.20.5.13" class="indexterm"></a><a id="id-1.5.8.20.5.14" class="indexterm"></a><a id="id-1.5.8.20.5.15" class="indexterm"></a><a id="id-1.5.8.20.5.16" class="indexterm"></a><a id="id-1.5.8.20.5.17" class="indexterm"></a><a id="id-1.5.8.20.5.18" class="indexterm"></a><a id="id-1.5.8.20.5.19" class="indexterm"></a><a id="id-1.5.8.20.5.20" class="indexterm"></a><div class="table" id="FUNCTIONS-JSON-CREATION-TABLE"><p class="title"><strong>Table 9.46. JSON Creation Functions</strong></p><div class="table-contents"><table class="table" summary="JSON Creation Functions" border="1"><colgroup><col /><col /><col /><col /></colgroup><thead><tr><th>Function</th><th>Description</th><th>Example</th><th>Example Result</th></tr></thead><tbody><tr><td><p><code class="literal">to_json(anyelement)</code>
          </p><p><code class="literal">to_jsonb(anyelement)</code>
       </p></td><td>
         Returns the value as <code class="type">json</code> or <code class="type">jsonb</code>.
         Arrays and composites are converted
         (recursively) to arrays and objects; otherwise, if there is a cast
         from the type to <code class="type">json</code>, the cast function will be used to
         perform the conversion; otherwise, a scalar value is produced.
         For any scalar type other than a number, a Boolean, or a null value,
         the text representation will be used, in such a fashion that it is a
         valid <code class="type">json</code> or <code class="type">jsonb</code> value.
       </td><td><code class="literal">to_json('Fred said "Hi."'::text)</code></td><td><code class="literal">"Fred said \"Hi.\""</code></td></tr><tr><td>
         <code class="literal">array_to_json(anyarray [, pretty_bool])</code>
       </td><td>
         Returns the array as a JSON array. A PostgreSQL multidimensional array
         becomes a JSON array of arrays. Line feeds will be added between
         dimension-1 elements if <em class="parameter"><code>pretty_bool</code></em> is true.
       </td><td><code class="literal">array_to_json('{{1,5},{99,100}}'::int[])</code></td><td><code class="literal">[[1,5],[99,100]]</code></td></tr><tr><td>
         <code class="literal">row_to_json(record [, pretty_bool])</code>
       </td><td>
         Returns the row as a JSON object. Line feeds will be added between
         level-1 elements if <em class="parameter"><code>pretty_bool</code></em> is true.
       </td><td><code class="literal">row_to_json(row(1,'foo'))</code></td><td><code class="literal">{"f1":1,"f2":"foo"}</code></td></tr><tr><td><p><code class="literal">json_build_array(VARIADIC "any")</code>
          </p><p><code class="literal">jsonb_build_array(VARIADIC "any")</code>
       </p></td><td>
         Builds a possibly-heterogeneously-typed JSON array out of a variadic
         argument list.
       </td><td><code class="literal">json_build_array(1,2,'3',4,5)</code></td><td><code class="literal">[1, 2, "3", 4, 5]</code></td></tr><tr><td><p><code class="literal">json_build_object(VARIADIC "any")</code>
          </p><p><code class="literal">jsonb_build_object(VARIADIC "any")</code>
       </p></td><td>
         Builds a JSON object out of a variadic argument list.  By
         convention, the argument list consists of alternating
         keys and values.
       </td><td><code class="literal">json_build_object('foo',1,'bar',2)</code></td><td><code class="literal">{"foo": 1, "bar": 2}</code></td></tr><tr><td><p><code class="literal">json_object(text[])</code>
          </p><p><code class="literal">jsonb_object(text[])</code>
       </p></td><td>
         Builds a JSON object out of a text array.  The array must have either
         exactly one dimension with an even number of members, in which case
         they are taken as alternating key/value pairs, or two dimensions
         such that each inner array has exactly two elements, which
         are taken as a key/value pair.
       </td><td><p><code class="literal">json_object('{a, 1, b, "def", c, 3.5}')</code></p>
        <p><code class="literal">json_object('{{a, 1},{b, "def"},{c, 3.5}}')</code></p></td><td><code class="literal">{"a": "1", "b": "def", "c": "3.5"}</code></td></tr><tr><td><p><code class="literal">json_object(keys text[], values text[])</code>
          </p><p><code class="literal">jsonb_object(keys text[], values text[])</code>
       </p></td><td>
         This form of <code class="function">json_object</code> takes keys and values pairwise from two separate
         arrays. In all other respects it is identical to the one-argument form.
       </td><td><code class="literal">json_object('{a, b}', '{1,2}')</code></td><td><code class="literal">{"a": "1", "b": "2"}</code></td></tr></tbody></table></div></div><br class="table-break" /><div class="note"><h3 class="title">Note</h3><p>
     <code class="function">array_to_json</code> and <code class="function">row_to_json</code> have the same
     behavior as <code class="function">to_json</code> except for offering a pretty-printing
     option.  The behavior described for <code class="function">to_json</code> likewise applies
     to each individual value converted by the other JSON creation functions.
    </p></div><div class="note"><h3 class="title">Note</h3><p>
     The <a class="xref" href="hstore.html" title="F.16. hstore">hstore</a> extension has a cast
     from <code class="type">hstore</code> to <code class="type">json</code>, so that
     <code class="type">hstore</code> values converted via the JSON creation functions
     will be represented as JSON objects, not as primitive string values.
    </p></div><p>
   <a class="xref" href="functions-json.html#FUNCTIONS-JSON-PROCESSING-TABLE" title="Table 9.47. JSON Processing Functions">Table 9.47</a> shows the functions that
   are available for processing <code class="type">json</code> and <code class="type">jsonb</code> values.
  </p><a id="id-1.5.8.20.5.25" class="indexterm"></a><a id="id-1.5.8.20.5.26" class="indexterm"></a><a id="id-1.5.8.20.5.27" class="indexterm"></a><a id="id-1.5.8.20.5.28" class="indexterm"></a><a id="id-1.5.8.20.5.29" class="indexterm"></a><a id="id-1.5.8.20.5.30" class="indexterm"></a><a id="id-1.5.8.20.5.31" class="indexterm"></a><a id="id-1.5.8.20.5.32" class="indexterm"></a><a id="id-1.5.8.20.5.33" class="indexterm"></a><a id="id-1.5.8.20.5.34" class="indexterm"></a><a id="id-1.5.8.20.5.35" class="indexterm"></a><a id="id-1.5.8.20.5.36" class="indexterm"></a><a id="id-1.5.8.20.5.37" class="indexterm"></a><a id="id-1.5.8.20.5.38" class="indexterm"></a><a id="id-1.5.8.20.5.39" class="indexterm"></a><a id="id-1.5.8.20.5.40" class="indexterm"></a><a id="id-1.5.8.20.5.41" class="indexterm"></a><a id="id-1.5.8.20.5.42" class="indexterm"></a><a id="id-1.5.8.20.5.43" class="indexterm"></a><a id="id-1.5.8.20.5.44" class="indexterm"></a><a id="id-1.5.8.20.5.45" class="indexterm"></a><a id="id-1.5.8.20.5.46" class="indexterm"></a><a id="id-1.5.8.20.5.47" class="indexterm"></a><a id="id-1.5.8.20.5.48" class="indexterm"></a><a id="id-1.5.8.20.5.49" class="indexterm"></a><a id="id-1.5.8.20.5.50" class="indexterm"></a><a id="id-1.5.8.20.5.51" class="indexterm"></a><a id="id-1.5.8.20.5.52" class="indexterm"></a><a id="id-1.5.8.20.5.53" class="indexterm"></a><a id="id-1.5.8.20.5.54" class="indexterm"></a><a id="id-1.5.8.20.5.55" class="indexterm"></a><a id="id-1.5.8.20.5.56" class="indexterm"></a><a id="id-1.5.8.20.5.57" class="indexterm"></a><a id="id-1.5.8.20.5.58" class="indexterm"></a><a id="id-1.5.8.20.5.59" class="indexterm"></a><a id="id-1.5.8.20.5.60" class="indexterm"></a><div class="table" id="FUNCTIONS-JSON-PROCESSING-TABLE"><p class="title"><strong>Table 9.47. JSON Processing Functions</strong></p><div class="table-contents"><table class="table" summary="JSON Processing Functions" border="1"><colgroup><col /><col /><col /><col /><col /></colgroup><thead><tr><th>Function</th><th>Return Type</th><th>Description</th><th>Example</th><th>Example Result</th></tr></thead><tbody><tr><td><p><code class="literal">json_array_length(json)</code>
         </p><p><code class="literal">jsonb_array_length(jsonb)</code>
       </p></td><td><code class="type">int</code></td><td>
         Returns the number of elements in the outermost JSON array.
       </td><td><code class="literal">json_array_length('[1,2,3,{"f1":1,"f2":[5,6]},4]')</code></td><td><code class="literal">5</code></td></tr><tr><td><p><code class="literal">json_each(json)</code>
         </p><p><code class="literal">jsonb_each(jsonb)</code>
       </p></td><td><p><code class="literal">setof key text, value json</code>
         </p><p><code class="literal">setof key text, value jsonb</code>
       </p></td><td>
         Expands the outermost JSON object into a set of key/value pairs.
       </td><td><code class="literal">select * from json_each('{"a":"foo", "b":"bar"}')</code></td><td>
<pre class="programlisting">
 key | value
-----+-------
 a   | "foo"
 b   | "bar"
</pre>
       </td></tr><tr><td><p><code class="literal">json_each_text(json)</code>
         </p><p><code class="literal">jsonb_each_text(jsonb)</code>
       </p></td><td><code class="type">setof key text, value text</code></td><td>
         Expands the outermost JSON object into a set of key/value pairs. The
         returned values will be of type <code class="type">text</code>.
       </td><td><code class="literal">select * from json_each_text('{"a":"foo", "b":"bar"}')</code></td><td>
<pre class="programlisting">
 key | value
-----+-------
 a   | foo
 b   | bar
</pre>
       </td></tr><tr><td><p><code class="literal">json_extract_path(from_json json, VARIADIC path_elems text[])</code>
        </p><p><code class="literal">jsonb_extract_path(from_json jsonb, VARIADIC path_elems text[])</code>
       </p></td><td><p><code class="type">json</code></p><p><code class="type">jsonb</code>
       </p></td><td>
         Returns JSON value pointed to by <em class="replaceable"><code>path_elems</code></em>
         (equivalent to <code class="literal">#></code> operator).
       </td><td><code class="literal">json_extract_path('{"f2":{"f3":1},"f4":{"f5":99,"f6":"foo"}}','f4')</code></td><td><code class="literal">{"f5":99,"f6":"foo"}</code></td></tr><tr><td><p><code class="literal">json_extract_path_text(from_json json, VARIADIC path_elems text[])</code>
         </p><p><code class="literal">jsonb_extract_path_text(from_json jsonb, VARIADIC path_elems text[])</code>
       </p></td><td><code class="type">text</code></td><td>
         Returns JSON value pointed to by <em class="replaceable"><code>path_elems</code></em>
         as <code class="type">text</code>
         (equivalent to <code class="literal">#>></code> operator).
       </td><td><code class="literal">json_extract_path_text('{"f2":{"f3":1},"f4":{"f5":99,"f6":"foo"}}','f4', 'f6')</code></td><td><code class="literal">foo</code></td></tr><tr><td><p><code class="literal">json_object_keys(json)</code>
         </p><p><code class="literal">jsonb_object_keys(jsonb)</code>
       </p></td><td><code class="type">setof text</code></td><td>
          Returns set of keys in the outermost JSON object.
       </td><td><code class="literal">json_object_keys('{"f1":"abc","f2":{"f3":"a", "f4":"b"}}')</code></td><td>
<pre class="programlisting">
 json_object_keys
------------------
 f1
 f2
</pre>
       </td></tr><tr><td><p><code class="literal">json_populate_record(base anyelement, from_json json)</code>
         </p><p><code class="literal">jsonb_populate_record(base anyelement, from_json jsonb)</code>
       </p></td><td><code class="type">anyelement</code></td><td>
         Expands the object in <em class="replaceable"><code>from_json</code></em> to a row
         whose columns match the record type defined by <em class="replaceable"><code>base</code></em>
         (see note below).
       </td><td><code class="literal">select * from json_populate_record(null::myrowtype, '{"a": 1, "b": ["2", "a b"], "c": {"d": 4, "e": "a  b c"}}')</code></td><td>
<pre class="programlisting">
 a |   b       |      c
---+-----------+-------------
 1 | {2,"a b"} | (4,"a b c")
</pre>
       </td></tr><tr><td><p><code class="literal">json_populate_recordset(base anyelement, from_json json)</code>
         </p><p><code class="literal">jsonb_populate_recordset(base anyelement, from_json jsonb)</code>
       </p></td><td><code class="type">setof anyelement</code></td><td>
         Expands the outermost array of objects
         in <em class="replaceable"><code>from_json</code></em> to a set of rows whose
         columns match the record type defined by <em class="replaceable"><code>base</code></em> (see
         note below).
       </td><td><code class="literal">select * from json_populate_recordset(null::myrowtype, '[{"a":1,"b":2},{"a":3,"b":4}]')</code></td><td>
<pre class="programlisting">
 a | b
---+---
 1 | 2
 3 | 4
</pre>
       </td></tr><tr><td><p><code class="literal">json_array_elements(json)</code>
         </p><p><code class="literal">jsonb_array_elements(jsonb)</code>
       </p></td><td><p><code class="type">setof json</code>
         </p><p><code class="type">setof jsonb</code>
       </p></td><td>
         Expands a JSON array to a set of JSON values.
       </td><td><code class="literal">select * from json_array_elements('[1,true, [2,false]]')</code></td><td>
<pre class="programlisting">
   value
-----------
 1
 true
 [2,false]
</pre>
       </td></tr><tr><td><p><code class="literal">json_array_elements_text(json)</code>
         </p><p><code class="literal">jsonb_array_elements_text(jsonb)</code>
       </p></td><td><code class="type">setof text</code></td><td>
         Expands a JSON array to a set of <code class="type">text</code> values.
       </td><td><code class="literal">select * from json_array_elements_text('["foo", "bar"]')</code></td><td>
<pre class="programlisting">
   value
-----------
 foo
 bar
</pre>
       </td></tr><tr><td><p><code class="literal">json_typeof(json)</code>
         </p><p><code class="literal">jsonb_typeof(jsonb)</code>
       </p></td><td><code class="type">text</code></td><td>
         Returns the type of the outermost JSON value as a text string.
         Possible types are
         <code class="literal">object</code>, <code class="literal">array</code>, <code class="literal">string</code>, <code class="literal">number</code>,
         <code class="literal">boolean</code>, and <code class="literal">null</code>.
       </td><td><code class="literal">json_typeof('-123.4')</code></td><td><code class="literal">number</code></td></tr><tr><td><p><code class="literal">json_to_record(json)</code>
          </p><p><code class="literal">jsonb_to_record(jsonb)</code>
       </p></td><td><code class="type">record</code></td><td>
         Builds an arbitrary record from a JSON object (see note below).  As
         with all functions returning <code class="type">record</code>, the caller must
         explicitly define the structure of the record with an <code class="literal">AS</code>
         clause.
       </td><td><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></td><td>
<pre class="programlisting">
 a |    b    |    c    | d |       r
---+---------+---------+---+---------------
 1 | [1,2,3] | {1,2,3} |   | (123,"a b c")
</pre>
       </td></tr><tr><td><p><code class="literal">json_to_recordset(json)</code>
         </p><p><code class="literal">jsonb_to_recordset(jsonb)</code>
       </p></td><td><code class="type">setof record</code></td><td>
         Builds an arbitrary set of records from a JSON array of objects (see
         note below).  As with all functions returning <code class="type">record</code>, the
         caller must explicitly define the structure of the record with
         an <code class="literal">AS</code> clause.
       </td><td><code class="literal">select * from json_to_recordset('[{"a":1,"b":"foo"},{"a":"2","c":"bar"}]') as x(a int, b text);</code></td><td>
<pre class="programlisting">
 a |  b
---+-----
 1 | foo
 2 |
</pre>
       </td></tr><tr><td><p><code class="literal">json_strip_nulls(from_json json)</code>
         </p><p><code class="literal">jsonb_strip_nulls(from_json jsonb)</code>
       </p></td><td><p><code class="type">json</code></p><p><code class="type">jsonb</code></p></td><td>
         Returns <em class="replaceable"><code>from_json</code></em>
         with all object fields that have null values omitted. Other null values
         are untouched.
       </td><td><code class="literal">json_strip_nulls('[{"f1":1,"f2":null},2,null,3]')</code></td><td><code class="literal">[{"f1":1},2,null,3]</code></td></tr><tr><td><p><code class="literal">jsonb_set(target jsonb, path text[], new_value jsonb [<span class="optional">, create_missing boolean</span>])</code>
         </p></td><td><p><code class="type">jsonb</code></p></td><td>
         Returns <em class="replaceable"><code>target</code></em>
         with the section designated by <em class="replaceable"><code>path</code></em>
         replaced by <em class="replaceable"><code>new_value</code></em>, or with
         <em class="replaceable"><code>new_value</code></em> added if
         <em class="replaceable"><code>create_missing</code></em> is true (default is
         <code class="literal">true</code>) and the item
         designated by <em class="replaceable"><code>path</code></em> does not exist.
         As with the path oriented operators, negative integers that
         appear in <em class="replaceable"><code>path</code></em> count from the end
         of JSON arrays.
       </td><td><p><code class="literal">jsonb_set('[{"f1":1,"f2":null},2,null,3]', '{0,f1}','[2,3,4]', false)</code>
         </p><p><code class="literal">jsonb_set('[{"f1":1,"f2":null},2]', '{0,f3}','[2,3,4]')</code>
         </p></td><td><p><code class="literal">[{"f1":[2,3,4],"f2":null},2,null,3]</code>
         </p><p><code class="literal">[{"f1": 1, "f2": null, "f3": [2, 3, 4]}, 2]</code>
        </p></td></tr><tr><td>
           <p><code class="literal">
           jsonb_insert(target jsonb, path text[], new_value jsonb [<span class="optional">, insert_after boolean</span>])
           </code></p>
       </td><td><p><code class="type">jsonb</code></p></td><td>
         Returns <em class="replaceable"><code>target</code></em> with
         <em class="replaceable"><code>new_value</code></em> inserted. If
         <em class="replaceable"><code>target</code></em> section designated by
         <em class="replaceable"><code>path</code></em> is in a JSONB array,
         <em class="replaceable"><code>new_value</code></em> will be inserted before target or
         after if <em class="replaceable"><code>insert_after</code></em> is true (default is
         <code class="literal">false</code>). If <em class="replaceable"><code>target</code></em> section
         designated by <em class="replaceable"><code>path</code></em> is in JSONB object,
         <em class="replaceable"><code>new_value</code></em> will be inserted only if
         <em class="replaceable"><code>target</code></em> does not exist. As with the path
         oriented operators, negative integers that appear in
         <em class="replaceable"><code>path</code></em> count from the end of JSON arrays.
       </td><td>
           <p><code class="literal">
               jsonb_insert('{"a": [0,1,2]}', '{a, 1}', '"new_value"')
           </code></p>
           <p><code class="literal">
               jsonb_insert('{"a": [0,1,2]}', '{a, 1}', '"new_value"', true)
           </code></p>
       </td><td><p><code class="literal">{"a": [0, "new_value", 1, 2]}</code>
         </p><p><code class="literal">{"a": [0, 1, "new_value", 2]}</code>
        </p></td></tr><tr><td><p><code class="literal">jsonb_pretty(from_json jsonb)</code>
         </p></td><td><p><code class="type">text</code></p></td><td>
         Returns <em class="replaceable"><code>from_json</code></em>
         as indented JSON text.
       </td><td><code class="literal">jsonb_pretty('[{"f1":1,"f2":null},2,null,3]')</code></td><td>
<pre class="programlisting">
[
    {
        "f1": 1,
        "f2": null
    },
    2,
    null,
    3
]
</pre>
        </td></tr><tr><td>
         <p><code class="literal">
           jsonb_path_exists(target jsonb, path jsonpath [<span class="optional">, vars jsonb [<span class="optional">, silent bool</span>]</span>])
         </code></p>
        </td><td><code class="type">boolean</code></td><td>
          Checks whether JSON path returns any item for the specified JSON
          value.
        </td><td>
         <p><code class="literal">
           jsonb_path_exists('{"a":[1,2,3,4,5]}', '$.a[*] ? (@ >= $min && @ <= $max)', '{"min":2,"max":4}')
         </code></p>
        </td><td>
          <p><code class="literal">true</code></p>
        </td></tr><tr><td>
         <p><code class="literal">
           jsonb_path_match(target jsonb, path jsonpath [<span class="optional">, vars jsonb [<span class="optional">, silent bool</span>]</span>])
         </code></p>
        </td><td><code class="type">boolean</code></td><td>
          Returns the result of JSON path predicate check for the specified JSON value.
          Only the first item of the result is taken into account.  If the
          result is not Boolean, then <code class="literal">null</code> is returned.
        </td><td>
         <p><code class="literal">
           jsonb_path_match('{"a":[1,2,3,4,5]}', 'exists($.a[*] ? (@ >= $min && @ <= $max))', '{"min":2,"max":4}')
        </code></p>
        </td><td>
          <p><code class="literal">true</code></p>
        </td></tr><tr><td>
         <p><code class="literal">
           jsonb_path_query(target jsonb, path jsonpath [<span class="optional">, vars jsonb [<span class="optional">, silent bool</span>]</span>])
         </code></p>
        </td><td><code class="type">setof jsonb</code></td><td>
          Gets all JSON items returned by JSON path for the specified JSON
          value.
        </td><td>
         <p><code class="literal">
           select * from jsonb_path_query('{"a":[1,2,3,4,5]}', '$.a[*] ? (@ >= $min && @ <= $max)', '{"min":2,"max":4}');
         </code></p>
        </td><td>
         <p>
</p><pre class="programlisting">
 jsonb_path_query
------------------
 2
 3
 4
</pre><p>
         </p>
        </td></tr><tr><td>
         <p><code class="literal">
           jsonb_path_query_array(target jsonb, path jsonpath [<span class="optional">, vars jsonb [<span class="optional">, silent bool</span>]</span>])
         </code></p>
        </td><td><code class="type">jsonb</code></td><td>
          Gets all JSON items returned by JSON path for the specified JSON
          value and wraps result into an array.
        </td><td>
         <p><code class="literal">
           jsonb_path_query_array('{"a":[1,2,3,4,5]}', '$.a[*] ? (@ >= $min && @ <= $max)', '{"min":2,"max":4}')
         </code></p>
        </td><td>
          <p><code class="literal">[2, 3, 4]</code></p>
        </td></tr><tr><td>
         <p><code class="literal">
           jsonb_path_query_first(target jsonb, path jsonpath [<span class="optional">, vars jsonb [<span class="optional">, silent bool</span>]</span>])
         </code></p>
        </td><td><code class="type">jsonb</code></td><td>
          Gets the first JSON item returned by JSON path for the specified JSON
          value.  Returns <code class="literal">NULL</code> on no results.
        </td><td>
         <p><code class="literal">
           jsonb_path_query_first('{"a":[1,2,3,4,5]}', '$.a[*] ? (@ >= $min && @ <= $max)', '{"min":2,"max":4}')
         </code></p>
        </td><td>
          <p><code class="literal">2</code></p>
        </td></tr></tbody></table></div></div><br class="table-break" /><div class="note"><h3 class="title">Note</h3><p>
      Many of these functions and operators will convert Unicode escapes in
      JSON strings to the appropriate single character.  This is a non-issue
      if the input is type <code class="type">jsonb</code>, because the conversion was already
      done; but for <code class="type">json</code> input, this may result in throwing an error,
      as noted in <a class="xref" href="datatype-json.html" title="8.14. JSON Types">Section 8.14</a>.
    </p></div><div class="note"><h3 class="title">Note</h3><p>
    The functions
    <code class="function">json[b]_populate_record</code>,
    <code class="function">json[b]_populate_recordset</code>,
    <code class="function">json[b]_to_record</code> and
    <code class="function">json[b]_to_recordset</code>
    operate on a JSON object, or array of objects, and extract the values
    associated with keys whose names match column names of the output row
    type.
    Object fields that do not correspond to any output column name are
    ignored, and output columns that do not match any object field will be
    filled with nulls.
    To convert a JSON value to the SQL type of an output column, the
    following rules are applied in sequence:
    </p><div class="itemizedlist"><ul class="itemizedlist compact" style="list-style-type: disc; "><li class="listitem"><p>
       A JSON null value is converted to a SQL null in all cases.
      </p></li><li class="listitem"><p>
       If the output column is of type <code class="type">json</code>
       or <code class="type">jsonb</code>, the JSON value is just reproduced exactly.
      </p></li><li class="listitem"><p>
       If the output column is a composite (row) type, and the JSON value is
       a JSON object, the fields of the object are converted to columns of
       the output row type by recursive application of these rules.
      </p></li><li class="listitem"><p>
       Likewise, if the output column is an array type and the JSON value is
       a JSON array, the elements of the JSON array are converted to elements
       of the output array by recursive application of these rules.
      </p></li><li class="listitem"><p>
       Otherwise, if the JSON value is a string literal, the contents of the
       string are fed to the input conversion function for the column's data
       type.
      </p></li><li class="listitem"><p>
       Otherwise, the ordinary text representation of the JSON value is fed
       to the input conversion function for the column's data type.
      </p></li></ul></div><p>
   </p><p>
    While the examples for these functions use constants, the typical use
    would be to reference a table in the <code class="literal">FROM</code> clause
    and use one of its <code class="type">json</code> or <code class="type">jsonb</code> columns
    as an argument to the function.  Extracted key values can then be
    referenced in other parts of the query, like <code class="literal">WHERE</code>
    clauses and target lists.  Extracting multiple values in this
    way can improve performance over extracting them separately with
    per-key operators.
   </p></div><div class="note"><h3 class="title">Note</h3><p>
      All the items of the <code class="literal">path</code> parameter of <code class="literal">jsonb_set</code>
      as well as <code class="literal">jsonb_insert</code> except the last item must be present
      in the <code class="literal">target</code>. If <code class="literal">create_missing</code> is false, all
      items of the <code class="literal">path</code> parameter of <code class="literal">jsonb_set</code> must be
      present. If these conditions are not met the <code class="literal">target</code> is
      returned unchanged.
    </p><p>
      If the last path item is an object key, it will be created if it
      is absent and given the new value. If the last path item is an array
      index, if it is positive the item to set is found by counting from
      the left, and if negative by counting from the right - <code class="literal">-1</code>
      designates the rightmost element, and so on.
      If the item is out of the range -array_length .. array_length -1,
      and create_missing is true, the new value is added at the beginning
      of the array if the item is negative, and at the end of the array if
      it is positive.
    </p></div><div class="note"><h3 class="title">Note</h3><p>
      The <code class="literal">json_typeof</code> function's <code class="literal">null</code> return value
      should not be confused with a SQL NULL.  While
      calling <code class="literal">json_typeof('null'::json)</code> will
      return <code class="literal">null</code>, calling <code class="literal">json_typeof(NULL::json)</code>
      will return a SQL NULL.
    </p></div><div class="note"><h3 class="title">Note</h3><p>
      If the argument to <code class="literal">json_strip_nulls</code> contains duplicate
      field names in any object, the result could be semantically somewhat
      different, depending on the order in which they occur. This is not an
      issue for <code class="literal">jsonb_strip_nulls</code> since <code class="type">jsonb</code> values never have
      duplicate object field names.
    </p></div><div class="note"><h3 class="title">Note</h3><p>
    The <code class="literal">jsonb_path_exists</code>, <code class="literal">jsonb_path_match</code>,
    <code class="literal">jsonb_path_query</code>, <code class="literal">jsonb_path_query_array</code>, and
    <code class="literal">jsonb_path_query_first</code>
    functions have optional <code class="literal">vars</code> and <code class="literal">silent</code>
    arguments.
   </p><p>
    If the <em class="parameter"><code>vars</code></em> argument is specified, it provides an
    object containing named variables to be substituted into a
    <code class="literal">jsonpath</code> expression.
   </p><p>
    If the <em class="parameter"><code>silent</code></em> argument is specified and has the
    <code class="literal">true</code> value, these functions suppress the same errors
    as the <code class="literal">@?</code> and <code class="literal">@@</code> operators.
   </p></div><p>
    See also <a class="xref" href="functions-aggregate.html" title="9.20. Aggregate Functions">Section 9.20</a> for the aggregate
    function <code class="function">json_agg</code> which aggregates record
    values as JSON, and the aggregate function
    <code class="function">json_object_agg</code> which aggregates pairs of values
    into a JSON object, and their <code class="type">jsonb</code> equivalents,
    <code class="function">jsonb_agg</code> and <code class="function">jsonb_object_agg</code>.
  </p></div><div class="sect2" id="FUNCTIONS-SQLJSON-PATH"><div class="titlepage"><div><div><h3 class="title">9.15.2. The SQL/JSON Path Language</h3></div></div></div><a id="id-1.5.8.20.6.2" class="indexterm"></a><p>
   SQL/JSON path expressions specify the items to be retrieved
   from the JSON data, similar to XPath expressions used
   for SQL access to XML. In <span class="productname">PostgreSQL</span>,
   path expressions are implemented as the <code class="type">jsonpath</code>
   data type and can use any elements described in
   <a class="xref" href="datatype-json.html#DATATYPE-JSONPATH" title="8.14.6. jsonpath Type">Section 8.14.6</a>.
  </p><p>JSON query functions and operators
   pass the provided path expression to the <em class="firstterm">path engine</em>
   for evaluation. If the expression matches the queried JSON data,
   the corresponding SQL/JSON item is returned.
   Path expressions are written in the SQL/JSON path language
   and can also include arithmetic expressions and functions.
   Query functions treat the provided expression as a
   text string, so it must be enclosed in single quotes.
  </p><p>
   A path expression consists of a sequence of elements allowed
   by the <code class="type">jsonpath</code> data type.
   The path expression is evaluated from left to right, but
   you can use parentheses to change the order of operations.
   If the evaluation is successful, a sequence of SQL/JSON items
   (<em class="firstterm">SQL/JSON sequence</em>) is produced,
   and the evaluation result is returned to the JSON query function
   that completes the specified computation.
  </p><p>
   To refer to the JSON data to be queried (the
   <em class="firstterm">context item</em>), use the <code class="literal">$</code> sign
   in the path expression. It can be followed by one or more
   <a class="link" href="datatype-json.html#TYPE-JSONPATH-ACCESSORS" title="Table 8.25. jsonpath Accessors">accessor operators</a>,
   which go down the JSON structure level by level to retrieve the
   content of context item. Each operator that follows deals with the
   result of the previous evaluation step.
  </p><p>
   For example, suppose you have some JSON data from a GPS tracker that you
   would like to parse, such as:
</p><pre class="programlisting">
{
  "track": {
    "segments": [
      {
        "location":   [ 47.763, 13.4034 ],
        "start time": "2018-10-14 10:05:14",
        "HR": 73
      },
      {
        "location":   [ 47.706, 13.2635 ],
        "start time": "2018-10-14 10:39:21",
        "HR": 135
      }
    ]
  }
}
</pre><p>
  </p><p>
   To retrieve the available track segments, you need to use the
   <code class="literal">.<em class="replaceable"><code>key</code></em></code> accessor
   operator for all the preceding JSON objects:
</p><pre class="programlisting">
'$.track.segments'
</pre><p>
  </p><p>
   If the item to retrieve is an element of an array, you have
   to unnest this array using the <code class="literal">[*]</code> operator. For example,
   the following path will return location coordinates for all
   the available track segments:
</p><pre class="programlisting">
'$.track.segments[*].location'
</pre><p>
  </p><p>
   To return the coordinates of the first segment only, you can
   specify the corresponding subscript in the <code class="literal">[]</code>
   accessor operator. Note that the SQL/JSON arrays are 0-relative:
</p><pre class="programlisting">
'$.track.segments[0].location'
</pre><p>
  </p><p>
   The result of each path evaluation step can be processed
   by one or more <code class="type">jsonpath</code> operators and methods
   listed in <a class="xref" href="functions-json.html#FUNCTIONS-SQLJSON-PATH-OPERATORS" title="9.15.2.3. SQL/JSON Path Operators and Methods">Section 9.15.2.3</a>.
   Each method name must be preceded by a dot. For example,
   you can get an array size:
</p><pre class="programlisting">
'$.track.segments.size()'
</pre><p>
   For more examples of using <code class="type">jsonpath</code> operators
   and methods within path expressions, see
   <a class="xref" href="functions-json.html#FUNCTIONS-SQLJSON-PATH-OPERATORS" title="9.15.2.3. SQL/JSON Path Operators and Methods">Section 9.15.2.3</a>.
  </p><p>
   When defining the path, you can also use one or more
   <em class="firstterm">filter expressions</em> that work similar to the
   <code class="literal">WHERE</code> clause in SQL. A filter expression begins with
   a question mark and provides a condition in parentheses:
</p><pre class="programlisting">
? (<em class="replaceable"><code>condition</code></em>)
</pre><p>
  </p><p>
   Filter expressions must be specified right after the path evaluation step
   to which they are applied. The result of this step is filtered to include
   only those items that satisfy the provided condition. SQL/JSON defines
   three-valued logic, so the condition can be <code class="literal">true</code>, <code class="literal">false</code>,
   or <code class="literal">unknown</code>. The <code class="literal">unknown</code> value
   plays the same role as SQL <code class="literal">NULL</code> and can be tested
   for with the <code class="literal">is unknown</code> predicate. Further path
   evaluation steps use only those items for which filter expressions
   return <code class="literal">true</code>.
  </p><p>
   Functions and operators that can be used in filter expressions are listed
   in <a class="xref" href="functions-json.html#FUNCTIONS-SQLJSON-FILTER-EX-TABLE" title="Table 9.49. jsonpath Filter Expression Elements">Table 9.49</a>. The path
   evaluation result to be filtered is denoted by the <code class="literal">@</code>
   variable. To refer to a JSON element stored at a lower nesting level,
   add one or more accessor operators after <code class="literal">@</code>.
  </p><p>
   Suppose you would like to retrieve all heart rate values higher
   than 130. You can achieve this using the following expression:
</p><pre class="programlisting">
'$.track.segments[*].HR ? (@ > 130)'
</pre><p>
  </p><p>
   To get the start time of segments with such values instead, you have to
   filter out irrelevant segments before returning the start time, so the
   filter expression is applied to the previous step, and the path used
   in the condition is different:
</p><pre class="programlisting">
'$.track.segments[*] ? (@.HR > 130)."start time"'
</pre><p>
  </p><p>
   You can use several filter expressions on the same nesting level, if
   required. For example, the following expression selects all segments
   that contain locations with relevant coordinates and high heart rate values:
</p><pre class="programlisting">
'$.track.segments[*] ? (@.location[1] < 13.4) ? (@.HR > 130)."start time"'
</pre><p>
  </p><p>
   Using filter expressions at different nesting levels is also allowed.
   The following example first filters all segments by location, and then
   returns high heart rate values for these segments, if available:
</p><pre class="programlisting">
'$.track.segments[*] ? (@.location[1] < 13.4).HR ? (@ > 130)'
</pre><p>
  </p><p>
   You can also nest filter expressions within each other:
</p><pre class="programlisting">
'$.track ? (exists(@.segments[*] ? (@.HR > 130))).segments.size()'
</pre><p>
   This expression returns the size of the track if it contains any
   segments with high heart rate values, or an empty sequence otherwise.
  </p><p>
   <span class="productname">PostgreSQL</span>'s implementation of SQL/JSON path
   language has the following deviations from the SQL/JSON standard:
  </p><div class="itemizedlist"><ul class="itemizedlist" style="list-style-type: disc; "><li class="listitem"><p>
     <code class="literal">.datetime()</code> item method is not implemented yet
     mainly because immutable <code class="type">jsonpath</code> functions and operators
     cannot reference session timezone, which is used in some datetime
     operations.  Datetime support will be added to <code class="type">jsonpath</code>
     in future versions of <span class="productname">PostgreSQL</span>.
    </p></li><li class="listitem"><p>
     A path expression can be a Boolean predicate, although the SQL/JSON
     standard allows predicates only in filters.  This is necessary for
     implementation of the <code class="literal">@@</code> operator. For example,
     the following <code class="type">jsonpath</code> expression is valid in
     <span class="productname">PostgreSQL</span>:
</p><pre class="programlisting">
'$.track.segments[*].HR < 70'
</pre><p>
    </p></li><li class="listitem"><p>
     There are minor differences in the interpretation of regular
     expression patterns used in <code class="literal">like_regex</code> filters, as
     described in <a class="xref" href="functions-json.html#JSONPATH-REGULAR-EXPRESSIONS" title="9.15.2.2. Regular Expressions">Section 9.15.2.2</a>.
    </p></li></ul></div><div class="sect3" id="STRICT-AND-LAX-MODES"><div class="titlepage"><div><div><h4 class="title">9.15.2.1. Strict and Lax Modes</h4></div></div></div><p>
     When you query JSON data, the path expression may not match the
     actual JSON data structure. An attempt to access a non-existent
     member of an object or element of an array results in a
     structural error. SQL/JSON path expressions have two modes
     of handling structural errors:
    </p><div class="itemizedlist"><ul class="itemizedlist" style="list-style-type: disc; "><li class="listitem"><p>
      lax (default) — the path engine implicitly adapts
      the queried data to the specified path.
      Any remaining structural errors are suppressed and converted
      to empty SQL/JSON sequences.
     </p></li><li class="listitem"><p>
      strict — if a structural error occurs, an error is raised.
     </p></li></ul></div><p>
    The lax mode facilitates matching of a JSON document structure and path
    expression if the JSON data does not conform to the expected schema.
    If an operand does not match the requirements of a particular operation,
    it can be automatically wrapped as an SQL/JSON array or unwrapped by
    converting its elements into an SQL/JSON sequence before performing
    this operation. Besides, comparison operators automatically unwrap their
    operands in the lax mode, so you can compare SQL/JSON arrays
    out-of-the-box. An array of size 1 is considered equal to its sole element.
    Automatic unwrapping is not performed only when:
    </p><div class="itemizedlist"><ul class="itemizedlist" style="list-style-type: disc; "><li class="listitem"><p>
       The path expression contains <code class="literal">type()</code> or
       <code class="literal">size()</code> methods that return the type
       and the number of elements in the array, respectively.
      </p></li><li class="listitem"><p>
       The queried JSON data contain nested arrays. In this case, only
       the outermost array is unwrapped, while all the inner arrays
       remain unchanged. Thus, implicit unwrapping can only go one
       level down within each path evaluation step.
      </p></li></ul></div><p>
   </p><p>
    For example, when querying the GPS data listed above, you can
    abstract from the fact that it stores an array of segments
    when using the lax mode:
</p><pre class="programlisting">
'lax $.track.segments.location'
</pre><p>
   </p><p>
    In the strict mode, the specified path must exactly match the structure of
    the queried JSON document to return an SQL/JSON item, so using this
    path expression will cause an error. To get the same result as in
    the lax mode, you have to explicitly unwrap the
    <code class="literal">segments</code> array:
</p><pre class="programlisting">
'strict $.track.segments[*].location'
</pre><p>
   </p></div><div class="sect3" id="JSONPATH-REGULAR-EXPRESSIONS"><div class="titlepage"><div><div><h4 class="title">9.15.2.2. Regular Expressions</h4></div></div></div><a id="id-1.5.8.20.6.23.2" class="indexterm"></a><p>
     SQL/JSON path expressions allow matching text to a regular expression
     with the <code class="literal">like_regex</code> filter.  For example, the
     following SQL/JSON path query would case-insensitively match all
     strings in an array that start with an English vowel:
</p><pre class="programlisting">
'$[*] ? (@ like_regex "^[aeiou]" flag "i")'
</pre><p>
    </p><p>
     The optional <code class="literal">flag</code> string may include one or more of
     the characters
     <code class="literal">i</code> for case-insensitive match,
     <code class="literal">m</code> to allow <code class="literal">^</code>
     and <code class="literal">$</code> to match at newlines,
     <code class="literal">s</code> to allow <code class="literal">.</code> to match a newline,
     and <code class="literal">q</code> to quote the whole pattern (reducing the
     behavior to a simple substring match).
    </p><p>
     The SQL/JSON standard borrows its definition for regular expressions
     from the <code class="literal">LIKE_REGEX</code> operator, which in turn uses the
     XQuery standard.  PostgreSQL does not currently support the
     <code class="literal">LIKE_REGEX</code> operator.  Therefore,
     the <code class="literal">like_regex</code> filter is implemented using the
     POSIX regular expression engine described in
     <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
     discrepancies from standard SQL/JSON behavior, which are cataloged in
     <a class="xref" href="functions-matching.html#POSIX-VS-XQUERY" title="9.7.3.8. Differences From XQuery (LIKE_REGEX)">Section 9.7.3.8</a>.
     Note, however, that the flag-letter incompatibilities described there
     do not apply to SQL/JSON, as it translates the XQuery flag letters to
     match what the POSIX engine expects.
    </p><p>
     Keep in mind that the pattern argument of <code class="literal">like_regex</code>
     is a JSON path string literal, written according to the rules given in
     <a class="xref" href="datatype-json.html#DATATYPE-JSONPATH" title="8.14.6. jsonpath Type">Section 8.14.6</a>.  This means in particular that any
     backslashes you want to use in the regular expression must be doubled.
     For example, to match strings that contain only digits:
</p><pre class="programlisting">
'$ ? (@ like_regex "^\\d+$")'
</pre><p>
    </p></div><div class="sect3" id="FUNCTIONS-SQLJSON-PATH-OPERATORS"><div class="titlepage"><div><div><h4 class="title">9.15.2.3. SQL/JSON Path Operators and Methods</h4></div></div></div><p>
    <a class="xref" href="functions-json.html#FUNCTIONS-SQLJSON-OP-TABLE" title="Table 9.48. jsonpath Operators and Methods">Table 9.48</a> shows the operators and
    methods available in <code class="type">jsonpath</code>.  <a class="xref" href="functions-json.html#FUNCTIONS-SQLJSON-FILTER-EX-TABLE" title="Table 9.49. jsonpath Filter Expression Elements">Table 9.49</a> shows the available filter
    expression elements.
   </p><div class="table" id="FUNCTIONS-SQLJSON-OP-TABLE"><p class="title"><strong>Table 9.48. <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 /><col /><col /><col /><col /></colgroup><thead><tr><th>Operator/Method</th><th>Description</th><th>Example JSON</th><th>Example Query</th><th>Result</th></tr></thead><tbody><tr><td><code class="literal">+</code> (unary)</td><td>Plus operator that iterates over the SQL/JSON sequence</td><td><code class="literal">{"x": [2.85, -14.7, -9.4]}</code></td><td><code class="literal">+ $.x.floor()</code></td><td><code class="literal">2, -15, -10</code></td></tr><tr><td><code class="literal">-</code> (unary)</td><td>Minus operator that iterates over the SQL/JSON sequence</td><td><code class="literal">{"x": [2.85, -14.7, -9.4]}</code></td><td><code class="literal">- $.x.floor()</code></td><td><code class="literal">-2, 15, 10</code></td></tr><tr><td><code class="literal">+</code> (binary)</td><td>Addition</td><td><code class="literal">[2]</code></td><td><code class="literal">2 + $[0]</code></td><td><code class="literal">4</code></td></tr><tr><td><code class="literal">-</code> (binary)</td><td>Subtraction</td><td><code class="literal">[2]</code></td><td><code class="literal">4 - $[0]</code></td><td><code class="literal">2</code></td></tr><tr><td><code class="literal">*</code></td><td>Multiplication</td><td><code class="literal">[4]</code></td><td><code class="literal">2 * $[0]</code></td><td><code class="literal">8</code></td></tr><tr><td><code class="literal">/</code></td><td>Division</td><td><code class="literal">[8]</code></td><td><code class="literal">$[0] / 2</code></td><td><code class="literal">4</code></td></tr><tr><td><code class="literal">%</code></td><td>Modulus</td><td><code class="literal">[32]</code></td><td><code class="literal">$[0] % 10</code></td><td><code class="literal">2</code></td></tr><tr><td><code class="literal">type()</code></td><td>Type of the SQL/JSON item</td><td><code class="literal">[1, "2", {}]</code></td><td><code class="literal">$[*].type()</code></td><td><code class="literal">"number", "string", "object"</code></td></tr><tr><td><code class="literal">size()</code></td><td>Size of the SQL/JSON item</td><td><code class="literal">{"m": [11, 15]}</code></td><td><code class="literal">$.m.size()</code></td><td><code class="literal">2</code></td></tr><tr><td><code class="literal">double()</code></td><td>Approximate floating-point number converted from an SQL/JSON number or a string</td><td><code class="literal">{"len": "1.9"}</code></td><td><code class="literal">$.len.double() * 2</code></td><td><code class="literal">3.8</code></td></tr><tr><td><code class="literal">ceiling()</code></td><td>Nearest integer greater than or equal to the SQL/JSON number</td><td><code class="literal">{"h": 1.3}</code></td><td><code class="literal">$.h.ceiling()</code></td><td><code class="literal">2</code></td></tr><tr><td><code class="literal">floor()</code></td><td>Nearest integer less than or equal to the SQL/JSON number</td><td><code class="literal">{"h": 1.3}</code></td><td><code class="literal">$.h.floor()</code></td><td><code class="literal">1</code></td></tr><tr><td><code class="literal">abs()</code></td><td>Absolute value of the SQL/JSON number</td><td><code class="literal">{"z": -0.3}</code></td><td><code class="literal">$.z.abs()</code></td><td><code class="literal">0.3</code></td></tr><tr><td><code class="literal">keyvalue()</code></td><td>
          Sequence of object's key-value pairs represented as array of items
          containing three fields (<code class="literal">"key"</code>,
          <code class="literal">"value"</code>, and <code class="literal">"id"</code>).
          <code class="literal">"id"</code> is a unique identifier of the object
          key-value pair belongs to.
        </td><td><code class="literal">{"x": "20", "y": 32}</code></td><td><code class="literal">$.keyvalue()</code></td><td><code class="literal">{"key": "x", "value": "20", "id": 0}, {"key": "y", "value": 32, "id": 0}</code></td></tr></tbody></table></div></div><br class="table-break" /><div class="table" id="FUNCTIONS-SQLJSON-FILTER-EX-TABLE"><p class="title"><strong>Table 9.49. <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 /><col /><col /><col /><col /></colgroup><thead><tr><th>Value/Predicate</th><th>Description</th><th>Example JSON</th><th>Example Query</th><th>Result</th></tr></thead><tbody><tr><td><code class="literal">==</code></td><td>Equality operator</td><td><code class="literal">[1, 2, 1, 3]</code></td><td><code class="literal">$[*] ? (@ == 1)</code></td><td><code class="literal">1, 1</code></td></tr><tr><td><code class="literal">!=</code></td><td>Non-equality operator</td><td><code class="literal">[1, 2, 1, 3]</code></td><td><code class="literal">$[*] ? (@ != 1)</code></td><td><code class="literal">2, 3</code></td></tr><tr><td><code class="literal"><></code></td><td>Non-equality operator (same as <code class="literal">!=</code>)</td><td><code class="literal">[1, 2, 1, 3]</code></td><td><code class="literal">$[*] ? (@ <> 1)</code></td><td><code class="literal">2, 3</code></td></tr><tr><td><code class="literal"><</code></td><td>Less-than operator</td><td><code class="literal">[1, 2, 3]</code></td><td><code class="literal">$[*] ? (@ < 2)</code></td><td><code class="literal">1</code></td></tr><tr><td><code class="literal"><=</code></td><td>Less-than-or-equal-to operator</td><td><code class="literal">[1, 2, 3]</code></td><td><code class="literal">$[*] ? (@ <= 2)</code></td><td><code class="literal">1, 2</code></td></tr><tr><td><code class="literal">></code></td><td>Greater-than operator</td><td><code class="literal">[1, 2, 3]</code></td><td><code class="literal">$[*] ? (@ > 2)</code></td><td><code class="literal">3</code></td></tr><tr><td><code class="literal">>=</code></td><td>Greater-than-or-equal-to operator</td><td><code class="literal">[1, 2, 3]</code></td><td><code class="literal">$[*] ? (@ >= 2)</code></td><td><code class="literal">2, 3</code></td></tr><tr><td><code class="literal">true</code></td><td>Value used to perform comparison with JSON <code class="literal">true</code> literal</td><td><code class="literal">[{"name": "John", "parent": false},
                           {"name": "Chris", "parent": true}]</code></td><td><code class="literal">$[*] ? (@.parent == true)</code></td><td><code class="literal">{"name": "Chris", "parent": true}</code></td></tr><tr><td><code class="literal">false</code></td><td>Value used to perform comparison with JSON <code class="literal">false</code> literal</td><td><code class="literal">[{"name": "John", "parent": false},
                           {"name": "Chris", "parent": true}]</code></td><td><code class="literal">$[*] ? (@.parent == false)</code></td><td><code class="literal">{"name": "John", "parent": false}</code></td></tr><tr><td><code class="literal">null</code></td><td>Value used to perform comparison with JSON <code class="literal">null</code> value</td><td><code class="literal">[{"name": "Mary", "job": null},
                         {"name": "Michael", "job": "driver"}]</code></td><td><code class="literal">$[*] ? (@.job == null) .name</code></td><td><code class="literal">"Mary"</code></td></tr><tr><td><code class="literal">&&</code></td><td>Boolean AND</td><td><code class="literal">[1, 3, 7]</code></td><td><code class="literal">$[*] ? (@ > 1 && @ < 5)</code></td><td><code class="literal">3</code></td></tr><tr><td><code class="literal">||</code></td><td>Boolean OR</td><td><code class="literal">[1, 3, 7]</code></td><td><code class="literal">$[*] ? (@ < 1 || @ > 5)</code></td><td><code class="literal">7</code></td></tr><tr><td><code class="literal">!</code></td><td>Boolean NOT</td><td><code class="literal">[1, 3, 7]</code></td><td><code class="literal">$[*] ? (!(@ < 5))</code></td><td><code class="literal">7</code></td></tr><tr><td><code class="literal">like_regex</code></td><td>
          Tests whether the first operand matches the regular expression
          given by the second operand, optionally with modifications
          described by a string of <code class="literal">flag</code> characters (see
          <a class="xref" href="functions-json.html#JSONPATH-REGULAR-EXPRESSIONS" title="9.15.2.2. Regular Expressions">Section 9.15.2.2</a>)
        </td><td><code class="literal">["abc", "abd", "aBdC", "abdacb", "babc"]</code></td><td><code class="literal">$[*] ? (@ like_regex "^ab.*c" flag "i")</code></td><td><code class="literal">"abc", "aBdC", "abdacb"</code></td></tr><tr><td><code class="literal">starts with</code></td><td>Tests whether the second operand is an initial substring of the first operand</td><td><code class="literal">["John Smith", "Mary Stone", "Bob Johnson"]</code></td><td><code class="literal">$[*] ? (@ starts with "John")</code></td><td><code class="literal">"John Smith"</code></td></tr><tr><td><code class="literal">exists</code></td><td>Tests whether a path expression matches at least one SQL/JSON item</td><td><code class="literal">{"x": [1, 2], "y": [2, 4]}</code></td><td><code class="literal">strict $.* ? (exists (@ ? (@[*] > 2)))</code></td><td><code class="literal">2, 4</code></td></tr><tr><td><code class="literal">is unknown</code></td><td>Tests whether a Boolean condition is <code class="literal">unknown</code></td><td><code class="literal">[-1, 2, 7, "infinity"]</code></td><td><code class="literal">$[*] ? ((@ > 0) is unknown)</code></td><td><code class="literal">"infinity"</code></td></tr></tbody></table></div></div><br class="table-break" /></div></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">Prev</a> </td><td width="20%" align="center"><a accesskey="u" href="functions.html">Up</a></td><td width="40%" align="right"> <a accesskey="n" href="functions-sequence.html">Next</a></td></tr><tr><td width="40%" align="left" valign="top">9.14. XML Functions </td><td width="20%" align="center"><a accesskey="h" href="index.html">Home</a></td><td width="40%" align="right" valign="top"> 9.16. Sequence Manipulation Functions</td></tr></table></div></body></html>
 |