gooderp18绿色标准版
您最多选择25个主题 主题必须以字母或数字开头,可以包含连字符 (-),并且长度不得超过35个字符

785 行
68KB

  1. <?xml version="1.0" encoding="UTF-8" standalone="no"?>
  2. <!DOCTYPE html PUBLIC "-//W3C//DTD XHTML 1.0 Transitional//EN" "http://www.w3.org/TR/xhtml1/DTD/xhtml1-transitional.dtd"><html xmlns="http://www.w3.org/1999/xhtml"><head><meta http-equiv="Content-Type" content="text/html; charset=UTF-8" /><title>9.15. JSON Functions and Operators</title><link rel="stylesheet" type="text/css" href="stylesheet.css" /><link rev="made" href="pgsql-docs@lists.postgresql.org" /><meta name="generator" content="DocBook XSL Stylesheets V1.79.1" /><link rel="prev" href="functions-xml.html" title="9.14. XML Functions" /><link rel="next" href="functions-sequence.html" title="9.16. Sequence Manipulation Functions" /></head><body><div xmlns="http://www.w3.org/TR/xhtml1/transitional" class="navheader"><table width="100%" summary="Navigation header"><tr><th colspan="5" align="center">9.15. JSON Functions and Operators</th></tr><tr><td width="10%" align="left"><a accesskey="p" href="functions-xml.html" title="9.14. XML Functions">Prev</a> </td><td width="10%" align="left"><a accesskey="u" href="functions.html" title="Chapter 9. Functions and Operators">Up</a></td><th width="60%" align="center">Chapter 9. Functions and Operators</th><td width="10%" align="right"><a accesskey="h" href="index.html" title="PostgreSQL 12.4 Documentation">Home</a></td><td width="10%" align="right"> <a accesskey="n" href="functions-sequence.html" title="9.16. Sequence Manipulation Functions">Next</a></td></tr></table><hr></hr></div><div class="sect1" id="FUNCTIONS-JSON"><div class="titlepage"><div><div><h2 class="title" style="clear: both">9.15. JSON Functions and Operators</h2></div></div></div><div class="toc"><dl class="toc"><dt><span class="sect2"><a href="functions-json.html#FUNCTIONS-JSON-PROCESSING">9.15.1. Processing and Creating JSON Data</a></span></dt><dt><span class="sect2"><a href="functions-json.html#FUNCTIONS-SQLJSON-PATH">9.15.2. The SQL/JSON Path Language</a></span></dt></dl></div><a id="id-1.5.8.20.2" class="indexterm"></a><p>
  3. This section describes:
  4. </p><div class="itemizedlist"><ul class="itemizedlist" style="list-style-type: disc; "><li class="listitem"><p>
  5. functions and operators for processing and creating JSON data
  6. </p></li><li class="listitem"><p>
  7. the SQL/JSON path language
  8. </p></li></ul></div><p>
  9. </p><p>
  10. To learn more about the SQL/JSON standard, see
  11. <a class="xref" href="biblio.html#SQLTR-19075-6" title="SQL Technical Report">[sqltr-19075-6]</a>. For details on JSON types
  12. supported in <span class="productname">PostgreSQL</span>,
  13. see <a class="xref" href="datatype-json.html" title="8.14. JSON Types">Section 8.14</a>.
  14. </p><div class="sect2" id="FUNCTIONS-JSON-PROCESSING"><div class="titlepage"><div><div><h3 class="title">9.15.1. Processing and Creating JSON Data</h3></div></div></div><p>
  15. <a class="xref" href="functions-json.html#FUNCTIONS-JSON-OP-TABLE" title="Table 9.44. json and jsonb Operators">Table 9.44</a> shows the operators that
  16. are available for use with JSON data types (see <a class="xref" href="datatype-json.html" title="8.14. JSON Types">Section 8.14</a>).
  17. </p><div class="table" id="FUNCTIONS-JSON-OP-TABLE"><p class="title"><strong>Table 9.44. <code class="type">json</code> and <code class="type">jsonb</code> Operators</strong></p><div class="table-contents"><table class="table" summary="json and jsonb Operators" border="1"><colgroup><col /><col /><col /><col /><col /><col /></colgroup><thead><tr><th>Operator</th><th>Right Operand Type</th><th>Return type</th><th>Description</th><th>Example</th><th>Example Result</th></tr></thead><tbody><tr><td><code class="literal">-&gt;</code></td><td><code class="type">int</code></td><td><code class="type">json</code> or <code class="type">jsonb</code></td><td>Get JSON array element (indexed from zero, negative
  18. integers count from the end)</td><td><code class="literal">'[{"a":"foo"},{"b":"bar"},{"c":"baz"}]'::json-&gt;2</code></td><td><code class="literal">{"c":"baz"}</code></td></tr><tr><td><code class="literal">-&gt;</code></td><td><code class="type">text</code></td><td><code class="type">json</code> or <code class="type">jsonb</code></td><td>Get JSON object field by key</td><td><code class="literal">'{"a": {"b":"foo"}}'::json-&gt;'a'</code></td><td><code class="literal">{"b":"foo"}</code></td></tr><tr><td><code class="literal">-&gt;&gt;</code></td><td><code class="type">int</code></td><td><code class="type">text</code></td><td>Get JSON array element as <code class="type">text</code></td><td><code class="literal">'[1,2,3]'::json-&gt;&gt;2</code></td><td><code class="literal">3</code></td></tr><tr><td><code class="literal">-&gt;&gt;</code></td><td><code class="type">text</code></td><td><code class="type">text</code></td><td>Get JSON object field as <code class="type">text</code></td><td><code class="literal">'{"a":1,"b":2}'::json-&gt;&gt;'b'</code></td><td><code class="literal">2</code></td></tr><tr><td><code class="literal">#&gt;</code></td><td><code class="type">text[]</code></td><td><code class="type">json</code> or <code class="type">jsonb</code></td><td>Get JSON object at the specified path</td><td><code class="literal">'{"a": {"b":{"c": "foo"}}}'::json#&gt;'{a,b}'</code></td><td><code class="literal">{"c": "foo"}</code></td></tr><tr><td><code class="literal">#&gt;&gt;</code></td><td><code class="type">text[]</code></td><td><code class="type">text</code></td><td>Get JSON object at the specified path as <code class="type">text</code></td><td><code class="literal">'{"a":[1,2,3],"b":[4,5,6]}'::json#&gt;&gt;'{a,2}'</code></td><td><code class="literal">3</code></td></tr></tbody></table></div></div><br class="table-break" /><div class="note"><h3 class="title">Note</h3><p>
  19. There are parallel variants of these operators for both the
  20. <code class="type">json</code> and <code class="type">jsonb</code> types.
  21. The field/element/path extraction operators
  22. return the same type as their left-hand input (either <code class="type">json</code>
  23. or <code class="type">jsonb</code>), except for those specified as
  24. returning <code class="type">text</code>, which coerce the value to text.
  25. The field/element/path extraction operators return NULL, rather than
  26. failing, if the JSON input does not have the right structure to match
  27. the request; for example if no such element exists. The
  28. field/element/path extraction operators that accept integer JSON
  29. array subscripts all support negative subscripting from the end of
  30. arrays.
  31. </p></div><p>
  32. The standard comparison operators shown in <a class="xref" href="functions-comparison.html#FUNCTIONS-COMPARISON-OP-TABLE" title="Table 9.1. Comparison Operators">Table 9.1</a> are available for
  33. <code class="type">jsonb</code>, but not for <code class="type">json</code>. They follow the
  34. ordering rules for B-tree operations outlined at <a class="xref" href="datatype-json.html#JSON-INDEXING" title="8.14.4. jsonb Indexing">Section 8.14.4</a>.
  35. </p><p>
  36. Some further operators also exist only for <code class="type">jsonb</code>, as shown
  37. in <a class="xref" href="functions-json.html#FUNCTIONS-JSONB-OP-TABLE" title="Table 9.45. Additional jsonb Operators">Table 9.45</a>.
  38. Many of these operators can be indexed by
  39. <code class="type">jsonb</code> operator classes. For a full description of
  40. <code class="type">jsonb</code> containment and existence semantics, see <a class="xref" href="datatype-json.html#JSON-CONTAINMENT" title="8.14.3. jsonb Containment and Existence">Section 8.14.3</a>. <a class="xref" href="datatype-json.html#JSON-INDEXING" title="8.14.4. jsonb Indexing">Section 8.14.4</a>
  41. describes how these operators can be used to effectively index
  42. <code class="type">jsonb</code> data.
  43. </p><div class="table" id="FUNCTIONS-JSONB-OP-TABLE"><p class="title"><strong>Table 9.45. Additional <code class="type">jsonb</code> Operators</strong></p><div class="table-contents"><table class="table" summary="Additional jsonb Operators" border="1"><colgroup><col /><col /><col /><col /></colgroup><thead><tr><th>Operator</th><th>Right Operand Type</th><th>Description</th><th>Example</th></tr></thead><tbody><tr><td><code class="literal">@&gt;</code></td><td><code class="type">jsonb</code></td><td>Does the left JSON value contain the right JSON
  44. path/value entries at the top level?</td><td><code class="literal">'{"a":1, "b":2}'::jsonb @&gt; '{"b":2}'::jsonb</code></td></tr><tr><td><code class="literal">&lt;@</code></td><td><code class="type">jsonb</code></td><td>Are the left JSON path/value entries contained at the top level within
  45. the right JSON value?</td><td><code class="literal">'{"b":2}'::jsonb &lt;@ '{"a":1, "b":2}'::jsonb</code></td></tr><tr><td><code class="literal">?</code></td><td><code class="type">text</code></td><td>Does the <span class="emphasis"><em>string</em></span> exist as a top-level
  46. key within the JSON value?</td><td><code class="literal">'{"a":1, "b":2}'::jsonb ? 'b'</code></td></tr><tr><td><code class="literal">?|</code></td><td><code class="type">text[]</code></td><td>Do any of these array <span class="emphasis"><em>strings</em></span>
  47. exist as top-level keys?</td><td><code class="literal">'{"a":1, "b":2, "c":3}'::jsonb ?| array['b', 'c']</code></td></tr><tr><td><code class="literal">?&amp;</code></td><td><code class="type">text[]</code></td><td>Do all of these array <span class="emphasis"><em>strings</em></span> exist
  48. as top-level keys?</td><td><code class="literal">'["a", "b"]'::jsonb ?&amp; array['a', 'b']</code></td></tr><tr><td><code class="literal">||</code></td><td><code class="type">jsonb</code></td><td>Concatenate two <code class="type">jsonb</code> values into a new <code class="type">jsonb</code> value</td><td><code class="literal">'["a", "b"]'::jsonb || '["c", "d"]'::jsonb</code></td></tr><tr><td><code class="literal">-</code></td><td><code class="type">text</code></td><td>Delete key/value pair or <span class="emphasis"><em>string</em></span>
  49. element from left operand. Key/value pairs are matched based
  50. on their key value.</td><td><code class="literal">'{"a": "b"}'::jsonb - 'a' </code></td></tr><tr><td><code class="literal">-</code></td><td><code class="type">text[]</code></td><td>Delete multiple key/value pairs or <span class="emphasis"><em>string</em></span>
  51. elements from left operand. Key/value pairs are matched based
  52. on their key value.</td><td><code class="literal">'{"a": "b", "c": "d"}'::jsonb - '{a,c}'::text[] </code></td></tr><tr><td><code class="literal">-</code></td><td><code class="type">integer</code></td><td>Delete the array element with specified index (Negative
  53. integers count from the end). Throws an error if top level
  54. container is not an array.</td><td><code class="literal">'["a", "b"]'::jsonb - 1 </code></td></tr><tr><td><code class="literal">#-</code></td><td><code class="type">text[]</code></td><td>Delete the field or element with specified path (for
  55. JSON arrays, negative integers count from the end)</td><td><code class="literal">'["a", {"b":1}]'::jsonb #- '{1,b}'</code></td></tr><tr><td><code class="literal">@?</code></td><td><code class="type">jsonpath</code></td><td>Does JSON path return any item for the specified JSON value?</td><td><code class="literal">'{"a":[1,2,3,4,5]}'::jsonb @? '$.a[*] ? (@ &gt; 2)'</code></td></tr><tr><td><code class="literal">@@</code></td><td><code class="type">jsonpath</code></td><td>Returns the result of JSON path predicate check for the specified JSON value.
  56. Only the first item of the result is taken into account. If the
  57. result is not Boolean, then <code class="literal">null</code> is returned.</td><td><code class="literal">'{"a":[1,2,3,4,5]}'::jsonb @@ '$.a[*] &gt; 2'</code></td></tr></tbody></table></div></div><br class="table-break" /><div class="note"><h3 class="title">Note</h3><p>
  58. The <code class="literal">||</code> operator concatenates the elements at the top level of
  59. each of its operands. It does not operate recursively. For example, if
  60. both operands are objects with a common key field name, the value of the
  61. field in the result will just be the value from the right hand operand.
  62. </p></div><div class="note"><h3 class="title">Note</h3><p>
  63. The <code class="literal">@?</code> and <code class="literal">@@</code> operators suppress
  64. the following errors: lacking object field or array element, unexpected
  65. JSON item type, and numeric errors.
  66. This behavior might be helpful while searching over JSON document
  67. collections of varying structure.
  68. </p></div><p>
  69. <a class="xref" href="functions-json.html#FUNCTIONS-JSON-CREATION-TABLE" title="Table 9.46. JSON Creation Functions">Table 9.46</a> shows the functions that are
  70. available for creating <code class="type">json</code> and <code class="type">jsonb</code> values.
  71. (There are no equivalent functions for <code class="type">jsonb</code>, of the <code class="literal">row_to_json</code>
  72. and <code class="literal">array_to_json</code> functions. However, the <code class="literal">to_jsonb</code>
  73. function supplies much the same functionality as these functions would.)
  74. </p><a id="id-1.5.8.20.5.11" class="indexterm"></a><a id="id-1.5.8.20.5.12" class="indexterm"></a><a id="id-1.5.8.20.5.13" class="indexterm"></a><a id="id-1.5.8.20.5.14" class="indexterm"></a><a id="id-1.5.8.20.5.15" class="indexterm"></a><a id="id-1.5.8.20.5.16" class="indexterm"></a><a id="id-1.5.8.20.5.17" class="indexterm"></a><a id="id-1.5.8.20.5.18" class="indexterm"></a><a id="id-1.5.8.20.5.19" class="indexterm"></a><a id="id-1.5.8.20.5.20" class="indexterm"></a><div class="table" id="FUNCTIONS-JSON-CREATION-TABLE"><p class="title"><strong>Table 9.46. JSON Creation Functions</strong></p><div class="table-contents"><table class="table" summary="JSON Creation Functions" border="1"><colgroup><col /><col /><col /><col /></colgroup><thead><tr><th>Function</th><th>Description</th><th>Example</th><th>Example Result</th></tr></thead><tbody><tr><td><p><code class="literal">to_json(anyelement)</code>
  75. </p><p><code class="literal">to_jsonb(anyelement)</code>
  76. </p></td><td>
  77. Returns the value as <code class="type">json</code> or <code class="type">jsonb</code>.
  78. Arrays and composites are converted
  79. (recursively) to arrays and objects; otherwise, if there is a cast
  80. from the type to <code class="type">json</code>, the cast function will be used to
  81. perform the conversion; otherwise, a scalar value is produced.
  82. For any scalar type other than a number, a Boolean, or a null value,
  83. the text representation will be used, in such a fashion that it is a
  84. valid <code class="type">json</code> or <code class="type">jsonb</code> value.
  85. </td><td><code class="literal">to_json('Fred said "Hi."'::text)</code></td><td><code class="literal">"Fred said \"Hi.\""</code></td></tr><tr><td>
  86. <code class="literal">array_to_json(anyarray [, pretty_bool])</code>
  87. </td><td>
  88. Returns the array as a JSON array. A PostgreSQL multidimensional array
  89. becomes a JSON array of arrays. Line feeds will be added between
  90. dimension-1 elements if <em class="parameter"><code>pretty_bool</code></em> is true.
  91. </td><td><code class="literal">array_to_json('{{1,5},{99,100}}'::int[])</code></td><td><code class="literal">[[1,5],[99,100]]</code></td></tr><tr><td>
  92. <code class="literal">row_to_json(record [, pretty_bool])</code>
  93. </td><td>
  94. Returns the row as a JSON object. Line feeds will be added between
  95. level-1 elements if <em class="parameter"><code>pretty_bool</code></em> is true.
  96. </td><td><code class="literal">row_to_json(row(1,'foo'))</code></td><td><code class="literal">{"f1":1,"f2":"foo"}</code></td></tr><tr><td><p><code class="literal">json_build_array(VARIADIC "any")</code>
  97. </p><p><code class="literal">jsonb_build_array(VARIADIC "any")</code>
  98. </p></td><td>
  99. Builds a possibly-heterogeneously-typed JSON array out of a variadic
  100. argument list.
  101. </td><td><code class="literal">json_build_array(1,2,'3',4,5)</code></td><td><code class="literal">[1, 2, "3", 4, 5]</code></td></tr><tr><td><p><code class="literal">json_build_object(VARIADIC "any")</code>
  102. </p><p><code class="literal">jsonb_build_object(VARIADIC "any")</code>
  103. </p></td><td>
  104. Builds a JSON object out of a variadic argument list. By
  105. convention, the argument list consists of alternating
  106. keys and values.
  107. </td><td><code class="literal">json_build_object('foo',1,'bar',2)</code></td><td><code class="literal">{"foo": 1, "bar": 2}</code></td></tr><tr><td><p><code class="literal">json_object(text[])</code>
  108. </p><p><code class="literal">jsonb_object(text[])</code>
  109. </p></td><td>
  110. Builds a JSON object out of a text array. The array must have either
  111. exactly one dimension with an even number of members, in which case
  112. they are taken as alternating key/value pairs, or two dimensions
  113. such that each inner array has exactly two elements, which
  114. are taken as a key/value pair.
  115. </td><td><p><code class="literal">json_object('{a, 1, b, "def", c, 3.5}')</code></p>
  116. <p><code class="literal">json_object('{{a, 1},{b, "def"},{c, 3.5}}')</code></p></td><td><code class="literal">{"a": "1", "b": "def", "c": "3.5"}</code></td></tr><tr><td><p><code class="literal">json_object(keys text[], values text[])</code>
  117. </p><p><code class="literal">jsonb_object(keys text[], values text[])</code>
  118. </p></td><td>
  119. This form of <code class="function">json_object</code> takes keys and values pairwise from two separate
  120. arrays. In all other respects it is identical to the one-argument form.
  121. </td><td><code class="literal">json_object('{a, b}', '{1,2}')</code></td><td><code class="literal">{"a": "1", "b": "2"}</code></td></tr></tbody></table></div></div><br class="table-break" /><div class="note"><h3 class="title">Note</h3><p>
  122. <code class="function">array_to_json</code> and <code class="function">row_to_json</code> have the same
  123. behavior as <code class="function">to_json</code> except for offering a pretty-printing
  124. option. The behavior described for <code class="function">to_json</code> likewise applies
  125. to each individual value converted by the other JSON creation functions.
  126. </p></div><div class="note"><h3 class="title">Note</h3><p>
  127. The <a class="xref" href="hstore.html" title="F.16. hstore">hstore</a> extension has a cast
  128. from <code class="type">hstore</code> to <code class="type">json</code>, so that
  129. <code class="type">hstore</code> values converted via the JSON creation functions
  130. will be represented as JSON objects, not as primitive string values.
  131. </p></div><p>
  132. <a class="xref" href="functions-json.html#FUNCTIONS-JSON-PROCESSING-TABLE" title="Table 9.47. JSON Processing Functions">Table 9.47</a> shows the functions that
  133. are available for processing <code class="type">json</code> and <code class="type">jsonb</code> values.
  134. </p><a id="id-1.5.8.20.5.25" class="indexterm"></a><a id="id-1.5.8.20.5.26" class="indexterm"></a><a id="id-1.5.8.20.5.27" class="indexterm"></a><a id="id-1.5.8.20.5.28" class="indexterm"></a><a id="id-1.5.8.20.5.29" class="indexterm"></a><a id="id-1.5.8.20.5.30" class="indexterm"></a><a id="id-1.5.8.20.5.31" class="indexterm"></a><a id="id-1.5.8.20.5.32" class="indexterm"></a><a id="id-1.5.8.20.5.33" class="indexterm"></a><a id="id-1.5.8.20.5.34" class="indexterm"></a><a id="id-1.5.8.20.5.35" class="indexterm"></a><a id="id-1.5.8.20.5.36" class="indexterm"></a><a id="id-1.5.8.20.5.37" class="indexterm"></a><a id="id-1.5.8.20.5.38" class="indexterm"></a><a id="id-1.5.8.20.5.39" class="indexterm"></a><a id="id-1.5.8.20.5.40" class="indexterm"></a><a id="id-1.5.8.20.5.41" class="indexterm"></a><a id="id-1.5.8.20.5.42" class="indexterm"></a><a id="id-1.5.8.20.5.43" class="indexterm"></a><a id="id-1.5.8.20.5.44" class="indexterm"></a><a id="id-1.5.8.20.5.45" class="indexterm"></a><a id="id-1.5.8.20.5.46" class="indexterm"></a><a id="id-1.5.8.20.5.47" class="indexterm"></a><a id="id-1.5.8.20.5.48" class="indexterm"></a><a id="id-1.5.8.20.5.49" class="indexterm"></a><a id="id-1.5.8.20.5.50" class="indexterm"></a><a id="id-1.5.8.20.5.51" class="indexterm"></a><a id="id-1.5.8.20.5.52" class="indexterm"></a><a id="id-1.5.8.20.5.53" class="indexterm"></a><a id="id-1.5.8.20.5.54" class="indexterm"></a><a id="id-1.5.8.20.5.55" class="indexterm"></a><a id="id-1.5.8.20.5.56" class="indexterm"></a><a id="id-1.5.8.20.5.57" class="indexterm"></a><a id="id-1.5.8.20.5.58" class="indexterm"></a><a id="id-1.5.8.20.5.59" class="indexterm"></a><a id="id-1.5.8.20.5.60" class="indexterm"></a><div class="table" id="FUNCTIONS-JSON-PROCESSING-TABLE"><p class="title"><strong>Table 9.47. JSON Processing Functions</strong></p><div class="table-contents"><table class="table" summary="JSON Processing Functions" border="1"><colgroup><col /><col /><col /><col /><col /></colgroup><thead><tr><th>Function</th><th>Return Type</th><th>Description</th><th>Example</th><th>Example Result</th></tr></thead><tbody><tr><td><p><code class="literal">json_array_length(json)</code>
  135. </p><p><code class="literal">jsonb_array_length(jsonb)</code>
  136. </p></td><td><code class="type">int</code></td><td>
  137. Returns the number of elements in the outermost JSON array.
  138. </td><td><code class="literal">json_array_length('[1,2,3,{"f1":1,"f2":[5,6]},4]')</code></td><td><code class="literal">5</code></td></tr><tr><td><p><code class="literal">json_each(json)</code>
  139. </p><p><code class="literal">jsonb_each(jsonb)</code>
  140. </p></td><td><p><code class="literal">setof key text, value json</code>
  141. </p><p><code class="literal">setof key text, value jsonb</code>
  142. </p></td><td>
  143. Expands the outermost JSON object into a set of key/value pairs.
  144. </td><td><code class="literal">select * from json_each('{"a":"foo", "b":"bar"}')</code></td><td>
  145. <pre class="programlisting">
  146. key | value
  147. -----+-------
  148. a | "foo"
  149. b | "bar"
  150. </pre>
  151. </td></tr><tr><td><p><code class="literal">json_each_text(json)</code>
  152. </p><p><code class="literal">jsonb_each_text(jsonb)</code>
  153. </p></td><td><code class="type">setof key text, value text</code></td><td>
  154. Expands the outermost JSON object into a set of key/value pairs. The
  155. returned values will be of type <code class="type">text</code>.
  156. </td><td><code class="literal">select * from json_each_text('{"a":"foo", "b":"bar"}')</code></td><td>
  157. <pre class="programlisting">
  158. key | value
  159. -----+-------
  160. a | foo
  161. b | bar
  162. </pre>
  163. </td></tr><tr><td><p><code class="literal">json_extract_path(from_json json, VARIADIC path_elems text[])</code>
  164. </p><p><code class="literal">jsonb_extract_path(from_json jsonb, VARIADIC path_elems text[])</code>
  165. </p></td><td><p><code class="type">json</code></p><p><code class="type">jsonb</code>
  166. </p></td><td>
  167. Returns JSON value pointed to by <em class="replaceable"><code>path_elems</code></em>
  168. (equivalent to <code class="literal">#&gt;</code> operator).
  169. </td><td><code class="literal">json_extract_path('{"f2":{"f3":1},"f4":{"f5":99,"f6":"foo"}}','f4')</code></td><td><code class="literal">{"f5":99,"f6":"foo"}</code></td></tr><tr><td><p><code class="literal">json_extract_path_text(from_json json, VARIADIC path_elems text[])</code>
  170. </p><p><code class="literal">jsonb_extract_path_text(from_json jsonb, VARIADIC path_elems text[])</code>
  171. </p></td><td><code class="type">text</code></td><td>
  172. Returns JSON value pointed to by <em class="replaceable"><code>path_elems</code></em>
  173. as <code class="type">text</code>
  174. (equivalent to <code class="literal">#&gt;&gt;</code> operator).
  175. </td><td><code class="literal">json_extract_path_text('{"f2":{"f3":1},"f4":{"f5":99,"f6":"foo"}}','f4', 'f6')</code></td><td><code class="literal">foo</code></td></tr><tr><td><p><code class="literal">json_object_keys(json)</code>
  176. </p><p><code class="literal">jsonb_object_keys(jsonb)</code>
  177. </p></td><td><code class="type">setof text</code></td><td>
  178. Returns set of keys in the outermost JSON object.
  179. </td><td><code class="literal">json_object_keys('{"f1":"abc","f2":{"f3":"a", "f4":"b"}}')</code></td><td>
  180. <pre class="programlisting">
  181. json_object_keys
  182. ------------------
  183. f1
  184. f2
  185. </pre>
  186. </td></tr><tr><td><p><code class="literal">json_populate_record(base anyelement, from_json json)</code>
  187. </p><p><code class="literal">jsonb_populate_record(base anyelement, from_json jsonb)</code>
  188. </p></td><td><code class="type">anyelement</code></td><td>
  189. Expands the object in <em class="replaceable"><code>from_json</code></em> to a row
  190. whose columns match the record type defined by <em class="replaceable"><code>base</code></em>
  191. (see note below).
  192. </td><td><code class="literal">select * from json_populate_record(null::myrowtype, '{"a": 1, "b": ["2", "a b"], "c": {"d": 4, "e": "a b c"}}')</code></td><td>
  193. <pre class="programlisting">
  194. a | b | c
  195. ---+-----------+-------------
  196. 1 | {2,"a b"} | (4,"a b c")
  197. </pre>
  198. </td></tr><tr><td><p><code class="literal">json_populate_recordset(base anyelement, from_json json)</code>
  199. </p><p><code class="literal">jsonb_populate_recordset(base anyelement, from_json jsonb)</code>
  200. </p></td><td><code class="type">setof anyelement</code></td><td>
  201. Expands the outermost array of objects
  202. in <em class="replaceable"><code>from_json</code></em> to a set of rows whose
  203. columns match the record type defined by <em class="replaceable"><code>base</code></em> (see
  204. note below).
  205. </td><td><code class="literal">select * from json_populate_recordset(null::myrowtype, '[{"a":1,"b":2},{"a":3,"b":4}]')</code></td><td>
  206. <pre class="programlisting">
  207. a | b
  208. ---+---
  209. 1 | 2
  210. 3 | 4
  211. </pre>
  212. </td></tr><tr><td><p><code class="literal">json_array_elements(json)</code>
  213. </p><p><code class="literal">jsonb_array_elements(jsonb)</code>
  214. </p></td><td><p><code class="type">setof json</code>
  215. </p><p><code class="type">setof jsonb</code>
  216. </p></td><td>
  217. Expands a JSON array to a set of JSON values.
  218. </td><td><code class="literal">select * from json_array_elements('[1,true, [2,false]]')</code></td><td>
  219. <pre class="programlisting">
  220. value
  221. -----------
  222. 1
  223. true
  224. [2,false]
  225. </pre>
  226. </td></tr><tr><td><p><code class="literal">json_array_elements_text(json)</code>
  227. </p><p><code class="literal">jsonb_array_elements_text(jsonb)</code>
  228. </p></td><td><code class="type">setof text</code></td><td>
  229. Expands a JSON array to a set of <code class="type">text</code> values.
  230. </td><td><code class="literal">select * from json_array_elements_text('["foo", "bar"]')</code></td><td>
  231. <pre class="programlisting">
  232. value
  233. -----------
  234. foo
  235. bar
  236. </pre>
  237. </td></tr><tr><td><p><code class="literal">json_typeof(json)</code>
  238. </p><p><code class="literal">jsonb_typeof(jsonb)</code>
  239. </p></td><td><code class="type">text</code></td><td>
  240. Returns the type of the outermost JSON value as a text string.
  241. Possible types are
  242. <code class="literal">object</code>, <code class="literal">array</code>, <code class="literal">string</code>, <code class="literal">number</code>,
  243. <code class="literal">boolean</code>, and <code class="literal">null</code>.
  244. </td><td><code class="literal">json_typeof('-123.4')</code></td><td><code class="literal">number</code></td></tr><tr><td><p><code class="literal">json_to_record(json)</code>
  245. </p><p><code class="literal">jsonb_to_record(jsonb)</code>
  246. </p></td><td><code class="type">record</code></td><td>
  247. Builds an arbitrary record from a JSON object (see note below). As
  248. with all functions returning <code class="type">record</code>, the caller must
  249. explicitly define the structure of the record with an <code class="literal">AS</code>
  250. clause.
  251. </td><td><code class="literal">select * from json_to_record('{"a":1,"b":[1,2,3],"c":[1,2,3],"e":"bar","r": {"a": 123, "b": "a b c"}}') as x(a int, b text, c int[], d text, r myrowtype) </code></td><td>
  252. <pre class="programlisting">
  253. a | b | c | d | r
  254. ---+---------+---------+---+---------------
  255. 1 | [1,2,3] | {1,2,3} | | (123,"a b c")
  256. </pre>
  257. </td></tr><tr><td><p><code class="literal">json_to_recordset(json)</code>
  258. </p><p><code class="literal">jsonb_to_recordset(jsonb)</code>
  259. </p></td><td><code class="type">setof record</code></td><td>
  260. Builds an arbitrary set of records from a JSON array of objects (see
  261. note below). As with all functions returning <code class="type">record</code>, the
  262. caller must explicitly define the structure of the record with
  263. an <code class="literal">AS</code> clause.
  264. </td><td><code class="literal">select * from json_to_recordset('[{"a":1,"b":"foo"},{"a":"2","c":"bar"}]') as x(a int, b text);</code></td><td>
  265. <pre class="programlisting">
  266. a | b
  267. ---+-----
  268. 1 | foo
  269. 2 |
  270. </pre>
  271. </td></tr><tr><td><p><code class="literal">json_strip_nulls(from_json json)</code>
  272. </p><p><code class="literal">jsonb_strip_nulls(from_json jsonb)</code>
  273. </p></td><td><p><code class="type">json</code></p><p><code class="type">jsonb</code></p></td><td>
  274. Returns <em class="replaceable"><code>from_json</code></em>
  275. with all object fields that have null values omitted. Other null values
  276. are untouched.
  277. </td><td><code class="literal">json_strip_nulls('[{"f1":1,"f2":null},2,null,3]')</code></td><td><code class="literal">[{"f1":1},2,null,3]</code></td></tr><tr><td><p><code class="literal">jsonb_set(target jsonb, path text[], new_value jsonb [<span class="optional">, create_missing boolean</span>])</code>
  278. </p></td><td><p><code class="type">jsonb</code></p></td><td>
  279. Returns <em class="replaceable"><code>target</code></em>
  280. with the section designated by <em class="replaceable"><code>path</code></em>
  281. replaced by <em class="replaceable"><code>new_value</code></em>, or with
  282. <em class="replaceable"><code>new_value</code></em> added if
  283. <em class="replaceable"><code>create_missing</code></em> is true (default is
  284. <code class="literal">true</code>) and the item
  285. designated by <em class="replaceable"><code>path</code></em> does not exist.
  286. As with the path oriented operators, negative integers that
  287. appear in <em class="replaceable"><code>path</code></em> count from the end
  288. of JSON arrays.
  289. </td><td><p><code class="literal">jsonb_set('[{"f1":1,"f2":null},2,null,3]', '{0,f1}','[2,3,4]', false)</code>
  290. </p><p><code class="literal">jsonb_set('[{"f1":1,"f2":null},2]', '{0,f3}','[2,3,4]')</code>
  291. </p></td><td><p><code class="literal">[{"f1":[2,3,4],"f2":null},2,null,3]</code>
  292. </p><p><code class="literal">[{"f1": 1, "f2": null, "f3": [2, 3, 4]}, 2]</code>
  293. </p></td></tr><tr><td>
  294. <p><code class="literal">
  295. jsonb_insert(target jsonb, path text[], new_value jsonb [<span class="optional">, insert_after boolean</span>])
  296. </code></p>
  297. </td><td><p><code class="type">jsonb</code></p></td><td>
  298. Returns <em class="replaceable"><code>target</code></em> with
  299. <em class="replaceable"><code>new_value</code></em> inserted. If
  300. <em class="replaceable"><code>target</code></em> section designated by
  301. <em class="replaceable"><code>path</code></em> is in a JSONB array,
  302. <em class="replaceable"><code>new_value</code></em> will be inserted before target or
  303. after if <em class="replaceable"><code>insert_after</code></em> is true (default is
  304. <code class="literal">false</code>). If <em class="replaceable"><code>target</code></em> section
  305. designated by <em class="replaceable"><code>path</code></em> is in JSONB object,
  306. <em class="replaceable"><code>new_value</code></em> will be inserted only if
  307. <em class="replaceable"><code>target</code></em> does not exist. As with the path
  308. oriented operators, negative integers that appear in
  309. <em class="replaceable"><code>path</code></em> count from the end of JSON arrays.
  310. </td><td>
  311. <p><code class="literal">
  312. jsonb_insert('{"a": [0,1,2]}', '{a, 1}', '"new_value"')
  313. </code></p>
  314. <p><code class="literal">
  315. jsonb_insert('{"a": [0,1,2]}', '{a, 1}', '"new_value"', true)
  316. </code></p>
  317. </td><td><p><code class="literal">{"a": [0, "new_value", 1, 2]}</code>
  318. </p><p><code class="literal">{"a": [0, 1, "new_value", 2]}</code>
  319. </p></td></tr><tr><td><p><code class="literal">jsonb_pretty(from_json jsonb)</code>
  320. </p></td><td><p><code class="type">text</code></p></td><td>
  321. Returns <em class="replaceable"><code>from_json</code></em>
  322. as indented JSON text.
  323. </td><td><code class="literal">jsonb_pretty('[{"f1":1,"f2":null},2,null,3]')</code></td><td>
  324. <pre class="programlisting">
  325. [
  326. {
  327. "f1": 1,
  328. "f2": null
  329. },
  330. 2,
  331. null,
  332. 3
  333. ]
  334. </pre>
  335. </td></tr><tr><td>
  336. <p><code class="literal">
  337. jsonb_path_exists(target jsonb, path jsonpath [<span class="optional">, vars jsonb [<span class="optional">, silent bool</span>]</span>])
  338. </code></p>
  339. </td><td><code class="type">boolean</code></td><td>
  340. Checks whether JSON path returns any item for the specified JSON
  341. value.
  342. </td><td>
  343. <p><code class="literal">
  344. jsonb_path_exists('{"a":[1,2,3,4,5]}', '$.a[*] ? (@ &gt;= $min &amp;&amp; @ &lt;= $max)', '{"min":2,"max":4}')
  345. </code></p>
  346. </td><td>
  347. <p><code class="literal">true</code></p>
  348. </td></tr><tr><td>
  349. <p><code class="literal">
  350. jsonb_path_match(target jsonb, path jsonpath [<span class="optional">, vars jsonb [<span class="optional">, silent bool</span>]</span>])
  351. </code></p>
  352. </td><td><code class="type">boolean</code></td><td>
  353. Returns the result of JSON path predicate check for the specified JSON value.
  354. Only the first item of the result is taken into account. If the
  355. result is not Boolean, then <code class="literal">null</code> is returned.
  356. </td><td>
  357. <p><code class="literal">
  358. jsonb_path_match('{"a":[1,2,3,4,5]}', 'exists($.a[*] ? (@ &gt;= $min &amp;&amp; @ &lt;= $max))', '{"min":2,"max":4}')
  359. </code></p>
  360. </td><td>
  361. <p><code class="literal">true</code></p>
  362. </td></tr><tr><td>
  363. <p><code class="literal">
  364. jsonb_path_query(target jsonb, path jsonpath [<span class="optional">, vars jsonb [<span class="optional">, silent bool</span>]</span>])
  365. </code></p>
  366. </td><td><code class="type">setof jsonb</code></td><td>
  367. Gets all JSON items returned by JSON path for the specified JSON
  368. value.
  369. </td><td>
  370. <p><code class="literal">
  371. select * from jsonb_path_query('{"a":[1,2,3,4,5]}', '$.a[*] ? (@ &gt;= $min &amp;&amp; @ &lt;= $max)', '{"min":2,"max":4}');
  372. </code></p>
  373. </td><td>
  374. <p>
  375. </p><pre class="programlisting">
  376. jsonb_path_query
  377. ------------------
  378. 2
  379. 3
  380. 4
  381. </pre><p>
  382. </p>
  383. </td></tr><tr><td>
  384. <p><code class="literal">
  385. jsonb_path_query_array(target jsonb, path jsonpath [<span class="optional">, vars jsonb [<span class="optional">, silent bool</span>]</span>])
  386. </code></p>
  387. </td><td><code class="type">jsonb</code></td><td>
  388. Gets all JSON items returned by JSON path for the specified JSON
  389. value and wraps result into an array.
  390. </td><td>
  391. <p><code class="literal">
  392. jsonb_path_query_array('{"a":[1,2,3,4,5]}', '$.a[*] ? (@ &gt;= $min &amp;&amp; @ &lt;= $max)', '{"min":2,"max":4}')
  393. </code></p>
  394. </td><td>
  395. <p><code class="literal">[2, 3, 4]</code></p>
  396. </td></tr><tr><td>
  397. <p><code class="literal">
  398. jsonb_path_query_first(target jsonb, path jsonpath [<span class="optional">, vars jsonb [<span class="optional">, silent bool</span>]</span>])
  399. </code></p>
  400. </td><td><code class="type">jsonb</code></td><td>
  401. Gets the first JSON item returned by JSON path for the specified JSON
  402. value. Returns <code class="literal">NULL</code> on no results.
  403. </td><td>
  404. <p><code class="literal">
  405. jsonb_path_query_first('{"a":[1,2,3,4,5]}', '$.a[*] ? (@ &gt;= $min &amp;&amp; @ &lt;= $max)', '{"min":2,"max":4}')
  406. </code></p>
  407. </td><td>
  408. <p><code class="literal">2</code></p>
  409. </td></tr></tbody></table></div></div><br class="table-break" /><div class="note"><h3 class="title">Note</h3><p>
  410. Many of these functions and operators will convert Unicode escapes in
  411. JSON strings to the appropriate single character. This is a non-issue
  412. if the input is type <code class="type">jsonb</code>, because the conversion was already
  413. done; but for <code class="type">json</code> input, this may result in throwing an error,
  414. as noted in <a class="xref" href="datatype-json.html" title="8.14. JSON Types">Section 8.14</a>.
  415. </p></div><div class="note"><h3 class="title">Note</h3><p>
  416. The functions
  417. <code class="function">json[b]_populate_record</code>,
  418. <code class="function">json[b]_populate_recordset</code>,
  419. <code class="function">json[b]_to_record</code> and
  420. <code class="function">json[b]_to_recordset</code>
  421. operate on a JSON object, or array of objects, and extract the values
  422. associated with keys whose names match column names of the output row
  423. type.
  424. Object fields that do not correspond to any output column name are
  425. ignored, and output columns that do not match any object field will be
  426. filled with nulls.
  427. To convert a JSON value to the SQL type of an output column, the
  428. following rules are applied in sequence:
  429. </p><div class="itemizedlist"><ul class="itemizedlist compact" style="list-style-type: disc; "><li class="listitem"><p>
  430. A JSON null value is converted to a SQL null in all cases.
  431. </p></li><li class="listitem"><p>
  432. If the output column is of type <code class="type">json</code>
  433. or <code class="type">jsonb</code>, the JSON value is just reproduced exactly.
  434. </p></li><li class="listitem"><p>
  435. If the output column is a composite (row) type, and the JSON value is
  436. a JSON object, the fields of the object are converted to columns of
  437. the output row type by recursive application of these rules.
  438. </p></li><li class="listitem"><p>
  439. Likewise, if the output column is an array type and the JSON value is
  440. a JSON array, the elements of the JSON array are converted to elements
  441. of the output array by recursive application of these rules.
  442. </p></li><li class="listitem"><p>
  443. Otherwise, if the JSON value is a string literal, the contents of the
  444. string are fed to the input conversion function for the column's data
  445. type.
  446. </p></li><li class="listitem"><p>
  447. Otherwise, the ordinary text representation of the JSON value is fed
  448. to the input conversion function for the column's data type.
  449. </p></li></ul></div><p>
  450. </p><p>
  451. While the examples for these functions use constants, the typical use
  452. would be to reference a table in the <code class="literal">FROM</code> clause
  453. and use one of its <code class="type">json</code> or <code class="type">jsonb</code> columns
  454. as an argument to the function. Extracted key values can then be
  455. referenced in other parts of the query, like <code class="literal">WHERE</code>
  456. clauses and target lists. Extracting multiple values in this
  457. way can improve performance over extracting them separately with
  458. per-key operators.
  459. </p></div><div class="note"><h3 class="title">Note</h3><p>
  460. All the items of the <code class="literal">path</code> parameter of <code class="literal">jsonb_set</code>
  461. as well as <code class="literal">jsonb_insert</code> except the last item must be present
  462. in the <code class="literal">target</code>. If <code class="literal">create_missing</code> is false, all
  463. items of the <code class="literal">path</code> parameter of <code class="literal">jsonb_set</code> must be
  464. present. If these conditions are not met the <code class="literal">target</code> is
  465. returned unchanged.
  466. </p><p>
  467. If the last path item is an object key, it will be created if it
  468. is absent and given the new value. If the last path item is an array
  469. index, if it is positive the item to set is found by counting from
  470. the left, and if negative by counting from the right - <code class="literal">-1</code>
  471. designates the rightmost element, and so on.
  472. If the item is out of the range -array_length .. array_length -1,
  473. and create_missing is true, the new value is added at the beginning
  474. of the array if the item is negative, and at the end of the array if
  475. it is positive.
  476. </p></div><div class="note"><h3 class="title">Note</h3><p>
  477. The <code class="literal">json_typeof</code> function's <code class="literal">null</code> return value
  478. should not be confused with a SQL NULL. While
  479. calling <code class="literal">json_typeof('null'::json)</code> will
  480. return <code class="literal">null</code>, calling <code class="literal">json_typeof(NULL::json)</code>
  481. will return a SQL NULL.
  482. </p></div><div class="note"><h3 class="title">Note</h3><p>
  483. If the argument to <code class="literal">json_strip_nulls</code> contains duplicate
  484. field names in any object, the result could be semantically somewhat
  485. different, depending on the order in which they occur. This is not an
  486. issue for <code class="literal">jsonb_strip_nulls</code> since <code class="type">jsonb</code> values never have
  487. duplicate object field names.
  488. </p></div><div class="note"><h3 class="title">Note</h3><p>
  489. The <code class="literal">jsonb_path_exists</code>, <code class="literal">jsonb_path_match</code>,
  490. <code class="literal">jsonb_path_query</code>, <code class="literal">jsonb_path_query_array</code>, and
  491. <code class="literal">jsonb_path_query_first</code>
  492. functions have optional <code class="literal">vars</code> and <code class="literal">silent</code>
  493. arguments.
  494. </p><p>
  495. If the <em class="parameter"><code>vars</code></em> argument is specified, it provides an
  496. object containing named variables to be substituted into a
  497. <code class="literal">jsonpath</code> expression.
  498. </p><p>
  499. If the <em class="parameter"><code>silent</code></em> argument is specified and has the
  500. <code class="literal">true</code> value, these functions suppress the same errors
  501. as the <code class="literal">@?</code> and <code class="literal">@@</code> operators.
  502. </p></div><p>
  503. See also <a class="xref" href="functions-aggregate.html" title="9.20. Aggregate Functions">Section 9.20</a> for the aggregate
  504. function <code class="function">json_agg</code> which aggregates record
  505. values as JSON, and the aggregate function
  506. <code class="function">json_object_agg</code> which aggregates pairs of values
  507. into a JSON object, and their <code class="type">jsonb</code> equivalents,
  508. <code class="function">jsonb_agg</code> and <code class="function">jsonb_object_agg</code>.
  509. </p></div><div class="sect2" id="FUNCTIONS-SQLJSON-PATH"><div class="titlepage"><div><div><h3 class="title">9.15.2. The SQL/JSON Path Language</h3></div></div></div><a id="id-1.5.8.20.6.2" class="indexterm"></a><p>
  510. SQL/JSON path expressions specify the items to be retrieved
  511. from the JSON data, similar to XPath expressions used
  512. for SQL access to XML. In <span class="productname">PostgreSQL</span>,
  513. path expressions are implemented as the <code class="type">jsonpath</code>
  514. data type and can use any elements described in
  515. <a class="xref" href="datatype-json.html#DATATYPE-JSONPATH" title="8.14.6. jsonpath Type">Section 8.14.6</a>.
  516. </p><p>JSON query functions and operators
  517. pass the provided path expression to the <em class="firstterm">path engine</em>
  518. for evaluation. If the expression matches the queried JSON data,
  519. the corresponding SQL/JSON item is returned.
  520. Path expressions are written in the SQL/JSON path language
  521. and can also include arithmetic expressions and functions.
  522. Query functions treat the provided expression as a
  523. text string, so it must be enclosed in single quotes.
  524. </p><p>
  525. A path expression consists of a sequence of elements allowed
  526. by the <code class="type">jsonpath</code> data type.
  527. The path expression is evaluated from left to right, but
  528. you can use parentheses to change the order of operations.
  529. If the evaluation is successful, a sequence of SQL/JSON items
  530. (<em class="firstterm">SQL/JSON sequence</em>) is produced,
  531. and the evaluation result is returned to the JSON query function
  532. that completes the specified computation.
  533. </p><p>
  534. To refer to the JSON data to be queried (the
  535. <em class="firstterm">context item</em>), use the <code class="literal">$</code> sign
  536. in the path expression. It can be followed by one or more
  537. <a class="link" href="datatype-json.html#TYPE-JSONPATH-ACCESSORS" title="Table 8.25. jsonpath Accessors">accessor operators</a>,
  538. which go down the JSON structure level by level to retrieve the
  539. content of context item. Each operator that follows deals with the
  540. result of the previous evaluation step.
  541. </p><p>
  542. For example, suppose you have some JSON data from a GPS tracker that you
  543. would like to parse, such as:
  544. </p><pre class="programlisting">
  545. {
  546. "track": {
  547. "segments": [
  548. {
  549. "location": [ 47.763, 13.4034 ],
  550. "start time": "2018-10-14 10:05:14",
  551. "HR": 73
  552. },
  553. {
  554. "location": [ 47.706, 13.2635 ],
  555. "start time": "2018-10-14 10:39:21",
  556. "HR": 135
  557. }
  558. ]
  559. }
  560. }
  561. </pre><p>
  562. </p><p>
  563. To retrieve the available track segments, you need to use the
  564. <code class="literal">.<em class="replaceable"><code>key</code></em></code> accessor
  565. operator for all the preceding JSON objects:
  566. </p><pre class="programlisting">
  567. '$.track.segments'
  568. </pre><p>
  569. </p><p>
  570. If the item to retrieve is an element of an array, you have
  571. to unnest this array using the <code class="literal">[*]</code> operator. For example,
  572. the following path will return location coordinates for all
  573. the available track segments:
  574. </p><pre class="programlisting">
  575. '$.track.segments[*].location'
  576. </pre><p>
  577. </p><p>
  578. To return the coordinates of the first segment only, you can
  579. specify the corresponding subscript in the <code class="literal">[]</code>
  580. accessor operator. Note that the SQL/JSON arrays are 0-relative:
  581. </p><pre class="programlisting">
  582. '$.track.segments[0].location'
  583. </pre><p>
  584. </p><p>
  585. The result of each path evaluation step can be processed
  586. by one or more <code class="type">jsonpath</code> operators and methods
  587. listed in <a class="xref" href="functions-json.html#FUNCTIONS-SQLJSON-PATH-OPERATORS" title="9.15.2.3. SQL/JSON Path Operators and Methods">Section 9.15.2.3</a>.
  588. Each method name must be preceded by a dot. For example,
  589. you can get an array size:
  590. </p><pre class="programlisting">
  591. '$.track.segments.size()'
  592. </pre><p>
  593. For more examples of using <code class="type">jsonpath</code> operators
  594. and methods within path expressions, see
  595. <a class="xref" href="functions-json.html#FUNCTIONS-SQLJSON-PATH-OPERATORS" title="9.15.2.3. SQL/JSON Path Operators and Methods">Section 9.15.2.3</a>.
  596. </p><p>
  597. When defining the path, you can also use one or more
  598. <em class="firstterm">filter expressions</em> that work similar to the
  599. <code class="literal">WHERE</code> clause in SQL. A filter expression begins with
  600. a question mark and provides a condition in parentheses:
  601. </p><pre class="programlisting">
  602. ? (<em class="replaceable"><code>condition</code></em>)
  603. </pre><p>
  604. </p><p>
  605. Filter expressions must be specified right after the path evaluation step
  606. to which they are applied. The result of this step is filtered to include
  607. only those items that satisfy the provided condition. SQL/JSON defines
  608. three-valued logic, so the condition can be <code class="literal">true</code>, <code class="literal">false</code>,
  609. or <code class="literal">unknown</code>. The <code class="literal">unknown</code> value
  610. plays the same role as SQL <code class="literal">NULL</code> and can be tested
  611. for with the <code class="literal">is unknown</code> predicate. Further path
  612. evaluation steps use only those items for which filter expressions
  613. return <code class="literal">true</code>.
  614. </p><p>
  615. Functions and operators that can be used in filter expressions are listed
  616. in <a class="xref" href="functions-json.html#FUNCTIONS-SQLJSON-FILTER-EX-TABLE" title="Table 9.49. jsonpath Filter Expression Elements">Table 9.49</a>. The path
  617. evaluation result to be filtered is denoted by the <code class="literal">@</code>
  618. variable. To refer to a JSON element stored at a lower nesting level,
  619. add one or more accessor operators after <code class="literal">@</code>.
  620. </p><p>
  621. Suppose you would like to retrieve all heart rate values higher
  622. than 130. You can achieve this using the following expression:
  623. </p><pre class="programlisting">
  624. '$.track.segments[*].HR ? (@ &gt; 130)'
  625. </pre><p>
  626. </p><p>
  627. To get the start time of segments with such values instead, you have to
  628. filter out irrelevant segments before returning the start time, so the
  629. filter expression is applied to the previous step, and the path used
  630. in the condition is different:
  631. </p><pre class="programlisting">
  632. '$.track.segments[*] ? (@.HR &gt; 130)."start time"'
  633. </pre><p>
  634. </p><p>
  635. You can use several filter expressions on the same nesting level, if
  636. required. For example, the following expression selects all segments
  637. that contain locations with relevant coordinates and high heart rate values:
  638. </p><pre class="programlisting">
  639. '$.track.segments[*] ? (@.location[1] &lt; 13.4) ? (@.HR &gt; 130)."start time"'
  640. </pre><p>
  641. </p><p>
  642. Using filter expressions at different nesting levels is also allowed.
  643. The following example first filters all segments by location, and then
  644. returns high heart rate values for these segments, if available:
  645. </p><pre class="programlisting">
  646. '$.track.segments[*] ? (@.location[1] &lt; 13.4).HR ? (@ &gt; 130)'
  647. </pre><p>
  648. </p><p>
  649. You can also nest filter expressions within each other:
  650. </p><pre class="programlisting">
  651. '$.track ? (exists(@.segments[*] ? (@.HR &gt; 130))).segments.size()'
  652. </pre><p>
  653. This expression returns the size of the track if it contains any
  654. segments with high heart rate values, or an empty sequence otherwise.
  655. </p><p>
  656. <span class="productname">PostgreSQL</span>'s implementation of SQL/JSON path
  657. language has the following deviations from the SQL/JSON standard:
  658. </p><div class="itemizedlist"><ul class="itemizedlist" style="list-style-type: disc; "><li class="listitem"><p>
  659. <code class="literal">.datetime()</code> item method is not implemented yet
  660. mainly because immutable <code class="type">jsonpath</code> functions and operators
  661. cannot reference session timezone, which is used in some datetime
  662. operations. Datetime support will be added to <code class="type">jsonpath</code>
  663. in future versions of <span class="productname">PostgreSQL</span>.
  664. </p></li><li class="listitem"><p>
  665. A path expression can be a Boolean predicate, although the SQL/JSON
  666. standard allows predicates only in filters. This is necessary for
  667. implementation of the <code class="literal">@@</code> operator. For example,
  668. the following <code class="type">jsonpath</code> expression is valid in
  669. <span class="productname">PostgreSQL</span>:
  670. </p><pre class="programlisting">
  671. '$.track.segments[*].HR &lt; 70'
  672. </pre><p>
  673. </p></li><li class="listitem"><p>
  674. There are minor differences in the interpretation of regular
  675. expression patterns used in <code class="literal">like_regex</code> filters, as
  676. described in <a class="xref" href="functions-json.html#JSONPATH-REGULAR-EXPRESSIONS" title="9.15.2.2. Regular Expressions">Section 9.15.2.2</a>.
  677. </p></li></ul></div><div class="sect3" id="STRICT-AND-LAX-MODES"><div class="titlepage"><div><div><h4 class="title">9.15.2.1. Strict and Lax Modes</h4></div></div></div><p>
  678. When you query JSON data, the path expression may not match the
  679. actual JSON data structure. An attempt to access a non-existent
  680. member of an object or element of an array results in a
  681. structural error. SQL/JSON path expressions have two modes
  682. of handling structural errors:
  683. </p><div class="itemizedlist"><ul class="itemizedlist" style="list-style-type: disc; "><li class="listitem"><p>
  684. lax (default) — the path engine implicitly adapts
  685. the queried data to the specified path.
  686. Any remaining structural errors are suppressed and converted
  687. to empty SQL/JSON sequences.
  688. </p></li><li class="listitem"><p>
  689. strict — if a structural error occurs, an error is raised.
  690. </p></li></ul></div><p>
  691. The lax mode facilitates matching of a JSON document structure and path
  692. expression if the JSON data does not conform to the expected schema.
  693. If an operand does not match the requirements of a particular operation,
  694. it can be automatically wrapped as an SQL/JSON array or unwrapped by
  695. converting its elements into an SQL/JSON sequence before performing
  696. this operation. Besides, comparison operators automatically unwrap their
  697. operands in the lax mode, so you can compare SQL/JSON arrays
  698. out-of-the-box. An array of size 1 is considered equal to its sole element.
  699. Automatic unwrapping is not performed only when:
  700. </p><div class="itemizedlist"><ul class="itemizedlist" style="list-style-type: disc; "><li class="listitem"><p>
  701. The path expression contains <code class="literal">type()</code> or
  702. <code class="literal">size()</code> methods that return the type
  703. and the number of elements in the array, respectively.
  704. </p></li><li class="listitem"><p>
  705. The queried JSON data contain nested arrays. In this case, only
  706. the outermost array is unwrapped, while all the inner arrays
  707. remain unchanged. Thus, implicit unwrapping can only go one
  708. level down within each path evaluation step.
  709. </p></li></ul></div><p>
  710. </p><p>
  711. For example, when querying the GPS data listed above, you can
  712. abstract from the fact that it stores an array of segments
  713. when using the lax mode:
  714. </p><pre class="programlisting">
  715. 'lax $.track.segments.location'
  716. </pre><p>
  717. </p><p>
  718. In the strict mode, the specified path must exactly match the structure of
  719. the queried JSON document to return an SQL/JSON item, so using this
  720. path expression will cause an error. To get the same result as in
  721. the lax mode, you have to explicitly unwrap the
  722. <code class="literal">segments</code> array:
  723. </p><pre class="programlisting">
  724. 'strict $.track.segments[*].location'
  725. </pre><p>
  726. </p></div><div class="sect3" id="JSONPATH-REGULAR-EXPRESSIONS"><div class="titlepage"><div><div><h4 class="title">9.15.2.2. Regular Expressions</h4></div></div></div><a id="id-1.5.8.20.6.23.2" class="indexterm"></a><p>
  727. SQL/JSON path expressions allow matching text to a regular expression
  728. with the <code class="literal">like_regex</code> filter. For example, the
  729. following SQL/JSON path query would case-insensitively match all
  730. strings in an array that start with an English vowel:
  731. </p><pre class="programlisting">
  732. '$[*] ? (@ like_regex "^[aeiou]" flag "i")'
  733. </pre><p>
  734. </p><p>
  735. The optional <code class="literal">flag</code> string may include one or more of
  736. the characters
  737. <code class="literal">i</code> for case-insensitive match,
  738. <code class="literal">m</code> to allow <code class="literal">^</code>
  739. and <code class="literal">$</code> to match at newlines,
  740. <code class="literal">s</code> to allow <code class="literal">.</code> to match a newline,
  741. and <code class="literal">q</code> to quote the whole pattern (reducing the
  742. behavior to a simple substring match).
  743. </p><p>
  744. The SQL/JSON standard borrows its definition for regular expressions
  745. from the <code class="literal">LIKE_REGEX</code> operator, which in turn uses the
  746. XQuery standard. PostgreSQL does not currently support the
  747. <code class="literal">LIKE_REGEX</code> operator. Therefore,
  748. the <code class="literal">like_regex</code> filter is implemented using the
  749. POSIX regular expression engine described in
  750. <a class="xref" href="functions-matching.html#FUNCTIONS-POSIX-REGEXP" title="9.7.3. POSIX Regular Expressions">Section 9.7.3</a>. This leads to various minor
  751. discrepancies from standard SQL/JSON behavior, which are cataloged in
  752. <a class="xref" href="functions-matching.html#POSIX-VS-XQUERY" title="9.7.3.8. Differences From XQuery (LIKE_REGEX)">Section 9.7.3.8</a>.
  753. Note, however, that the flag-letter incompatibilities described there
  754. do not apply to SQL/JSON, as it translates the XQuery flag letters to
  755. match what the POSIX engine expects.
  756. </p><p>
  757. Keep in mind that the pattern argument of <code class="literal">like_regex</code>
  758. is a JSON path string literal, written according to the rules given in
  759. <a class="xref" href="datatype-json.html#DATATYPE-JSONPATH" title="8.14.6. jsonpath Type">Section 8.14.6</a>. This means in particular that any
  760. backslashes you want to use in the regular expression must be doubled.
  761. For example, to match strings that contain only digits:
  762. </p><pre class="programlisting">
  763. '$ ? (@ like_regex "^\\d+$")'
  764. </pre><p>
  765. </p></div><div class="sect3" id="FUNCTIONS-SQLJSON-PATH-OPERATORS"><div class="titlepage"><div><div><h4 class="title">9.15.2.3. SQL/JSON Path Operators and Methods</h4></div></div></div><p>
  766. <a class="xref" href="functions-json.html#FUNCTIONS-SQLJSON-OP-TABLE" title="Table 9.48. jsonpath Operators and Methods">Table 9.48</a> shows the operators and
  767. methods available in <code class="type">jsonpath</code>. <a class="xref" href="functions-json.html#FUNCTIONS-SQLJSON-FILTER-EX-TABLE" title="Table 9.49. jsonpath Filter Expression Elements">Table 9.49</a> shows the available filter
  768. expression elements.
  769. </p><div class="table" id="FUNCTIONS-SQLJSON-OP-TABLE"><p class="title"><strong>Table 9.48. <code class="type">jsonpath</code> Operators and Methods</strong></p><div class="table-contents"><table class="table" summary="jsonpath Operators and Methods" border="1"><colgroup><col /><col /><col /><col /><col /></colgroup><thead><tr><th>Operator/Method</th><th>Description</th><th>Example JSON</th><th>Example Query</th><th>Result</th></tr></thead><tbody><tr><td><code class="literal">+</code> (unary)</td><td>Plus operator that iterates over the SQL/JSON sequence</td><td><code class="literal">{"x": [2.85, -14.7, -9.4]}</code></td><td><code class="literal">+ $.x.floor()</code></td><td><code class="literal">2, -15, -10</code></td></tr><tr><td><code class="literal">-</code> (unary)</td><td>Minus operator that iterates over the SQL/JSON sequence</td><td><code class="literal">{"x": [2.85, -14.7, -9.4]}</code></td><td><code class="literal">- $.x.floor()</code></td><td><code class="literal">-2, 15, 10</code></td></tr><tr><td><code class="literal">+</code> (binary)</td><td>Addition</td><td><code class="literal">[2]</code></td><td><code class="literal">2 + $[0]</code></td><td><code class="literal">4</code></td></tr><tr><td><code class="literal">-</code> (binary)</td><td>Subtraction</td><td><code class="literal">[2]</code></td><td><code class="literal">4 - $[0]</code></td><td><code class="literal">2</code></td></tr><tr><td><code class="literal">*</code></td><td>Multiplication</td><td><code class="literal">[4]</code></td><td><code class="literal">2 * $[0]</code></td><td><code class="literal">8</code></td></tr><tr><td><code class="literal">/</code></td><td>Division</td><td><code class="literal">[8]</code></td><td><code class="literal">$[0] / 2</code></td><td><code class="literal">4</code></td></tr><tr><td><code class="literal">%</code></td><td>Modulus</td><td><code class="literal">[32]</code></td><td><code class="literal">$[0] % 10</code></td><td><code class="literal">2</code></td></tr><tr><td><code class="literal">type()</code></td><td>Type of the SQL/JSON item</td><td><code class="literal">[1, "2", {}]</code></td><td><code class="literal">$[*].type()</code></td><td><code class="literal">"number", "string", "object"</code></td></tr><tr><td><code class="literal">size()</code></td><td>Size of the SQL/JSON item</td><td><code class="literal">{"m": [11, 15]}</code></td><td><code class="literal">$.m.size()</code></td><td><code class="literal">2</code></td></tr><tr><td><code class="literal">double()</code></td><td>Approximate floating-point number converted from an SQL/JSON number or a string</td><td><code class="literal">{"len": "1.9"}</code></td><td><code class="literal">$.len.double() * 2</code></td><td><code class="literal">3.8</code></td></tr><tr><td><code class="literal">ceiling()</code></td><td>Nearest integer greater than or equal to the SQL/JSON number</td><td><code class="literal">{"h": 1.3}</code></td><td><code class="literal">$.h.ceiling()</code></td><td><code class="literal">2</code></td></tr><tr><td><code class="literal">floor()</code></td><td>Nearest integer less than or equal to the SQL/JSON number</td><td><code class="literal">{"h": 1.3}</code></td><td><code class="literal">$.h.floor()</code></td><td><code class="literal">1</code></td></tr><tr><td><code class="literal">abs()</code></td><td>Absolute value of the SQL/JSON number</td><td><code class="literal">{"z": -0.3}</code></td><td><code class="literal">$.z.abs()</code></td><td><code class="literal">0.3</code></td></tr><tr><td><code class="literal">keyvalue()</code></td><td>
  770. Sequence of object's key-value pairs represented as array of items
  771. containing three fields (<code class="literal">"key"</code>,
  772. <code class="literal">"value"</code>, and <code class="literal">"id"</code>).
  773. <code class="literal">"id"</code> is a unique identifier of the object
  774. key-value pair belongs to.
  775. </td><td><code class="literal">{"x": "20", "y": 32}</code></td><td><code class="literal">$.keyvalue()</code></td><td><code class="literal">{"key": "x", "value": "20", "id": 0}, {"key": "y", "value": 32, "id": 0}</code></td></tr></tbody></table></div></div><br class="table-break" /><div class="table" id="FUNCTIONS-SQLJSON-FILTER-EX-TABLE"><p class="title"><strong>Table 9.49. <code class="type">jsonpath</code> Filter Expression Elements</strong></p><div class="table-contents"><table class="table" summary="jsonpath Filter Expression Elements" border="1"><colgroup><col /><col /><col /><col /><col /></colgroup><thead><tr><th>Value/Predicate</th><th>Description</th><th>Example JSON</th><th>Example Query</th><th>Result</th></tr></thead><tbody><tr><td><code class="literal">==</code></td><td>Equality operator</td><td><code class="literal">[1, 2, 1, 3]</code></td><td><code class="literal">$[*] ? (@ == 1)</code></td><td><code class="literal">1, 1</code></td></tr><tr><td><code class="literal">!=</code></td><td>Non-equality operator</td><td><code class="literal">[1, 2, 1, 3]</code></td><td><code class="literal">$[*] ? (@ != 1)</code></td><td><code class="literal">2, 3</code></td></tr><tr><td><code class="literal">&lt;&gt;</code></td><td>Non-equality operator (same as <code class="literal">!=</code>)</td><td><code class="literal">[1, 2, 1, 3]</code></td><td><code class="literal">$[*] ? (@ &lt;&gt; 1)</code></td><td><code class="literal">2, 3</code></td></tr><tr><td><code class="literal">&lt;</code></td><td>Less-than operator</td><td><code class="literal">[1, 2, 3]</code></td><td><code class="literal">$[*] ? (@ &lt; 2)</code></td><td><code class="literal">1</code></td></tr><tr><td><code class="literal">&lt;=</code></td><td>Less-than-or-equal-to operator</td><td><code class="literal">[1, 2, 3]</code></td><td><code class="literal">$[*] ? (@ &lt;= 2)</code></td><td><code class="literal">1, 2</code></td></tr><tr><td><code class="literal">&gt;</code></td><td>Greater-than operator</td><td><code class="literal">[1, 2, 3]</code></td><td><code class="literal">$[*] ? (@ &gt; 2)</code></td><td><code class="literal">3</code></td></tr><tr><td><code class="literal">&gt;=</code></td><td>Greater-than-or-equal-to operator</td><td><code class="literal">[1, 2, 3]</code></td><td><code class="literal">$[*] ? (@ &gt;= 2)</code></td><td><code class="literal">2, 3</code></td></tr><tr><td><code class="literal">true</code></td><td>Value used to perform comparison with JSON <code class="literal">true</code> literal</td><td><code class="literal">[{"name": "John", "parent": false},
  776. {"name": "Chris", "parent": true}]</code></td><td><code class="literal">$[*] ? (@.parent == true)</code></td><td><code class="literal">{"name": "Chris", "parent": true}</code></td></tr><tr><td><code class="literal">false</code></td><td>Value used to perform comparison with JSON <code class="literal">false</code> literal</td><td><code class="literal">[{"name": "John", "parent": false},
  777. {"name": "Chris", "parent": true}]</code></td><td><code class="literal">$[*] ? (@.parent == false)</code></td><td><code class="literal">{"name": "John", "parent": false}</code></td></tr><tr><td><code class="literal">null</code></td><td>Value used to perform comparison with JSON <code class="literal">null</code> value</td><td><code class="literal">[{"name": "Mary", "job": null},
  778. {"name": "Michael", "job": "driver"}]</code></td><td><code class="literal">$[*] ? (@.job == null) .name</code></td><td><code class="literal">"Mary"</code></td></tr><tr><td><code class="literal">&amp;&amp;</code></td><td>Boolean AND</td><td><code class="literal">[1, 3, 7]</code></td><td><code class="literal">$[*] ? (@ &gt; 1 &amp;&amp; @ &lt; 5)</code></td><td><code class="literal">3</code></td></tr><tr><td><code class="literal">||</code></td><td>Boolean OR</td><td><code class="literal">[1, 3, 7]</code></td><td><code class="literal">$[*] ? (@ &lt; 1 || @ &gt; 5)</code></td><td><code class="literal">7</code></td></tr><tr><td><code class="literal">!</code></td><td>Boolean NOT</td><td><code class="literal">[1, 3, 7]</code></td><td><code class="literal">$[*] ? (!(@ &lt; 5))</code></td><td><code class="literal">7</code></td></tr><tr><td><code class="literal">like_regex</code></td><td>
  779. Tests whether the first operand matches the regular expression
  780. given by the second operand, optionally with modifications
  781. described by a string of <code class="literal">flag</code> characters (see
  782. <a class="xref" href="functions-json.html#JSONPATH-REGULAR-EXPRESSIONS" title="9.15.2.2. Regular Expressions">Section 9.15.2.2</a>)
  783. </td><td><code class="literal">["abc", "abd", "aBdC", "abdacb", "babc"]</code></td><td><code class="literal">$[*] ? (@ like_regex "^ab.*c" flag "i")</code></td><td><code class="literal">"abc", "aBdC", "abdacb"</code></td></tr><tr><td><code class="literal">starts with</code></td><td>Tests whether the second operand is an initial substring of the first operand</td><td><code class="literal">["John Smith", "Mary Stone", "Bob Johnson"]</code></td><td><code class="literal">$[*] ? (@ starts with "John")</code></td><td><code class="literal">"John Smith"</code></td></tr><tr><td><code class="literal">exists</code></td><td>Tests whether a path expression matches at least one SQL/JSON item</td><td><code class="literal">{"x": [1, 2], "y": [2, 4]}</code></td><td><code class="literal">strict $.* ? (exists (@ ? (@[*] &gt; 2)))</code></td><td><code class="literal">2, 4</code></td></tr><tr><td><code class="literal">is unknown</code></td><td>Tests whether a Boolean condition is <code class="literal">unknown</code></td><td><code class="literal">[-1, 2, 7, "infinity"]</code></td><td><code class="literal">$[*] ? ((@ &gt; 0) is unknown)</code></td><td><code class="literal">"infinity"</code></td></tr></tbody></table></div></div><br class="table-break" /></div></div></div><div class="navfooter"><hr /><table width="100%" summary="Navigation footer"><tr><td width="40%" align="left"><a accesskey="p" href="functions-xml.html">Prev</a> </td><td width="20%" align="center"><a accesskey="u" href="functions.html">Up</a></td><td width="40%" align="right"> <a accesskey="n" href="functions-sequence.html">Next</a></td></tr><tr><td width="40%" align="left" valign="top">9.14. XML Functions </td><td width="20%" align="center"><a accesskey="h" href="index.html">Home</a></td><td width="40%" align="right" valign="top"> 9.16. Sequence Manipulation Functions</td></tr></table></div></body></html>
上海开阖软件有限公司 沪ICP备12045867号-1