doc-exports/docs/dws/dev/dws_06_0020.html
Lu, Huayi e6fa411af0 DWS DEV 830.201 version
Reviewed-by: Pruthi, Vineet <vineet.pruthi@t-systems.com>
Co-authored-by: Lu, Huayi <luhuayi@huawei.com>
Co-committed-by: Lu, Huayi <luhuayi@huawei.com>
2024-05-16 07:24:04 +00:00

186 lines
33 KiB
HTML

<a name="EN-US_TOPIC_0000001233628605"></a><a name="EN-US_TOPIC_0000001233628605"></a>
<h1 class="topictitle1">JSON Types</h1>
<div id="body8662426"><p id="EN-US_TOPIC_0000001233628605__ab29d10de61914e008ee962756251fd81">JavaScript Object Notation (JSON) data types are used for storing JSON data.</p>
<p id="EN-US_TOPIC_0000001233628605__ad87850d43fff48e2aff142adfec18387">It can be an independent scalar, an array, or a key-value object. An array and an object can be called a container.</p>
<ol id="EN-US_TOPIC_0000001233628605__ol950303317375"><li id="EN-US_TOPIC_0000001233628605__li9503333203713">Scalar: a number, Boolean, string, or null</li><li id="EN-US_TOPIC_0000001233628605__li105035337377">Array: defined in a pair of square brackets ([]), in which elements can be of any JSON data type, and are not necessarily of the same type.</li><li id="EN-US_TOPIC_0000001233628605__li45031833173715">Object: defined in a pair of braces ({}), in which objects are stored in the format of <strong id="EN-US_TOPIC_0000001233628605__b177616787424915">key:value</strong>. Each key must be a string enclosed in double quotation marks (""), and its value can be of any JSON data type. In case of duplicate keys, the last key-value pair will be used.</li></ol>
<p id="EN-US_TOPIC_0000001233628605__p19418142611118"><span id="EN-US_TOPIC_0000001233628605__text68311144174012">GaussDB(DWS)</span> supports the json and jsonb data types to store JSON data. Where:</p>
<ul id="EN-US_TOPIC_0000001233628605__ul47224302116"><li id="EN-US_TOPIC_0000001233628605__li17383341115">json copies all entered strings and parses them when they are used. During this process, the entered spaces, duplicate keys, and sequence are retained.</li><li id="EN-US_TOPIC_0000001233628605__li97221304115">jsonb parses the binary data of the input. During parsing, jsonb deletes semantic-irrelevant details and duplicate keys, and sorts key values, so that the data does not to be parsed again during use.</li></ul>
<p id="EN-US_TOPIC_0000001233628605__p5164175522916">Both JSON and JSONB are of JSON data type, and the same strings can be entered as input. The main difference between JSON and JSONB is the efficiency. Because json data is an exact copy of the input text, the data must be parsed on every execution. In contrast, jsonb data is stored in a decomposed binary form and can be processed faster, though this makes it slightly slower to input due to the conversion mechanism. In addition, because the JSONB data form is normalized, it supports more operations, for example, comparing sizes according to a specific rule. JSONB also supports indexing, which is a significant advantage.</p>
<div class="section" id="EN-US_TOPIC_0000001233628605__section852311714815"><h4 class="sectiontitle">Input Format</h4><p id="EN-US_TOPIC_0000001233628605__p4875131135617">The input must be a JSON-compliant string, which is enclosed in single quotation marks ('').</p>
<p id="EN-US_TOPIC_0000001233628605__p2503113373718">Null (null-json): Only null is supported, and all letters are in lowercase.</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001233628605__screen16503123363710"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal">1</span>
<span class="normal">2</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">SELECT</span><span class="w"> </span><span class="s1">'null'</span><span class="p">::</span><span class="n">json</span><span class="p">;</span><span class="w"> </span><span class="c1">-- suc</span>
<span class="k">SELECT</span><span class="w"> </span><span class="s1">'NULL'</span><span class="p">::</span><span class="n">jsonb</span><span class="p">;</span><span class="w"> </span><span class="c1">-- err</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001233628605__p1850318334373">Number (num-json): The value can be a positive or negative integer, decimal fraction, or 0. The scientific notation is supported.</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001233628605__screen749143505715"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal">1</span>
<span class="normal">2</span>
<span class="normal">3</span>
<span class="normal">4</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">SELECT</span><span class="w"> </span><span class="s1">'1'</span><span class="p">::</span><span class="n">json</span><span class="p">;</span>
<span class="k">SELECT</span><span class="w"> </span><span class="s1">'-1.5'</span><span class="p">::</span><span class="n">json</span><span class="p">;</span>
<span class="k">SELECT</span><span class="w"> </span><span class="s1">'-1.5e-5'</span><span class="p">::</span><span class="n">jsonb</span><span class="p">,</span><span class="w"> </span><span class="s1">'-1.5e+2'</span><span class="p">::</span><span class="n">jsonb</span><span class="p">;</span>
<span class="k">SELECT</span><span class="w"> </span><span class="s1">'001'</span><span class="p">::</span><span class="n">json</span><span class="p">,</span><span class="w"> </span><span class="s1">'+15'</span><span class="p">::</span><span class="n">json</span><span class="p">,</span><span class="w"> </span><span class="s1">'NaN'</span><span class="p">::</span><span class="n">json</span><span class="p">;</span><span class="w"> </span><span class="c1">-- Redundant leading zeros, plus signs (+), NaN, and infinity are not supported.</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001233628605__p195031333113718">Boolean (bool-json): The value can only be <strong id="EN-US_TOPIC_0000001233628605__b152992333824915">true</strong> or <strong id="EN-US_TOPIC_0000001233628605__b143935443924915">false</strong> in lowercase.</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001233628605__screen1039141005815"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal">1</span>
<span class="normal">2</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">SELECT</span><span class="w"> </span><span class="s1">'true'</span><span class="p">::</span><span class="n">json</span><span class="p">;</span>
<span class="k">SELECT</span><span class="w"> </span><span class="s1">'false'</span><span class="p">::</span><span class="n">jsonb</span><span class="p">;</span><span class="w"> </span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001233628605__p155031133113718">String (str-json): The value must be a string enclosed in double quotation marks ("").</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001233628605__screen4503183315372"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal">1</span>
<span class="normal">2</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">SELECT</span><span class="w"> </span><span class="s1">'&quot;a&quot;'</span><span class="p">::</span><span class="n">json</span><span class="p">;</span>
<span class="k">SELECT</span><span class="w"> </span><span class="s1">'&quot;abc&quot;'</span><span class="p">::</span><span class="n">jsonb</span><span class="p">;</span><span class="w"> </span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001233628605__p050320334372">Array (array-json): Arrays are enclosed in square brackets ([]). Elements in the array can be any valid JSON data, and are unnecessarily of the same type.</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001233628605__screen1050303314377"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal">1</span>
<span class="normal">2</span>
<span class="normal">3</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">SELECT</span><span class="w"> </span><span class="s1">'[1, 2, &quot;foo&quot;, null]'</span><span class="p">::</span><span class="n">json</span><span class="p">;</span>
<span class="k">SELECT</span><span class="w"> </span><span class="s1">'[]'</span><span class="p">::</span><span class="n">json</span><span class="p">;</span>
<span class="k">SELECT</span><span class="w"> </span><span class="s1">'[1, 2, &quot;foo&quot;, null, [[]], {}]'</span><span class="p">::</span><span class="n">jsonb</span><span class="p">;</span><span class="w"> </span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001233628605__p7503333183717">Object (object-json): The value is enclosed in braces ({}). The key must be a JSON-compliant string, and the value can be any valid JSON string.</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001233628605__screen208711959161312"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal">1</span>
<span class="normal">2</span>
<span class="normal">3</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">SELECT</span><span class="w"> </span><span class="s1">'{}'</span><span class="p">::</span><span class="n">json</span><span class="p">;</span>
<span class="k">SELECT</span><span class="w"> </span><span class="s1">'{&quot;a&quot;: 1, &quot;b&quot;: {&quot;a&quot;: 2, &quot;b&quot;: null}}'</span><span class="p">::</span><span class="n">json</span><span class="p">;</span>
<span class="k">SELECT</span><span class="w"> </span><span class="s1">'{&quot;foo&quot;: [true, &quot;bar&quot;], &quot;tags&quot;: {&quot;a&quot;: 1, &quot;b&quot;: null}}'</span><span class="p">::</span><span class="n">jsonb</span><span class="p">;</span><span class="w"> </span>
</pre></div></td></tr></table></div>
</div>
</div>
<div class="caution" id="EN-US_TOPIC_0000001233628605__note12013195912"><span class="cautiontitle"><img src="public_sys-resources/caution_3.0-en-us.png"> </span><div class="cautionbody"><ul id="EN-US_TOPIC_0000001233628605__ul1624011599591"><li id="EN-US_TOPIC_0000001233628605__li024013598596">Note that <strong id="EN-US_TOPIC_0000001233628605__b1326319169389">'null'::json</strong> and <strong id="EN-US_TOPIC_0000001233628605__b1359041973812">null::json</strong> are different. The difference is similar to that between the strings <strong id="EN-US_TOPIC_0000001233628605__b115035653810">str=""</strong> and <strong id="EN-US_TOPIC_0000001233628605__b12631195993819">str=null</strong>.</li><li id="EN-US_TOPIC_0000001233628605__li72401959165920">For numbers, when scientific notation is used, JSONB expands them, while JSON stores an exact copy of the input text.</li></ul>
</div></div>
<div class="section" id="EN-US_TOPIC_0000001233628605__section0104174211010"><h4 class="sectiontitle">JSONB Advanced Features</h4><p id="EN-US_TOPIC_0000001233628605__p1496860315">The main difference between JSON and JSONB is the storage mode. JSONB stores parsed binary data, which reflects the JSON hierarchy and facilitates direct access. Therefore, JSONB has more advanced features than JSON.</p>
<p id="EN-US_TOPIC_0000001233628605__p165041633203713"><strong id="EN-US_TOPIC_0000001233628605__b37651046104013">Normalizes formats</strong></p>
<ul id="EN-US_TOPIC_0000001233628605__ul39961510835"><li id="EN-US_TOPIC_0000001233628605__li0504183315375">After the input <strong id="EN-US_TOPIC_0000001233628605__b5510620415">object-json</strong> string is parsed into JSONB binary, semantically irrelevant details are naturally discarded, for example, spaces:<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001233628605__screen1487822810316"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal">1</span>
<span class="normal">2</span>
<span class="normal">3</span>
<span class="normal">4</span>
<span class="normal">5</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">SELECT</span><span class="w"> </span><span class="s1">' [1, &quot; a &quot;, {&quot;a&quot; :1 }] '</span><span class="p">::</span><span class="n">jsonb</span><span class="p">;</span>
<span class="w"> </span><span class="n">jsonb</span>
<span class="c1">----------------------</span>
<span class="p">[</span><span class="mi">1</span><span class="p">,</span><span class="w"> </span><span class="ss">&quot; a &quot;</span><span class="p">,</span><span class="w"> </span><span class="err">{</span><span class="ss">&quot;a&quot;</span><span class="p">:</span><span class="w"> </span><span class="mi">1</span><span class="err">}</span><span class="p">]</span>
<span class="p">(</span><span class="mi">1</span><span class="w"> </span><span class="k">row</span><span class="p">)</span>
</pre></div></td></tr></table></div>
</div>
</li><li id="EN-US_TOPIC_0000001233628605__li11504153314376">For <strong id="EN-US_TOPIC_0000001233628605__b198631538154119">object-json</strong>, duplicate key-values are deleted and only the last key-value is retained. An example is as follows:<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001233628605__screen168096816419"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal">1</span>
<span class="normal">2</span>
<span class="normal">3</span>
<span class="normal">4</span>
<span class="normal">5</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">SELECT</span><span class="w"> </span><span class="s1">'{&quot;a&quot; : 1, &quot;a&quot; : 2}'</span><span class="p">::</span><span class="n">jsonb</span><span class="p">;</span>
<span class="n">jsonb</span>
<span class="c1">----------</span>
<span class="err">{</span><span class="ss">&quot;a&quot;</span><span class="p">:</span><span class="w"> </span><span class="mi">2</span><span class="err">}</span>
<span class="p">(</span><span class="mi">1</span><span class="w"> </span><span class="k">row</span><span class="p">)</span>
</pre></div></td></tr></table></div>
</div>
</li><li id="EN-US_TOPIC_0000001233628605__li1130861919317">For <strong id="EN-US_TOPIC_0000001233628605__b2404111234210">object-json</strong>, key-values will be re-sorted. The sorting rule is as follows: 1. Longer key-values are sorted last. 2. If the key-values are of the same length, the key-values with a larger ASCII code are sorted last. An example is as follows:<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001233628605__screen940019311542"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal">1</span>
<span class="normal">2</span>
<span class="normal">3</span>
<span class="normal">4</span>
<span class="normal">5</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">SELECT</span><span class="w"> </span><span class="s1">'{&quot;aa&quot; : 1, &quot;b&quot; : 2, &quot;a&quot; : 3}'</span><span class="p">::</span><span class="n">jsonb</span><span class="p">;</span>
<span class="w"> </span><span class="n">jsonb</span>
<span class="c1">---------------------------</span>
<span class="err">{</span><span class="ss">&quot;a&quot;</span><span class="p">:</span><span class="w"> </span><span class="mi">3</span><span class="p">,</span><span class="w"> </span><span class="ss">&quot;b&quot;</span><span class="p">:</span><span class="w"> </span><span class="mi">2</span><span class="p">,</span><span class="w"> </span><span class="ss">&quot;aa&quot;</span><span class="p">:</span><span class="w"> </span><span class="mi">1</span><span class="err">}</span>
<span class="p">(</span><span class="mi">1</span><span class="w"> </span><span class="k">row</span><span class="p">)</span>
</pre></div></td></tr></table></div>
</div>
</li></ul>
</div>
<p id="EN-US_TOPIC_0000001233628605__p750403393719"><strong id="EN-US_TOPIC_0000001233628605__b14618143811433">Compares sizes</strong></p>
<p id="EN-US_TOPIC_0000001233628605__p1050493311378">Format normalization ensures that only one form of JSONB data exists in the same semantics. Therefore, sizes can be compared according to a specific rule.</p>
<ol id="EN-US_TOPIC_0000001233628605__ol165051333183718"><li id="EN-US_TOPIC_0000001233628605__li175051433143720">First, type comparison: <strong id="EN-US_TOPIC_0000001233628605__b39006382924915">object-jsonb</strong> &gt; <strong id="EN-US_TOPIC_0000001233628605__b11287015024915">array-jsonb</strong> &gt; <strong id="EN-US_TOPIC_0000001233628605__b98653569824915">bool-jsonb</strong> &gt; <strong id="EN-US_TOPIC_0000001233628605__b695267224915">num-jsonb</strong> &gt; <strong id="EN-US_TOPIC_0000001233628605__b174556811824915">str-jsonb</strong> &gt; <strong id="EN-US_TOPIC_0000001233628605__b102324966624915">null-jsonb</strong></li><li id="EN-US_TOPIC_0000001233628605__li1850513337375">Content is compared if the data type is the same:<ul id="EN-US_TOPIC_0000001233628605__ul7505163343712"><li id="EN-US_TOPIC_0000001233628605__li0505143319376"><strong id="EN-US_TOPIC_0000001233628605__b1644784454415">str-json</strong>: The default text sorting rule of the database is used for comparison. A positive value indicates greater than, a negative value indicates less than, and <strong id="EN-US_TOPIC_0000001233628605__b3456104413441">0</strong> indicates equal.</li><li id="EN-US_TOPIC_0000001233628605__li17505163313377"><strong id="EN-US_TOPIC_0000001233628605__b24193862924915">num-json</strong>: numeric comparison</li><li id="EN-US_TOPIC_0000001233628605__li850513313719"><strong id="EN-US_TOPIC_0000001233628605__b128236824224915">bool-json</strong>: <strong id="EN-US_TOPIC_0000001233628605__b209431043024915">true</strong> &gt; <strong id="EN-US_TOPIC_0000001233628605__b118756658124915">false</strong></li><li id="EN-US_TOPIC_0000001233628605__li8505133123719"><strong id="EN-US_TOPIC_0000001233628605__b79935799324915">array-jsonb</strong>: long elements &gt; short elements. If the lengths are the same, compare each element in sequence.</li><li id="EN-US_TOPIC_0000001233628605__li0505183363719"><strong id="EN-US_TOPIC_0000001233628605__b1595910575219">object-jsonb</strong>: long key-value pairs &gt; short key-value pairs. If the lengths are the same, compare each key-value pair in sequence, first the key and then the value.</li></ul>
</li></ol>
<div class="caution" id="EN-US_TOPIC_0000001233628605__note19201183915510"><span class="cautiontitle"><img src="public_sys-resources/caution_3.0-en-us.png"> </span><div class="cautionbody"><p id="EN-US_TOPIC_0000001233628605__p1250643363718">For comparison within the <strong id="EN-US_TOPIC_0000001233628605__b1361022064815">object-jsonb</strong> type, the final result after format sorting is used for comparison. Therefore, the comparison result may not be so intuitive as direct input.</p>
</div></div>
<p id="EN-US_TOPIC_0000001233628605__p1450612337378"><strong id="EN-US_TOPIC_0000001233628605__b750616339372">Creates an index</strong></p>
<p id="EN-US_TOPIC_0000001233628605__p982116404413">B-Tree and GIN indexes can be created for the JSONB type.</p>
<p id="EN-US_TOPIC_0000001233628605__p18801248989">If the entire JSONB column uses a Btree index, the following operators can be used: =, &lt;, &lt;=, &gt;, and &gt;=.</p>
<p id="EN-US_TOPIC_0000001233628605__p991695441910">Example: Create the table <strong id="EN-US_TOPIC_0000001233628605__b173288494554">test</strong> and insert data into it.</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001233628605__screen0992123982012"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal">1</span>
<span class="normal">2</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">CREATE</span><span class="w"> </span><span class="k">TABLE</span><span class="w"> </span><span class="n">test</span><span class="p">(</span><span class="n">id</span><span class="w"> </span><span class="n">bigserial</span><span class="p">,</span><span class="w"> </span><span class="k">data</span><span class="w"> </span><span class="n">JSONB</span><span class="p">,</span><span class="w"> </span><span class="k">PRIMARY</span><span class="w"> </span><span class="k">KEY</span><span class="w"> </span><span class="p">(</span><span class="n">id</span><span class="p">));</span>
<span class="k">INSERT</span><span class="w"> </span><span class="k">INTO</span><span class="w"> </span><span class="n">test</span><span class="p">(</span><span class="k">data</span><span class="p">)</span><span class="w"> </span><span class="k">VALUES</span><span class="p">(</span><span class="s1">'{&quot;name&quot;:&quot;Jack&quot;, &quot;age&quot;:10, &quot;nick_name&quot;:[&quot;Jacky&quot;,&quot;baobao&quot;], &quot;phone_list&quot;:[&quot;1111&quot;,&quot;2222&quot;]}'</span><span class="p">::</span><span class="n">jsonb</span><span class="p">);</span>
</pre></div></td></tr></table></div>
</div>
<ul id="EN-US_TOPIC_0000001233628605__ul10537125017208"><li id="EN-US_TOPIC_0000001233628605__li105379503203">Create a btree index.<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001233628605__screen148114517371"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal">1</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">CREATE</span><span class="w"> </span><span class="k">INDEX</span><span class="w"> </span><span class="n">idx_test_data_age</span><span class="w"> </span><span class="k">ON</span><span class="w"> </span><span class="n">test</span><span class="w"> </span><span class="k">USING</span><span class="w"> </span><span class="n">btree</span><span class="p">(((</span><span class="k">data</span><span class="o">-&gt;&gt;</span><span class="s1">'age'</span><span class="p">)::</span><span class="nb">int</span><span class="p">));</span>
</pre></div></td></tr></table></div>
</div>
<div class="p" id="EN-US_TOPIC_0000001233628605__p16768125212393">Use the Btree index to query data of "age&gt;1".<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001233628605__screen105307495396"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal">1</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">SELECT</span><span class="w"> </span><span class="o">*</span><span class="w"> </span><span class="k">FROM</span><span class="w"> </span><span class="n">test</span><span class="w"> </span><span class="k">WHERE</span><span class="w"> </span><span class="p">(</span><span class="k">data</span><span class="o">-&gt;&gt;</span><span class="s1">'age'</span><span class="p">)::</span><span class="nb">int</span><span class="o">&gt;</span><span class="mi">1</span><span class="p">;</span>
</pre></div></td></tr></table></div>
</div>
</div>
</li><li id="EN-US_TOPIC_0000001233628605__li74201969214">Creating a Gin Index<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001233628605__screen171960154018"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal">1</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">CREATE</span><span class="w"> </span><span class="k">INDEX</span><span class="w"> </span><span class="n">idx_test_data</span><span class="w"> </span><span class="k">ON</span><span class="w"> </span><span class="n">test</span><span class="w"> </span><span class="k">USING</span><span class="w"> </span><span class="n">gin</span><span class="w"> </span><span class="p">(</span><span class="k">data</span><span class="p">);</span>
</pre></div></td></tr></table></div>
</div>
<div class="p" id="EN-US_TOPIC_0000001233628605__p1282681214402">-- Use the GIN index to check whether there are top-level keywords.<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001233628605__screen81560816408"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal">1</span>
<span class="normal">2</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">SELECT</span><span class="w"> </span><span class="o">*</span><span class="w"> </span><span class="k">FROM</span><span class="w"> </span><span class="n">test</span><span class="w"> </span><span class="k">WHERE</span><span class="w"> </span><span class="k">data</span><span class="w"> </span><span class="o">?</span><span class="w"> </span><span class="s1">'id'</span><span class="p">;</span>
<span class="k">SELECT</span><span class="w"> </span><span class="o">*</span><span class="w"> </span><span class="k">FROM</span><span class="w"> </span><span class="n">test</span><span class="w"> </span><span class="k">WHERE</span><span class="w"> </span><span class="k">data</span><span class="w"> </span><span class="o">?|</span><span class="w"> </span><span class="nb">array</span><span class="p">[</span><span class="s1">'id'</span><span class="p">,</span><span class="s1">'name'</span><span class="p">];</span>
</pre></div></td></tr></table></div>
</div>
</div>
</li><li id="EN-US_TOPIC_0000001233628605__li633172612219">Use the GIN index to check whether there are non-top-level keywords.<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001233628605__screen643762234016"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal">1</span>
<span class="normal">2</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">CREATE</span><span class="w"> </span><span class="k">INDEX</span><span class="w"> </span><span class="n">idx_test_data_nick_name</span><span class="w"> </span><span class="k">ON</span><span class="w"> </span><span class="n">test</span><span class="w"> </span><span class="k">USING</span><span class="w"> </span><span class="n">gin</span><span class="p">((</span><span class="k">data</span><span class="o">-&gt;</span><span class="s1">'nick_name'</span><span class="p">));</span>
<span class="k">SELECT</span><span class="w"> </span><span class="o">*</span><span class="w"> </span><span class="k">FROM</span><span class="w"> </span><span class="n">test</span><span class="w"> </span><span class="k">WHERE</span><span class="w"> </span><span class="k">data</span><span class="o">-&gt;</span><span class="s1">'nick_name'</span><span class="w"> </span><span class="o">?</span><span class="w"> </span><span class="s1">'Jacky'</span><span class="p">;</span>
</pre></div></td></tr></table></div>
</div>
</li><li id="EN-US_TOPIC_0000001233628605__li12641113582117">Use @&gt; to check whether JSON contains nested JSON objects.<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001233628605__screen163461540124015"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal">1</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">SELECT</span><span class="w"> </span><span class="o">*</span><span class="w"> </span><span class="k">FROM</span><span class="w"> </span><span class="n">test</span><span class="w"> </span><span class="k">WHERE</span><span class="w"> </span><span class="k">data</span><span class="w"> </span><span class="o">@&gt;</span><span class="w"> </span><span class="s1">'{&quot;age&quot;:10, &quot;nick_name&quot;:[&quot;Jacky&quot;]}'</span><span class="p">;</span>
</pre></div></td></tr></table></div>
</div>
</li></ul>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001233628605__screen1924171617318"></div>
<p id="EN-US_TOPIC_0000001233628605__p12436162118107"><strong id="EN-US_TOPIC_0000001233628605__b152639010512">Includes elements in a JSON</strong></p>
<p id="EN-US_TOPIC_0000001233628605__p1650603310374">An important capability of JSONB is to query whether a JSON contains some elements or whether some elements exist in a JSON.</p>
<ul id="EN-US_TOPIC_0000001233628605__ul02341553131819"><li id="EN-US_TOPIC_0000001233628605__li7234145314181">Simple scalar/original values contain only the same value:<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001233628605__screen8282152419178"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal">1</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">SELECT</span><span class="w"> </span><span class="s1">'&quot;foo&quot;'</span><span class="p">::</span><span class="n">jsonb</span><span class="w"> </span><span class="o">@&gt;</span><span class="w"> </span><span class="s1">'&quot;foo&quot;'</span><span class="p">::</span><span class="n">jsonb</span><span class="p">;</span>
</pre></div></td></tr></table></div>
</div>
</li><li id="EN-US_TOPIC_0000001233628605__li823425341816">The array on the left contains the string on the right.<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001233628605__screen3810440121713"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal">1</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">SELECT</span><span class="w"> </span><span class="s1">'[1, &quot;aa&quot;, 3]'</span><span class="p">::</span><span class="n">jsonb</span><span class="w"> </span><span class="o">?</span><span class="w"> </span><span class="s1">'aa'</span><span class="p">;</span>
</pre></div></td></tr></table></div>
</div>
</li><li id="EN-US_TOPIC_0000001233628605__li523425381810">The array on the left contains all elements of the array on the right. The sequence and repetition are not important.<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001233628605__screen81903503173"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal">1</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">SELECT</span><span class="w"> </span><span class="s1">'[1, 2, 3]'</span><span class="p">::</span><span class="n">jsonb</span><span class="w"> </span><span class="o">@&gt;</span><span class="w"> </span><span class="s1">'[1, 3, 1]'</span><span class="p">::</span><span class="n">jsonb</span><span class="p">;</span>
</pre></div></td></tr></table></div>
</div>
</li><li id="EN-US_TOPIC_0000001233628605__li17234353171818">The <strong id="EN-US_TOPIC_0000001233628605__b710113825615">object-json</strong> on the left contains all key-values of the <strong id="EN-US_TOPIC_0000001233628605__b17101189563">object-json</strong> on the right.<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001233628605__screen61301054189"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal">1</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">SELECT</span><span class="w"> </span><span class="s1">'{&quot;product&quot;: &quot;PostgreSQL&quot;, &quot;version&quot;: 9.4, &quot;jsonb&quot;:true}'</span><span class="p">::</span><span class="n">jsonb</span><span class="w"> </span><span class="o">@&gt;</span><span class="w"> </span><span class="s1">'{&quot;version&quot;:9.4}'</span><span class="p">::</span><span class="n">jsonb</span><span class="p">;</span>
</pre></div></td></tr></table></div>
</div>
</li><li id="EN-US_TOPIC_0000001233628605__li6234175321812">The array on the left does not contain all elements in the array on the right, because the three elements in the array on the left are <strong id="EN-US_TOPIC_0000001233628605__b5290154015568">1</strong>, <strong id="EN-US_TOPIC_0000001233628605__b129054065619">2</strong>, and <strong id="EN-US_TOPIC_0000001233628605__b029024019560">[1,3]</strong>, and the elements on the right are <strong id="EN-US_TOPIC_0000001233628605__b1229054025614">1</strong> and <strong id="EN-US_TOPIC_0000001233628605__b4290154017563">3</strong>.<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001233628605__screen7853821101811"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal">1</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">SELECT</span><span class="w"> </span><span class="s1">'[1, 2, [1, 3]]'</span><span class="p">::</span><span class="n">jsonb</span><span class="w"> </span><span class="o">@&gt;</span><span class="w"> </span><span class="s1">'[1, 3]'</span><span class="p">::</span><span class="n">jsonb</span><span class="p">;</span><span class="w"> </span><span class="c1">-- false</span>
</pre></div></td></tr></table></div>
</div>
</li><li id="EN-US_TOPIC_0000001233628605__li823565311183">The array on the right does not contain all elements in the array on the left in the following example:<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001233628605__screen948624418183"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal">1</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">SELECT</span><span class="w"> </span><span class="s1">'{&quot;foo&quot;: {&quot;bar&quot;: &quot;baz&quot;}}'</span><span class="p">::</span><span class="n">jsonb</span><span class="w"> </span><span class="o">@&gt;</span><span class="w"> </span><span class="s1">'{&quot;bar&quot;: &quot;baz&quot;}'</span><span class="p">::</span><span class="n">jsonb</span><span class="p">;</span><span class="w"> </span><span class="c1">-- false</span>
</pre></div></td></tr></table></div>
</div>
</li></ul>
</div>
<div>
<div class="familylinks">
<div class="parentlink"><strong>Parent topic:</strong> <a href="dws_06_0008.html">Data Types</a></div>
</div>
</div>