doc-exports/docs/dws/dev/dws_04_0448.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

592 lines
109 KiB
HTML

<a name="EN-US_TOPIC_0000001188163564"></a><a name="EN-US_TOPIC_0000001188163564"></a>
<h1 class="topictitle1">Optimizing Subqueries</h1>
<div id="body8662426"><div class="section" id="EN-US_TOPIC_0000001188163564__s89f7b5b363ae496596646f2b19736667"><h4 class="sectiontitle">What Is a Subquery</h4><p id="EN-US_TOPIC_0000001188163564__a6dd3f01e5205499f9150aa40f812876c">When an application runs a SQL statement to operate the database, a large number of subqueries are used because they are more clear than table join. Especially in complicated query statements, subqueries have more complete and independent semantics, which makes SQL statements clearer and easy to understand. Therefore, subqueries are widely used.</p>
<p id="EN-US_TOPIC_0000001188163564__a35dece67761a47b887e3c81d17297f9d">In <span id="EN-US_TOPIC_0000001188163564__text944110597">GaussDB(DWS)</span>, subqueries can also be called sublinks based on the location of subqueries in SQL statements.</p>
<ul id="EN-US_TOPIC_0000001188163564__u39bda620553f44b49cd13f3bfa9a7f3b"><li id="EN-US_TOPIC_0000001188163564__l283c91bd656942708467d0eec56fbb5f">Subquery: corresponds to a scope table (RangeTblEntry) in the query parse tree. That is, a subquery is a <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b28731037102514">SELECT</strong> statement following immediately after the <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b4548718142616">FROM</strong> keyword.</li><li id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_li93141270456">Sublink: corresponds to an expression in the query parsing tree. That is, a sublink is a statement in the <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b3403105052918">WHERE</strong> or <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b16110948142911">ON</strong> clause or in the target list.<div class="p" id="EN-US_TOPIC_0000001188163564__a5fde0ba6ead3492cbbd54bb8959d8b0a">In conclusion, a subquery is a scope table and a sublink is an expression in the query parsing tree. A sublink can be found in constraint conditions and expressions. In <span id="EN-US_TOPIC_0000001188163564__text1124079524">GaussDB(DWS)</span>, sublinks can be classified into the following types:<ul id="EN-US_TOPIC_0000001188163564__u4c2383de15454248aaab0b47f7c8a30b"><li id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_li2747273457">exist_sublink: corresponding to the <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b5700181810019">EXIST</strong> and <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b205131722707">NOT EXIST</strong> statements.</li><li id="EN-US_TOPIC_0000001188163564__l31227632ed7f436084664ab4cbb16b16">any_sublink: corresponding to the <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b44751971118">OP ANY(SELECT...)</strong> statement. <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b18721825126">OP</strong> can be the <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b1910913409111">IN</strong>, <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b3215648815">&lt;</strong>, <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b163155536114">&gt;</strong>, or <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b29001702024">=</strong> operator.</li><li id="EN-US_TOPIC_0000001188163564__l5e121b85bddf493784693ee9d0ca5d3a">all_sublink: corresponding to the <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b156409563217">OP ALL(SELECT...)</strong> statement. <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b5785107339">OP</strong> can be the <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b127858710315">IN</strong>, <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b177852074319">&lt;</strong>, <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b3785373315">&gt;</strong>, or <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b67851676320">=</strong> operator.</li><li id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_li37471971451">rowcompare_sublink: corresponding to the <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b475171417417">RECORD OP (SELECT...)</strong> statement.</li><li id="EN-US_TOPIC_0000001188163564__l20bc62613fde4ad2b4293c6bdd91be5a">expr_sublink: corresponding to the<strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b715216431125"> (</strong><strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b5518553999">SELECT</strong> with a single target list item<strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b8817546161218">)</strong> statement.</li><li id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_li77471670455">array_sublink: corresponding to the <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b1866714161759">ARRAY(SELECT...)</strong> statement.</li><li id="EN-US_TOPIC_0000001188163564__l30a5163bcf444e488bbfd1af355dda25">cte_sublink: corresponding to the <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b3963909142">WITH(...)</strong> statement.</li></ul>
</div>
<p id="EN-US_TOPIC_0000001188163564__a283066567494481b865d5ec0705e5621">The sublinks commonly used in OLAP and HTAP are exist_sublink and any_sublink. The sublinks are pulled up by the optimization engine of <span id="EN-US_TOPIC_0000001188163564__text1066099892">GaussDB(DWS)</span>. Because of the flexible use of subqueries in SQL statements, complex subqueries may affect query performance. Subqueries are classified into non-correlated subqueries and correlated subqueries.</p>
<ul id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_ul26210451347"><li id="EN-US_TOPIC_0000001188163564__l92fabb6a7dc94f45a71ca928e4e9d3e6"><strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b135211517151918">Non-correlated subquery</strong><p id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_p10957790317">The execution of a subquery is independent from any attribute of outer queries. In this way, a subquery can be executed before outer queries.</p>
<p id="EN-US_TOPIC_0000001188163564__a5d3cc1cbc11b4b7a8dd64563bff8a950">Example:</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188163564__s486317ce988e43d1b9f131133e050b44"><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>
<span class="normal"> 6</span>
<span class="normal"> 7</span>
<span class="normal"> 8</span>
<span class="normal"> 9</span>
<span class="normal">10</span>
<span class="normal">11</span>
<span class="normal">12</span>
<span class="normal">13</span>
<span class="normal">14</span>
<span class="normal">15</span>
<span class="normal">16</span>
<span class="normal">17</span>
<span class="normal">18</span>
<span class="normal">19</span>
<span class="normal">20</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">select</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">c1</span><span class="p">,</span><span class="n">t1</span><span class="p">.</span><span class="n">c2</span>
<span class="k">from</span><span class="w"> </span><span class="n">t1</span>
<span class="k">where</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">c1</span><span class="w"> </span><span class="k">in</span><span class="w"> </span><span class="p">(</span>
<span class="w"> </span><span class="k">select</span><span class="w"> </span><span class="n">c2</span>
<span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">t2</span>
<span class="w"> </span><span class="k">where</span><span class="w"> </span><span class="n">t2</span><span class="p">.</span><span class="n">c2</span><span class="w"> </span><span class="k">IN</span><span class="w"> </span><span class="p">(</span><span class="mi">2</span><span class="p">,</span><span class="mi">3</span><span class="p">,</span><span class="mi">4</span><span class="p">)</span>
<span class="p">);</span>
<span class="w"> </span><span class="n">QUERY</span><span class="w"> </span><span class="n">PLAN</span>
<span class="c1">---------------------------------------------------------------</span>
<span class="n">Streaming</span><span class="w"> </span><span class="p">(</span><span class="k">type</span><span class="p">:</span><span class="w"> </span><span class="n">GATHER</span><span class="p">)</span>
<span class="w"> </span><span class="n">Node</span><span class="o">/</span><span class="n">s</span><span class="p">:</span><span class="w"> </span><span class="k">All</span><span class="w"> </span><span class="n">datanodes</span>
<span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="n">Hash</span><span class="w"> </span><span class="k">Right</span><span class="w"> </span><span class="n">Semi</span><span class="w"> </span><span class="k">Join</span>
<span class="w"> </span><span class="n">Hash</span><span class="w"> </span><span class="n">Cond</span><span class="p">:</span><span class="w"> </span><span class="p">(</span><span class="n">t2</span><span class="p">.</span><span class="n">c2</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">c1</span><span class="p">)</span>
<span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="n">Streaming</span><span class="p">(</span><span class="k">type</span><span class="p">:</span><span class="w"> </span><span class="n">REDISTRIBUTE</span><span class="p">)</span>
<span class="w"> </span><span class="n">Spawn</span><span class="w"> </span><span class="k">on</span><span class="p">:</span><span class="w"> </span><span class="k">All</span><span class="w"> </span><span class="n">datanodes</span>
<span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="n">Seq</span><span class="w"> </span><span class="n">Scan</span><span class="w"> </span><span class="k">on</span><span class="w"> </span><span class="n">t2</span>
<span class="w"> </span><span class="n">Filter</span><span class="p">:</span><span class="w"> </span><span class="p">(</span><span class="n">c2</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="k">ANY</span><span class="w"> </span><span class="p">(</span><span class="s1">'{2,3,4}'</span><span class="p">::</span><span class="nb">integer</span><span class="p">[]))</span>
<span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="n">Hash</span>
<span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="n">Seq</span><span class="w"> </span><span class="n">Scan</span><span class="w"> </span><span class="k">on</span><span class="w"> </span><span class="n">t1</span>
<span class="p">(</span><span class="mi">10</span><span class="w"> </span><span class="k">rows</span><span class="p">)</span>
</pre></div></td></tr></table></div>
</div>
</li></ul>
<ul id="EN-US_TOPIC_0000001188163564__ue1e11d82f29744e5bb9febd932005cd0"><li id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_li15140794355"><strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b17861315173513">Correlated subquery</strong><p id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_p93094161316">The execution of a subquery depends on some attributes of outer queries which are used as <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b162211753103819">AND</strong> conditions of the subquery. In the following example, <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b67260153404">t1.c1</strong> in the <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b16331491407">t2.c1 = t1.c1</strong> condition is a dependent attribute. Such a subquery depends on outer queries and needs to be executed once for each outer query.</p>
<p id="EN-US_TOPIC_0000001188163564__a673bad0d18ae439ba61e79ed3592225f">Example:</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188163564__sd52e71ca442d4531881a405aa851616c"><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>
<span class="normal"> 6</span>
<span class="normal"> 7</span>
<span class="normal"> 8</span>
<span class="normal"> 9</span>
<span class="normal">10</span>
<span class="normal">11</span>
<span class="normal">12</span>
<span class="normal">13</span>
<span class="normal">14</span>
<span class="normal">15</span>
<span class="normal">16</span>
<span class="normal">17</span>
<span class="normal">18</span>
<span class="normal">19</span>
<span class="normal">20</span>
<span class="normal">21</span>
<span class="normal">22</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">select</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">c1</span><span class="p">,</span><span class="n">t1</span><span class="p">.</span><span class="n">c2</span>
<span class="k">from</span><span class="w"> </span><span class="n">t1</span>
<span class="k">where</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">c1</span><span class="w"> </span><span class="k">in</span><span class="w"> </span><span class="p">(</span>
<span class="w"> </span><span class="k">select</span><span class="w"> </span><span class="n">c2</span>
<span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">t2</span>
<span class="w"> </span><span class="k">where</span><span class="w"> </span><span class="n">t2</span><span class="p">.</span><span class="n">c1</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">c1</span><span class="w"> </span><span class="k">AND</span><span class="w"> </span><span class="n">t2</span><span class="p">.</span><span class="n">c2</span><span class="w"> </span><span class="k">in</span><span class="w"> </span><span class="p">(</span><span class="mi">2</span><span class="p">,</span><span class="mi">3</span><span class="p">,</span><span class="mi">4</span><span class="p">)</span>
<span class="p">);</span>
<span class="w"> </span><span class="n">QUERY</span><span class="w"> </span><span class="n">PLAN</span>
<span class="c1">-----------------------------------------------------------------------</span>
<span class="n">Streaming</span><span class="w"> </span><span class="p">(</span><span class="k">type</span><span class="p">:</span><span class="w"> </span><span class="n">GATHER</span><span class="p">)</span>
<span class="w"> </span><span class="n">Node</span><span class="o">/</span><span class="n">s</span><span class="p">:</span><span class="w"> </span><span class="k">All</span><span class="w"> </span><span class="n">datanodes</span>
<span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="n">Seq</span><span class="w"> </span><span class="n">Scan</span><span class="w"> </span><span class="k">on</span><span class="w"> </span><span class="n">t1</span>
<span class="w"> </span><span class="n">Filter</span><span class="p">:</span><span class="w"> </span><span class="p">(</span><span class="n">SubPlan</span><span class="w"> </span><span class="mi">1</span><span class="p">)</span>
<span class="w"> </span><span class="n">SubPlan</span><span class="w"> </span><span class="mi">1</span>
<span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="k">Result</span>
<span class="w"> </span><span class="n">Filter</span><span class="p">:</span><span class="w"> </span><span class="p">(</span><span class="n">t2</span><span class="p">.</span><span class="n">c1</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">c1</span><span class="p">)</span>
<span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="n">Materialize</span>
<span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="n">Streaming</span><span class="p">(</span><span class="k">type</span><span class="p">:</span><span class="w"> </span><span class="n">BROADCAST</span><span class="p">)</span>
<span class="w"> </span><span class="n">Spawn</span><span class="w"> </span><span class="k">on</span><span class="p">:</span><span class="w"> </span><span class="k">All</span><span class="w"> </span><span class="n">datanodes</span>
<span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="n">Seq</span><span class="w"> </span><span class="n">Scan</span><span class="w"> </span><span class="k">on</span><span class="w"> </span><span class="n">t2</span>
<span class="w"> </span><span class="n">Filter</span><span class="p">:</span><span class="w"> </span><span class="p">(</span><span class="n">c2</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="k">ANY</span><span class="w"> </span><span class="p">(</span><span class="s1">'{2,3,4}'</span><span class="p">::</span><span class="nb">integer</span><span class="p">[]))</span>
<span class="p">(</span><span class="mi">12</span><span class="w"> </span><span class="k">rows</span><span class="p">)</span>
</pre></div></td></tr></table></div>
</div>
</li></ul>
</li></ul>
</div>
<div class="section" id="EN-US_TOPIC_0000001188163564__sf889dabb629b4a0086497d5d0932210a"><h4 class="sectiontitle"><span id="EN-US_TOPIC_0000001188163564__text1817736340">GaussDB(DWS)</span> SubLink Optimization</h4><p id="EN-US_TOPIC_0000001188163564__abb7ae9fbc58a41fcbfe3917fcbac91b7">A subquery is pulled up to join with tables in outer queries, preventing the subquery from being converted into the combination of a subplan and broadcast. You can run the <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b465952018541">EXPLAIN</strong> statement to check whether a subquery is converted into the combination of a subplan and broadcast.</p>
<p id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_p10622345366">Example:</p>
<p id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_p126243423617"><span><img id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_image062034183619" src="figure/en-us_image_0000001188163792.png"></span></p>
<ul id="EN-US_TOPIC_0000001188163564__ubf8d7c098fb34dd4bee46dcbce44ae73"><li id="EN-US_TOPIC_0000001188163564__l9db3f0383ed94f20bd401f9b9dffbae5">Sublink-release supported by <span id="EN-US_TOPIC_0000001188163564__text1749563421">GaussDB(DWS)</span><ul id="EN-US_TOPIC_0000001188163564__u9755b4929b2045feb0771bf6a1e5c149"><li id="EN-US_TOPIC_0000001188163564__lb2d22dc7b7cf4b0b849d22869343f1cf">Pulling up the <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b48467361838">IN</strong> sublink<ul id="EN-US_TOPIC_0000001188163564__uca62214cabb34ee1a4295af338b771ea"><li id="EN-US_TOPIC_0000001188163564__la6142076958249f98ff686275faae81b">The subquery cannot contain columns in the outer query (columns in more outer queries are allowed).</li><li id="EN-US_TOPIC_0000001188163564__lebb71b175f8643b3a0bd99e76dcb3954">The subquery cannot contain volatile functions.</li></ul>
<p id="EN-US_TOPIC_0000001188163564__aa03474399d804ef5bf7cdb0d4dec1288"><span><img id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_image20621334113611" src="figure/en-us_image_0000001188642234.png"></span></p>
</li><li id="EN-US_TOPIC_0000001188163564__lf1ef74b21be948ce899b26ad6b4fa597">Pulling up the <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b186144791">EXISTS</strong> sublink<p id="EN-US_TOPIC_0000001188163564__a295cad43002a40afa3c55fe3221408cc">The <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b104996127912">WHERE</strong> clause must contain a column in the outer query. Other parts of the subquery cannot contain the column. Other restrictions are as follows:</p>
<ul id="EN-US_TOPIC_0000001188163564__u152a8fd61b0248f3b3a50e8eacf9cc45"><li id="EN-US_TOPIC_0000001188163564__l1ba7e3e607104a4d95856803ad9bf412">The subquery must contain the <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b14747105201013">FROM</strong> clause.</li><li id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_li65037328337">The subquery cannot contain the <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b1442099117">WITH</strong> clause.</li><li id="EN-US_TOPIC_0000001188163564__lb0cd1bbc031b41169ae3afa203997f80">The subquery cannot contain aggregate functions.</li><li id="EN-US_TOPIC_0000001188163564__l149f12c069ad461aa9d8aa3266d7d3b0">The subquery cannot contain a <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b1236413508288">SET</strong>, <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b7530718292">SORT</strong>, <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b16870185112916">LIMIT</strong>, <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b14891027112919">WindowAgg</strong>, or <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b892723572911">HAVING</strong> operation.</li><li id="EN-US_TOPIC_0000001188163564__ld8999d500dab4c15bc522d899a83ce9e">The subquery cannot contain volatile functions.</li></ul>
<p id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_p182903943318"><span><img id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_image16293473616" src="figure/en-us_image_0000001233883399.png"></span></p>
</li><li id="EN-US_TOPIC_0000001188163564__l418d3627b7914a74a99385227ecf30b8">Pulling up an equivalent query containing aggregation functions<p id="EN-US_TOPIC_0000001188163564__ae0555f799dc642d0877d900618201540"><a name="EN-US_TOPIC_0000001188163564__l418d3627b7914a74a99385227ecf30b8"></a><a name="l418d3627b7914a74a99385227ecf30b8"></a>The <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b145154391301">WHERE</strong> condition of the subquery must contain a column from the outer query. Equivalence comparison must be performed between this column and related columns in tables of the subquery. These conditions must be connected using <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b132051944143120">AND</strong>. Other parts of the subquery cannot contain the column. Other restrictions are as follows:</p>
<ul id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_ul05971419192"><li id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_li87647617195">The expression in the <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b11171557111811">WHERE</strong> condition of the subquery must be table columns.</li><li id="EN-US_TOPIC_0000001188163564__l79960ec4b6e24ecd833a2b21a2e0a632">After the <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b17636659161914">SELECT</strong> keyword of the subquery, there must be only one output column. The output column must be an aggregation function (for example, <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b159521823162017">MAX</strong>), and the parameter (for example, <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b128934992111">t2.c2</strong>) of the aggregate function cannot be columns of a table (for example, <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b9535174410216">t1</strong>) in outer quires. The aggregate function cannot be <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b841757102214">COUNT</strong>.<div class="p" id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_p311751133511">For example, the following subquery can be pulled up:<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188163564__sc9b46f573043496985d3092d541896d9"><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="o">*</span><span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">t1</span><span class="w"> </span><span class="k">where</span><span class="w"> </span><span class="n">c1</span><span class="w"> </span><span class="o">&gt;</span><span class="p">(</span>
<span class="w"> </span><span class="k">select</span><span class="w"> </span><span class="k">max</span><span class="p">(</span><span class="n">t2</span><span class="p">.</span><span class="n">c1</span><span class="p">)</span><span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">t2</span><span class="w"> </span><span class="k">where</span><span class="w"> </span><span class="n">t2</span><span class="p">.</span><span class="n">c1</span><span class="o">=</span><span class="n">t1</span><span class="p">.</span><span class="n">c1</span>
<span class="p">);</span>
</pre></div></td></tr></table></div>
</div>
</div>
<p id="EN-US_TOPIC_0000001188163564__a1c5a27591d9c4064a649770cf415a58f">The following subquery cannot be pulled up because the subquery has no aggregation function.</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188163564__sc32cb97662c74b34ae7691ffa3981d0f"><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="o">*</span><span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">t1</span><span class="w"> </span><span class="k">where</span><span class="w"> </span><span class="n">c1</span><span class="w"> </span><span class="o">&gt;</span><span class="p">(</span>
<span class="w"> </span><span class="k">select</span><span class="w"> </span><span class="n">t2</span><span class="p">.</span><span class="n">c1</span><span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">t2</span><span class="w"> </span><span class="k">where</span><span class="w"> </span><span class="n">t2</span><span class="p">.</span><span class="n">c1</span><span class="o">=</span><span class="n">t1</span><span class="p">.</span><span class="n">c1</span>
<span class="p">);</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_p360735818503">The following subquery cannot be pulled up because the subquery has two output columns:</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188163564__s44f6b205fafa4aac9d8434d99d1ed4e5"><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="o">*</span><span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">t1</span><span class="w"> </span><span class="k">where</span><span class="w"> </span><span class="p">(</span><span class="n">c1</span><span class="p">,</span><span class="n">c2</span><span class="p">)</span><span class="w"> </span><span class="o">&gt;</span><span class="p">(</span>
<span class="w"> </span><span class="k">select</span><span class="w"> </span><span class="k">max</span><span class="p">(</span><span class="n">t2</span><span class="p">.</span><span class="n">c1</span><span class="p">),</span><span class="k">min</span><span class="p">(</span><span class="n">t2</span><span class="p">.</span><span class="n">c2</span><span class="p">)</span><span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">t2</span><span class="w"> </span><span class="k">where</span><span class="w"> </span><span class="n">t2</span><span class="p">.</span><span class="n">c1</span><span class="o">=</span><span class="n">t1</span><span class="p">.</span><span class="n">c1</span>
<span class="p">);</span>
</pre></div></td></tr></table></div>
</div>
</li><li id="EN-US_TOPIC_0000001188163564__l3734f716ed704098b34da16f029ccbf2">The subquery must be a <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b1872811214265">FROM</strong> clause.</li><li id="EN-US_TOPIC_0000001188163564__l447c80deebb94029a865f691f864f79b">The subquery cannot contain a <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b1086915445270">GROUP BY</strong>, <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b570174818275">HAVING</strong>, or <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b7724165418271">SET</strong> operation.</li><li id="EN-US_TOPIC_0000001188163564__lade68a368cbe441ea96a50d5cb276c22">The subquery can only be inner join.<div class="p" id="EN-US_TOPIC_0000001188163564__a8fb382ce9fd945d3b19c55252c69464b"><a name="EN-US_TOPIC_0000001188163564__lade68a368cbe441ea96a50d5cb276c22"></a><a name="lade68a368cbe441ea96a50d5cb276c22"></a>For example, the following subquery can be pulled up:<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188163564__s76bc7e2883ab42a789917cd3bff9f5ce"><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="o">*</span><span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">t1</span><span class="w"> </span><span class="k">where</span><span class="w"> </span><span class="n">c1</span><span class="w"> </span><span class="o">&gt;</span><span class="p">(</span>
<span class="w"> </span><span class="k">select</span><span class="w"> </span><span class="k">max</span><span class="p">(</span><span class="n">t2</span><span class="p">.</span><span class="n">c1</span><span class="p">)</span><span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">t2</span><span class="w"> </span><span class="k">full</span><span class="w"> </span><span class="k">join</span><span class="w"> </span><span class="n">t3</span><span class="w"> </span><span class="k">on</span><span class="w"> </span><span class="p">(</span><span class="n">t2</span><span class="p">.</span><span class="n">c2</span><span class="o">=</span><span class="n">t3</span><span class="p">.</span><span class="n">c2</span><span class="p">)</span><span class="w"> </span><span class="k">where</span><span class="w"> </span><span class="n">t2</span><span class="p">.</span><span class="n">c1</span><span class="o">=</span><span class="n">t1</span><span class="p">.</span><span class="n">c1</span>
<span class="p">);</span>
</pre></div></td></tr></table></div>
</div>
</div>
</li><li id="EN-US_TOPIC_0000001188163564__l7d56a1c6e546413180d98c39808475dd">The target list of the subquery cannot contain the function that returns a set.</li><li id="EN-US_TOPIC_0000001188163564__l64bee5f57907455892a44bf8d0d7f5e4">The <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b187921503426">WHERE</strong> condition of the subquery must contain a column from the outer query. Equivalence comparison must be performed between this column and related columns in tables of the subquery. These conditions must be connected using <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b177936506428">AND</strong>. Other parts of the subquery cannot contain the column. For example, the following subquery can be pulled up:<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188163564__s5a1870bacc1b47c48ff1971bd9ab3e5d"><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="o">*</span><span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">t3</span><span class="w"> </span><span class="k">where</span><span class="w"> </span><span class="n">t3</span><span class="p">.</span><span class="n">c1</span><span class="o">=</span><span class="p">(</span>
<span class="w"> </span><span class="k">select</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">c1</span>
<span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">t1</span><span class="w"> </span><span class="k">where</span><span class="w"> </span><span class="n">c1</span><span class="w"> </span><span class="o">&gt;</span><span class="p">(</span>
<span class="w"> </span><span class="k">select</span><span class="w"> </span><span class="k">max</span><span class="p">(</span><span class="n">t2</span><span class="p">.</span><span class="n">c1</span><span class="p">)</span><span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">t2</span><span class="w"> </span><span class="k">where</span><span class="w"> </span><span class="n">t2</span><span class="p">.</span><span class="n">c1</span><span class="o">=</span><span class="n">t1</span><span class="p">.</span><span class="n">c1</span><span class="w"> </span>
<span class="p">));</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001188163564__a0d39d5f13c63497ea0ef38f5a5f96eeb">If another condition is added to the subquery in the previous example, the subquery cannot be pulled up because the subquery references to the column in the outer query. Example:</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188163564__s79a365aa62d64f549b7dbdf28f773419"><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>
<span class="normal">6</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">t3</span><span class="w"> </span><span class="k">where</span><span class="w"> </span><span class="n">t3</span><span class="p">.</span><span class="n">c1</span><span class="o">=</span><span class="p">(</span>
<span class="w"> </span><span class="k">select</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">c1</span>
<span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">t1</span><span class="w"> </span><span class="k">where</span><span class="w"> </span><span class="n">c1</span><span class="w"> </span><span class="o">&gt;</span><span class="p">(</span>
<span class="w"> </span><span class="k">select</span><span class="w"> </span><span class="k">max</span><span class="p">(</span><span class="n">t2</span><span class="p">.</span><span class="n">c1</span><span class="p">)</span><span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">t2</span><span class="w"> </span><span class="k">where</span><span class="w"> </span><span class="n">t2</span><span class="p">.</span><span class="n">c1</span><span class="o">=</span><span class="n">t1</span><span class="p">.</span><span class="n">c1</span><span class="w"> </span><span class="k">and</span><span class="w"> </span><span class="n">t3</span><span class="p">.</span><span class="n">c1</span><span class="o">&gt;</span><span class="n">t2</span><span class="p">.</span><span class="n">c2</span>
<span class="p">));</span>
</pre></div></td></tr></table></div>
</div>
</li></ul>
</li><li id="EN-US_TOPIC_0000001188163564__lf181a61bf76e4332ab3569683d92c863">Pulling up a sublink in the <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b172894592452">OR</strong> clause<p id="EN-US_TOPIC_0000001188163564__ab017395304314f44b06c94274ef2ffe4">If the <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b8141192419466">WHERE</strong> condition contains a <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b4186270477">EXIST</strong>-related sublink connected by <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b55161649134715">OR</strong>,</p>
<p id="EN-US_TOPIC_0000001188163564__aa0ff56c431cd41b4a196a2ada3036bc2">for example,</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188163564__sc0f780d275c54edfb079add3b6b57f61"><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="n">a</span><span class="p">,</span><span class="w"> </span><span class="k">c</span><span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">t1</span>
<span class="k">where</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">a</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="p">(</span><span class="k">select</span><span class="w"> </span><span class="k">avg</span><span class="p">(</span><span class="n">a</span><span class="p">)</span><span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">t3</span><span class="w"> </span><span class="k">where</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">b</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">t3</span><span class="p">.</span><span class="n">b</span><span class="p">)</span><span class="w"> </span><span class="k">or</span>
<span class="k">exists</span><span class="w"> </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">t4</span><span class="w"> </span><span class="k">where</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="k">c</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">t4</span><span class="p">.</span><span class="k">c</span><span class="p">);</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_p136443423619">the process of pulling up such a sublink is as follows:</p>
<ol id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_ol1696110827"><li id="EN-US_TOPIC_0000001188163564__lb275d456bcdd4f68a851fffa2ea101f2">Extract <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b10158184765118">opExpr</strong> from the <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b15903205314511">OR</strong> clause in the <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b16713358175113">WHERE </strong>condition. The value is <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b168902017185213">t1.a = (select avg(a) from t3 where t1.b = t3.b)</strong>.</li><li id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_li56961101423">The <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b663415423527">opExpr</strong> contains a subquery. If the subquery can be pulled up, the subquery is rewritten as <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b1743414331530">elect avg(a), t3.b from t3 group by t3.b</strong>, generating the <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b9706134615531">NOT NULL</strong> condition <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b1434625317536">t3.b is not null</strong>. The <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b669817178544">opExpr</strong> is replaced with this <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b1652983995416">NOT NULL</strong> condition. In this case, the SQL statement changes to:<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188163564__s2f8cc50f4fad4d2aa4d7932ca486c538"><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="n">a</span><span class="p">,</span><span class="w"> </span><span class="k">c</span>
<span class="k">from</span><span class="w"> </span><span class="n">t1</span><span class="w"> </span><span class="k">left</span><span class="w"> </span><span class="k">join</span><span class="w"> </span><span class="p">(</span><span class="k">select</span><span class="w"> </span><span class="k">avg</span><span class="p">(</span><span class="n">a</span><span class="p">)</span><span class="w"> </span><span class="k">avg</span><span class="p">,</span><span class="w"> </span><span class="n">t3</span><span class="p">.</span><span class="n">b</span><span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">t3</span><span class="w"> </span><span class="k">group</span><span class="w"> </span><span class="k">by</span><span class="w"> </span><span class="n">t3</span><span class="p">.</span><span class="n">b</span><span class="p">)</span><span class="w"> </span><span class="k">as</span><span class="w"> </span><span class="n">t3</span><span class="w"> </span><span class="k">on</span><span class="w"> </span><span class="p">(</span><span class="n">t1</span><span class="p">.</span><span class="n">a</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="k">avg</span><span class="w"> </span><span class="k">and</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">b</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">t3</span><span class="p">.</span><span class="n">b</span><span class="p">)</span>
<span class="k">where</span><span class="w"> </span><span class="n">t3</span><span class="p">.</span><span class="n">b</span><span class="w"> </span><span class="k">is</span><span class="w"> </span><span class="k">not</span><span class="w"> </span><span class="k">null</span><span class="w"> </span><span class="k">or</span><span class="w"> </span><span class="k">exists</span><span class="w"> </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">t4</span><span class="w"> </span><span class="k">where</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="k">c</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">t4</span><span class="p">.</span><span class="k">c</span><span class="p">);</span>
</pre></div></td></tr></table></div>
</div>
</li><li id="EN-US_TOPIC_0000001188163564__l6def76bcdfc34d89847158c790488b14">Extract the <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b122151427175519">EXISTS</strong> sublink <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b25734013558">exists (select * from t4 where t1.c = t4.c)</strong> from the <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b3710750105510">OR</strong> clause to check whether the sublink can be pulled up. If it can be pulled up, it is converted into <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b84020178570">select t4.c from t4 group by t4.c</strong>, generating the <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b2982113217572">NOT NULL</strong> condition <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b1534173811576">t4.c is not null</strong>. In this case, the SQL statement changes to:<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188163564__sfba440774695467bbf438683bf70f54f"><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="n">a</span><span class="p">,</span><span class="w"> </span><span class="k">c</span>
<span class="k">from</span><span class="w"> </span><span class="n">t1</span><span class="w"> </span><span class="k">left</span><span class="w"> </span><span class="k">join</span><span class="w"> </span><span class="p">(</span><span class="k">select</span><span class="w"> </span><span class="k">avg</span><span class="p">(</span><span class="n">a</span><span class="p">)</span><span class="w"> </span><span class="k">avg</span><span class="p">,</span><span class="w"> </span><span class="n">t3</span><span class="p">.</span><span class="n">b</span><span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">t3</span><span class="w"> </span><span class="k">group</span><span class="w"> </span><span class="k">by</span><span class="w"> </span><span class="n">t3</span><span class="p">.</span><span class="n">b</span><span class="p">)</span><span class="w"> </span><span class="k">as</span><span class="w"> </span><span class="n">t3</span><span class="w"> </span><span class="k">on</span><span class="w"> </span><span class="p">(</span><span class="n">t1</span><span class="p">.</span><span class="n">a</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="k">avg</span><span class="w"> </span><span class="k">and</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">b</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">t3</span><span class="p">.</span><span class="n">b</span><span class="p">)</span>
<span class="k">left</span><span class="w"> </span><span class="k">join</span><span class="w"> </span><span class="p">(</span><span class="k">select</span><span class="w"> </span><span class="n">t4</span><span class="p">.</span><span class="k">c</span><span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">t4</span><span class="w"> </span><span class="k">group</span><span class="w"> </span><span class="k">by</span><span class="w"> </span><span class="n">t4</span><span class="p">.</span><span class="k">c</span><span class="p">)</span><span class="w"> </span><span class="k">where</span><span class="w"> </span><span class="n">t3</span><span class="p">.</span><span class="n">b</span><span class="w"> </span><span class="k">is</span><span class="w"> </span><span class="k">not</span><span class="w"> </span><span class="k">null</span><span class="w"> </span><span class="k">or</span><span class="w"> </span><span class="n">t4</span><span class="p">.</span><span class="k">c</span><span class="w"> </span><span class="k">is</span><span class="w"> </span><span class="k">not</span><span class="w"> </span><span class="k">null</span><span class="p">;</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001188163564__a334ca78d9e234d7ea1f2d4e59db36708"><span><img id="EN-US_TOPIC_0000001188163564__i3ad2f4fe765c41ec9c754715c9a230f5" src="figure/en-us_image_0000001188323766.png"></span></p>
</li></ol>
</li></ul>
</li></ul>
<ul id="EN-US_TOPIC_0000001188163564__u4f8d76b40daf496cb16187ce80d51215"><li id="EN-US_TOPIC_0000001188163564__led80a5662bf74f26874beec88da9a5ff">Sublink-release not supported by <span id="EN-US_TOPIC_0000001188163564__text1601833281">GaussDB(DWS)</span><p id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_p56593412366">Except the sublinks described above, all the other sublinks cannot be pulled up. In this case, a join subquery is planned as the combination of a subplan and broadcast. As a result, if tables in the subquery have a large amount of data, query performance may be poor.</p>
<p id="EN-US_TOPIC_0000001188163564__acb168568c03e4e2fbefcdc6ecd3b86e0">If a correlated subquery joins with two tables in outer queries, the subquery cannot be pulled up. You need to change the parent query into a <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b1395371615519">WITH</strong> clause and then perform the join.</p>
<p id="EN-US_TOPIC_0000001188163564__af1db3145050c46ff9369d2340cbcd757">Example:</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188163564__sa6f362d01f034b0294218282b25554d7"><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="k">distinct</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">a</span><span class="p">,</span><span class="w"> </span><span class="n">t2</span><span class="p">.</span><span class="n">a</span>
<span class="k">from</span><span class="w"> </span><span class="n">t1</span><span class="w"> </span><span class="k">left</span><span class="w"> </span><span class="k">join</span><span class="w"> </span><span class="n">t2</span><span class="w"> </span><span class="k">on</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">a</span><span class="o">=</span><span class="n">t2</span><span class="p">.</span><span class="n">a</span><span class="w"> </span><span class="k">and</span><span class="w"> </span><span class="k">not</span><span class="w"> </span><span class="k">exists</span><span class="w"> </span><span class="p">(</span><span class="k">select</span><span class="w"> </span><span class="n">a</span><span class="p">,</span><span class="n">b</span><span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">test1</span><span class="w"> </span><span class="k">where</span><span class="w"> </span><span class="n">test1</span><span class="p">.</span><span class="n">a</span><span class="o">=</span><span class="n">t1</span><span class="p">.</span><span class="n">a</span><span class="w"> </span><span class="k">and</span><span class="w"> </span><span class="n">test1</span><span class="p">.</span><span class="n">b</span><span class="o">=</span><span class="n">t2</span><span class="p">.</span><span class="n">a</span><span class="p">);</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001188163564__ad56056f60d054f80b1adcb768ddf7a56">The parent query is changed into:</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188163564__s371b8f611835497cb25ae20a95700cbb"><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>
<span class="normal">6</span>
<span class="normal">7</span>
<span class="normal">8</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">with</span><span class="w"> </span><span class="n">temp</span><span class="w"> </span><span class="k">as</span>
<span class="p">(</span>
<span class="w"> </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="p">(</span><span class="k">select</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">a</span><span class="w"> </span><span class="k">as</span><span class="w"> </span><span class="n">a</span><span class="p">,</span><span class="w"> </span><span class="n">t2</span><span class="p">.</span><span class="n">a</span><span class="w"> </span><span class="k">as</span><span class="w"> </span><span class="n">b</span><span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">t1</span><span class="w"> </span><span class="k">left</span><span class="w"> </span><span class="k">join</span><span class="w"> </span><span class="n">t2</span><span class="w"> </span><span class="k">on</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">a</span><span class="o">=</span><span class="n">t2</span><span class="p">.</span><span class="n">a</span><span class="p">)</span>
<span class="p">)</span>
<span class="k">select</span><span class="w"> </span><span class="k">distinct</span><span class="w"> </span><span class="n">a</span><span class="p">,</span><span class="n">b</span>
<span class="k">from</span><span class="w"> </span><span class="n">temp</span>
<span class="k">where</span><span class="w"> </span><span class="k">not</span><span class="w"> </span><span class="k">exists</span><span class="w"> </span><span class="p">(</span><span class="k">select</span><span class="w"> </span><span class="n">a</span><span class="p">,</span><span class="n">b</span><span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">test1</span><span class="w"> </span><span class="k">where</span><span class="w"> </span><span class="n">temp</span><span class="p">.</span><span class="n">a</span><span class="o">=</span><span class="n">test1</span><span class="p">.</span><span class="n">a</span><span class="w"> </span><span class="k">and</span><span class="w"> </span><span class="n">temp</span><span class="p">.</span><span class="n">b</span><span class="o">=</span><span class="n">test1</span><span class="p">.</span><span class="n">b</span><span class="p">);</span>
</pre></div></td></tr></table></div>
</div>
<ul id="EN-US_TOPIC_0000001188163564__u10619d3af9824318b96ca8fb699e7562"><li id="EN-US_TOPIC_0000001188163564__l686282f0f69c48e69484a270efb1aa5b">The subquery (without <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b7606539815">COUNT</strong>) in the target list cannot be pulled up.<p id="EN-US_TOPIC_0000001188163564__a6f6f018bb1a5487085f14709a18aafc6">Example:</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188163564__sdb12423883fd479f846ef8409f316d47"><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">explain</span><span class="w"> </span><span class="p">(</span><span class="n">costs</span><span class="w"> </span><span class="k">off</span><span class="p">)</span>
<span class="k">select</span><span class="w"> </span><span class="p">(</span><span class="k">select</span><span class="w"> </span><span class="n">c2</span><span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">t2</span><span class="w"> </span><span class="k">where</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">c1</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">t2</span><span class="p">.</span><span class="n">c1</span><span class="p">)</span><span class="w"> </span><span class="n">ssq</span><span class="p">,</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">c2</span>
<span class="k">from</span><span class="w"> </span><span class="n">t1</span>
<span class="k">where</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">c2</span><span class="w"> </span><span class="o">&gt;</span><span class="w"> </span><span class="mi">10</span><span class="p">;</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001188163564__aaeea243dae8d41cf9c4a74e465b7da88">The execution plan is as follows:</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188163564__s3574869e0dc442b98d2ea1b71e73cc81"><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>
<span class="normal"> 6</span>
<span class="normal"> 7</span>
<span class="normal"> 8</span>
<span class="normal"> 9</span>
<span class="normal">10</span>
<span class="normal">11</span>
<span class="normal">12</span>
<span class="normal">13</span>
<span class="normal">14</span>
<span class="normal">15</span>
<span class="normal">16</span>
<span class="normal">17</span>
<span class="normal">18</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">explain</span><span class="w"> </span><span class="p">(</span><span class="n">costs</span><span class="w"> </span><span class="k">off</span><span class="p">)</span>
<span class="k">select</span><span class="w"> </span><span class="p">(</span><span class="k">select</span><span class="w"> </span><span class="n">c2</span><span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">t2</span><span class="w"> </span><span class="k">where</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">c1</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">t2</span><span class="p">.</span><span class="n">c1</span><span class="p">)</span><span class="w"> </span><span class="n">ssq</span><span class="p">,</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">c2</span>
<span class="k">from</span><span class="w"> </span><span class="n">t1</span>
<span class="k">where</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">c2</span><span class="w"> </span><span class="o">&gt;</span><span class="w"> </span><span class="mi">10</span><span class="p">;</span>
<span class="w"> </span><span class="n">QUERY</span><span class="w"> </span><span class="n">PLAN</span>
<span class="c1">------------------------------------------------------</span>
<span class="w"> </span><span class="n">Streaming</span><span class="w"> </span><span class="p">(</span><span class="k">type</span><span class="p">:</span><span class="w"> </span><span class="n">GATHER</span><span class="p">)</span>
<span class="w"> </span><span class="n">Node</span><span class="o">/</span><span class="n">s</span><span class="p">:</span><span class="w"> </span><span class="k">All</span><span class="w"> </span><span class="n">datanodes</span>
<span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="n">Seq</span><span class="w"> </span><span class="n">Scan</span><span class="w"> </span><span class="k">on</span><span class="w"> </span><span class="n">t1</span>
<span class="w"> </span><span class="n">Filter</span><span class="p">:</span><span class="w"> </span><span class="p">(</span><span class="n">c2</span><span class="w"> </span><span class="o">&gt;</span><span class="w"> </span><span class="mi">10</span><span class="p">)</span>
<span class="w"> </span><span class="n">SubPlan</span><span class="w"> </span><span class="mi">1</span>
<span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="k">Result</span>
<span class="w"> </span><span class="n">Filter</span><span class="p">:</span><span class="w"> </span><span class="p">(</span><span class="n">t1</span><span class="p">.</span><span class="n">c1</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">t2</span><span class="p">.</span><span class="n">c1</span><span class="p">)</span>
<span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="n">Materialize</span>
<span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="n">Streaming</span><span class="p">(</span><span class="k">type</span><span class="p">:</span><span class="w"> </span><span class="n">BROADCAST</span><span class="p">)</span>
<span class="w"> </span><span class="n">Spawn</span><span class="w"> </span><span class="k">on</span><span class="p">:</span><span class="w"> </span><span class="k">All</span><span class="w"> </span><span class="n">datanodes</span>
<span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="n">Seq</span><span class="w"> </span><span class="n">Scan</span><span class="w"> </span><span class="k">on</span><span class="w"> </span><span class="n">t2</span>
<span class="p">(</span><span class="mi">11</span><span class="w"> </span><span class="k">rows</span><span class="p">)</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_p26831347021">The correlated subquery is displayed in the target list (query return list). Values need to be returned even if the condition <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b19815427173">t1.c1=t2.c1</strong> is not met. Therefore, use left outer join to join <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b1934513816184">T1</strong> and <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b191189511810">T2</strong> so that SSQ can return padding values when the condition <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b18742101415212">t1.c1=t2.c1</strong> is not met.</p>
<div class="note" id="EN-US_TOPIC_0000001188163564__na42dfb37f6e44152bd92e458c40b4526"><img src="public_sys-resources/note_3.0-en-us.png"><span class="notetitle"> </span><div class="notebody"><p id="EN-US_TOPIC_0000001188163564__a63287bfef1bd49d98763fff5d69268c8">ScalarSubQuery (SSQ) and Correlated-ScalarSubQuery (CSSQ) are described as follows:</p>
<ul id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_ul77812235413"><li id="EN-US_TOPIC_0000001188163564__l103b45a3d63d475897857ed2c95c51b3">SSQ: a sublink that returns only a single row and column scalar value</li><li id="EN-US_TOPIC_0000001188163564__lc269855da0cd4cb4ab2b4497e7bbb774">CSSQ: an SSQ containing conditions</li></ul>
</div></div>
<p id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_p168310471422">The preceding SQL statement can be changed into:</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188163564__scbfcbc285497474fa8bba51ad72a0e35"><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>
<span class="normal">6</span>
<span class="normal">7</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">with</span><span class="w"> </span><span class="n">ssq</span><span class="w"> </span><span class="k">as</span>
<span class="p">(</span>
<span class="w"> </span><span class="k">select</span><span class="w"> </span><span class="n">t2</span><span class="p">.</span><span class="n">c2</span><span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">t2</span>
<span class="p">)</span>
<span class="k">select</span><span class="w"> </span><span class="n">ssq</span><span class="p">.</span><span class="n">c2</span><span class="p">,</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">c2</span>
<span class="k">from</span><span class="w"> </span><span class="n">t1</span><span class="w"> </span><span class="k">left</span><span class="w"> </span><span class="k">join</span><span class="w"> </span><span class="n">ssq</span><span class="w"> </span><span class="k">on</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">c1</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">ssq</span><span class="p">.</span><span class="n">c2</span>
<span class="k">where</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">c2</span><span class="w"> </span><span class="o">&gt;</span><span class="w"> </span><span class="mi">10</span><span class="p">;</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_p668320471128">The execution plan after the change is as follows:</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188163564__sdda38bbe5dfa4059b6ef664fe38092a7"><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>
<span class="normal"> 6</span>
<span class="normal"> 7</span>
<span class="normal"> 8</span>
<span class="normal"> 9</span>
<span class="normal">10</span>
<span class="normal">11</span>
<span class="normal">12</span>
<span class="normal">13</span></pre></div></td><td class="code"><div><pre><span></span><span class="w"> </span><span class="n">QUERY</span><span class="w"> </span><span class="n">PLAN</span>
<span class="c1">-------------------------------------------</span>
<span class="w"> </span><span class="n">Streaming</span><span class="w"> </span><span class="p">(</span><span class="k">type</span><span class="p">:</span><span class="w"> </span><span class="n">GATHER</span><span class="p">)</span>
<span class="w"> </span><span class="n">Node</span><span class="o">/</span><span class="n">s</span><span class="p">:</span><span class="w"> </span><span class="k">All</span><span class="w"> </span><span class="n">datanodes</span>
<span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="n">Hash</span><span class="w"> </span><span class="k">Right</span><span class="w"> </span><span class="k">Join</span>
<span class="w"> </span><span class="n">Hash</span><span class="w"> </span><span class="n">Cond</span><span class="p">:</span><span class="w"> </span><span class="p">(</span><span class="n">t2</span><span class="p">.</span><span class="n">c2</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">c1</span><span class="p">)</span>
<span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="n">Streaming</span><span class="p">(</span><span class="k">type</span><span class="p">:</span><span class="w"> </span><span class="n">REDISTRIBUTE</span><span class="p">)</span>
<span class="w"> </span><span class="n">Spawn</span><span class="w"> </span><span class="k">on</span><span class="p">:</span><span class="w"> </span><span class="k">All</span><span class="w"> </span><span class="n">datanodes</span>
<span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="n">Seq</span><span class="w"> </span><span class="n">Scan</span><span class="w"> </span><span class="k">on</span><span class="w"> </span><span class="n">t2</span>
<span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="n">Hash</span>
<span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="n">Seq</span><span class="w"> </span><span class="n">Scan</span><span class="w"> </span><span class="k">on</span><span class="w"> </span><span class="n">t1</span>
<span class="w"> </span><span class="n">Filter</span><span class="p">:</span><span class="w"> </span><span class="p">(</span><span class="n">c2</span><span class="w"> </span><span class="o">&gt;</span><span class="w"> </span><span class="mi">10</span><span class="p">)</span>
<span class="p">(</span><span class="mi">10</span><span class="w"> </span><span class="k">rows</span><span class="p">)</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001188163564__a93d44ea1fad64955ae6b314ecd1f3fff">In the preceding example, the SSQ is pulled up to right join, preventing poor performance caused by the combination of a subplan and broadcast when the table (<strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b178810198242">T2</strong>) in the subquery is too large.</p>
</li><li id="EN-US_TOPIC_0000001188163564__l916ed844fd984c0fb8eb7846e61269b0">The subquery (with <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b7174144182416">COUNT</strong>) in the target list cannot be pulled up.<p id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_p16853478217">Example:</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188163564__s047e9f3c10b84d74a0f0548e34bcba2f"><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="p">(</span><span class="k">select</span><span class="w"> </span><span class="k">count</span><span class="p">(</span><span class="o">*</span><span class="p">)</span><span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">t2</span><span class="w"> </span><span class="k">where</span><span class="w"> </span><span class="n">t2</span><span class="p">.</span><span class="n">c1</span><span class="o">=</span><span class="n">t1</span><span class="p">.</span><span class="n">c1</span><span class="p">)</span><span class="w"> </span><span class="n">cnt</span><span class="p">,</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">c1</span><span class="p">,</span><span class="w"> </span><span class="n">t3</span><span class="p">.</span><span class="n">c1</span>
<span class="k">from</span><span class="w"> </span><span class="n">t1</span><span class="p">,</span><span class="n">t3</span>
<span class="k">where</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">c1</span><span class="o">=</span><span class="n">t3</span><span class="p">.</span><span class="n">c1</span><span class="w"> </span><span class="k">order</span><span class="w"> </span><span class="k">by</span><span class="w"> </span><span class="n">cnt</span><span class="p">,</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">c1</span><span class="p">;</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_p068564710215">The execution plan is as follows:</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188163564__s50fae0c765e64f35a56d0db168e254cd"><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>
<span class="normal"> 6</span>
<span class="normal"> 7</span>
<span class="normal"> 8</span>
<span class="normal"> 9</span>
<span class="normal">10</span>
<span class="normal">11</span>
<span class="normal">12</span>
<span class="normal">13</span>
<span class="normal">14</span>
<span class="normal">15</span>
<span class="normal">16</span>
<span class="normal">17</span>
<span class="normal">18</span>
<span class="normal">19</span>
<span class="normal">20</span></pre></div></td><td class="code"><div><pre><span></span><span class="w"> </span><span class="n">QUERY</span><span class="w"> </span><span class="n">PLAN</span>
<span class="c1">------------------------------------------------------------------</span>
<span class="w"> </span><span class="n">Streaming</span><span class="w"> </span><span class="p">(</span><span class="k">type</span><span class="p">:</span><span class="w"> </span><span class="n">GATHER</span><span class="p">)</span>
<span class="w"> </span><span class="n">Node</span><span class="o">/</span><span class="n">s</span><span class="p">:</span><span class="w"> </span><span class="k">All</span><span class="w"> </span><span class="n">datanodes</span>
<span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="n">Sort</span>
<span class="w"> </span><span class="n">Sort</span><span class="w"> </span><span class="k">Key</span><span class="p">:</span><span class="w"> </span><span class="p">((</span><span class="n">SubPlan</span><span class="w"> </span><span class="mi">1</span><span class="p">)),</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">c1</span>
<span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="n">Hash</span><span class="w"> </span><span class="k">Join</span>
<span class="w"> </span><span class="n">Hash</span><span class="w"> </span><span class="n">Cond</span><span class="p">:</span><span class="w"> </span><span class="p">(</span><span class="n">t1</span><span class="p">.</span><span class="n">c1</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">t3</span><span class="p">.</span><span class="n">c1</span><span class="p">)</span>
<span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="n">Seq</span><span class="w"> </span><span class="n">Scan</span><span class="w"> </span><span class="k">on</span><span class="w"> </span><span class="n">t1</span>
<span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="n">Hash</span>
<span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="n">Seq</span><span class="w"> </span><span class="n">Scan</span><span class="w"> </span><span class="k">on</span><span class="w"> </span><span class="n">t3</span>
<span class="w"> </span><span class="n">SubPlan</span><span class="w"> </span><span class="mi">1</span>
<span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="k">Aggregate</span>
<span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="k">Result</span>
<span class="w"> </span><span class="n">Filter</span><span class="p">:</span><span class="w"> </span><span class="p">(</span><span class="n">t2</span><span class="p">.</span><span class="n">c1</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">c1</span><span class="p">)</span>
<span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="n">Materialize</span>
<span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="n">Streaming</span><span class="p">(</span><span class="k">type</span><span class="p">:</span><span class="w"> </span><span class="n">BROADCAST</span><span class="p">)</span>
<span class="w"> </span><span class="n">Spawn</span><span class="w"> </span><span class="k">on</span><span class="p">:</span><span class="w"> </span><span class="k">All</span><span class="w"> </span><span class="n">datanodes</span>
<span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="n">Seq</span><span class="w"> </span><span class="n">Scan</span><span class="w"> </span><span class="k">on</span><span class="w"> </span><span class="n">t2</span>
<span class="p">(</span><span class="mi">17</span><span class="w"> </span><span class="k">rows</span><span class="p">)</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001188163564__aaae141d52dd74ce8ba6468169ae5b6c5">The correlated subquery is displayed in the target list (query return list). Values need to be returned even if the condition <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b15327152762616">t1.c1=t2.c1</strong> is not met. Therefore, use left outer join to join <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b123285276265">T1</strong> and <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b1328152717268">T2</strong> so that SSQ can return padding values when the condition <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b1328182710267">t1.c1=t2.c1</strong> is not met. However, <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b494017509262">COUNT</strong> is used to ensure that <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b7368191782916">0</strong> is returned when the condition is note met. Therefore, <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b1276111114291">case-when NULL then 0 else count(*)</strong> can be used.</p>
<p id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_p46861147125">The preceding SQL statement can be changed into:</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188163564__s873f7f9ddbac418195c8c394b23ab647"><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>
<span class="normal"> 6</span>
<span class="normal"> 7</span>
<span class="normal"> 8</span>
<span class="normal"> 9</span>
<span class="normal">10</span>
<span class="normal">11</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">with</span><span class="w"> </span><span class="n">ssq</span><span class="w"> </span><span class="k">as</span>
<span class="p">(</span>
<span class="w"> </span><span class="k">select</span><span class="w"> </span><span class="k">count</span><span class="p">(</span><span class="o">*</span><span class="p">)</span><span class="w"> </span><span class="n">cnt</span><span class="p">,</span><span class="w"> </span><span class="n">c1</span><span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">t2</span><span class="w"> </span><span class="k">group</span><span class="w"> </span><span class="k">by</span><span class="w"> </span><span class="n">c1</span>
<span class="p">)</span>
<span class="k">select</span><span class="w"> </span><span class="k">case</span><span class="w"> </span><span class="k">when</span>
<span class="w"> </span><span class="n">ssq</span><span class="p">.</span><span class="n">cnt</span><span class="w"> </span><span class="k">is</span><span class="w"> </span><span class="k">null</span><span class="w"> </span><span class="k">then</span><span class="w"> </span><span class="mi">0</span>
<span class="w"> </span><span class="k">else</span><span class="w"> </span><span class="n">ssq</span><span class="p">.</span><span class="n">cnt</span>
<span class="w"> </span><span class="k">end</span><span class="w"> </span><span class="n">cnt</span><span class="p">,</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">c1</span><span class="p">,</span><span class="w"> </span><span class="n">t3</span><span class="p">.</span><span class="n">c1</span>
<span class="k">from</span><span class="w"> </span><span class="n">t1</span><span class="w"> </span><span class="k">left</span><span class="w"> </span><span class="k">join</span><span class="w"> </span><span class="n">ssq</span><span class="w"> </span><span class="k">on</span><span class="w"> </span><span class="n">ssq</span><span class="p">.</span><span class="n">c1</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">c1</span><span class="p">,</span><span class="n">t3</span>
<span class="k">where</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">c1</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">t3</span><span class="p">.</span><span class="n">c1</span>
<span class="k">order</span><span class="w"> </span><span class="k">by</span><span class="w"> </span><span class="n">ssq</span><span class="p">.</span><span class="n">cnt</span><span class="p">,</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">c1</span><span class="p">;</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_p368654718210">The execution plan after the change is as follows:</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188163564__s9878c8701ec142789a287df9cb99f0ae"><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>
<span class="normal"> 6</span>
<span class="normal"> 7</span>
<span class="normal"> 8</span>
<span class="normal"> 9</span>
<span class="normal">10</span>
<span class="normal">11</span>
<span class="normal">12</span>
<span class="normal">13</span>
<span class="normal">14</span>
<span class="normal">15</span>
<span class="normal">16</span>
<span class="normal">17</span>
<span class="normal">18</span></pre></div></td><td class="code"><div><pre><span></span><span class="w"> </span><span class="n">QUERY</span><span class="w"> </span><span class="n">PLAN</span>
<span class="c1">-----------------------------------------------------</span>
<span class="w"> </span><span class="n">Streaming</span><span class="w"> </span><span class="p">(</span><span class="k">type</span><span class="p">:</span><span class="w"> </span><span class="n">GATHER</span><span class="p">)</span>
<span class="w"> </span><span class="n">Node</span><span class="o">/</span><span class="n">s</span><span class="p">:</span><span class="w"> </span><span class="k">All</span><span class="w"> </span><span class="n">datanodes</span>
<span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="n">Sort</span>
<span class="w"> </span><span class="n">Sort</span><span class="w"> </span><span class="k">Key</span><span class="p">:</span><span class="w"> </span><span class="p">(</span><span class="k">count</span><span class="p">(</span><span class="o">*</span><span class="p">)),</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">c1</span>
<span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="n">Hash</span><span class="w"> </span><span class="k">Join</span>
<span class="w"> </span><span class="n">Hash</span><span class="w"> </span><span class="n">Cond</span><span class="p">:</span><span class="w"> </span><span class="p">(</span><span class="n">t1</span><span class="p">.</span><span class="n">c1</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">t3</span><span class="p">.</span><span class="n">c1</span><span class="p">)</span>
<span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="n">Hash</span><span class="w"> </span><span class="k">Left</span><span class="w"> </span><span class="k">Join</span>
<span class="w"> </span><span class="n">Hash</span><span class="w"> </span><span class="n">Cond</span><span class="p">:</span><span class="w"> </span><span class="p">(</span><span class="n">t1</span><span class="p">.</span><span class="n">c1</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">t2</span><span class="p">.</span><span class="n">c1</span><span class="p">)</span>
<span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="n">Seq</span><span class="w"> </span><span class="n">Scan</span><span class="w"> </span><span class="k">on</span><span class="w"> </span><span class="n">t1</span>
<span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="n">Hash</span>
<span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="n">HashAggregate</span>
<span class="w"> </span><span class="k">Group</span><span class="w"> </span><span class="k">By</span><span class="w"> </span><span class="k">Key</span><span class="p">:</span><span class="w"> </span><span class="n">t2</span><span class="p">.</span><span class="n">c1</span>
<span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="n">Seq</span><span class="w"> </span><span class="n">Scan</span><span class="w"> </span><span class="k">on</span><span class="w"> </span><span class="n">t2</span>
<span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="n">Hash</span>
<span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="n">Seq</span><span class="w"> </span><span class="n">Scan</span><span class="w"> </span><span class="k">on</span><span class="w"> </span><span class="n">t3</span>
<span class="p">(</span><span class="mi">15</span><span class="w"> </span><span class="k">rows</span><span class="p">)</span>
</pre></div></td></tr></table></div>
</div>
</li></ul>
<ul id="EN-US_TOPIC_0000001188163564__u8f13ea58a7d442b2945718d7d117394c"><li id="EN-US_TOPIC_0000001188163564__l333bcc3cc1494da7af787a77ff32b857">Pulling up nonequivalent subqueries<p id="EN-US_TOPIC_0000001188163564__a48da4b79f1404282a50460e6dc893b99"><a name="EN-US_TOPIC_0000001188163564__l333bcc3cc1494da7af787a77ff32b857"></a><a name="l333bcc3cc1494da7af787a77ff32b857"></a>Example:</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188163564__s58145ddc91f848658f1eeff2a8a5ba91"><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="n">t1</span><span class="p">.</span><span class="n">c1</span><span class="p">,</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">c2</span>
<span class="k">from</span><span class="w"> </span><span class="n">t1</span>
<span class="k">where</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">c1</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="p">(</span><span class="k">select</span><span class="w"> </span><span class="n">agg</span><span class="p">()</span><span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">t2</span><span class="p">.</span><span class="n">c2</span><span class="w"> </span><span class="o">&gt;</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">c2</span><span class="p">);</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_p67343423619">Nonequivalent subqueries cannot be pulled up. You can perform join twice (one CorrelationKey and one rownum self-join) to rewrite the statement.</p>
<p id="EN-US_TOPIC_0000001188163564__a21b5d0b6f3ff4ec3afc18c51e26be7eb">You can rewrite the statement in either of the following ways:</p>
<ul id="EN-US_TOPIC_0000001188163564__u9d10a4c00fb54160861cd1a785dbe398"><li id="EN-US_TOPIC_0000001188163564__l51682d91b7724e7fa33ff3c07f2a92e4">Subquery rewriting<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188163564__sa5cf99a2783442cba3eecbd11fce31b5"><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>
<span class="normal">6</span>
<span class="normal">7</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">select</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">c1</span><span class="p">,</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">c2</span>
<span class="k">from</span><span class="w"> </span><span class="n">t1</span><span class="p">,</span><span class="w"> </span><span class="p">(</span>
<span class="w"> </span><span class="k">select</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">rowid</span><span class="p">,</span><span class="w"> </span><span class="n">agg</span><span class="p">()</span><span class="w"> </span><span class="n">aggref</span>
<span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">t1</span><span class="p">,</span><span class="n">t2</span>
<span class="w"> </span><span class="k">where</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">c2</span><span class="w"> </span><span class="o">&gt;</span><span class="w"> </span><span class="n">t2</span><span class="p">.</span><span class="n">c2</span><span class="w"> </span><span class="k">group</span><span class="w"> </span><span class="k">by</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">rowid</span>
<span class="p">)</span><span class="w"> </span><span class="n">dt</span><span class="w"> </span><span class="cm">/* derived table */</span>
<span class="k">where</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">rowid</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">dt</span><span class="p">.</span><span class="n">rowid</span><span class="w"> </span><span class="k">AND</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">c1</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">dt</span><span class="p">.</span><span class="n">aggref</span><span class="p">;</span>
</pre></div></td></tr></table></div>
</div>
</li><li id="EN-US_TOPIC_0000001188163564__lccdc5edbf34444ee9c24aec9398e85d9">CTE rewriting<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188163564__s01fe6e14f72740e99c26582cc0f00afb"><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>
<span class="normal"> 6</span>
<span class="normal"> 7</span>
<span class="normal"> 8</span>
<span class="normal"> 9</span>
<span class="normal">10</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">WITH</span><span class="w"> </span><span class="n">dt</span><span class="w"> </span><span class="k">as</span>
<span class="p">(</span>
<span class="w"> </span><span class="k">select</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">rowid</span><span class="p">,</span><span class="w"> </span><span class="n">agg</span><span class="p">()</span><span class="w"> </span><span class="n">aggref</span>
<span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">t1</span><span class="p">,</span><span class="n">t2</span>
<span class="w"> </span><span class="k">where</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">c2</span><span class="w"> </span><span class="o">&gt;</span><span class="w"> </span><span class="n">t2</span><span class="p">.</span><span class="n">c2</span><span class="w"> </span><span class="k">group</span><span class="w"> </span><span class="k">by</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">rowid</span>
<span class="p">)</span>
<span class="k">select</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">c1</span><span class="p">,</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">c2</span>
<span class="k">from</span><span class="w"> </span><span class="n">t1</span><span class="p">,</span><span class="w"> </span><span class="n">derived_table</span>
<span class="k">where</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">rowid</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">derived_table</span><span class="p">.</span><span class="n">rowid</span><span class="w"> </span><span class="k">AND</span>
<span class="n">t1</span><span class="p">.</span><span class="n">c1</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">derived_table</span><span class="p">.</span><span class="n">aggref</span><span class="p">;</span>
</pre></div></td></tr></table></div>
</div>
</li></ul>
</li></ul>
<div class="notice" id="EN-US_TOPIC_0000001188163564__n1ef3d57e3c9e45a99e0293042524ecc2"><span class="noticetitle"><img src="public_sys-resources/notice_3.0-en-us.png"> </span><div class="noticebody"><ul id="EN-US_TOPIC_0000001188163564__u80c80b7201764485a171c3e078f1052f"><li id="EN-US_TOPIC_0000001188163564__lffd63a0b54af489c925a7890efd75999">Currently, <span id="EN-US_TOPIC_0000001188163564__text1750627354">GaussDB(DWS)</span> does not have an effective way to provide globally unique row IDs for tables and intermediate result sets. Therefore, the rewriting is difficult. It is recommended that this issue is avoided at the service layer or by using <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b1037116349504">t1.xc_node_id + t1.ctid</strong> to associate row IDs. However, the high repetition rate of <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b1818885915010">xc_node_id</strong> leads to low association efficiency, and <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b1840453720510">xc_node_id+ctid</strong> cannot be used as the join condition of hash join.</li><li id="EN-US_TOPIC_0000001188163564__ld649e2d1526e43eeae95b9ff9ff4480a">If the AGG type is <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b2430170194319">COUNT(*)</strong>, <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b1550017558435">0</strong> is used for data padding if <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b126541023134419">CASE-WHEN</strong> is not matched. If the type is not <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b14830191254519">COUNT(*)</strong>, <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b455614255454">NULL</strong> is used.</li><li id="EN-US_TOPIC_0000001188163564__lef36d37e7ef2483e8e73ed9672bb3bff">CTE rewriting works better by using share scan.</li></ul>
</div></div>
</li></ul>
</div>
<div class="section" id="EN-US_TOPIC_0000001188163564__s490a654504544cac8efd4a0f4724acc8"><h4 class="sectiontitle">More Optimization Examples</h4><p id="EN-US_TOPIC_0000001188163564__abce2b853a4c54c9f9b578f8910ed45a0">1. Change the base table to a replication table and create an index on the filter column.</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188163564__sf64dd66b5a7340978ba03e2ea470441e"><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">create</span><span class="w"> </span><span class="k">table</span><span class="w"> </span><span class="n">master_table</span><span class="w"> </span><span class="p">(</span><span class="n">a</span><span class="w"> </span><span class="nb">int</span><span class="p">);</span>
<span class="k">create</span><span class="w"> </span><span class="k">table</span><span class="w"> </span><span class="n">sub_table</span><span class="p">(</span><span class="n">a</span><span class="w"> </span><span class="nb">int</span><span class="p">,</span><span class="w"> </span><span class="n">b</span><span class="w"> </span><span class="nb">int</span><span class="p">);</span>
<span class="k">select</span><span class="w"> </span><span class="n">a</span><span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">master_table</span><span class="w"> </span><span class="k">group</span><span class="w"> </span><span class="k">by</span><span class="w"> </span><span class="n">a</span><span class="w"> </span><span class="k">having</span><span class="w"> </span><span class="n">a</span><span class="w"> </span><span class="k">in</span><span class="w"> </span><span class="p">(</span><span class="k">select</span><span class="w"> </span><span class="n">a</span><span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">sub_table</span><span class="p">);</span><span class="w"> </span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001188163564__af202cc48835441218c106f81a18e9624">In this example, a correlated subquery is contained. To improve the query performance, you can change <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b842352706112924">sub_table</strong> to a replication table and create an index on the <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b842352706113144">a</strong> column.</p>
</div>
<p id="EN-US_TOPIC_0000001188163564__a0a376625c99241f4b8ec6365e20635c3">2. Modify the <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b842352706113333">SELECT</strong> statement, change the subquery to a <strong id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_b842352706132645">JOIN</strong> relationship between the primary table and the parent query, or modify the subquery to improve the query performance. Ensure that the subquery to be used is semantically correct.</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188163564__sb6c8ee80ebc5476dbb6cd1182a309657"><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>
<span class="normal"> 6</span>
<span class="normal"> 7</span>
<span class="normal"> 8</span>
<span class="normal"> 9</span>
<span class="normal">10</span>
<span class="normal">11</span>
<span class="normal">12</span>
<span class="normal">13</span>
<span class="normal">14</span>
<span class="normal">15</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">explain</span><span class="w"> </span><span class="p">(</span><span class="n">costs</span><span class="w"> </span><span class="k">off</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">master_table</span><span class="w"> </span><span class="k">as</span><span class="w"> </span><span class="n">t1</span><span class="w"> </span><span class="k">where</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">a</span><span class="w"> </span><span class="k">in</span><span class="w"> </span><span class="p">(</span><span class="k">select</span><span class="w"> </span><span class="n">t2</span><span class="p">.</span><span class="n">a</span><span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">sub_table</span><span class="w"> </span><span class="k">as</span><span class="w"> </span><span class="n">t2</span><span class="w"> </span><span class="k">where</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">a</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">t2</span><span class="p">.</span><span class="n">b</span><span class="p">);</span>
<span class="w"> </span><span class="n">QUERY</span><span class="w"> </span><span class="n">PLAN</span>
<span class="c1">----------------------------------------------------------</span>
<span class="n">Streaming</span><span class="w"> </span><span class="p">(</span><span class="k">type</span><span class="p">:</span><span class="w"> </span><span class="n">GATHER</span><span class="p">)</span>
<span class="w"> </span><span class="n">Node</span><span class="o">/</span><span class="n">s</span><span class="p">:</span><span class="w"> </span><span class="k">All</span><span class="w"> </span><span class="n">datanodes</span>
<span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="n">Seq</span><span class="w"> </span><span class="n">Scan</span><span class="w"> </span><span class="k">on</span><span class="w"> </span><span class="n">master_table</span><span class="w"> </span><span class="n">t1</span>
<span class="w"> </span><span class="n">Filter</span><span class="p">:</span><span class="w"> </span><span class="p">(</span><span class="n">SubPlan</span><span class="w"> </span><span class="mi">1</span><span class="p">)</span>
<span class="w"> </span><span class="n">SubPlan</span><span class="w"> </span><span class="mi">1</span>
<span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="k">Result</span>
<span class="w"> </span><span class="n">Filter</span><span class="p">:</span><span class="w"> </span><span class="p">(</span><span class="n">t1</span><span class="p">.</span><span class="n">a</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">t2</span><span class="p">.</span><span class="n">b</span><span class="p">)</span>
<span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="n">Materialize</span>
<span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="n">Streaming</span><span class="p">(</span><span class="k">type</span><span class="p">:</span><span class="w"> </span><span class="n">BROADCAST</span><span class="p">)</span>
<span class="w"> </span><span class="n">Spawn</span><span class="w"> </span><span class="k">on</span><span class="p">:</span><span class="w"> </span><span class="k">All</span><span class="w"> </span><span class="n">datanodes</span>
<span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="n">Seq</span><span class="w"> </span><span class="n">Scan</span><span class="w"> </span><span class="k">on</span><span class="w"> </span><span class="n">sub_table</span><span class="w"> </span><span class="n">t2</span>
<span class="p">(</span><span class="mi">11</span><span class="w"> </span><span class="k">rows</span><span class="p">)</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001188163564__en-us_topic_0118337169_p176977114234">In the preceding example, a subplan is used. To remove the subplan, you can modify the statement as follows:</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188163564__sc22ffc52f14a444981e64b71c609d206"><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>
<span class="normal"> 6</span>
<span class="normal"> 7</span>
<span class="normal"> 8</span>
<span class="normal"> 9</span>
<span class="normal">10</span>
<span class="normal">11</span>
<span class="normal">12</span>
<span class="normal">13</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">explain</span><span class="p">(</span><span class="n">costs</span><span class="w"> </span><span class="k">off</span><span class="p">)</span><span class="w"> </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">master_table</span><span class="w"> </span><span class="k">as</span><span class="w"> </span><span class="n">t1</span><span class="w"> </span><span class="k">where</span><span class="w"> </span><span class="k">exists</span><span class="w"> </span><span class="p">(</span><span class="k">select</span><span class="w"> </span><span class="n">t2</span><span class="p">.</span><span class="n">a</span><span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">sub_table</span><span class="w"> </span><span class="k">as</span><span class="w"> </span><span class="n">t2</span><span class="w"> </span><span class="k">where</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">a</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">t2</span><span class="p">.</span><span class="n">b</span><span class="w"> </span><span class="k">and</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">a</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">t2</span><span class="p">.</span><span class="n">a</span><span class="p">);</span>
<span class="w"> </span><span class="n">QUERY</span><span class="w"> </span><span class="n">PLAN</span>
<span class="c1">--------------------------------------------------</span>
<span class="n">Streaming</span><span class="w"> </span><span class="p">(</span><span class="k">type</span><span class="p">:</span><span class="w"> </span><span class="n">GATHER</span><span class="p">)</span>
<span class="w"> </span><span class="n">Node</span><span class="o">/</span><span class="n">s</span><span class="p">:</span><span class="w"> </span><span class="k">All</span><span class="w"> </span><span class="n">datanodes</span>
<span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="n">Hash</span><span class="w"> </span><span class="n">Semi</span><span class="w"> </span><span class="k">Join</span>
<span class="w"> </span><span class="n">Hash</span><span class="w"> </span><span class="n">Cond</span><span class="p">:</span><span class="w"> </span><span class="p">(</span><span class="n">t1</span><span class="p">.</span><span class="n">a</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">t2</span><span class="p">.</span><span class="n">b</span><span class="p">)</span>
<span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="n">Seq</span><span class="w"> </span><span class="n">Scan</span><span class="w"> </span><span class="k">on</span><span class="w"> </span><span class="n">master_table</span><span class="w"> </span><span class="n">t1</span>
<span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="n">Hash</span>
<span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="n">Streaming</span><span class="p">(</span><span class="k">type</span><span class="p">:</span><span class="w"> </span><span class="n">REDISTRIBUTE</span><span class="p">)</span>
<span class="w"> </span><span class="n">Spawn</span><span class="w"> </span><span class="k">on</span><span class="p">:</span><span class="w"> </span><span class="k">All</span><span class="w"> </span><span class="n">datanodes</span>
<span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="n">Seq</span><span class="w"> </span><span class="n">Scan</span><span class="w"> </span><span class="k">on</span><span class="w"> </span><span class="n">sub_table</span><span class="w"> </span><span class="n">t2</span>
<span class="p">(</span><span class="mi">9</span><span class="w"> </span><span class="k">rows</span><span class="p">)</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001188163564__a62b41e86cdd042cea97b6ddb86e2a1b7">In this way, the subplan is replaced by the semi-join between the two tables, greatly improving the execution efficiency.</p>
</div>
<div>
<div class="familylinks">
<div class="parentlink"><strong>Parent topic:</strong> <a href="dws_04_0445.html">Typical SQL Optimization Methods</a></div>
</div>
</div>