]> granicus.if.org Git - postgresql/commitdiff
doc: Reorder JSON functions documentation
authorPeter Eisentraut <peter@eisentraut.org>
Thu, 26 Sep 2019 07:44:22 +0000 (09:44 +0200)
committerPeter Eisentraut <peter@eisentraut.org>
Thu, 26 Sep 2019 07:44:22 +0000 (09:44 +0200)
Put the description of the SQL/JSON path language after the
description of the general JSON functions and operators, instead of
before.

Discussion: https://www.postgresql.org/message-id/16968.1569189812@sss.pgh.pa.us

doc/src/sgml/func.sgml

index 67f1a828a89b6c4cfca3a0ebaa680dbb33cb39ff..cc3041f63731b540a76ef3c411a4c52b88fb9693 100644 (file)
@@ -11690,1144 +11690,463 @@ table2-mapping
  </sect1>
 
  <sect1 id="functions-json">
-  <title>JSON Functions, Operators, and Expressions</title>
-
-  <para>
-   The functions, operators, and expressions described in this section
-   operate on JSON data:
-  </para>
-
-  <itemizedlist>
-   <listitem>
-    <para>
-     SQL/JSON path expressions
-     (see <xref linkend="functions-sqljson-path"/>).
-    </para>
-   </listitem>
-   <listitem>
-    <para>
-     PostgreSQL-specific functions and operators for JSON
-     data types (see <xref linkend="functions-pgjson"/>).
-    </para>
-   </listitem>
-  </itemizedlist>
-
-  <para>
-    To learn more about the SQL/JSON standard, see
-    <xref linkend="sqltr-19075-6"/>. For details on JSON types
-    supported in <productname>PostgreSQL</productname>,
-    see <xref linkend="datatype-json"/>.
-  </para>
+  <title>JSON Functions and Operators</title>
 
- <sect2 id="functions-sqljson-path">
-  <title>SQL/JSON Path Expressions</title>
   <indexterm zone="functions-json">
-    <primary>SQL/JSON</primary>
-    <secondary>path expressions</secondary>
+   <primary>JSON</primary>
+   <secondary>functions and operators</secondary>
   </indexterm>
 
   <para>
-   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 <productname>PostgreSQL</productname>,
-   path expressions are implemented as the <type>jsonpath</type>
-   data type and can use any elements described in
-   <xref linkend="datatype-jsonpath"/>.
-  </para>
-
-  <para>JSON query functions and operators
-   pass the provided path expression to the <firstterm>path engine</firstterm>
-   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.
-  </para>
-
-  <para>
-   A path expression consists of a sequence of elements allowed
-   by the <type>jsonpath</type> 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
-   (<firstterm>SQL/JSON sequence</firstterm>) is produced,
-   and the evaluation result is returned to the JSON query function
-   that completes the specified computation.
-  </para>
-
-  <para>
-   To refer to the JSON data to be queried (the
-   <firstterm>context item</firstterm>), use the <literal>$</literal> sign
-   in the path expression. It can be followed by one or more
-   <link linkend="type-jsonpath-accessors">accessor operators</link>,
-   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.
-  </para>
-
-  <para>
-   For example, suppose you have some JSON data from a GPS tracker that you
-   would like to parse, such as:
-<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
-      } ]
-  }
-}
-</programlisting>
-  </para>
-
-  <para>
-   To retrieve the available track segments, you need to use the
-   <literal>.<replaceable>key</replaceable></literal> accessor
-   operator for all the preceding JSON objects:
-<programlisting>
-'$.track.segments'
-</programlisting>
-  </para>
+   This section describes:
 
-  <para>
-   If the item to retrieve is an element of an array, you have
-   to unnest this array using the <literal>[*]</literal> operator. For example,
-   the following path will return location coordinates for all
-   the available track segments:
-<programlisting>
-'$.track.segments[*].location'
-</programlisting>
+   <itemizedlist>
+    <listitem>
+     <para>
+      functions and operators for processing and creating JSON data
+     </para>
+    </listitem>
+    <listitem>
+     <para>
+      the SQL/JSON path language
+     </para>
+    </listitem>
+   </itemizedlist>
   </para>
 
   <para>
-   To return the coordinates of the first segment only, you can
-   specify the corresponding subscript in the <literal>[]</literal>
-   accessor operator. Note that the SQL/JSON arrays are 0-relative:
-<programlisting>
-'$.track.segments[0].location'
-</programlisting>
+   To learn more about the SQL/JSON standard, see
+   <xref linkend="sqltr-19075-6"/>. For details on JSON types
+   supported in <productname>PostgreSQL</productname>,
+   see <xref linkend="datatype-json"/>.
   </para>
 
-  <para>
-   The result of each path evaluation step can be processed
-   by one or more <type>jsonpath</type> operators and methods
-   listed in <xref linkend="functions-sqljson-path-operators"/>.
-   Each method name must be preceded by a dot. For example,
-   you can get an array size:
-<programlisting>
-'$.track.segments.size()'
-</programlisting>
-   For more examples of using <type>jsonpath</type> operators
-   and methods within path expressions, see
-   <xref linkend="functions-sqljson-path-operators"/>.
-  </para>
+  <sect2 id="functions-json-processing">
+   <title>Processing and Creating JSON Data</title>
 
   <para>
-   When defining the path, you can also use one or more
-   <firstterm>filter expressions</firstterm> that work similar to the
-   <literal>WHERE</literal> clause in SQL. A filter expression begins with
-   a question mark and provides a condition in parentheses:
-
-    <programlisting>
-? (<replaceable>condition</replaceable>)
-    </programlisting>
+   <xref linkend="functions-json-op-table"/> shows the operators that
+   are available for use with JSON data types (see <xref
+   linkend="datatype-json"/>).
   </para>
 
-  <para>
-   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 <literal>true</literal>, <literal>false</literal>,
-   or <literal>unknown</literal>. The <literal>unknown</literal> value
-   plays the same role as SQL <literal>NULL</literal> and can be tested
-   for with the <literal>is unknown</literal> predicate. Further path
-   evaluation steps use only those items for which filter expressions
-   return <literal>true</literal>.
-  </para>
+  <table id="functions-json-op-table">
+     <title><type>json</type> and <type>jsonb</type> Operators</title>
+     <tgroup cols="6">
+      <thead>
+       <row>
+        <entry>Operator</entry>
+        <entry>Right Operand Type</entry>
+        <entry>Return type</entry>
+        <entry>Description</entry>
+        <entry>Example</entry>
+        <entry>Example Result</entry>
+       </row>
+      </thead>
+      <tbody>
+       <row>
+        <entry><literal>-&gt;</literal></entry>
+        <entry><type>int</type></entry>
+        <entry><type>json</type> or <type>jsonb</type></entry>
+        <entry>Get JSON array element (indexed from zero, negative
+        integers count from the end)</entry>
+        <entry><literal>'[{"a":"foo"},{"b":"bar"},{"c":"baz"}]'::json-&gt;2</literal></entry>
+        <entry><literal>{"c":"baz"}</literal></entry>
+       </row>
+       <row>
+        <entry><literal>-&gt;</literal></entry>
+        <entry><type>text</type></entry>
+        <entry><type>json</type> or <type>jsonb</type></entry>
+        <entry>Get JSON object field by key</entry>
+        <entry><literal>'{"a": {"b":"foo"}}'::json-&gt;'a'</literal></entry>
+        <entry><literal>{"b":"foo"}</literal></entry>
+       </row>
+        <row>
+        <entry><literal>-&gt;&gt;</literal></entry>
+        <entry><type>int</type></entry>
+        <entry><type>text</type></entry>
+        <entry>Get JSON array element as <type>text</type></entry>
+        <entry><literal>'[1,2,3]'::json-&gt;&gt;2</literal></entry>
+        <entry><literal>3</literal></entry>
+       </row>
+       <row>
+        <entry><literal>-&gt;&gt;</literal></entry>
+        <entry><type>text</type></entry>
+        <entry><type>text</type></entry>
+        <entry>Get JSON object field as <type>text</type></entry>
+        <entry><literal>'{"a":1,"b":2}'::json-&gt;&gt;'b'</literal></entry>
+        <entry><literal>2</literal></entry>
+       </row>
+       <row>
+        <entry><literal>#&gt;</literal></entry>
+        <entry><type>text[]</type></entry>
+        <entry><type>json</type> or <type>jsonb</type></entry>
+        <entry>Get JSON object at the specified path</entry>
+        <entry><literal>'{"a": {"b":{"c": "foo"}}}'::json#&gt;'{a,b}'</literal></entry>
+        <entry><literal>{"c": "foo"}</literal></entry>
+       </row>
+       <row>
+        <entry><literal>#&gt;&gt;</literal></entry>
+        <entry><type>text[]</type></entry>
+        <entry><type>text</type></entry>
+        <entry>Get JSON object at the specified path as <type>text</type></entry>
+        <entry><literal>'{"a":[1,2,3],"b":[4,5,6]}'::json#&gt;&gt;'{a,2}'</literal></entry>
+        <entry><literal>3</literal></entry>
+       </row>
+      </tbody>
+     </tgroup>
+   </table>
 
+  <note>
+   <para>
+    There are parallel variants of these operators for both the
+    <type>json</type> and <type>jsonb</type> types.
+    The field/element/path extraction operators
+    return the same type as their left-hand input (either <type>json</type>
+    or <type>jsonb</type>), except for those specified as
+    returning <type>text</type>, 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.
+   </para>
+  </note>
   <para>
-   Functions and operators that can be used in filter expressions are listed
-   in <xref linkend="functions-sqljson-filter-ex-table"/>. The path
-   evaluation result to be filtered is denoted by the <literal>@</literal>
-   variable. To refer to a JSON element stored at a lower nesting level,
-   add one or more accessor operators after <literal>@</literal>.
+   The standard comparison operators shown in  <xref
+   linkend="functions-comparison-op-table"/> are available for
+   <type>jsonb</type>, but not for <type>json</type>. They follow the
+   ordering rules for B-tree operations outlined at <xref
+   linkend="json-indexing"/>.
   </para>
-
   <para>
-   Suppose you would like to retrieve all heart rate values higher
-   than 130. You can achieve this using the following expression:
-<programlisting>
-'$.track.segments[*].HR ? (@ &gt; 130)'
-</programlisting>
+   Some further operators also exist only for <type>jsonb</type>, as shown
+   in <xref linkend="functions-jsonb-op-table"/>.
+   Many of these operators can be indexed by
+   <type>jsonb</type> operator classes.  For a full description of
+   <type>jsonb</type> containment and existence semantics, see <xref
+   linkend="json-containment"/>.  <xref linkend="json-indexing"/>
+   describes how these operators can be used to effectively index
+   <type>jsonb</type> data.
   </para>
-
-  <para>
-   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:
-<programlisting>
-'$.track.segments[*] ? (@.HR &gt; 130)."start time"'
-</programlisting>
-  </para>
-
-  <para>
-   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:
-<programlisting>
-'$.track.segments[*] ? (@.location[1] &lt; 13.4) ? (@.HR &gt; 130)."start time"'
-</programlisting>
-  </para>
-
-  <para>
-   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:
-<programlisting>
-'$.track.segments[*] ? (@.location[1] &lt; 13.4).HR ? (@ &gt; 130)'
-</programlisting>
-  </para>
-
-  <para>
-   You can also nest filter expressions within each other:
-<programlisting>
-'$.track ? (exists(@.segments[*] ? (@.HR &gt; 130))).segments.size()'
-</programlisting>
-   This expression returns the size of the track if it contains any
-   segments with high heart rate values, or an empty sequence otherwise.
-  </para>
-
-  <para>
-   <productname>PostgreSQL</productname>'s implementation of SQL/JSON path
-   language has the following deviations from the SQL/JSON standard:
-  </para>
-
-  <itemizedlist>
-   <listitem>
-    <para>
-     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 <literal>@@</literal> operator. For example,
-     the following <type>jsonpath</type> expression is valid in
-     <productname>PostgreSQL</productname>:
-<programlisting>
-'$.track.segments[*].HR &lt; 70'
-</programlisting>
-    </para>
-   </listitem>
-
-   <listitem>
-    <para>
-     There are minor differences in the interpretation of regular
-     expression patterns used in <literal>like_regex</literal> filters, as
-     described in <xref linkend="jsonpath-regular-expressions"/>.
-    </para>
-   </listitem>
-  </itemizedlist>
-
-   <sect3 id="strict-and-lax-modes">
-   <title>Strict and Lax Modes</title>
-    <para>
-     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:
-    </para>
-
-   <itemizedlist>
-    <listitem>
-     <para>
-      lax (default) &mdash; 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.
-     </para>
-    </listitem>
-    <listitem>
-     <para>
-      strict &mdash; if a structural error occurs, an error is raised.
-     </para>
-    </listitem>
-   </itemizedlist>
-
-   <para>
-    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:
-    <itemizedlist>
-     <listitem>
-      <para>
-       The path expression contains <literal>type()</literal> or
-       <literal>size()</literal> methods that return the type
-       and the number of elements in the array, respectively.
-      </para>
-     </listitem>
-     <listitem>
-      <para>
-       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.
-      </para>
-     </listitem>
-    </itemizedlist>
-   </para>
-
-   <para>
-    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:
-<programlisting>
-'lax $.track.segments.location'
-</programlisting>
-   </para>
-
-   <para>
-    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
-    <literal>segments</literal> array:
-<programlisting>
-'strict $.track.segments[*].location'
-</programlisting>
-   </para>
-
-   </sect3>
-
-   <sect3 id="jsonpath-regular-expressions">
-    <title>Regular Expressions</title>
-
-    <indexterm zone="jsonpath-regular-expressions">
-     <primary><literal>LIKE_REGEX</literal></primary>
-     <secondary>in SQL/JSON</secondary>
-    </indexterm>
-
-    <para>
-     SQL/JSON path expressions allow matching text to a regular expression
-     with the <literal>like_regex</literal> filter.  For example, the
-     following SQL/JSON path query would case-insensitively match all
-     strings in an array that start with an English vowel:
-<programlisting>
-'$[*] ? (@ like_regex "^[aeiou]" flag "i")'
-</programlisting>
-    </para>
-
-    <para>
-     The optional <literal>flag</literal> string may include one or more of
-     the characters
-     <literal>i</literal> for case-insensitive match,
-     <literal>m</literal> to allow <literal>^</literal>
-     and <literal>$</literal> to match at newlines,
-     <literal>s</literal> to allow <literal>.</literal> to match a newline,
-     and <literal>q</literal> to quote the whole pattern (reducing the
-     behavior to a simple substring match).
-    </para>
-
-    <para>
-     The SQL/JSON standard borrows its definition for regular expressions
-     from the <literal>LIKE_REGEX</literal> operator, which in turn uses the
-     XQuery standard.  PostgreSQL does not currently support the
-     <literal>LIKE_REGEX</literal> operator.  Therefore,
-     the <literal>like_regex</literal> filter is implemented using the
-     POSIX regular expression engine described in
-     <xref linkend="functions-posix-regexp"/>.  This leads to various minor
-     discrepancies from standard SQL/JSON behavior, which are cataloged in
-     <xref linkend="posix-vs-xquery"/>.
-     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.
-    </para>
-
-    <para>
-     Keep in mind that the pattern argument of <literal>like_regex</literal>
-     is a JSON path string literal, written according to the rules given in
-     <xref linkend="datatype-jsonpath"/>.  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:
-<programlisting>
-'$ ? (@ like_regex "^\\d+$")'
-</programlisting>
-    </para>
-
-   </sect3>
-
-   <sect3 id="functions-sqljson-path-operators">
-   <title>SQL/JSON Path Operators and Methods</title>
-
-   <para>
-    <xref linkend="functions-sqljson-op-table"/> shows the operators and
-    methods available in <type>jsonpath</type>.  <xref
-    linkend="functions-sqljson-filter-ex-table"/> shows the available filter
-    expression elements.
-   </para>
-
-   <table id="functions-sqljson-op-table">
-    <title><type>jsonpath</type> Operators and Methods</title>
-     <tgroup cols="5">
+  <table id="functions-jsonb-op-table">
+     <title>Additional <type>jsonb</type> Operators</title>
+     <tgroup cols="4">
       <thead>
        <row>
-        <entry>Operator/Method</entry>
+        <entry>Operator</entry>
+        <entry>Right Operand Type</entry>
         <entry>Description</entry>
-        <entry>Example JSON</entry>
-        <entry>Example Query</entry>
-        <entry>Result</entry>
+        <entry>Example</entry>
        </row>
       </thead>
       <tbody>
        <row>
-        <entry><literal>+</literal> (unary)</entry>
-        <entry>Plus operator that iterates over the SQL/JSON sequence</entry>
-        <entry><literal>{"x": [2.85, -14.7, -9.4]}</literal></entry>
-        <entry><literal>+ $.x.floor()</literal></entry>
-        <entry><literal>2, -15, -10</literal></entry>
-       </row>
-       <row>
-        <entry><literal>-</literal> (unary)</entry>
-        <entry>Minus operator that iterates over the SQL/JSON sequence</entry>
-        <entry><literal>{"x": [2.85, -14.7, -9.4]}</literal></entry>
-        <entry><literal>- $.x.floor()</literal></entry>
-        <entry><literal>-2, 15, 10</literal></entry>
+        <entry><literal>@&gt;</literal></entry>
+        <entry><type>jsonb</type></entry>
+        <entry>Does the left JSON value contain the right JSON
+        path/value entries at the top level?</entry>
+        <entry><literal>'{"a":1, "b":2}'::jsonb &#64;&gt; '{"b":2}'::jsonb</literal></entry>
        </row>
        <row>
-        <entry><literal>+</literal> (binary)</entry>
-        <entry>Addition</entry>
-        <entry><literal>[2]</literal></entry>
-        <entry><literal>2 + $[0]</literal></entry>
-        <entry><literal>4</literal></entry>
+        <entry><literal>&lt;@</literal></entry>
+        <entry><type>jsonb</type></entry>
+        <entry>Are the left JSON path/value entries contained at the top level within
+        the right JSON value?</entry>
+        <entry><literal>'{"b":2}'::jsonb &lt;@ '{"a":1, "b":2}'::jsonb</literal></entry>
        </row>
        <row>
-        <entry><literal>-</literal> (binary)</entry>
-        <entry>Subtraction</entry>
-        <entry><literal>[2]</literal></entry>
-        <entry><literal>4 - $[0]</literal></entry>
-        <entry><literal>2</literal></entry>
+        <entry><literal>?</literal></entry>
+        <entry><type>text</type></entry>
+        <entry>Does the <emphasis>string</emphasis> exist as a top-level
+        key within the JSON value?</entry>
+        <entry><literal>'{"a":1, "b":2}'::jsonb ? 'b'</literal></entry>
        </row>
        <row>
-        <entry><literal>*</literal></entry>
-        <entry>Multiplication</entry>
-        <entry><literal>[4]</literal></entry>
-        <entry><literal>2 * $[0]</literal></entry>
-        <entry><literal>8</literal></entry>
-       </row>
-       <row>
-        <entry><literal>/</literal></entry>
-        <entry>Division</entry>
-        <entry><literal>[8]</literal></entry>
-        <entry><literal>$[0] / 2</literal></entry>
-        <entry><literal>4</literal></entry>
-       </row>
-       <row>
-        <entry><literal>%</literal></entry>
-        <entry>Modulus</entry>
-        <entry><literal>[32]</literal></entry>
-        <entry><literal>$[0] % 10</literal></entry>
-        <entry><literal>2</literal></entry>
-       </row>
-       <row>
-        <entry><literal>type()</literal></entry>
-        <entry>Type of the SQL/JSON item</entry>
-        <entry><literal>[1, "2", {}]</literal></entry>
-        <entry><literal>$[*].type()</literal></entry>
-        <entry><literal>"number", "string", "object"</literal></entry>
+        <entry><literal>?|</literal></entry>
+        <entry><type>text[]</type></entry>
+        <entry>Do any of these array <emphasis>strings</emphasis>
+        exist as top-level keys?</entry>
+        <entry><literal>'{"a":1, "b":2, "c":3}'::jsonb ?| array['b', 'c']</literal></entry>
        </row>
        <row>
-        <entry><literal>size()</literal></entry>
-        <entry>Size of the SQL/JSON item</entry>
-        <entry><literal>{"m": [11, 15]}</literal></entry>
-        <entry><literal>$.m.size()</literal></entry>
-        <entry><literal>2</literal></entry>
+        <entry><literal>?&amp;</literal></entry>
+        <entry><type>text[]</type></entry>
+        <entry>Do all of these array <emphasis>strings</emphasis> exist
+        as top-level keys?</entry>
+        <entry><literal>'["a", "b"]'::jsonb ?&amp; array['a', 'b']</literal></entry>
        </row>
        <row>
-        <entry><literal>double()</literal></entry>
-        <entry>Approximate floating-point number converted from an SQL/JSON number or a string</entry>
-        <entry><literal>{"len": "1.9"}</literal></entry>
-        <entry><literal>$.len.double() * 2</literal></entry>
-        <entry><literal>3.8</literal></entry>
+        <entry><literal>||</literal></entry>
+        <entry><type>jsonb</type></entry>
+        <entry>Concatenate two <type>jsonb</type> values into a new <type>jsonb</type> value</entry>
+        <entry><literal>'["a", "b"]'::jsonb || '["c", "d"]'::jsonb</literal></entry>
        </row>
        <row>
-        <entry><literal>ceiling()</literal></entry>
-        <entry>Nearest integer greater than or equal to the SQL/JSON number</entry>
-        <entry><literal>{"h": 1.3}</literal></entry>
-        <entry><literal>$.h.ceiling()</literal></entry>
-        <entry><literal>2</literal></entry>
+        <entry><literal>-</literal></entry>
+        <entry><type>text</type></entry>
+        <entry>Delete key/value pair or <emphasis>string</emphasis>
+        element from left operand.  Key/value pairs are matched based
+        on their key value.</entry>
+        <entry><literal>'{"a": "b"}'::jsonb - 'a' </literal></entry>
        </row>
        <row>
-        <entry><literal>floor()</literal></entry>
-        <entry>Nearest integer less than or equal to the SQL/JSON number</entry>
-        <entry><literal>{"h": 1.3}</literal></entry>
-        <entry><literal>$.h.floor()</literal></entry>
-        <entry><literal>1</literal></entry>
+        <entry><literal>-</literal></entry>
+        <entry><type>text[]</type></entry>
+        <entry>Delete multiple key/value pairs or <emphasis>string</emphasis>
+        elements from left operand.  Key/value pairs are matched based
+        on their key value.</entry>
+        <entry><literal>'{"a": "b", "c": "d"}'::jsonb - '{a,c}'::text[] </literal></entry>
        </row>
        <row>
-        <entry><literal>abs()</literal></entry>
-        <entry>Absolute value of the SQL/JSON number</entry>
-        <entry><literal>{"z": -0.3}</literal></entry>
-        <entry><literal>$.z.abs()</literal></entry>
-        <entry><literal>0.3</literal></entry>
+        <entry><literal>-</literal></entry>
+        <entry><type>integer</type></entry>
+        <entry>Delete the array element with specified index (Negative
+        integers count from the end).  Throws an error if top level
+        container is not an array.</entry>
+        <entry><literal>'["a", "b"]'::jsonb - 1 </literal></entry>
        </row>
        <row>
-        <entry><literal>datetime()</literal></entry>
-        <entry>Date/time value converted from a string</entry>
-        <entry><literal>["2015-8-1", "2015-08-12"]</literal></entry>
-        <entry><literal>$[*] ? (@.datetime() &lt; "2015-08-2". datetime())</literal></entry>
-        <entry><literal>2015-8-1</literal></entry>
+        <entry><literal>#-</literal></entry>
+        <entry><type>text[]</type></entry>
+        <entry>Delete the field or element with specified path (for
+        JSON arrays, negative integers count from the end)</entry>
+        <entry><literal>'["a", {"b":1}]'::jsonb #- '{1,b}'</literal></entry>
        </row>
        <row>
-        <entry><literal>datetime(<replaceable>template</replaceable>)</literal></entry>
-        <entry>Date/time value converted from a string using the specified template</entry>
-        <entry><literal>["12:30", "18:40"]</literal></entry>
-        <entry><literal>$[*].datetime("HH24:MI")</literal></entry>
-        <entry><literal>"12:30:00", "18:40:00"</literal></entry>
+        <entry><literal>@?</literal></entry>
+        <entry><type>jsonpath</type></entry>
+        <entry>Does JSON path return any item for the specified JSON value?</entry>
+        <entry><literal>'{"a":[1,2,3,4,5]}'::jsonb @? '$.a[*] ? (@ > 2)'</literal></entry>
        </row>
        <row>
-        <entry><literal>keyvalue()</literal></entry>
-        <entry>
-          Sequence of object's key-value pairs represented as array of items
-          containing three fields (<literal>"key"</literal>,
-          <literal>"value"</literal>, and <literal>"id"</literal>).
-          <literal>"id"</literal> is a unique identifier of the object
-          key-value pair belongs to.
-        </entry>
-        <entry><literal>{"x": "20", "y": 32}</literal></entry>
-        <entry><literal>$.keyvalue()</literal></entry>
-        <entry><literal>{"key": "x", "value": "20", "id": 0}, {"key": "y", "value": 32, "id": 0}</literal></entry>
+        <entry><literal>@@</literal></entry>
+        <entry><type>jsonpath</type></entry>
+        <entry>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 <literal>null</literal> is returned.</entry>
+        <entry><literal>'{"a":[1,2,3,4,5]}'::jsonb @@ '$.a[*] > 2'</literal></entry>
        </row>
       </tbody>
      </tgroup>
-    </table>
+   </table>
 
-    <note>
-     <para>
-      The result type of <literal>datetime()</literal> and
-      <literal>datetime(<replaceable>template</replaceable>)</literal>
-      methods can be <type>date</type>, <type>timetz</type>, <type>time</type>,
-      <type>timestamptz</type>, or <type>timestamp</type>.
-      Both methods determine the result type dynamically.
-     </para>
-     <para>
-      The <literal>datetime()</literal> method sequentially tries ISO formats
-      for <type>date</type>, <type>timetz</type>, <type>time</type>,
-      <type>timestamptz</type>, and <type>timestamp</type>. It stops on
-      the first matching format and the corresponding data type.
-     </para>
-     <para>
-      The <literal>datetime(<replaceable>template</replaceable>)</literal>
-      method determines the result type by the provided template string.
-     </para>
-     <para>
-      The <literal>datetime()</literal> and
-      <literal>datetime(<replaceable>template</replaceable>)</literal> methods
-      use the same parsing rules as <literal>to_timestamp</literal> SQL
-      function does (see <xref linkend="functions-formatting"/>) with three
-      exceptions.  At first, these methods doesn't allow unmatched template
-      patterns.  At second, only following separators are allowed in the
-      template string: minus sign, period, solidus, comma, apostrophe,
-      semicolon, colon and space.  At third, separators in the template string
-      must exactly match the input string.
-     </para>
-    </note>
+  <note>
+   <para>
+    The <literal>||</literal> 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.
+   </para>
+  </note>
 
-    <table id="functions-sqljson-filter-ex-table">
-     <title><type>jsonpath</type> Filter Expression Elements</title>
-     <tgroup cols="5">
-      <thead>
-       <row>
-        <entry>Value/Predicate</entry>
-        <entry>Description</entry>
-        <entry>Example JSON</entry>
-        <entry>Example Query</entry>
-        <entry>Result</entry>
-       </row>
-      </thead>
-      <tbody>
-       <row>
-        <entry><literal>==</literal></entry>
-        <entry>Equality operator</entry>
-        <entry><literal>[1, 2, 1, 3]</literal></entry>
-        <entry><literal>$[*] ? (@ == 1)</literal></entry>
-        <entry><literal>1, 1</literal></entry>
-       </row>
-       <row>
-        <entry><literal>!=</literal></entry>
-        <entry>Non-equality operator</entry>
-        <entry><literal>[1, 2, 1, 3]</literal></entry>
-        <entry><literal>$[*] ? (@ != 1)</literal></entry>
-        <entry><literal>2, 3</literal></entry>
-       </row>
-       <row>
-        <entry><literal>&lt;&gt;</literal></entry>
-        <entry>Non-equality operator (same as <literal>!=</literal>)</entry>
-        <entry><literal>[1, 2, 1, 3]</literal></entry>
-        <entry><literal>$[*] ? (@ &lt;&gt; 1)</literal></entry>
-        <entry><literal>2, 3</literal></entry>
-       </row>
-       <row>
-        <entry><literal>&lt;</literal></entry>
-        <entry>Less-than operator</entry>
-        <entry><literal>[1, 2, 3]</literal></entry>
-        <entry><literal>$[*] ? (@ &lt; 2)</literal></entry>
-        <entry><literal>1</literal></entry>
-       </row>
-       <row>
-        <entry><literal>&lt;=</literal></entry>
-        <entry>Less-than-or-equal-to operator</entry>
-        <entry><literal>[1, 2, 3]</literal></entry>
-        <entry><literal>$[*] ? (@ &lt;= 2)</literal></entry>
-        <entry><literal>1, 2</literal></entry>
-       </row>
-       <row>
-        <entry><literal>&gt;</literal></entry>
-        <entry>Greater-than operator</entry>
-        <entry><literal>[1, 2, 3]</literal></entry>
-        <entry><literal>$[*] ? (@ &gt; 2)</literal></entry>
-        <entry><literal>3</literal></entry>
-       </row>
-       <row>
-        <entry><literal>&gt;=</literal></entry>
-        <entry>Greater-than-or-equal-to operator</entry>
-        <entry><literal>[1, 2, 3]</literal></entry>
-        <entry><literal>$[*] ? (@ &gt;= 2)</literal></entry>
-        <entry><literal>2, 3</literal></entry>
-       </row>
-       <row>
-        <entry><literal>true</literal></entry>
-        <entry>Value used to perform comparison with JSON <literal>true</literal> literal</entry>
-        <entry><literal>[{"name": "John", "parent": false},
-                           {"name": "Chris", "parent": true}]</literal></entry>
-        <entry><literal>$[*] ? (@.parent == true)</literal></entry>
-        <entry><literal>{"name": "Chris", "parent": true}</literal></entry>
-       </row>
-       <row>
-        <entry><literal>false</literal></entry>
-        <entry>Value used to perform comparison with JSON <literal>false</literal> literal</entry>
-        <entry><literal>[{"name": "John", "parent": false},
-                           {"name": "Chris", "parent": true}]</literal></entry>
-        <entry><literal>$[*] ? (@.parent == false)</literal></entry>
-        <entry><literal>{"name": "John", "parent": false}</literal></entry>
-       </row>
-       <row>
-        <entry><literal>null</literal></entry>
-        <entry>Value used to perform comparison with JSON <literal>null</literal> value</entry>
-        <entry><literal>[{"name": "Mary", "job": null},
-                         {"name": "Michael", "job": "driver"}]</literal></entry>
-        <entry><literal>$[*] ? (@.job == null) .name</literal></entry>
-        <entry><literal>"Mary"</literal></entry>
-       </row>
-       <row>
-        <entry><literal>&amp;&amp;</literal></entry>
-        <entry>Boolean AND</entry>
-        <entry><literal>[1, 3, 7]</literal></entry>
-        <entry><literal>$[*] ? (@ &gt; 1 &amp;&amp; @ &lt; 5)</literal></entry>
-        <entry><literal>3</literal></entry>
-       </row>
-       <row>
-        <entry><literal>||</literal></entry>
-        <entry>Boolean OR</entry>
-        <entry><literal>[1, 3, 7]</literal></entry>
-        <entry><literal>$[*] ? (@ &lt; 1 || @ &gt; 5)</literal></entry>
-        <entry><literal>7</literal></entry>
-       </row>
-       <row>
-        <entry><literal>!</literal></entry>
-        <entry>Boolean NOT</entry>
-        <entry><literal>[1, 3, 7]</literal></entry>
-        <entry><literal>$[*] ? (!(@ &lt; 5))</literal></entry>
-        <entry><literal>7</literal></entry>
-       </row>
-       <row>
-        <entry><literal>like_regex</literal></entry>
-        <entry>
-          Tests whether the first operand matches the regular expression
-          given by the second operand, optionally with modifications
-          described by a string of <literal>flag</literal> characters (see
-          <xref linkend="jsonpath-regular-expressions"/>)
-        </entry>
-        <entry><literal>["abc", "abd", "aBdC", "abdacb", "babc"]</literal></entry>
-        <entry><literal>$[*] ? (@ like_regex "^ab.*c" flag "i")</literal></entry>
-        <entry><literal>"abc", "aBdC", "abdacb"</literal></entry>
-       </row>
-       <row>
-        <entry><literal>starts with</literal></entry>
-        <entry>Tests whether the second operand is an initial substring of the first operand</entry>
-        <entry><literal>["John Smith", "Mary Stone", "Bob Johnson"]</literal></entry>
-        <entry><literal>$[*] ? (@ starts with "John")</literal></entry>
-        <entry><literal>"John Smith"</literal></entry>
-       </row>
-       <row>
-        <entry><literal>exists</literal></entry>
-        <entry>Tests whether a path expression matches at least one SQL/JSON item</entry>
-        <entry><literal>{"x": [1, 2], "y": [2, 4]}</literal></entry>
-        <entry><literal>strict $.* ? (exists (@ ? (@[*] > 2)))</literal></entry>
-        <entry><literal>2, 4</literal></entry>
-       </row>
-       <row>
-        <entry><literal>is unknown</literal></entry>
-        <entry>Tests whether a Boolean condition is <literal>unknown</literal></entry>
-        <entry><literal>[-1, 2, 7, "infinity"]</literal></entry>
-        <entry><literal>$[*] ? ((@ > 0) is unknown)</literal></entry>
-        <entry><literal>"infinity"</literal></entry>
-       </row>
-      </tbody>
-     </tgroup>
-    </table>
-
-    <note>
-     <para>
-      When different date/time values are compared, an implicit cast is
-      applied. A <type>date</type> value can be cast to <type>timestamp</type>
-      or <type>timestamptz</type>, <type>timestamp</type> can be cast to
-      <type>timestamptz</type>, and <type>time</type> &mdash; to <type>timetz</type>.
-     </para>
-    </note>
-   </sect3>
+  <note>
+   <para>
+    The <literal>@?</literal> and <literal>@@</literal> operators suppress
+    the following errors: lacking object field or array element, unexpected
+    JSON item type, datetime and numeric errors.
+    This behavior might be helpful while searching over JSON document
+    collections of varying structure.
+   </para>
+  </note>
 
-  </sect2>
+  <para>
+   <xref linkend="functions-json-creation-table"/> shows the functions that are
+   available for creating <type>json</type> and <type>jsonb</type> values.
+   (There are no equivalent functions for <type>jsonb</type>, of the <literal>row_to_json</literal>
+   and <literal>array_to_json</literal> functions. However, the <literal>to_jsonb</literal>
+   function supplies much the same functionality as these functions would.)
+  </para>
 
-  <sect2 id="functions-pgjson">
-  <title>JSON Functions and Operators</title>
-  <indexterm zone="functions-json">
-    <primary>JSON</primary>
-    <secondary>functions and operators</secondary>
+  <indexterm>
+   <primary>to_json</primary>
+  </indexterm>
+  <indexterm>
+   <primary>array_to_json</primary>
+  </indexterm>
+  <indexterm>
+   <primary>row_to_json</primary>
+  </indexterm>
+  <indexterm>
+   <primary>json_build_array</primary>
+  </indexterm>
+  <indexterm>
+   <primary>json_build_object</primary>
+  </indexterm>
+  <indexterm>
+   <primary>json_object</primary>
+  </indexterm>
+  <indexterm>
+   <primary>to_jsonb</primary>
+  </indexterm>
+  <indexterm>
+   <primary>jsonb_build_array</primary>
+  </indexterm>
+  <indexterm>
+   <primary>jsonb_build_object</primary>
+  </indexterm>
+  <indexterm>
+   <primary>jsonb_object</primary>
   </indexterm>
 
+  <table id="functions-json-creation-table">
+    <title>JSON Creation Functions</title>
+    <tgroup cols="4">
+     <thead>
+      <row>
+       <entry>Function</entry>
+       <entry>Description</entry>
+       <entry>Example</entry>
+       <entry>Example Result</entry>
+      </row>
+     </thead>
+     <tbody>
+      <row>
+       <entry><para><literal>to_json(anyelement)</literal>
+          </para><para><literal>to_jsonb(anyelement)</literal>
+       </para></entry>
+       <entry>
+         Returns the value as <type>json</type> or <type>jsonb</type>.
+         Arrays and composites are converted
+         (recursively) to arrays and objects; otherwise, if there is a cast
+         from the type to <type>json</type>, 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 <type>json</type> or <type>jsonb</type> value.
+       </entry>
+       <entry><literal>to_json('Fred said "Hi."'::text)</literal></entry>
+       <entry><literal>"Fred said \"Hi.\""</literal></entry>
+      </row>
+      <row>
+       <entry>
+         <literal>array_to_json(anyarray [, pretty_bool])</literal>
+       </entry>
+       <entry>
+         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 <parameter>pretty_bool</parameter> is true.
+       </entry>
+       <entry><literal>array_to_json('{{1,5},{99,100}}'::int[])</literal></entry>
+       <entry><literal>[[1,5],[99,100]]</literal></entry>
+      </row>
+      <row>
+       <entry>
+         <literal>row_to_json(record [, pretty_bool])</literal>
+       </entry>
+       <entry>
+         Returns the row as a JSON object. Line feeds will be added between
+         level-1 elements if <parameter>pretty_bool</parameter> is true.
+       </entry>
+       <entry><literal>row_to_json(row(1,'foo'))</literal></entry>
+       <entry><literal>{"f1":1,"f2":"foo"}</literal></entry>
+      </row>
+      <row>
+       <entry><para><literal>json_build_array(VARIADIC "any")</literal>
+          </para><para><literal>jsonb_build_array(VARIADIC "any")</literal>
+       </para></entry>
+       <entry>
+         Builds a possibly-heterogeneously-typed JSON array out of a variadic
+         argument list.
+       </entry>
+       <entry><literal>json_build_array(1,2,'3',4,5)</literal></entry>
+       <entry><literal>[1, 2, "3", 4, 5]</literal></entry>
+      </row>
+      <row>
+       <entry><para><literal>json_build_object(VARIADIC "any")</literal>
+          </para><para><literal>jsonb_build_object(VARIADIC "any")</literal>
+       </para></entry>
+       <entry>
+         Builds a JSON object out of a variadic argument list.  By
+         convention, the argument list consists of alternating
+         keys and values.
+       </entry>
+       <entry><literal>json_build_object('foo',1,'bar',2)</literal></entry>
+       <entry><literal>{"foo": 1, "bar": 2}</literal></entry>
+      </row>
+      <row>
+       <entry><para><literal>json_object(text[])</literal>
+          </para><para><literal>jsonb_object(text[])</literal>
+       </para></entry>
+       <entry>
+         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.
+       </entry>
+       <entry><para><literal>json_object('{a, 1, b, "def", c, 3.5}')</literal></para>
+        <para><literal>json_object('{{a, 1},{b, "def"},{c, 3.5}}')</literal></para></entry>
+       <entry><literal>{"a": "1", "b": "def", "c": "3.5"}</literal></entry>
+      </row>
+      <row>
+       <entry><para><literal>json_object(keys text[], values text[])</literal>
+          </para><para><literal>jsonb_object(keys text[], values text[])</literal>
+       </para></entry>
+       <entry>
+         This form of <function>json_object</function> takes keys and values pairwise from two separate
+         arrays. In all other respects it is identical to the one-argument form.
+       </entry>
+       <entry><literal>json_object('{a, b}', '{1,2}')</literal></entry>
+       <entry><literal>{"a": "1", "b": "2"}</literal></entry>
+      </row>
+     </tbody>
+    </tgroup>
+   </table>
+
+  <note>
+    <para>
+     <function>array_to_json</function> and <function>row_to_json</function> have the same
+     behavior as <function>to_json</function> except for offering a pretty-printing
+     option.  The behavior described for <function>to_json</function> likewise applies
+     to each individual value converted by the other JSON creation functions.
+    </para>
+  </note>
+
+  <note>
+    <para>
+     The <xref linkend="hstore"/> extension has a cast
+     from <type>hstore</type> to <type>json</type>, so that
+     <type>hstore</type> values converted via the JSON creation functions
+     will be represented as JSON objects, not as primitive string values.
+    </para>
+  </note>
+
   <para>
-   <xref linkend="functions-json-op-table"/> shows the operators that
-   are available for use with JSON data types (see <xref
-   linkend="datatype-json"/>).
-  </para>
-
-  <table id="functions-json-op-table">
-     <title><type>json</type> and <type>jsonb</type> Operators</title>
-     <tgroup cols="6">
-      <thead>
-       <row>
-        <entry>Operator</entry>
-        <entry>Right Operand Type</entry>
-        <entry>Return type</entry>
-        <entry>Description</entry>
-        <entry>Example</entry>
-        <entry>Example Result</entry>
-       </row>
-      </thead>
-      <tbody>
-       <row>
-        <entry><literal>-&gt;</literal></entry>
-        <entry><type>int</type></entry>
-        <entry><type>json</type> or <type>jsonb</type></entry>
-        <entry>Get JSON array element (indexed from zero, negative
-        integers count from the end)</entry>
-        <entry><literal>'[{"a":"foo"},{"b":"bar"},{"c":"baz"}]'::json-&gt;2</literal></entry>
-        <entry><literal>{"c":"baz"}</literal></entry>
-       </row>
-       <row>
-        <entry><literal>-&gt;</literal></entry>
-        <entry><type>text</type></entry>
-        <entry><type>json</type> or <type>jsonb</type></entry>
-        <entry>Get JSON object field by key</entry>
-        <entry><literal>'{"a": {"b":"foo"}}'::json-&gt;'a'</literal></entry>
-        <entry><literal>{"b":"foo"}</literal></entry>
-       </row>
-        <row>
-        <entry><literal>-&gt;&gt;</literal></entry>
-        <entry><type>int</type></entry>
-        <entry><type>text</type></entry>
-        <entry>Get JSON array element as <type>text</type></entry>
-        <entry><literal>'[1,2,3]'::json-&gt;&gt;2</literal></entry>
-        <entry><literal>3</literal></entry>
-       </row>
-       <row>
-        <entry><literal>-&gt;&gt;</literal></entry>
-        <entry><type>text</type></entry>
-        <entry><type>text</type></entry>
-        <entry>Get JSON object field as <type>text</type></entry>
-        <entry><literal>'{"a":1,"b":2}'::json-&gt;&gt;'b'</literal></entry>
-        <entry><literal>2</literal></entry>
-       </row>
-       <row>
-        <entry><literal>#&gt;</literal></entry>
-        <entry><type>text[]</type></entry>
-        <entry><type>json</type> or <type>jsonb</type></entry>
-        <entry>Get JSON object at the specified path</entry>
-        <entry><literal>'{"a": {"b":{"c": "foo"}}}'::json#&gt;'{a,b}'</literal></entry>
-        <entry><literal>{"c": "foo"}</literal></entry>
-       </row>
-       <row>
-        <entry><literal>#&gt;&gt;</literal></entry>
-        <entry><type>text[]</type></entry>
-        <entry><type>text</type></entry>
-        <entry>Get JSON object at the specified path as <type>text</type></entry>
-        <entry><literal>'{"a":[1,2,3],"b":[4,5,6]}'::json#&gt;&gt;'{a,2}'</literal></entry>
-        <entry><literal>3</literal></entry>
-       </row>
-      </tbody>
-     </tgroup>
-   </table>
-
-  <note>
-   <para>
-    There are parallel variants of these operators for both the
-    <type>json</type> and <type>jsonb</type> types.
-    The field/element/path extraction operators
-    return the same type as their left-hand input (either <type>json</type>
-    or <type>jsonb</type>), except for those specified as
-    returning <type>text</type>, 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.
-   </para>
-  </note>
-  <para>
-   The standard comparison operators shown in  <xref
-   linkend="functions-comparison-op-table"/> are available for
-   <type>jsonb</type>, but not for <type>json</type>. They follow the
-   ordering rules for B-tree operations outlined at <xref
-   linkend="json-indexing"/>.
-  </para>
-  <para>
-   Some further operators also exist only for <type>jsonb</type>, as shown
-   in <xref linkend="functions-jsonb-op-table"/>.
-   Many of these operators can be indexed by
-   <type>jsonb</type> operator classes.  For a full description of
-   <type>jsonb</type> containment and existence semantics, see <xref
-   linkend="json-containment"/>.  <xref linkend="json-indexing"/>
-   describes how these operators can be used to effectively index
-   <type>jsonb</type> data.
-  </para>
-  <table id="functions-jsonb-op-table">
-     <title>Additional <type>jsonb</type> Operators</title>
-     <tgroup cols="4">
-      <thead>
-       <row>
-        <entry>Operator</entry>
-        <entry>Right Operand Type</entry>
-        <entry>Description</entry>
-        <entry>Example</entry>
-       </row>
-      </thead>
-      <tbody>
-       <row>
-        <entry><literal>@&gt;</literal></entry>
-        <entry><type>jsonb</type></entry>
-        <entry>Does the left JSON value contain the right JSON
-        path/value entries at the top level?</entry>
-        <entry><literal>'{"a":1, "b":2}'::jsonb &#64;&gt; '{"b":2}'::jsonb</literal></entry>
-       </row>
-       <row>
-        <entry><literal>&lt;@</literal></entry>
-        <entry><type>jsonb</type></entry>
-        <entry>Are the left JSON path/value entries contained at the top level within
-        the right JSON value?</entry>
-        <entry><literal>'{"b":2}'::jsonb &lt;@ '{"a":1, "b":2}'::jsonb</literal></entry>
-       </row>
-       <row>
-        <entry><literal>?</literal></entry>
-        <entry><type>text</type></entry>
-        <entry>Does the <emphasis>string</emphasis> exist as a top-level
-        key within the JSON value?</entry>
-        <entry><literal>'{"a":1, "b":2}'::jsonb ? 'b'</literal></entry>
-       </row>
-       <row>
-        <entry><literal>?|</literal></entry>
-        <entry><type>text[]</type></entry>
-        <entry>Do any of these array <emphasis>strings</emphasis>
-        exist as top-level keys?</entry>
-        <entry><literal>'{"a":1, "b":2, "c":3}'::jsonb ?| array['b', 'c']</literal></entry>
-       </row>
-       <row>
-        <entry><literal>?&amp;</literal></entry>
-        <entry><type>text[]</type></entry>
-        <entry>Do all of these array <emphasis>strings</emphasis> exist
-        as top-level keys?</entry>
-        <entry><literal>'["a", "b"]'::jsonb ?&amp; array['a', 'b']</literal></entry>
-       </row>
-       <row>
-        <entry><literal>||</literal></entry>
-        <entry><type>jsonb</type></entry>
-        <entry>Concatenate two <type>jsonb</type> values into a new <type>jsonb</type> value</entry>
-        <entry><literal>'["a", "b"]'::jsonb || '["c", "d"]'::jsonb</literal></entry>
-       </row>
-       <row>
-        <entry><literal>-</literal></entry>
-        <entry><type>text</type></entry>
-        <entry>Delete key/value pair or <emphasis>string</emphasis>
-        element from left operand.  Key/value pairs are matched based
-        on their key value.</entry>
-        <entry><literal>'{"a": "b"}'::jsonb - 'a' </literal></entry>
-       </row>
-       <row>
-        <entry><literal>-</literal></entry>
-        <entry><type>text[]</type></entry>
-        <entry>Delete multiple key/value pairs or <emphasis>string</emphasis>
-        elements from left operand.  Key/value pairs are matched based
-        on their key value.</entry>
-        <entry><literal>'{"a": "b", "c": "d"}'::jsonb - '{a,c}'::text[] </literal></entry>
-       </row>
-       <row>
-        <entry><literal>-</literal></entry>
-        <entry><type>integer</type></entry>
-        <entry>Delete the array element with specified index (Negative
-        integers count from the end).  Throws an error if top level
-        container is not an array.</entry>
-        <entry><literal>'["a", "b"]'::jsonb - 1 </literal></entry>
-       </row>
-       <row>
-        <entry><literal>#-</literal></entry>
-        <entry><type>text[]</type></entry>
-        <entry>Delete the field or element with specified path (for
-        JSON arrays, negative integers count from the end)</entry>
-        <entry><literal>'["a", {"b":1}]'::jsonb #- '{1,b}'</literal></entry>
-       </row>
-       <row>
-        <entry><literal>@?</literal></entry>
-        <entry><type>jsonpath</type></entry>
-        <entry>Does JSON path return any item for the specified JSON value?</entry>
-        <entry><literal>'{"a":[1,2,3,4,5]}'::jsonb @? '$.a[*] ? (@ > 2)'</literal></entry>
-       </row>
-       <row>
-        <entry><literal>@@</literal></entry>
-        <entry><type>jsonpath</type></entry>
-        <entry>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 <literal>null</literal> is returned.</entry>
-        <entry><literal>'{"a":[1,2,3,4,5]}'::jsonb @@ '$.a[*] > 2'</literal></entry>
-       </row>
-      </tbody>
-     </tgroup>
-   </table>
-
-  <note>
-   <para>
-    The <literal>||</literal> 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.
-   </para>
-  </note>
-
-  <note>
-   <para>
-    The <literal>@?</literal> and <literal>@@</literal> operators suppress
-    the following errors: lacking object field or array element, unexpected
-    JSON item type, datetime and numeric errors.
-    This behavior might be helpful while searching over JSON document
-    collections of varying structure.
-   </para>
-  </note>
-
-  <para>
-   <xref linkend="functions-json-creation-table"/> shows the functions that are
-   available for creating <type>json</type> and <type>jsonb</type> values.
-   (There are no equivalent functions for <type>jsonb</type>, of the <literal>row_to_json</literal>
-   and <literal>array_to_json</literal> functions. However, the <literal>to_jsonb</literal>
-   function supplies much the same functionality as these functions would.)
+   <xref linkend="functions-json-processing-table"/> shows the functions that
+   are available for processing <type>json</type> and <type>jsonb</type> values.
   </para>
 
   <indexterm>
-   <primary>to_json</primary>
+   <primary>json_array_length</primary>
   </indexterm>
   <indexterm>
-   <primary>array_to_json</primary>
+   <primary>jsonb_array_length</primary>
   </indexterm>
   <indexterm>
-   <primary>row_to_json</primary>
+   <primary>json_each</primary>
   </indexterm>
   <indexterm>
-   <primary>json_build_array</primary>
+   <primary>jsonb_each</primary>
   </indexterm>
   <indexterm>
-   <primary>json_build_object</primary>
+   <primary>json_each_text</primary>
   </indexterm>
   <indexterm>
-   <primary>json_object</primary>
+   <primary>jsonb_each_text</primary>
   </indexterm>
   <indexterm>
-   <primary>to_jsonb</primary>
+   <primary>json_extract_path</primary>
   </indexterm>
   <indexterm>
-   <primary>jsonb_build_array</primary>
+   <primary>jsonb_extract_path</primary>
   </indexterm>
   <indexterm>
-   <primary>jsonb_build_object</primary>
+   <primary>json_extract_path_text</primary>
   </indexterm>
   <indexterm>
-   <primary>jsonb_object</primary>
-  </indexterm>
-
-  <table id="functions-json-creation-table">
-    <title>JSON Creation Functions</title>
-    <tgroup cols="4">
-     <thead>
-      <row>
-       <entry>Function</entry>
-       <entry>Description</entry>
-       <entry>Example</entry>
-       <entry>Example Result</entry>
-      </row>
-     </thead>
-     <tbody>
-      <row>
-       <entry><para><literal>to_json(anyelement)</literal>
-          </para><para><literal>to_jsonb(anyelement)</literal>
-       </para></entry>
-       <entry>
-         Returns the value as <type>json</type> or <type>jsonb</type>.
-         Arrays and composites are converted
-         (recursively) to arrays and objects; otherwise, if there is a cast
-         from the type to <type>json</type>, 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 <type>json</type> or <type>jsonb</type> value.
-       </entry>
-       <entry><literal>to_json('Fred said "Hi."'::text)</literal></entry>
-       <entry><literal>"Fred said \"Hi.\""</literal></entry>
-      </row>
-      <row>
-       <entry>
-         <literal>array_to_json(anyarray [, pretty_bool])</literal>
-       </entry>
-       <entry>
-         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 <parameter>pretty_bool</parameter> is true.
-       </entry>
-       <entry><literal>array_to_json('{{1,5},{99,100}}'::int[])</literal></entry>
-       <entry><literal>[[1,5],[99,100]]</literal></entry>
-      </row>
-      <row>
-       <entry>
-         <literal>row_to_json(record [, pretty_bool])</literal>
-       </entry>
-       <entry>
-         Returns the row as a JSON object. Line feeds will be added between
-         level-1 elements if <parameter>pretty_bool</parameter> is true.
-       </entry>
-       <entry><literal>row_to_json(row(1,'foo'))</literal></entry>
-       <entry><literal>{"f1":1,"f2":"foo"}</literal></entry>
-      </row>
-      <row>
-       <entry><para><literal>json_build_array(VARIADIC "any")</literal>
-          </para><para><literal>jsonb_build_array(VARIADIC "any")</literal>
-       </para></entry>
-       <entry>
-         Builds a possibly-heterogeneously-typed JSON array out of a variadic
-         argument list.
-       </entry>
-       <entry><literal>json_build_array(1,2,'3',4,5)</literal></entry>
-       <entry><literal>[1, 2, "3", 4, 5]</literal></entry>
-      </row>
-      <row>
-       <entry><para><literal>json_build_object(VARIADIC "any")</literal>
-          </para><para><literal>jsonb_build_object(VARIADIC "any")</literal>
-       </para></entry>
-       <entry>
-         Builds a JSON object out of a variadic argument list.  By
-         convention, the argument list consists of alternating
-         keys and values.
-       </entry>
-       <entry><literal>json_build_object('foo',1,'bar',2)</literal></entry>
-       <entry><literal>{"foo": 1, "bar": 2}</literal></entry>
-      </row>
-      <row>
-       <entry><para><literal>json_object(text[])</literal>
-          </para><para><literal>jsonb_object(text[])</literal>
-       </para></entry>
-       <entry>
-         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.
-       </entry>
-       <entry><para><literal>json_object('{a, 1, b, "def", c, 3.5}')</literal></para>
-        <para><literal>json_object('{{a, 1},{b, "def"},{c, 3.5}}')</literal></para></entry>
-       <entry><literal>{"a": "1", "b": "def", "c": "3.5"}</literal></entry>
-      </row>
-      <row>
-       <entry><para><literal>json_object(keys text[], values text[])</literal>
-          </para><para><literal>jsonb_object(keys text[], values text[])</literal>
-       </para></entry>
-       <entry>
-         This form of <function>json_object</function> takes keys and values pairwise from two separate
-         arrays. In all other respects it is identical to the one-argument form.
-       </entry>
-       <entry><literal>json_object('{a, b}', '{1,2}')</literal></entry>
-       <entry><literal>{"a": "1", "b": "2"}</literal></entry>
-      </row>
-     </tbody>
-    </tgroup>
-   </table>
-
-  <note>
-    <para>
-     <function>array_to_json</function> and <function>row_to_json</function> have the same
-     behavior as <function>to_json</function> except for offering a pretty-printing
-     option.  The behavior described for <function>to_json</function> likewise applies
-     to each individual value converted by the other JSON creation functions.
-    </para>
-  </note>
-
-  <note>
-    <para>
-     The <xref linkend="hstore"/> extension has a cast
-     from <type>hstore</type> to <type>json</type>, so that
-     <type>hstore</type> values converted via the JSON creation functions
-     will be represented as JSON objects, not as primitive string values.
-    </para>
-  </note>
-
-  <para>
-   <xref linkend="functions-json-processing-table"/> shows the functions that
-   are available for processing <type>json</type> and <type>jsonb</type> values.
-  </para>
-
-  <indexterm>
-   <primary>json_array_length</primary>
-  </indexterm>
-  <indexterm>
-   <primary>jsonb_array_length</primary>
-  </indexterm>
-  <indexterm>
-   <primary>json_each</primary>
-  </indexterm>
-  <indexterm>
-   <primary>jsonb_each</primary>
-  </indexterm>
-  <indexterm>
-   <primary>json_each_text</primary>
-  </indexterm>
-  <indexterm>
-   <primary>jsonb_each_text</primary>
-  </indexterm>
-  <indexterm>
-   <primary>json_extract_path</primary>
-  </indexterm>
-  <indexterm>
-   <primary>jsonb_extract_path</primary>
-  </indexterm>
-  <indexterm>
-   <primary>json_extract_path_text</primary>
-  </indexterm>
-  <indexterm>
-   <primary>jsonb_extract_path_text</primary>
+   <primary>jsonb_extract_path_text</primary>
   </indexterm>
   <indexterm>
    <primary>json_object_keys</primary>
@@ -13233,319 +12552,996 @@ table2-mapping
          </para><para><literal>{"a": [0, 1, "new_value", 2]}</literal>
         </para></entry>
        </row>
-      <row>
-       <entry><para><literal>jsonb_pretty(from_json jsonb)</literal>
-         </para></entry>
-       <entry><para><type>text</type></para></entry>
-       <entry>
-         Returns <replaceable>from_json</replaceable>
-         as indented JSON text.
-       </entry>
-       <entry><literal>jsonb_pretty('[{"f1":1,"f2":null},2,null,3]')</literal></entry>
-       <entry>
-<programlisting>
-[
-    {
-        "f1": 1,
-        "f2": null
-    },
-    2,
-    null,
-    3
-]
-</programlisting>
-        </entry>
+      <row>
+       <entry><para><literal>jsonb_pretty(from_json jsonb)</literal>
+         </para></entry>
+       <entry><para><type>text</type></para></entry>
+       <entry>
+         Returns <replaceable>from_json</replaceable>
+         as indented JSON text.
+       </entry>
+       <entry><literal>jsonb_pretty('[{"f1":1,"f2":null},2,null,3]')</literal></entry>
+       <entry>
+<programlisting>
+[
+    {
+        "f1": 1,
+        "f2": null
+    },
+    2,
+    null,
+    3
+]
+</programlisting>
+        </entry>
+       </row>
+       <row>
+        <entry>
+         <para><literal>
+           jsonb_path_exists(target jsonb, path jsonpath [, vars jsonb [, silent bool]])
+         </literal></para>
+         <para><literal>
+           jsonb_path_exists_tz(target jsonb, path jsonpath [, vars jsonb, silent bool])
+         </literal></para>
+        </entry>
+        <entry><type>boolean</type></entry>
+        <entry>
+          Checks whether JSON path returns any item for the specified JSON
+          value.
+        </entry>
+        <entry>
+         <para><literal>
+           jsonb_path_exists('{"a":[1,2,3,4,5]}', '$.a[*] ? (@ >= $min &amp;&amp; @ &lt;= $max)', '{"min":2,"max":4}')
+         </literal></para>
+        </entry>
+        <entry>
+          <para><literal>true</literal></para>
+        </entry>
+       </row>
+       <row>
+        <entry>
+         <para><literal>
+           jsonb_path_match(target jsonb, path jsonpath [, vars jsonb, silent bool])
+         </literal></para>
+         <para><literal>
+           jsonb_path_match_tz(target jsonb, path jsonpath [, vars jsonb, silent bool])
+         </literal></para>
+        </entry>
+        <entry><type>boolean</type></entry>
+        <entry>
+          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 <literal>null</literal> is returned.
+        </entry>
+        <entry>
+         <para><literal>
+           jsonb_path_match('{"a":[1,2,3,4,5]}', 'exists($.a[*] ? (@ >= $min &amp;&amp; @ &lt;= $max))', '{"min":2,"max":4}')
+        </literal></para>
+        </entry>
+        <entry>
+          <para><literal>true</literal></para>
+        </entry>
+       </row>
+       <row>
+        <entry>
+         <para><literal>
+           jsonb_path_query(target jsonb, path jsonpath [, vars jsonb, silent bool])
+         </literal></para>
+         <para><literal>
+           jsonb_path_query_tz(target jsonb, path jsonpath [, vars jsonb, silent bool])
+         </literal></para>
+        </entry>
+        <entry><type>setof jsonb</type></entry>
+        <entry>
+          Gets all JSON items returned by JSON path for the specified JSON
+          value.
+        </entry>
+        <entry>
+         <para><literal>
+           select * from jsonb_path_query('{"a":[1,2,3,4,5]}', '$.a[*] ? (@ >= $min &amp;&amp; @ &lt;= $max)', '{"min":2,"max":4}');
+         </literal></para>
+        </entry>
+        <entry>
+         <para>
+<programlisting>
+ jsonb_path_query
+------------------
+ 2
+ 3
+ 4
+</programlisting>
+         </para>
+        </entry>
+       </row>
+       <row>
+        <entry>
+         <para><literal>
+           jsonb_path_query_array(target jsonb, path jsonpath [, vars jsonb, silent bool])
+         </literal></para>
+         <para><literal>
+           jsonb_path_query_array_tz(target jsonb, path jsonpath [, vars jsonb, silent bool])
+         </literal></para>
+        </entry>
+        <entry><type>jsonb</type></entry>
+        <entry>
+          Gets all JSON items returned by JSON path for the specified JSON
+          value and wraps result into an array.
+        </entry>
+        <entry>
+         <para><literal>
+           jsonb_path_query_array('{"a":[1,2,3,4,5]}', '$.a[*] ? (@ >= $min &amp;&amp; @ &lt;= $max)', '{"min":2,"max":4}')
+         </literal></para>
+        </entry>
+        <entry>
+          <para><literal>[2, 3, 4]</literal></para>
+        </entry>
+       </row>
+       <row>
+        <entry>
+         <para><literal>
+           jsonb_path_query_first(target jsonb, path jsonpath [, vars jsonb, silent bool])
+         </literal></para>
+         <para><literal>
+           jsonb_path_query_first_tz(target jsonb, path jsonpath [, vars jsonb, silent bool])
+         </literal></para>
+        </entry>
+        <entry><type>jsonb</type></entry>
+        <entry>
+          Gets the first JSON item returned by JSON path for the specified JSON
+          value.  Returns <literal>NULL</literal> on no results.
+        </entry>
+        <entry>
+         <para><literal>
+           jsonb_path_query_first('{"a":[1,2,3,4,5]}', '$.a[*] ? (@ >= $min &amp;&amp; @ &lt;= $max)', '{"min":2,"max":4}')
+         </literal></para>
+        </entry>
+        <entry>
+          <para><literal>2</literal></para>
+        </entry>
+       </row>
+     </tbody>
+    </tgroup>
+   </table>
+
+  <note>
+    <para>
+      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 <type>jsonb</type>, because the conversion was already
+      done; but for <type>json</type> input, this may result in throwing an error,
+      as noted in <xref linkend="datatype-json"/>.
+    </para>
+  </note>
+
+  <note>
+   <para>
+    The functions
+    <function>json[b]_populate_record</function>,
+    <function>json[b]_populate_recordset</function>,
+    <function>json[b]_to_record</function> and
+    <function>json[b]_to_recordset</function>
+    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:
+    <itemizedlist spacing="compact">
+     <listitem>
+      <para>
+       A JSON null value is converted to a SQL null in all cases.
+      </para>
+     </listitem>
+     <listitem>
+      <para>
+       If the output column is of type <type>json</type>
+       or <type>jsonb</type>, the JSON value is just reproduced exactly.
+      </para>
+     </listitem>
+     <listitem>
+      <para>
+       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.
+      </para>
+     </listitem>
+     <listitem>
+      <para>
+       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.
+      </para>
+     </listitem>
+     <listitem>
+      <para>
+       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.
+      </para>
+     </listitem>
+     <listitem>
+      <para>
+       Otherwise, the ordinary text representation of the JSON value is fed
+       to the input conversion function for the column's data type.
+      </para>
+     </listitem>
+    </itemizedlist>
+   </para>
+
+   <para>
+    While the examples for these functions use constants, the typical use
+    would be to reference a table in the <literal>FROM</literal> clause
+    and use one of its <type>json</type> or <type>jsonb</type> columns
+    as an argument to the function.  Extracted key values can then be
+    referenced in other parts of the query, like <literal>WHERE</literal>
+    clauses and target lists.  Extracting multiple values in this
+    way can improve performance over extracting them separately with
+    per-key operators.
+   </para>
+  </note>
+
+  <note>
+    <para>
+      All the items of the <literal>path</literal> parameter of <literal>jsonb_set</literal>
+      as well as <literal>jsonb_insert</literal> except the last item must be present
+      in the <literal>target</literal>. If <literal>create_missing</literal> is false, all
+      items of the <literal>path</literal> parameter of <literal>jsonb_set</literal> must be
+      present. If these conditions are not met the <literal>target</literal> is
+      returned unchanged.
+    </para>
+    <para>
+      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 - <literal>-1</literal>
+      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.
+    </para>
+  </note>
+
+  <note>
+    <para>
+      The <literal>json_typeof</literal> function's <literal>null</literal> return value
+      should not be confused with a SQL NULL.  While
+      calling <literal>json_typeof('null'::json)</literal> will
+      return <literal>null</literal>, calling <literal>json_typeof(NULL::json)</literal>
+      will return a SQL NULL.
+    </para>
+  </note>
+
+  <note>
+    <para>
+      If the argument to <literal>json_strip_nulls</literal> 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 <literal>jsonb_strip_nulls</literal> since <type>jsonb</type> values never have
+      duplicate object field names.
+    </para>
+  </note>
+
+  <note>
+   <para>
+    The <literal>jsonb_path_*</literal> functions have optional
+    <literal>vars</literal> and <literal>silent</literal> arguments.
+   </para>
+   <para>
+    If the <parameter>vars</parameter> argument is specified, it provides an
+    object containing named variables to be substituted into a
+    <literal>jsonpath</literal> expression.
+   </para>
+   <para>
+    If the <parameter>silent</parameter> argument is specified and has the
+    <literal>true</literal> value, these functions suppress the same errors
+    as the <literal>@?</literal> and <literal>@@</literal> operators.
+   </para>
+  </note>
+
+  <note>
+   <para>
+    Some of the <literal>jsonb_path_*</literal> functions have the
+    <literal>_tz</literal> suffix. These functions have been implemented to
+    support comparison of date/time values that involves implicit
+    timezone-aware casts. Since operations with time zones are not immutable,
+    these functions are qualified as stable. Their counterparts without the
+    suffix do not support such casts, so they are immutable and can be used for
+    such use-cases as expression indexes
+    (see <xref linkend="indexes-expressional"/>). There is no difference
+    between these functions for other <type>jsonpath</type> operations.
+   </para>
+  </note>
+
+  <para>
+    See also <xref linkend="functions-aggregate"/> for the aggregate
+    function <function>json_agg</function> which aggregates record
+    values as JSON, and the aggregate function
+    <function>json_object_agg</function> which aggregates pairs of values
+    into a JSON object, and their <type>jsonb</type> equivalents,
+    <function>jsonb_agg</function> and <function>jsonb_object_agg</function>.
+  </para>
+ </sect2>
+
+ <sect2 id="functions-sqljson-path">
+  <title>The SQL/JSON Path Language</title>
+
+  <indexterm zone="functions-sqljson-path">
+   <primary>SQL/JSON path language</primary>
+  </indexterm>
+
+  <para>
+   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 <productname>PostgreSQL</productname>,
+   path expressions are implemented as the <type>jsonpath</type>
+   data type and can use any elements described in
+   <xref linkend="datatype-jsonpath"/>.
+  </para>
+
+  <para>JSON query functions and operators
+   pass the provided path expression to the <firstterm>path engine</firstterm>
+   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.
+  </para>
+
+  <para>
+   A path expression consists of a sequence of elements allowed
+   by the <type>jsonpath</type> 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
+   (<firstterm>SQL/JSON sequence</firstterm>) is produced,
+   and the evaluation result is returned to the JSON query function
+   that completes the specified computation.
+  </para>
+
+  <para>
+   To refer to the JSON data to be queried (the
+   <firstterm>context item</firstterm>), use the <literal>$</literal> sign
+   in the path expression. It can be followed by one or more
+   <link linkend="type-jsonpath-accessors">accessor operators</link>,
+   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.
+  </para>
+
+  <para>
+   For example, suppose you have some JSON data from a GPS tracker that you
+   would like to parse, such as:
+<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
+      } ]
+  }
+}
+</programlisting>
+  </para>
+
+  <para>
+   To retrieve the available track segments, you need to use the
+   <literal>.<replaceable>key</replaceable></literal> accessor
+   operator for all the preceding JSON objects:
+<programlisting>
+'$.track.segments'
+</programlisting>
+  </para>
+
+  <para>
+   If the item to retrieve is an element of an array, you have
+   to unnest this array using the <literal>[*]</literal> operator. For example,
+   the following path will return location coordinates for all
+   the available track segments:
+<programlisting>
+'$.track.segments[*].location'
+</programlisting>
+  </para>
+
+  <para>
+   To return the coordinates of the first segment only, you can
+   specify the corresponding subscript in the <literal>[]</literal>
+   accessor operator. Note that the SQL/JSON arrays are 0-relative:
+<programlisting>
+'$.track.segments[0].location'
+</programlisting>
+  </para>
+
+  <para>
+   The result of each path evaluation step can be processed
+   by one or more <type>jsonpath</type> operators and methods
+   listed in <xref linkend="functions-sqljson-path-operators"/>.
+   Each method name must be preceded by a dot. For example,
+   you can get an array size:
+<programlisting>
+'$.track.segments.size()'
+</programlisting>
+   For more examples of using <type>jsonpath</type> operators
+   and methods within path expressions, see
+   <xref linkend="functions-sqljson-path-operators"/>.
+  </para>
+
+  <para>
+   When defining the path, you can also use one or more
+   <firstterm>filter expressions</firstterm> that work similar to the
+   <literal>WHERE</literal> clause in SQL. A filter expression begins with
+   a question mark and provides a condition in parentheses:
+
+    <programlisting>
+? (<replaceable>condition</replaceable>)
+    </programlisting>
+  </para>
+
+  <para>
+   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 <literal>true</literal>, <literal>false</literal>,
+   or <literal>unknown</literal>. The <literal>unknown</literal> value
+   plays the same role as SQL <literal>NULL</literal> and can be tested
+   for with the <literal>is unknown</literal> predicate. Further path
+   evaluation steps use only those items for which filter expressions
+   return <literal>true</literal>.
+  </para>
+
+  <para>
+   Functions and operators that can be used in filter expressions are listed
+   in <xref linkend="functions-sqljson-filter-ex-table"/>. The path
+   evaluation result to be filtered is denoted by the <literal>@</literal>
+   variable. To refer to a JSON element stored at a lower nesting level,
+   add one or more accessor operators after <literal>@</literal>.
+  </para>
+
+  <para>
+   Suppose you would like to retrieve all heart rate values higher
+   than 130. You can achieve this using the following expression:
+<programlisting>
+'$.track.segments[*].HR ? (@ &gt; 130)'
+</programlisting>
+  </para>
+
+  <para>
+   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:
+<programlisting>
+'$.track.segments[*] ? (@.HR &gt; 130)."start time"'
+</programlisting>
+  </para>
+
+  <para>
+   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:
+<programlisting>
+'$.track.segments[*] ? (@.location[1] &lt; 13.4) ? (@.HR &gt; 130)."start time"'
+</programlisting>
+  </para>
+
+  <para>
+   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:
+<programlisting>
+'$.track.segments[*] ? (@.location[1] &lt; 13.4).HR ? (@ &gt; 130)'
+</programlisting>
+  </para>
+
+  <para>
+   You can also nest filter expressions within each other:
+<programlisting>
+'$.track ? (exists(@.segments[*] ? (@.HR &gt; 130))).segments.size()'
+</programlisting>
+   This expression returns the size of the track if it contains any
+   segments with high heart rate values, or an empty sequence otherwise.
+  </para>
+
+  <para>
+   <productname>PostgreSQL</productname>'s implementation of SQL/JSON path
+   language has the following deviations from the SQL/JSON standard:
+  </para>
+
+  <itemizedlist>
+   <listitem>
+    <para>
+     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 <literal>@@</literal> operator. For example,
+     the following <type>jsonpath</type> expression is valid in
+     <productname>PostgreSQL</productname>:
+<programlisting>
+'$.track.segments[*].HR &lt; 70'
+</programlisting>
+    </para>
+   </listitem>
+
+   <listitem>
+    <para>
+     There are minor differences in the interpretation of regular
+     expression patterns used in <literal>like_regex</literal> filters, as
+     described in <xref linkend="jsonpath-regular-expressions"/>.
+    </para>
+   </listitem>
+  </itemizedlist>
+
+   <sect3 id="strict-and-lax-modes">
+   <title>Strict and Lax Modes</title>
+    <para>
+     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:
+    </para>
+
+   <itemizedlist>
+    <listitem>
+     <para>
+      lax (default) &mdash; 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.
+     </para>
+    </listitem>
+    <listitem>
+     <para>
+      strict &mdash; if a structural error occurs, an error is raised.
+     </para>
+    </listitem>
+   </itemizedlist>
+
+   <para>
+    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:
+    <itemizedlist>
+     <listitem>
+      <para>
+       The path expression contains <literal>type()</literal> or
+       <literal>size()</literal> methods that return the type
+       and the number of elements in the array, respectively.
+      </para>
+     </listitem>
+     <listitem>
+      <para>
+       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.
+      </para>
+     </listitem>
+    </itemizedlist>
+   </para>
+
+   <para>
+    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:
+<programlisting>
+'lax $.track.segments.location'
+</programlisting>
+   </para>
+
+   <para>
+    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
+    <literal>segments</literal> array:
+<programlisting>
+'strict $.track.segments[*].location'
+</programlisting>
+   </para>
+
+   </sect3>
+
+   <sect3 id="jsonpath-regular-expressions">
+    <title>Regular Expressions</title>
+
+    <indexterm zone="jsonpath-regular-expressions">
+     <primary><literal>LIKE_REGEX</literal></primary>
+     <secondary>in SQL/JSON</secondary>
+    </indexterm>
+
+    <para>
+     SQL/JSON path expressions allow matching text to a regular expression
+     with the <literal>like_regex</literal> filter.  For example, the
+     following SQL/JSON path query would case-insensitively match all
+     strings in an array that start with an English vowel:
+<programlisting>
+'$[*] ? (@ like_regex "^[aeiou]" flag "i")'
+</programlisting>
+    </para>
+
+    <para>
+     The optional <literal>flag</literal> string may include one or more of
+     the characters
+     <literal>i</literal> for case-insensitive match,
+     <literal>m</literal> to allow <literal>^</literal>
+     and <literal>$</literal> to match at newlines,
+     <literal>s</literal> to allow <literal>.</literal> to match a newline,
+     and <literal>q</literal> to quote the whole pattern (reducing the
+     behavior to a simple substring match).
+    </para>
+
+    <para>
+     The SQL/JSON standard borrows its definition for regular expressions
+     from the <literal>LIKE_REGEX</literal> operator, which in turn uses the
+     XQuery standard.  PostgreSQL does not currently support the
+     <literal>LIKE_REGEX</literal> operator.  Therefore,
+     the <literal>like_regex</literal> filter is implemented using the
+     POSIX regular expression engine described in
+     <xref linkend="functions-posix-regexp"/>.  This leads to various minor
+     discrepancies from standard SQL/JSON behavior, which are cataloged in
+     <xref linkend="posix-vs-xquery"/>.
+     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.
+    </para>
+
+    <para>
+     Keep in mind that the pattern argument of <literal>like_regex</literal>
+     is a JSON path string literal, written according to the rules given in
+     <xref linkend="datatype-jsonpath"/>.  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:
+<programlisting>
+'$ ? (@ like_regex "^\\d+$")'
+</programlisting>
+    </para>
+
+   </sect3>
+
+   <sect3 id="functions-sqljson-path-operators">
+   <title>SQL/JSON Path Operators and Methods</title>
+
+   <para>
+    <xref linkend="functions-sqljson-op-table"/> shows the operators and
+    methods available in <type>jsonpath</type>.  <xref
+    linkend="functions-sqljson-filter-ex-table"/> shows the available filter
+    expression elements.
+   </para>
+
+   <table id="functions-sqljson-op-table">
+    <title><type>jsonpath</type> Operators and Methods</title>
+     <tgroup cols="5">
+      <thead>
+       <row>
+        <entry>Operator/Method</entry>
+        <entry>Description</entry>
+        <entry>Example JSON</entry>
+        <entry>Example Query</entry>
+        <entry>Result</entry>
+       </row>
+      </thead>
+      <tbody>
+       <row>
+        <entry><literal>+</literal> (unary)</entry>
+        <entry>Plus operator that iterates over the SQL/JSON sequence</entry>
+        <entry><literal>{"x": [2.85, -14.7, -9.4]}</literal></entry>
+        <entry><literal>+ $.x.floor()</literal></entry>
+        <entry><literal>2, -15, -10</literal></entry>
+       </row>
+       <row>
+        <entry><literal>-</literal> (unary)</entry>
+        <entry>Minus operator that iterates over the SQL/JSON sequence</entry>
+        <entry><literal>{"x": [2.85, -14.7, -9.4]}</literal></entry>
+        <entry><literal>- $.x.floor()</literal></entry>
+        <entry><literal>-2, 15, 10</literal></entry>
+       </row>
+       <row>
+        <entry><literal>+</literal> (binary)</entry>
+        <entry>Addition</entry>
+        <entry><literal>[2]</literal></entry>
+        <entry><literal>2 + $[0]</literal></entry>
+        <entry><literal>4</literal></entry>
+       </row>
+       <row>
+        <entry><literal>-</literal> (binary)</entry>
+        <entry>Subtraction</entry>
+        <entry><literal>[2]</literal></entry>
+        <entry><literal>4 - $[0]</literal></entry>
+        <entry><literal>2</literal></entry>
+       </row>
+       <row>
+        <entry><literal>*</literal></entry>
+        <entry>Multiplication</entry>
+        <entry><literal>[4]</literal></entry>
+        <entry><literal>2 * $[0]</literal></entry>
+        <entry><literal>8</literal></entry>
+       </row>
+       <row>
+        <entry><literal>/</literal></entry>
+        <entry>Division</entry>
+        <entry><literal>[8]</literal></entry>
+        <entry><literal>$[0] / 2</literal></entry>
+        <entry><literal>4</literal></entry>
+       </row>
+       <row>
+        <entry><literal>%</literal></entry>
+        <entry>Modulus</entry>
+        <entry><literal>[32]</literal></entry>
+        <entry><literal>$[0] % 10</literal></entry>
+        <entry><literal>2</literal></entry>
+       </row>
+       <row>
+        <entry><literal>type()</literal></entry>
+        <entry>Type of the SQL/JSON item</entry>
+        <entry><literal>[1, "2", {}]</literal></entry>
+        <entry><literal>$[*].type()</literal></entry>
+        <entry><literal>"number", "string", "object"</literal></entry>
+       </row>
+       <row>
+        <entry><literal>size()</literal></entry>
+        <entry>Size of the SQL/JSON item</entry>
+        <entry><literal>{"m": [11, 15]}</literal></entry>
+        <entry><literal>$.m.size()</literal></entry>
+        <entry><literal>2</literal></entry>
+       </row>
+       <row>
+        <entry><literal>double()</literal></entry>
+        <entry>Approximate floating-point number converted from an SQL/JSON number or a string</entry>
+        <entry><literal>{"len": "1.9"}</literal></entry>
+        <entry><literal>$.len.double() * 2</literal></entry>
+        <entry><literal>3.8</literal></entry>
+       </row>
+       <row>
+        <entry><literal>ceiling()</literal></entry>
+        <entry>Nearest integer greater than or equal to the SQL/JSON number</entry>
+        <entry><literal>{"h": 1.3}</literal></entry>
+        <entry><literal>$.h.ceiling()</literal></entry>
+        <entry><literal>2</literal></entry>
+       </row>
+       <row>
+        <entry><literal>floor()</literal></entry>
+        <entry>Nearest integer less than or equal to the SQL/JSON number</entry>
+        <entry><literal>{"h": 1.3}</literal></entry>
+        <entry><literal>$.h.floor()</literal></entry>
+        <entry><literal>1</literal></entry>
        </row>
        <row>
-        <entry>
-         <para><literal>
-           jsonb_path_exists(target jsonb, path jsonpath [, vars jsonb [, silent bool]])
-         </literal></para>
-         <para><literal>
-           jsonb_path_exists_tz(target jsonb, path jsonpath [, vars jsonb, silent bool])
-         </literal></para>
-        </entry>
-        <entry><type>boolean</type></entry>
-        <entry>
-          Checks whether JSON path returns any item for the specified JSON
-          value.
-        </entry>
-        <entry>
-         <para><literal>
-           jsonb_path_exists('{"a":[1,2,3,4,5]}', '$.a[*] ? (@ >= $min &amp;&amp; @ &lt;= $max)', '{"min":2,"max":4}')
-         </literal></para>
-        </entry>
-        <entry>
-          <para><literal>true</literal></para>
-        </entry>
+        <entry><literal>abs()</literal></entry>
+        <entry>Absolute value of the SQL/JSON number</entry>
+        <entry><literal>{"z": -0.3}</literal></entry>
+        <entry><literal>$.z.abs()</literal></entry>
+        <entry><literal>0.3</literal></entry>
        </row>
        <row>
-        <entry>
-         <para><literal>
-           jsonb_path_match(target jsonb, path jsonpath [, vars jsonb, silent bool])
-         </literal></para>
-         <para><literal>
-           jsonb_path_match_tz(target jsonb, path jsonpath [, vars jsonb, silent bool])
-         </literal></para>
-        </entry>
-        <entry><type>boolean</type></entry>
-        <entry>
-          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 <literal>null</literal> is returned.
-        </entry>
-        <entry>
-         <para><literal>
-           jsonb_path_match('{"a":[1,2,3,4,5]}', 'exists($.a[*] ? (@ >= $min &amp;&amp; @ &lt;= $max))', '{"min":2,"max":4}')
-        </literal></para>
-        </entry>
-        <entry>
-          <para><literal>true</literal></para>
-        </entry>
+        <entry><literal>datetime()</literal></entry>
+        <entry>Date/time value converted from a string</entry>
+        <entry><literal>["2015-8-1", "2015-08-12"]</literal></entry>
+        <entry><literal>$[*] ? (@.datetime() &lt; "2015-08-2". datetime())</literal></entry>
+        <entry><literal>2015-8-1</literal></entry>
        </row>
        <row>
+        <entry><literal>datetime(<replaceable>template</replaceable>)</literal></entry>
+        <entry>Date/time value converted from a string using the specified template</entry>
+        <entry><literal>["12:30", "18:40"]</literal></entry>
+        <entry><literal>$[*].datetime("HH24:MI")</literal></entry>
+        <entry><literal>"12:30:00", "18:40:00"</literal></entry>
+       </row>
+       <row>
+        <entry><literal>keyvalue()</literal></entry>
         <entry>
-         <para><literal>
-           jsonb_path_query(target jsonb, path jsonpath [, vars jsonb, silent bool])
-         </literal></para>
-         <para><literal>
-           jsonb_path_query_tz(target jsonb, path jsonpath [, vars jsonb, silent bool])
-         </literal></para>
-        </entry>
-        <entry><type>setof jsonb</type></entry>
-        <entry>
-          Gets all JSON items returned by JSON path for the specified JSON
-          value.
-        </entry>
-        <entry>
-         <para><literal>
-           select * from jsonb_path_query('{"a":[1,2,3,4,5]}', '$.a[*] ? (@ >= $min &amp;&amp; @ &lt;= $max)', '{"min":2,"max":4}');
-         </literal></para>
-        </entry>
-        <entry>
-         <para>
-<programlisting>
- jsonb_path_query
-------------------
- 2
- 3
- 4
-</programlisting>
-         </para>
+          Sequence of object's key-value pairs represented as array of items
+          containing three fields (<literal>"key"</literal>,
+          <literal>"value"</literal>, and <literal>"id"</literal>).
+          <literal>"id"</literal> is a unique identifier of the object
+          key-value pair belongs to.
         </entry>
+        <entry><literal>{"x": "20", "y": 32}</literal></entry>
+        <entry><literal>$.keyvalue()</literal></entry>
+        <entry><literal>{"key": "x", "value": "20", "id": 0}, {"key": "y", "value": 32, "id": 0}</literal></entry>
+       </row>
+      </tbody>
+     </tgroup>
+    </table>
+
+    <note>
+     <para>
+      The result type of <literal>datetime()</literal> and
+      <literal>datetime(<replaceable>template</replaceable>)</literal>
+      methods can be <type>date</type>, <type>timetz</type>, <type>time</type>,
+      <type>timestamptz</type>, or <type>timestamp</type>.
+      Both methods determine the result type dynamically.
+     </para>
+     <para>
+      The <literal>datetime()</literal> method sequentially tries ISO formats
+      for <type>date</type>, <type>timetz</type>, <type>time</type>,
+      <type>timestamptz</type>, and <type>timestamp</type>. It stops on
+      the first matching format and the corresponding data type.
+     </para>
+     <para>
+      The <literal>datetime(<replaceable>template</replaceable>)</literal>
+      method determines the result type by the provided template string.
+     </para>
+     <para>
+      The <literal>datetime()</literal> and
+      <literal>datetime(<replaceable>template</replaceable>)</literal> methods
+      use the same parsing rules as <literal>to_timestamp</literal> SQL
+      function does (see <xref linkend="functions-formatting"/>) with three
+      exceptions.  At first, these methods doesn't allow unmatched template
+      patterns.  At second, only following separators are allowed in the
+      template string: minus sign, period, solidus, comma, apostrophe,
+      semicolon, colon and space.  At third, separators in the template string
+      must exactly match the input string.
+     </para>
+    </note>
+
+    <table id="functions-sqljson-filter-ex-table">
+     <title><type>jsonpath</type> Filter Expression Elements</title>
+     <tgroup cols="5">
+      <thead>
+       <row>
+        <entry>Value/Predicate</entry>
+        <entry>Description</entry>
+        <entry>Example JSON</entry>
+        <entry>Example Query</entry>
+        <entry>Result</entry>
+       </row>
+      </thead>
+      <tbody>
+       <row>
+        <entry><literal>==</literal></entry>
+        <entry>Equality operator</entry>
+        <entry><literal>[1, 2, 1, 3]</literal></entry>
+        <entry><literal>$[*] ? (@ == 1)</literal></entry>
+        <entry><literal>1, 1</literal></entry>
+       </row>
+       <row>
+        <entry><literal>!=</literal></entry>
+        <entry>Non-equality operator</entry>
+        <entry><literal>[1, 2, 1, 3]</literal></entry>
+        <entry><literal>$[*] ? (@ != 1)</literal></entry>
+        <entry><literal>2, 3</literal></entry>
+       </row>
+       <row>
+        <entry><literal>&lt;&gt;</literal></entry>
+        <entry>Non-equality operator (same as <literal>!=</literal>)</entry>
+        <entry><literal>[1, 2, 1, 3]</literal></entry>
+        <entry><literal>$[*] ? (@ &lt;&gt; 1)</literal></entry>
+        <entry><literal>2, 3</literal></entry>
+       </row>
+       <row>
+        <entry><literal>&lt;</literal></entry>
+        <entry>Less-than operator</entry>
+        <entry><literal>[1, 2, 3]</literal></entry>
+        <entry><literal>$[*] ? (@ &lt; 2)</literal></entry>
+        <entry><literal>1</literal></entry>
+       </row>
+       <row>
+        <entry><literal>&lt;=</literal></entry>
+        <entry>Less-than-or-equal-to operator</entry>
+        <entry><literal>[1, 2, 3]</literal></entry>
+        <entry><literal>$[*] ? (@ &lt;= 2)</literal></entry>
+        <entry><literal>1, 2</literal></entry>
+       </row>
+       <row>
+        <entry><literal>&gt;</literal></entry>
+        <entry>Greater-than operator</entry>
+        <entry><literal>[1, 2, 3]</literal></entry>
+        <entry><literal>$[*] ? (@ &gt; 2)</literal></entry>
+        <entry><literal>3</literal></entry>
+       </row>
+       <row>
+        <entry><literal>&gt;=</literal></entry>
+        <entry>Greater-than-or-equal-to operator</entry>
+        <entry><literal>[1, 2, 3]</literal></entry>
+        <entry><literal>$[*] ? (@ &gt;= 2)</literal></entry>
+        <entry><literal>2, 3</literal></entry>
+       </row>
+       <row>
+        <entry><literal>true</literal></entry>
+        <entry>Value used to perform comparison with JSON <literal>true</literal> literal</entry>
+        <entry><literal>[{"name": "John", "parent": false},
+                           {"name": "Chris", "parent": true}]</literal></entry>
+        <entry><literal>$[*] ? (@.parent == true)</literal></entry>
+        <entry><literal>{"name": "Chris", "parent": true}</literal></entry>
+       </row>
+       <row>
+        <entry><literal>false</literal></entry>
+        <entry>Value used to perform comparison with JSON <literal>false</literal> literal</entry>
+        <entry><literal>[{"name": "John", "parent": false},
+                           {"name": "Chris", "parent": true}]</literal></entry>
+        <entry><literal>$[*] ? (@.parent == false)</literal></entry>
+        <entry><literal>{"name": "John", "parent": false}</literal></entry>
+       </row>
+       <row>
+        <entry><literal>null</literal></entry>
+        <entry>Value used to perform comparison with JSON <literal>null</literal> value</entry>
+        <entry><literal>[{"name": "Mary", "job": null},
+                         {"name": "Michael", "job": "driver"}]</literal></entry>
+        <entry><literal>$[*] ? (@.job == null) .name</literal></entry>
+        <entry><literal>"Mary"</literal></entry>
+       </row>
+       <row>
+        <entry><literal>&amp;&amp;</literal></entry>
+        <entry>Boolean AND</entry>
+        <entry><literal>[1, 3, 7]</literal></entry>
+        <entry><literal>$[*] ? (@ &gt; 1 &amp;&amp; @ &lt; 5)</literal></entry>
+        <entry><literal>3</literal></entry>
+       </row>
+       <row>
+        <entry><literal>||</literal></entry>
+        <entry>Boolean OR</entry>
+        <entry><literal>[1, 3, 7]</literal></entry>
+        <entry><literal>$[*] ? (@ &lt; 1 || @ &gt; 5)</literal></entry>
+        <entry><literal>7</literal></entry>
        </row>
        <row>
-        <entry>
-         <para><literal>
-           jsonb_path_query_array(target jsonb, path jsonpath [, vars jsonb, silent bool])
-         </literal></para>
-         <para><literal>
-           jsonb_path_query_array_tz(target jsonb, path jsonpath [, vars jsonb, silent bool])
-         </literal></para>
-        </entry>
-        <entry><type>jsonb</type></entry>
-        <entry>
-          Gets all JSON items returned by JSON path for the specified JSON
-          value and wraps result into an array.
-        </entry>
-        <entry>
-         <para><literal>
-           jsonb_path_query_array('{"a":[1,2,3,4,5]}', '$.a[*] ? (@ >= $min &amp;&amp; @ &lt;= $max)', '{"min":2,"max":4}')
-         </literal></para>
-        </entry>
-        <entry>
-          <para><literal>[2, 3, 4]</literal></para>
-        </entry>
+        <entry><literal>!</literal></entry>
+        <entry>Boolean NOT</entry>
+        <entry><literal>[1, 3, 7]</literal></entry>
+        <entry><literal>$[*] ? (!(@ &lt; 5))</literal></entry>
+        <entry><literal>7</literal></entry>
        </row>
        <row>
+        <entry><literal>like_regex</literal></entry>
         <entry>
-         <para><literal>
-           jsonb_path_query_first(target jsonb, path jsonpath [, vars jsonb, silent bool])
-         </literal></para>
-         <para><literal>
-           jsonb_path_query_first_tz(target jsonb, path jsonpath [, vars jsonb, silent bool])
-         </literal></para>
-        </entry>
-        <entry><type>jsonb</type></entry>
-        <entry>
-          Gets the first JSON item returned by JSON path for the specified JSON
-          value.  Returns <literal>NULL</literal> on no results.
-        </entry>
-        <entry>
-         <para><literal>
-           jsonb_path_query_first('{"a":[1,2,3,4,5]}', '$.a[*] ? (@ >= $min &amp;&amp; @ &lt;= $max)', '{"min":2,"max":4}')
-         </literal></para>
-        </entry>
-        <entry>
-          <para><literal>2</literal></para>
+          Tests whether the first operand matches the regular expression
+          given by the second operand, optionally with modifications
+          described by a string of <literal>flag</literal> characters (see
+          <xref linkend="jsonpath-regular-expressions"/>)
         </entry>
+        <entry><literal>["abc", "abd", "aBdC", "abdacb", "babc"]</literal></entry>
+        <entry><literal>$[*] ? (@ like_regex "^ab.*c" flag "i")</literal></entry>
+        <entry><literal>"abc", "aBdC", "abdacb"</literal></entry>
        </row>
-     </tbody>
-    </tgroup>
-   </table>
-
-  <note>
-    <para>
-      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 <type>jsonb</type>, because the conversion was already
-      done; but for <type>json</type> input, this may result in throwing an error,
-      as noted in <xref linkend="datatype-json"/>.
-    </para>
-  </note>
-
-  <note>
-   <para>
-    The functions
-    <function>json[b]_populate_record</function>,
-    <function>json[b]_populate_recordset</function>,
-    <function>json[b]_to_record</function> and
-    <function>json[b]_to_recordset</function>
-    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:
-    <itemizedlist spacing="compact">
-     <listitem>
-      <para>
-       A JSON null value is converted to a SQL null in all cases.
-      </para>
-     </listitem>
-     <listitem>
-      <para>
-       If the output column is of type <type>json</type>
-       or <type>jsonb</type>, the JSON value is just reproduced exactly.
-      </para>
-     </listitem>
-     <listitem>
-      <para>
-       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.
-      </para>
-     </listitem>
-     <listitem>
-      <para>
-       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.
-      </para>
-     </listitem>
-     <listitem>
-      <para>
-       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.
-      </para>
-     </listitem>
-     <listitem>
-      <para>
-       Otherwise, the ordinary text representation of the JSON value is fed
-       to the input conversion function for the column's data type.
-      </para>
-     </listitem>
-    </itemizedlist>
-   </para>
-
-   <para>
-    While the examples for these functions use constants, the typical use
-    would be to reference a table in the <literal>FROM</literal> clause
-    and use one of its <type>json</type> or <type>jsonb</type> columns
-    as an argument to the function.  Extracted key values can then be
-    referenced in other parts of the query, like <literal>WHERE</literal>
-    clauses and target lists.  Extracting multiple values in this
-    way can improve performance over extracting them separately with
-    per-key operators.
-   </para>
-  </note>
-
-  <note>
-    <para>
-      All the items of the <literal>path</literal> parameter of <literal>jsonb_set</literal>
-      as well as <literal>jsonb_insert</literal> except the last item must be present
-      in the <literal>target</literal>. If <literal>create_missing</literal> is false, all
-      items of the <literal>path</literal> parameter of <literal>jsonb_set</literal> must be
-      present. If these conditions are not met the <literal>target</literal> is
-      returned unchanged.
-    </para>
-    <para>
-      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 - <literal>-1</literal>
-      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.
-    </para>
-  </note>
-
-  <note>
-    <para>
-      The <literal>json_typeof</literal> function's <literal>null</literal> return value
-      should not be confused with a SQL NULL.  While
-      calling <literal>json_typeof('null'::json)</literal> will
-      return <literal>null</literal>, calling <literal>json_typeof(NULL::json)</literal>
-      will return a SQL NULL.
-    </para>
-  </note>
-
-  <note>
-    <para>
-      If the argument to <literal>json_strip_nulls</literal> 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 <literal>jsonb_strip_nulls</literal> since <type>jsonb</type> values never have
-      duplicate object field names.
-    </para>
-  </note>
-
-  <note>
-   <para>
-    The <literal>jsonb_path_*</literal> functions have optional
-    <literal>vars</literal> and <literal>silent</literal> arguments.
-   </para>
-   <para>
-    If the <parameter>vars</parameter> argument is specified, it provides an
-    object containing named variables to be substituted into a
-    <literal>jsonpath</literal> expression.
-   </para>
-   <para>
-    If the <parameter>silent</parameter> argument is specified and has the
-    <literal>true</literal> value, these functions suppress the same errors
-    as the <literal>@?</literal> and <literal>@@</literal> operators.
-   </para>
-  </note>
-
-  <note>
-   <para>
-    Some of the <literal>jsonb_path_*</literal> functions have the
-    <literal>_tz</literal> suffix. These functions have been implemented to
-    support comparison of date/time values that involves implicit
-    timezone-aware casts. Since operations with time zones are not immutable,
-    these functions are qualified as stable. Their counterparts without the
-    suffix do not support such casts, so they are immutable and can be used for
-    such use-cases as expression indexes
-    (see <xref linkend="indexes-expressional"/>). There is no difference
-    between these functions for other <type>jsonpath</type> operations.
-   </para>
-  </note>
-
-  <para>
-    See also <xref linkend="functions-aggregate"/> for the aggregate
-    function <function>json_agg</function> which aggregates record
-    values as JSON, and the aggregate function
-    <function>json_object_agg</function> which aggregates pairs of values
-    into a JSON object, and their <type>jsonb</type> equivalents,
-    <function>jsonb_agg</function> and <function>jsonb_object_agg</function>.
-  </para>
+       <row>
+        <entry><literal>starts with</literal></entry>
+        <entry>Tests whether the second operand is an initial substring of the first operand</entry>
+        <entry><literal>["John Smith", "Mary Stone", "Bob Johnson"]</literal></entry>
+        <entry><literal>$[*] ? (@ starts with "John")</literal></entry>
+        <entry><literal>"John Smith"</literal></entry>
+       </row>
+       <row>
+        <entry><literal>exists</literal></entry>
+        <entry>Tests whether a path expression matches at least one SQL/JSON item</entry>
+        <entry><literal>{"x": [1, 2], "y": [2, 4]}</literal></entry>
+        <entry><literal>strict $.* ? (exists (@ ? (@[*] > 2)))</literal></entry>
+        <entry><literal>2, 4</literal></entry>
+       </row>
+       <row>
+        <entry><literal>is unknown</literal></entry>
+        <entry>Tests whether a Boolean condition is <literal>unknown</literal></entry>
+        <entry><literal>[-1, 2, 7, "infinity"]</literal></entry>
+        <entry><literal>$[*] ? ((@ > 0) is unknown)</literal></entry>
+        <entry><literal>"infinity"</literal></entry>
+       </row>
+      </tbody>
+     </tgroup>
+    </table>
 
- </sect2>
+    <note>
+     <para>
+      When different date/time values are compared, an implicit cast is
+      applied. A <type>date</type> value can be cast to <type>timestamp</type>
+      or <type>timestamptz</type>, <type>timestamp</type> can be cast to
+      <type>timestamptz</type>, and <type>time</type> &mdash; to <type>timetz</type>.
+     </para>
+    </note>
+   </sect3>
+  </sect2>
  </sect1>
 
  <sect1 id="functions-sequence">