Sophie

Sophie

distrib > Mageia > 7 > x86_64 > by-pkgid > 9b6cc37ce608401d44f6535a0c7cb777 > files > 316

postgresql11-docs-11.5-1.mga7.noarch.rpm

<?xml version="1.0" encoding="UTF-8" standalone="no"?>
<!DOCTYPE html PUBLIC "-//W3C//DTD XHTML 1.0 Transitional//EN" "http://www.w3.org/TR/xhtml1/DTD/xhtml1-transitional.dtd"><html xmlns="http://www.w3.org/1999/xhtml"><head><meta http-equiv="Content-Type" content="text/html; charset=UTF-8" /><title>9.15. JSON Functions and Operators</title><link rel="stylesheet" type="text/css" href="stylesheet.css" /><link rev="made" href="pgsql-docs@lists.postgresql.org" /><meta name="generator" content="DocBook XSL Stylesheets Vsnapshot" /><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 11.5 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><a id="id-1.5.8.20.2" class="indexterm"></a><p>
   <a class="xref" href="functions-json.html#FUNCTIONS-JSON-OP-TABLE" title="Table 9.43. json and jsonb Operators">Table 9.43</a> shows the operators that
   are available for use with the two JSON data types (see <a class="xref" href="datatype-json.html" title="8.14. JSON Types">Section 8.14</a>).
  </p><div class="table" id="FUNCTIONS-JSON-OP-TABLE"><p class="title"><strong>Table 9.43. <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 /></colgroup><thead><tr><th>Operator</th><th>Right Operand 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>Get JSON array element (indexed from zero, negative
        integers count from the end)</td><td><code class="literal">'[{"a":"foo"},{"b":"bar"},{"c":"baz"}]'::json-&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>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>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>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>Get JSON object at 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>Get JSON object at 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>
    There are parallel variants of these operators for both the
    <code class="type">json</code> and <code class="type">jsonb</code> types.
    The field/element/path extraction operators
    return the same type as their left-hand input (either <code class="type">json</code>
    or <code class="type">jsonb</code>), except for those specified as
    returning <code class="type">text</code>, which coerce the value to text.
    The field/element/path extraction operators return NULL, rather than
    failing, if the JSON input does not have the right structure to match
    the request; for example if no such element exists.  The
    field/element/path extraction operators that accept integer JSON
    array subscripts all support negative subscripting from the end of
    arrays.
   </p></div><p>
   The standard comparison operators shown in  <a class="xref" href="functions-comparison.html#FUNCTIONS-COMPARISON-OP-TABLE" title="Table 9.1. Comparison Operators">Table 9.1</a> are available for
   <code class="type">jsonb</code>, but not for <code class="type">json</code>. They follow the
   ordering rules for B-tree operations outlined at <a class="xref" href="datatype-json.html#JSON-INDEXING" title="8.14.4. jsonb Indexing">Section 8.14.4</a>.
  </p><p>
   Some further operators also exist only for <code class="type">jsonb</code>, as shown
   in <a class="xref" href="functions-json.html#FUNCTIONS-JSONB-OP-TABLE" title="Table 9.44. Additional jsonb Operators">Table 9.44</a>.
   Many of these operators can be indexed by
   <code class="type">jsonb</code> operator classes.  For a full description of
   <code class="type">jsonb</code> containment and existence semantics, see <a class="xref" href="datatype-json.html#JSON-CONTAINMENT" title="8.14.3. jsonb Containment and Existence">Section 8.14.3</a>.  <a class="xref" href="datatype-json.html#JSON-INDEXING" title="8.14.4. jsonb Indexing">Section 8.14.4</a>
   describes how these operators can be used to effectively index
   <code class="type">jsonb</code> data.
  </p><div class="table" id="FUNCTIONS-JSONB-OP-TABLE"><p class="title"><strong>Table 9.44. 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
        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
        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
        key within the JSON value?</td><td><code class="literal">'{"a":1, "b":2}'::jsonb ? 'b'</code></td></tr><tr><td><code class="literal">?|</code></td><td><code class="type">text[]</code></td><td>Do any of these array <span class="emphasis"><em>strings</em></span>
        exist as top-level keys?</td><td><code class="literal">'{"a":1, "b":2, "c":3}'::jsonb ?| array['b', 'c']</code></td></tr><tr><td><code class="literal">?&amp;</code></td><td><code class="type">text[]</code></td><td>Do all of these array <span class="emphasis"><em>strings</em></span> exist
        as top-level keys?</td><td><code class="literal">'["a", "b"]'::jsonb ?&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>
        element from left operand.  Key/value pairs are matched based
        on their key value.</td><td><code class="literal">'{"a": "b"}'::jsonb - 'a' </code></td></tr><tr><td><code class="literal">-</code></td><td><code class="type">text[]</code></td><td>Delete multiple key/value pairs or <span class="emphasis"><em>string</em></span>
        elements from left operand.  Key/value pairs are matched based
        on their key value.</td><td><code class="literal">'{"a": "b", "c": "d"}'::jsonb - '{a,c}'::text[] </code></td></tr><tr><td><code class="literal">-</code></td><td><code class="type">integer</code></td><td>Delete the array element with specified index (Negative
        integers count from the end).  Throws an error if top level
        container is not an array.</td><td><code class="literal">'["a", "b"]'::jsonb - 1 </code></td></tr><tr><td><code class="literal">#-</code></td><td><code class="type">text[]</code></td><td>Delete the field or element with specified path (for
        JSON arrays, negative integers count from the end)</td><td><code class="literal">'["a", {"b":1}]'::jsonb #- '{1,b}'</code></td></tr></tbody></table></div></div><br class="table-break" /><div class="note"><h3 class="title">Note</h3><p>
    The <code class="literal">||</code> operator concatenates the elements at the top level of
    each of its operands. It does not operate recursively. For example, if
    both operands are objects with a common key field name, the value of the
    field in the result will just be the value from the right hand operand.
   </p></div><p>
   <a class="xref" href="functions-json.html#FUNCTIONS-JSON-CREATION-TABLE" title="Table 9.45. JSON Creation Functions">Table 9.45</a> shows the functions that are
   available for creating <code class="type">json</code> and <code class="type">jsonb</code> values.
   (There are no equivalent functions for <code class="type">jsonb</code>, of the <code class="literal">row_to_json</code>
   and <code class="literal">array_to_json</code> functions. However, the <code class="literal">to_jsonb</code>
   function supplies much the same functionality as these functions would.)
  </p><a id="id-1.5.8.20.11" class="indexterm"></a><a id="id-1.5.8.20.12" class="indexterm"></a><a id="id-1.5.8.20.13" class="indexterm"></a><a id="id-1.5.8.20.14" class="indexterm"></a><a id="id-1.5.8.20.15" class="indexterm"></a><a id="id-1.5.8.20.16" class="indexterm"></a><a id="id-1.5.8.20.17" class="indexterm"></a><a id="id-1.5.8.20.18" class="indexterm"></a><a id="id-1.5.8.20.19" class="indexterm"></a><a id="id-1.5.8.20.20" class="indexterm"></a><div class="table" id="FUNCTIONS-JSON-CREATION-TABLE"><p class="title"><strong>Table 9.45. JSON Creation Functions</strong></p><div class="table-contents"><table class="table" summary="JSON Creation Functions" border="1"><colgroup><col /><col /><col /><col /></colgroup><thead><tr><th>Function</th><th>Description</th><th>Example</th><th>Example Result</th></tr></thead><tbody><tr><td><p><code class="literal">to_json(anyelement)</code>
          </p><p><code class="literal">to_jsonb(anyelement)</code>
       </p></td><td>
         Returns the value as <code class="type">json</code> or <code class="type">jsonb</code>.
         Arrays and composites are converted
         (recursively) to arrays and objects; otherwise, if there is a cast
         from the type to <code class="type">json</code>, the cast function will be used to
         perform the conversion; otherwise, a scalar value is produced.
         For any scalar type other than a number, a Boolean, or a null value,
         the text representation will be used, in such a fashion that it is a
         valid <code class="type">json</code> or <code class="type">jsonb</code> value.
       </td><td><code class="literal">to_json('Fred said "Hi."'::text)</code></td><td><code class="literal">"Fred said \"Hi.\""</code></td></tr><tr><td>
         <code class="literal">array_to_json(anyarray [, pretty_bool])</code>
       </td><td>
         Returns the array as a JSON array. A PostgreSQL multidimensional array
         becomes a JSON array of arrays. Line feeds will be added between
         dimension-1 elements if <em class="parameter"><code>pretty_bool</code></em> is true.
       </td><td><code class="literal">array_to_json('{{1,5},{99,100}}'::int[])</code></td><td><code class="literal">[[1,5],[99,100]]</code></td></tr><tr><td>
         <code class="literal">row_to_json(record [, pretty_bool])</code>
       </td><td>
         Returns the row as a JSON object. Line feeds will be added between
         level-1 elements if <em class="parameter"><code>pretty_bool</code></em> is true.
       </td><td><code class="literal">row_to_json(row(1,'foo'))</code></td><td><code class="literal">{"f1":1,"f2":"foo"}</code></td></tr><tr><td><p><code class="literal">json_build_array(VARIADIC "any")</code>
          </p><p><code class="literal">jsonb_build_array(VARIADIC "any")</code>
       </p></td><td>
         Builds a possibly-heterogeneously-typed JSON array out of a variadic
         argument list.
       </td><td><code class="literal">json_build_array(1,2,'3',4,5)</code></td><td><code class="literal">[1, 2, "3", 4, 5]</code></td></tr><tr><td><p><code class="literal">json_build_object(VARIADIC "any")</code>
          </p><p><code class="literal">jsonb_build_object(VARIADIC "any")</code>
       </p></td><td>
         Builds a JSON object out of a variadic argument list.  By
         convention, the argument list consists of alternating
         keys and values.
       </td><td><code class="literal">json_build_object('foo',1,'bar',2)</code></td><td><code class="literal">{"foo": 1, "bar": 2}</code></td></tr><tr><td><p><code class="literal">json_object(text[])</code>
          </p><p><code class="literal">jsonb_object(text[])</code>
       </p></td><td>
         Builds a JSON object out of a text array.  The array must have either
         exactly one dimension with an even number of members, in which case
         they are taken as alternating key/value pairs, or two dimensions
         such that each inner array has exactly two elements, which
         are taken as a key/value pair.
       </td><td><p><code class="literal">json_object('{a, 1, b, "def", c, 3.5}')</code></p>
        <p><code class="literal">json_object('{{a, 1},{b, "def"},{c, 3.5}}')</code></p></td><td><code class="literal">{"a": "1", "b": "def", "c": "3.5"}</code></td></tr><tr><td><p><code class="literal">json_object(keys text[], values text[])</code>
          </p><p><code class="literal">jsonb_object(keys text[], values text[])</code>
       </p></td><td>
         This form of <code class="function">json_object</code> takes keys and values pairwise from two separate
         arrays. In all other respects it is identical to the one-argument form.
       </td><td><code class="literal">json_object('{a, b}', '{1,2}')</code></td><td><code class="literal">{"a": "1", "b": "2"}</code></td></tr></tbody></table></div></div><br class="table-break" /><div class="note"><h3 class="title">Note</h3><p>
     <code class="function">array_to_json</code> and <code class="function">row_to_json</code> have the same
     behavior as <code class="function">to_json</code> except for offering a pretty-printing
     option.  The behavior described for <code class="function">to_json</code> likewise applies
     to each individual value converted by the other JSON creation functions.
    </p></div><div class="note"><h3 class="title">Note</h3><p>
     The <a class="xref" href="hstore.html" title="F.16. hstore">hstore</a> extension has a cast
     from <code class="type">hstore</code> to <code class="type">json</code>, so that
     <code class="type">hstore</code> values converted via the JSON creation functions
     will be represented as JSON objects, not as primitive string values.
    </p></div><p>
   <a class="xref" href="functions-json.html#FUNCTIONS-JSON-PROCESSING-TABLE" title="Table 9.46. JSON Processing Functions">Table 9.46</a> shows the functions that
   are available for processing <code class="type">json</code> and <code class="type">jsonb</code> values.
  </p><a id="id-1.5.8.20.25" class="indexterm"></a><a id="id-1.5.8.20.26" class="indexterm"></a><a id="id-1.5.8.20.27" class="indexterm"></a><a id="id-1.5.8.20.28" class="indexterm"></a><a id="id-1.5.8.20.29" class="indexterm"></a><a id="id-1.5.8.20.30" class="indexterm"></a><a id="id-1.5.8.20.31" class="indexterm"></a><a id="id-1.5.8.20.32" class="indexterm"></a><a id="id-1.5.8.20.33" class="indexterm"></a><a id="id-1.5.8.20.34" class="indexterm"></a><a id="id-1.5.8.20.35" class="indexterm"></a><a id="id-1.5.8.20.36" class="indexterm"></a><a id="id-1.5.8.20.37" class="indexterm"></a><a id="id-1.5.8.20.38" class="indexterm"></a><a id="id-1.5.8.20.39" class="indexterm"></a><a id="id-1.5.8.20.40" class="indexterm"></a><a id="id-1.5.8.20.41" class="indexterm"></a><a id="id-1.5.8.20.42" class="indexterm"></a><a id="id-1.5.8.20.43" class="indexterm"></a><a id="id-1.5.8.20.44" class="indexterm"></a><a id="id-1.5.8.20.45" class="indexterm"></a><a id="id-1.5.8.20.46" class="indexterm"></a><a id="id-1.5.8.20.47" class="indexterm"></a><a id="id-1.5.8.20.48" class="indexterm"></a><a id="id-1.5.8.20.49" class="indexterm"></a><a id="id-1.5.8.20.50" class="indexterm"></a><a id="id-1.5.8.20.51" class="indexterm"></a><a id="id-1.5.8.20.52" class="indexterm"></a><a id="id-1.5.8.20.53" class="indexterm"></a><a id="id-1.5.8.20.54" class="indexterm"></a><a id="id-1.5.8.20.55" class="indexterm"></a><div class="table" id="FUNCTIONS-JSON-PROCESSING-TABLE"><p class="title"><strong>Table 9.46. JSON Processing Functions</strong></p><div class="table-contents"><table class="table" summary="JSON Processing Functions" border="1"><colgroup><col /><col /><col /><col /><col /></colgroup><thead><tr><th>Function</th><th>Return Type</th><th>Description</th><th>Example</th><th>Example Result</th></tr></thead><tbody><tr><td><p><code class="literal">json_array_length(json)</code>
         </p><p><code class="literal">jsonb_array_length(jsonb)</code>
       </p></td><td><code class="type">int</code></td><td>
         Returns the number of elements in the outermost JSON array.
       </td><td><code class="literal">json_array_length('[1,2,3,{"f1":1,"f2":[5,6]},4]')</code></td><td><code class="literal">5</code></td></tr><tr><td><p><code class="literal">json_each(json)</code>
         </p><p><code class="literal">jsonb_each(jsonb)</code>
       </p></td><td><p><code class="literal">setof key text, value json</code>
         </p><p><code class="literal">setof key text, value jsonb</code>
       </p></td><td>
         Expands the outermost JSON object into a set of key/value pairs.
       </td><td><code class="literal">select * from json_each('{"a":"foo", "b":"bar"}')</code></td><td>
<pre class="programlisting">
 key | value
-----+-------
 a   | "foo"
 b   | "bar"
</pre>
       </td></tr><tr><td><p><code class="literal">json_each_text(json)</code>
         </p><p><code class="literal">jsonb_each_text(jsonb)</code>
       </p></td><td><code class="type">setof key text, value text</code></td><td>
         Expands the outermost JSON object into a set of key/value pairs. The
         returned values will be of type <code class="type">text</code>.
       </td><td><code class="literal">select * from json_each_text('{"a":"foo", "b":"bar"}')</code></td><td>
<pre class="programlisting">
 key | value
-----+-------
 a   | foo
 b   | bar
</pre>
       </td></tr><tr><td><p><code class="literal">json_extract_path(from_json json, VARIADIC path_elems text[])</code>
        </p><p><code class="literal">jsonb_extract_path(from_json jsonb, VARIADIC path_elems text[])</code>
       </p></td><td><p><code class="type">json</code></p><p><code class="type">jsonb</code>
       </p></td><td>
         Returns JSON value pointed to by <em class="replaceable"><code>path_elems</code></em>
         (equivalent to <code class="literal">#&gt;</code> operator).
       </td><td><code class="literal">json_extract_path('{"f2":{"f3":1},"f4":{"f5":99,"f6":"foo"}}','f4')</code></td><td><code class="literal">{"f5":99,"f6":"foo"}</code></td></tr><tr><td><p><code class="literal">json_extract_path_text(from_json json, VARIADIC path_elems text[])</code>
         </p><p><code class="literal">jsonb_extract_path_text(from_json jsonb, VARIADIC path_elems text[])</code>
       </p></td><td><code class="type">text</code></td><td>
         Returns JSON value pointed to by <em class="replaceable"><code>path_elems</code></em>
         as <code class="type">text</code>
         (equivalent to <code class="literal">#&gt;&gt;</code> operator).
       </td><td><code class="literal">json_extract_path_text('{"f2":{"f3":1},"f4":{"f5":99,"f6":"foo"}}','f4', 'f6')</code></td><td><code class="literal">foo</code></td></tr><tr><td><p><code class="literal">json_object_keys(json)</code>
         </p><p><code class="literal">jsonb_object_keys(jsonb)</code>
       </p></td><td><code class="type">setof text</code></td><td>
          Returns set of keys in the outermost JSON object.
       </td><td><code class="literal">json_object_keys('{"f1":"abc","f2":{"f3":"a", "f4":"b"}}')</code></td><td>
<pre class="programlisting">
 json_object_keys
------------------
 f1
 f2
</pre>
       </td></tr><tr><td><p><code class="literal">json_populate_record(base anyelement, from_json json)</code>
         </p><p><code class="literal">jsonb_populate_record(base anyelement, from_json jsonb)</code>
       </p></td><td><code class="type">anyelement</code></td><td>
         Expands the object in <em class="replaceable"><code>from_json</code></em> to a row
         whose columns match the record type defined by <em class="replaceable"><code>base</code></em>
         (see note below).
       </td><td><code class="literal">select * from json_populate_record(null::myrowtype, '{"a": 1, "b": ["2", "a b"], "c": {"d": 4, "e": "a  b c"}}')</code></td><td>
<pre class="programlisting">
 a |   b       |      c
---+-----------+-------------
 1 | {2,"a b"} | (4,"a b c")
</pre>
       </td></tr><tr><td><p><code class="literal">json_populate_recordset(base anyelement, from_json json)</code>
         </p><p><code class="literal">jsonb_populate_recordset(base anyelement, from_json jsonb)</code>
       </p></td><td><code class="type">setof anyelement</code></td><td>
         Expands the outermost array of objects
         in <em class="replaceable"><code>from_json</code></em> to a set of rows whose
         columns match the record type defined by <em class="replaceable"><code>base</code></em> (see
         note below).
       </td><td><code class="literal">select * from json_populate_recordset(null::myrowtype, '[{"a":1,"b":2},{"a":3,"b":4}]')</code></td><td>
<pre class="programlisting">
 a | b
---+---
 1 | 2
 3 | 4
</pre>
       </td></tr><tr><td><p><code class="literal">json_array_elements(json)</code>
         </p><p><code class="literal">jsonb_array_elements(jsonb)</code>
       </p></td><td><p><code class="type">setof json</code>
         </p><p><code class="type">setof jsonb</code>
       </p></td><td>
         Expands a JSON array to a set of JSON values.
       </td><td><code class="literal">select * from json_array_elements('[1,true, [2,false]]')</code></td><td>
<pre class="programlisting">
   value
-----------
 1
 true
 [2,false]
</pre>
       </td></tr><tr><td><p><code class="literal">json_array_elements_text(json)</code>
         </p><p><code class="literal">jsonb_array_elements_text(jsonb)</code>
       </p></td><td><code class="type">setof text</code></td><td>
         Expands a JSON array to a set of <code class="type">text</code> values.
       </td><td><code class="literal">select * from json_array_elements_text('["foo", "bar"]')</code></td><td>
<pre class="programlisting">
   value
-----------
 foo
 bar
</pre>
       </td></tr><tr><td><p><code class="literal">json_typeof(json)</code>
         </p><p><code class="literal">jsonb_typeof(jsonb)</code>
       </p></td><td><code class="type">text</code></td><td>
         Returns the type of the outermost JSON value as a text string.
         Possible types are
         <code class="literal">object</code>, <code class="literal">array</code>, <code class="literal">string</code>, <code class="literal">number</code>,
         <code class="literal">boolean</code>, and <code class="literal">null</code>.
       </td><td><code class="literal">json_typeof('-123.4')</code></td><td><code class="literal">number</code></td></tr><tr><td><p><code class="literal">json_to_record(json)</code>
          </p><p><code class="literal">jsonb_to_record(jsonb)</code>
       </p></td><td><code class="type">record</code></td><td>
         Builds an arbitrary record from a JSON object (see note below).  As
         with all functions returning <code class="type">record</code>, the caller must
         explicitly define the structure of the record with an <code class="literal">AS</code>
         clause.
       </td><td><code class="literal">select * from json_to_record('{"a":1,"b":[1,2,3],"c":[1,2,3],"e":"bar","r": {"a": 123, "b": "a b c"}}') as x(a int, b text, c int[], d text, r myrowtype) </code></td><td>
<pre class="programlisting">
 a |    b    |    c    | d |       r
---+---------+---------+---+---------------
 1 | [1,2,3] | {1,2,3} |   | (123,"a b c")
</pre>
       </td></tr><tr><td><p><code class="literal">json_to_recordset(json)</code>
         </p><p><code class="literal">jsonb_to_recordset(jsonb)</code>
       </p></td><td><code class="type">setof record</code></td><td>
         Builds an arbitrary set of records from a JSON array of objects (see
         note below).  As with all functions returning <code class="type">record</code>, the
         caller must explicitly define the structure of the record with
         an <code class="literal">AS</code> clause.
       </td><td><code class="literal">select * from json_to_recordset('[{"a":1,"b":"foo"},{"a":"2","c":"bar"}]') as x(a int, b text);</code></td><td>
<pre class="programlisting">
 a |  b
---+-----
 1 | foo
 2 |
</pre>
       </td></tr><tr><td><p><code class="literal">json_strip_nulls(from_json json)</code>
         </p><p><code class="literal">jsonb_strip_nulls(from_json jsonb)</code>
       </p></td><td><p><code class="type">json</code></p><p><code class="type">jsonb</code></p></td><td>
         Returns <em class="replaceable"><code>from_json</code></em>
         with all object fields that have null values omitted. Other null values
         are untouched.
       </td><td><code class="literal">json_strip_nulls('[{"f1":1,"f2":null},2,null,3]')</code></td><td><code class="literal">[{"f1":1},2,null,3]</code></td></tr><tr><td><p><code class="literal">jsonb_set(target jsonb, path text[], new_value jsonb[<span class="optional">, <em class="parameter"><code>create_missing</code></em> <code class="type">boolean</code></span>])</code>
         </p></td><td><p><code class="type">jsonb</code></p></td><td>
         Returns <em class="replaceable"><code>target</code></em>
         with the section designated by <em class="replaceable"><code>path</code></em>
         replaced by <em class="replaceable"><code>new_value</code></em>, or with
         <em class="replaceable"><code>new_value</code></em> added if
         <em class="replaceable"><code>create_missing</code></em> is true ( default is
         <code class="literal">true</code>) and the item
         designated by <em class="replaceable"><code>path</code></em> does not exist.
         As with the path orientated operators, negative integers that
         appear in <em class="replaceable"><code>path</code></em> count from the end
         of JSON arrays.
       </td><td><p><code class="literal">jsonb_set('[{"f1":1,"f2":null},2,null,3]', '{0,f1}','[2,3,4]', false)</code>
         </p><p><code class="literal">jsonb_set('[{"f1":1,"f2":null},2]', '{0,f3}','[2,3,4]')</code>
         </p></td><td><p><code class="literal">[{"f1":[2,3,4],"f2":null},2,null,3]</code>
         </p><p><code class="literal">[{"f1": 1, "f2": null, "f3": [2, 3, 4]}, 2]</code>
        </p></td></tr><tr><td>
           <p><code class="literal">
           jsonb_insert(target jsonb, path text[], new_value jsonb, [<span class="optional"><em class="parameter"><code>insert_after</code></em> <code class="type">boolean</code></span>])
           </code></p>
       </td><td><p><code class="type">jsonb</code></p></td><td>
         Returns <em class="replaceable"><code>target</code></em> with
         <em class="replaceable"><code>new_value</code></em> inserted. If
         <em class="replaceable"><code>target</code></em> section designated by
         <em class="replaceable"><code>path</code></em> is in a JSONB array,
         <em class="replaceable"><code>new_value</code></em> will be inserted before target or
         after if <em class="replaceable"><code>insert_after</code></em> is true (default is
         <code class="literal">false</code>). If <em class="replaceable"><code>target</code></em> section
         designated by <em class="replaceable"><code>path</code></em> is in JSONB object,
         <em class="replaceable"><code>new_value</code></em> will be inserted only if
         <em class="replaceable"><code>target</code></em> does not exist. As with the path
         orientated operators, negative integers that appear in
         <em class="replaceable"><code>path</code></em> count from the end of JSON arrays.
       </td><td>
           <p><code class="literal">
               jsonb_insert('{"a": [0,1,2]}', '{a, 1}', '"new_value"')
           </code></p>
           <p><code class="literal">
               jsonb_insert('{"a": [0,1,2]}', '{a, 1}', '"new_value"', true)
           </code></p>
       </td><td><p><code class="literal">{"a": [0, "new_value", 1, 2]}</code>
         </p><p><code class="literal">{"a": [0, 1, "new_value", 2]}</code>
        </p></td></tr><tr><td><p><code class="literal">jsonb_pretty(from_json jsonb)</code>
         </p></td><td><p><code class="type">text</code></p></td><td>
         Returns <em class="replaceable"><code>from_json</code></em>
         as indented JSON text.
       </td><td><code class="literal">jsonb_pretty('[{"f1":1,"f2":null},2,null,3]')</code></td><td>
<pre class="programlisting">
[
    {
        "f1": 1,
        "f2": null
    },
    2,
    null,
    3
]
</pre>
        </td></tr></tbody></table></div></div><br class="table-break" /><div class="note"><h3 class="title">Note</h3><p>
      Many of these functions and operators will convert Unicode escapes in
      JSON strings to the appropriate single character.  This is a non-issue
      if the input is type <code class="type">jsonb</code>, because the conversion was already
      done; but for <code class="type">json</code> input, this may result in throwing an error,
      as noted in <a class="xref" href="datatype-json.html" title="8.14. JSON Types">Section 8.14</a>.
    </p></div><div class="note"><h3 class="title">Note</h3><p>
    The functions
    <code class="function">json[b]_populate_record</code>,
    <code class="function">json[b]_populate_recordset</code>,
    <code class="function">json[b]_to_record</code> and
    <code class="function">json[b]_to_recordset</code>
    operate on a JSON object, or array of objects, and extract the values
    associated with keys whose names match column names of the output row
    type.
    Object fields that do not correspond to any output column name are
    ignored, and output columns that do not match any object field will be
    filled with nulls.
    To convert a JSON value to the SQL type of an output column, the
    following rules are applied in sequence:
    </p><div class="itemizedlist"><ul class="itemizedlist compact" style="list-style-type: disc; "><li class="listitem"><p>
       A JSON null value is converted to a SQL null in all cases.
      </p></li><li class="listitem"><p>
       If the output column is of type <code class="type">json</code>
       or <code class="type">jsonb</code>, the JSON value is just reproduced exactly.
      </p></li><li class="listitem"><p>
       If the output column is a composite (row) type, and the JSON value is
       a JSON object, the fields of the object are converted to columns of
       the output row type by recursive application of these rules.
      </p></li><li class="listitem"><p>
       Likewise, if the output column is an array type and the JSON value is
       a JSON array, the elements of the JSON array are converted to elements
       of the output array by recursive application of these rules.
      </p></li><li class="listitem"><p>
       Otherwise, if the JSON value is a string literal, the contents of the
       string are fed to the input conversion function for the column's data
       type.
      </p></li><li class="listitem"><p>
       Otherwise, the ordinary text representation of the JSON value is fed
       to the input conversion function for the column's data type.
      </p></li></ul></div><p>
   </p><p>
    While the examples for these functions use constants, the typical use
    would be to reference a table in the <code class="literal">FROM</code> clause
    and use one of its <code class="type">json</code> or <code class="type">jsonb</code> columns
    as an argument to the function.  Extracted key values can then be
    referenced in other parts of the query, like <code class="literal">WHERE</code>
    clauses and target lists.  Extracting multiple values in this
    way can improve performance over extracting them separately with
    per-key operators.
   </p></div><div class="note"><h3 class="title">Note</h3><p>
      All the items of the <code class="literal">path</code> parameter of <code class="literal">jsonb_set</code>
      as well as <code class="literal">jsonb_insert</code> except the last item must be present
      in the <code class="literal">target</code>. If <code class="literal">create_missing</code> is false, all
      items of the <code class="literal">path</code> parameter of <code class="literal">jsonb_set</code> must be
      present. If these conditions are not met the <code class="literal">target</code> is
      returned unchanged.
    </p><p>
      If the last path item is an object key, it will be created if it
      is absent and given the new value. If the last path item is an array
      index, if it is positive the item to set is found by counting from
      the left, and if negative by counting from the right - <code class="literal">-1</code>
      designates the rightmost element, and so on.
      If the item is out of the range -array_length .. array_length -1,
      and create_missing is true, the new value is added at the beginning
      of the array if the item is negative, and at the end of the array if
      it is positive.
    </p></div><div class="note"><h3 class="title">Note</h3><p>
      The <code class="literal">json_typeof</code> function's <code class="literal">null</code> return value
      should not be confused with a SQL NULL.  While
      calling <code class="literal">json_typeof('null'::json)</code> will
      return <code class="literal">null</code>, calling <code class="literal">json_typeof(NULL::json)</code>
      will return a SQL NULL.
    </p></div><div class="note"><h3 class="title">Note</h3><p>
      If the argument to <code class="literal">json_strip_nulls</code> contains duplicate
      field names in any object, the result could be semantically somewhat
      different, depending on the order in which they occur. This is not an
      issue for <code class="literal">jsonb_strip_nulls</code> since <code class="type">jsonb</code> values never have
      duplicate object field names.
    </p></div><p>
    See also <a class="xref" href="functions-aggregate.html" title="9.20. Aggregate Functions">Section 9.20</a> for the aggregate
    function <code class="function">json_agg</code> which aggregates record
    values as JSON, and the aggregate function
    <code class="function">json_object_agg</code> which aggregates pairs of values
    into a JSON object, and their <code class="type">jsonb</code> equivalents,
    <code class="function">jsonb_agg</code> and <code class="function">jsonb_object_agg</code>.
  </p></div><div class="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>