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

415 lines
59 KiB
HTML

<a name="EN-US_TOPIC_0000001233883283"></a><a name="EN-US_TOPIC_0000001233883283"></a>
<h1 class="topictitle1">Optimizing Statement Pushdown</h1>
<div id="body8662426"><div class="section" id="EN-US_TOPIC_0000001233883283__s57105f73f887407e854fc21e9a795a75"><h4 class="sectiontitle">Statement Pushdown</h4><p id="EN-US_TOPIC_0000001233883283__af3976cebdd8f4d4da3020240bbe18b04">Currently, the <span id="EN-US_TOPIC_0000001233883283__text993543452">GaussDB(DWS)</span> optimizer can use three methods to develop statement execution policies in the distributed framework: generating a statement pushdown plan, a distributed execution plan, or a distributed execution plan for sending statements.</p>
<ul id="EN-US_TOPIC_0000001233883283__ul772994445616"><li id="EN-US_TOPIC_0000001233883283__li157291344115617">A statement pushdown plan pushes query statements from a CN down to DNs for execution and returns the execution results to the CN.</li><li id="EN-US_TOPIC_0000001233883283__li4729124410565">In a distributed execution plan, a CN compiles and optimizes query statements, generates a plan tree, and then sends the plan tree to DNs for execution. After the statements have been executed, execution results will be returned to the CN.</li><li id="EN-US_TOPIC_0000001233883283__li472918446564">A distributed execution plan for sending statements pushes queries that can be pushed down (mostly base table scanning statements) to DNs for execution. Then, the plan obtains the intermediate results and sends them to the CN, on which the remaining queries are to be executed.</li></ul>
<p id="EN-US_TOPIC_0000001233883283__a24024f37122c4b29956d4cabd97db306">The third policy sends many intermediate results from the DNs to a CN for further execution. In this case, the CN performance bottleneck (in bandwidth, storage, and computing) is caused by statements that cannot be pushed down to DNs. Therefore, you are not advised to use the query statements that only the third policy is applicable to.</p>
<p id="EN-US_TOPIC_0000001233883283__en-us_topic_0073253801_p199253811121">Statements cannot be pushed down to DNs if they have <a href="#EN-US_TOPIC_0000001233883283__s926a7f64d03546399fe529744b9bf420">Functions That Do Not Support Pushdown</a> or <a href="#EN-US_TOPIC_0000001233883283__sf9bb07c596384fbc833219a5e72da7e4">Syntax That Does Not Support Pushdown</a>. Generally, you can rewrite the execution statements to solve the problem.</p>
</div>
<div class="section" id="EN-US_TOPIC_0000001233883283__sb1747133eddb445284bb43cc7ea5a177"><h4 class="sectiontitle">Viewing Whether the Execution Plan Has Been Pushed Down to DNs</h4><p id="EN-US_TOPIC_0000001233883283__ab6f2891fc59c4f8aae2d96ce2b3ff2dc">Perform the following procedure to quickly determine whether the execution plan can be pushed down to DNs:</p>
<ol id="EN-US_TOPIC_0000001233883283__o5dd150860eb94b8eb8bd903862ac0e1e"><li id="EN-US_TOPIC_0000001233883283__lc126ecc4862e40a78b3a4163e761f6b7"><span>Set the GUC parameter <a href="dws_04_0936.html#EN-US_TOPIC_0000001188163572__s9b7f64f4f112450490c8c74b520cc915">enable_fast_query_shipping</a> to <strong id="EN-US_TOPIC_0000001233883283__b842352706101141">off</strong> to use the distributed framework policy for the query optimizer.</span><p><div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001233883283__sd7bd6ff8b92e411b98048a71e1d23359"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal">1</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">SET</span><span class="w"> </span><span class="n">enable_fast_query_shipping</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="k">off</span><span class="p">;</span>
</pre></div></td></tr></table></div>
</div>
</p></li><li id="EN-US_TOPIC_0000001233883283__l064b58ed9f2e43d1b5d4041576311800"><span>View the execution plan.</span><p><p id="EN-US_TOPIC_0000001233883283__en-us_topic_0073253801_p897222911224">If the execution plan contains Data Node Scan, the SQL statements cannot be pushed down to DNs. If the execution plan contains Streaming, the SQL statements can be pushed down to DNs.</p>
<p id="EN-US_TOPIC_0000001233883283__ac346c3c6c0fa412984bac8b241f0b98e">For example:</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001233883283__s29ae60aebc304d4d95afdb19f5b3c943"><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="k">count</span><span class="p">(</span><span class="n">ss</span><span class="p">.</span><span class="n">ss_sold_date_sk</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">ss</span><span class="p">.</span><span class="n">ss_sold_date_sk</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">store_sales</span><span class="w"> </span><span class="n">ss</span><span class="p">,</span><span class="w"> </span><span class="n">store_returns</span><span class="w"> </span><span class="n">sr</span><span class="w"> </span>
<span class="k">where</span><span class="w"> </span>
<span class="n">sr</span><span class="p">.</span><span class="n">sr_customer_sk</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">ss</span><span class="p">.</span><span class="n">ss_customer_sk</span><span class="p">;</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001233883283__af9a6ad299e114f5cade72a994445ed66">The execution plan is as follows, which indicates that the SQL statement cannot be pushed down.</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001233883283__screen829820591281"><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="w"> </span><span class="n">QUERY</span><span class="w"> </span><span class="n">PLAN</span>
<span class="c1">--------------------------------------------------------------------------</span>
<span class="k">Aggregate</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="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">ss</span><span class="p">.</span><span class="n">ss_customer_sk</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">sr</span><span class="p">.</span><span class="n">sr_customer_sk</span><span class="p">)</span>
<span class="o">-&gt;</span><span class="w"> </span><span class="k">Data</span><span class="w"> </span><span class="n">Node</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">store_sales</span><span class="w"> </span><span class="ss">&quot;_REMOTE_TABLE_QUERY_&quot;</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="o">-&gt;</span><span class="w"> </span><span class="n">Hash</span>
<span class="o">-&gt;</span><span class="w"> </span><span class="k">Data</span><span class="w"> </span><span class="n">Node</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">store_returns</span><span class="w"> </span><span class="ss">&quot;_REMOTE_TABLE_QUERY_&quot;</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="p">(</span><span class="mi">8</span><span class="w"> </span><span class="k">rows</span><span class="p">)</span>
</pre></div></td></tr></table></div>
</div>
</p></li></ol>
</div>
<div class="section" id="EN-US_TOPIC_0000001233883283__sf9bb07c596384fbc833219a5e72da7e4"><a name="EN-US_TOPIC_0000001233883283__sf9bb07c596384fbc833219a5e72da7e4"></a><a name="sf9bb07c596384fbc833219a5e72da7e4"></a><h4 class="sectiontitle">Syntax That Does Not Support Pushdown</h4><p id="EN-US_TOPIC_0000001233883283__en-us_topic_0073253801_p29154710">SQL syntax that does not support pushdown is described using the following table definition examples:</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001233883283__se0d720283c3a41b3b802238ef337f31e"><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></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">CUSTOMER1</span>
<span class="p">(</span>
<span class="w"> </span><span class="n">C_CUSTKEY</span><span class="w"> </span><span class="nb">BIGINT</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="p">,</span><span class="w"> </span><span class="n">C_NAME</span><span class="w"> </span><span class="nb">VARCHAR</span><span class="p">(</span><span class="mi">25</span><span class="p">)</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="p">,</span><span class="w"> </span><span class="n">C_ADDRESS</span><span class="w"> </span><span class="nb">VARCHAR</span><span class="p">(</span><span class="mi">40</span><span class="p">)</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="p">,</span><span class="w"> </span><span class="n">C_NATIONKEY</span><span class="w"> </span><span class="nb">INT</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="p">,</span><span class="w"> </span><span class="n">C_PHONE</span><span class="w"> </span><span class="nb">CHAR</span><span class="p">(</span><span class="mi">15</span><span class="p">)</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="p">,</span><span class="w"> </span><span class="n">C_ACCTBAL</span><span class="w"> </span><span class="nb">DECIMAL</span><span class="p">(</span><span class="mi">15</span><span class="p">,</span><span class="mi">2</span><span class="p">)</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="p">,</span><span class="w"> </span><span class="n">C_MKTSEGMENT</span><span class="w"> </span><span class="nb">CHAR</span><span class="p">(</span><span class="mi">10</span><span class="p">)</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="p">,</span><span class="w"> </span><span class="n">C_COMMENT</span><span class="w"> </span><span class="nb">VARCHAR</span><span class="p">(</span><span class="mi">117</span><span class="p">)</span><span class="w"> </span><span class="k">NOT</span><span class="w"> </span><span class="k">NULL</span>
<span class="p">)</span>
<span class="n">DISTRIBUTE</span><span class="w"> </span><span class="k">BY</span><span class="w"> </span><span class="n">hash</span><span class="p">(</span><span class="n">C_CUSTKEY</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">test_stream</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">float</span><span class="p">);</span><span class="c1">--float does not support redistribution.</span>
<span class="k">CREATE</span><span class="w"> </span><span class="k">TABLE</span><span class="w"> </span><span class="n">sal_emp</span><span class="w"> </span><span class="p">(</span><span class="w"> </span><span class="n">c1</span><span class="w"> </span><span class="nb">integer</span><span class="p">[]</span><span class="w"> </span><span class="p">)</span><span class="w"> </span><span class="n">DISTRIBUTE</span><span class="w"> </span><span class="k">BY</span><span class="w"> </span><span class="n">replication</span><span class="p">;</span>
</pre></div></td></tr></table></div>
</div>
<ul id="EN-US_TOPIC_0000001233883283__u8df4f1d6228d41a4b112c7832143faaf"><li id="EN-US_TOPIC_0000001233883283__lee83a23013b54eedb1e4036adf27c478">The <strong id="EN-US_TOPIC_0000001233883283__b191266098515104">returning</strong> statement cannot be pushed down.<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001233883283__s5a6036f8d69042549142a7e2457e3037"><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></pre></div></td><td class="code"><div><pre><span></span><span class="k">explain</span><span class="w"> </span><span class="k">update</span><span class="w"> </span><span class="n">customer1</span><span class="w"> </span><span class="k">set</span><span class="w"> </span><span class="n">C_NAME</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="s1">'a'</span><span class="w"> </span><span class="n">returning</span><span class="w"> </span><span class="n">c_name</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="w"> </span>
<span class="c1">------------------------------------------------------------------</span>
<span class="w"> </span><span class="k">Update</span><span class="w"> </span><span class="k">on</span><span class="w"> </span><span class="n">customer1</span><span class="w"> </span><span class="p">(</span><span class="n">cost</span><span class="o">=</span><span class="mi">0</span><span class="p">.</span><span class="mi">00</span><span class="p">..</span><span class="mi">0</span><span class="p">.</span><span class="mi">00</span><span class="w"> </span><span class="k">rows</span><span class="o">=</span><span class="mi">30</span><span class="w"> </span><span class="n">width</span><span class="o">=</span><span class="mi">187</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="n">Node</span><span class="w"> </span><span class="n">expr</span><span class="p">:</span><span class="w"> </span><span class="n">c_custkey</span>
<span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="k">Data</span><span class="w"> </span><span class="n">Node</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">customer1</span><span class="w"> </span><span class="ss">&quot;_REMOTE_TABLE_QUERY_&quot;</span><span class="w"> </span><span class="p">(</span><span class="n">cost</span><span class="o">=</span><span class="mi">0</span><span class="p">.</span><span class="mi">00</span><span class="p">..</span><span class="mi">0</span><span class="p">.</span><span class="mi">00</span><span class="w"> </span><span class="k">rows</span><span class="o">=</span><span class="mi">30</span><span class="w"> </span><span class="n">width</span><span class="o">=</span><span class="mi">187</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="p">(</span><span class="mi">5</span><span class="w"> </span><span class="k">rows</span><span class="p">)</span>
</pre></div></td></tr></table></div>
</div>
</li><li id="EN-US_TOPIC_0000001233883283__l9ba05ea1a6d340b69ec2e0f15b4c25ea">If columns in <strong id="EN-US_TOPIC_0000001233883283__b398593832151623">count(distinct expr)</strong> do not support redistribution, they do not support pushdown.<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001233883283__sf09b1b8c47414dddb60c2dc9e2445b23"><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></pre></div></td><td class="code"><div><pre><span></span><span class="k">explain</span><span class="w"> </span><span class="k">verbose</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="k">distinct</span><span class="w"> </span><span class="n">b</span><span class="p">)</span><span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">test_stream</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="w"> </span>
<span class="c1">------------------------------------------------------------------ Aggregate (cost=2.50..2.51 rows=1 width=8)</span>
<span class="w"> </span><span class="k">Output</span><span class="p">:</span><span class="w"> </span><span class="k">count</span><span class="p">(</span><span class="k">DISTINCT</span><span class="w"> </span><span class="n">test_stream</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="k">Data</span><span class="w"> </span><span class="n">Node</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">test_stream</span><span class="w"> </span><span class="ss">&quot;_REMOTE_TABLE_QUERY_&quot;</span><span class="w"> </span><span class="p">(</span><span class="n">cost</span><span class="o">=</span><span class="mi">0</span><span class="p">.</span><span class="mi">00</span><span class="p">..</span><span class="mi">0</span><span class="p">.</span><span class="mi">00</span><span class="w"> </span><span class="k">rows</span><span class="o">=</span><span class="mi">30</span><span class="w"> </span><span class="n">width</span><span class="o">=</span><span class="mi">8</span><span class="p">)</span>
<span class="w"> </span><span class="k">Output</span><span class="p">:</span><span class="w"> </span><span class="n">test_stream</span><span class="p">.</span><span class="n">b</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="n">Remote</span><span class="w"> </span><span class="n">query</span><span class="p">:</span><span class="w"> </span><span class="k">SELECT</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="k">ONLY</span><span class="w"> </span><span class="k">public</span><span class="p">.</span><span class="n">test_stream</span><span class="w"> </span><span class="k">WHERE</span><span class="w"> </span><span class="k">true</span>
<span class="p">(</span><span class="mi">6</span><span class="w"> </span><span class="k">rows</span><span class="p">)</span>
</pre></div></td></tr></table></div>
</div>
</li><li id="EN-US_TOPIC_0000001233883283__le40bd2edb3864d04872bd0f69089bdb5">Statements using <strong id="EN-US_TOPIC_0000001233883283__b25196881215200">distinct on</strong> cannot be pushed down.<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001233883283__s3d2a889db6714a21b74989dfdf0757f8"><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></pre></div></td><td class="code"><div><pre><span></span><span class="k">explain</span><span class="w"> </span><span class="k">verbose</span><span class="w"> </span><span class="k">select</span><span class="w"> </span><span class="k">distinct</span><span class="w"> </span><span class="k">on</span><span class="w"> </span><span class="p">(</span><span class="n">c_custkey</span><span class="p">)</span><span class="w"> </span><span class="n">c_custkey</span><span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">customer1</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">c_custkey</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="w"> </span>
<span class="c1">------------------------------------------------------------------ Unique (cost=49.83..54.83 rows=30 width=8)</span>
<span class="w"> </span><span class="k">Output</span><span class="p">:</span><span class="w"> </span><span class="n">customer1</span><span class="p">.</span><span class="n">c_custkey</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="p">(</span><span class="n">cost</span><span class="o">=</span><span class="mi">49</span><span class="p">.</span><span class="mi">83</span><span class="p">..</span><span class="mi">52</span><span class="p">.</span><span class="mi">33</span><span class="w"> </span><span class="k">rows</span><span class="o">=</span><span class="mi">30</span><span class="w"> </span><span class="n">width</span><span class="o">=</span><span class="mi">8</span><span class="p">)</span>
<span class="w"> </span><span class="k">Output</span><span class="p">:</span><span class="w"> </span><span class="n">customer1</span><span class="p">.</span><span class="n">c_custkey</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="n">customer1</span><span class="p">.</span><span class="n">c_custkey</span>
<span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="k">Data</span><span class="w"> </span><span class="n">Node</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">customer1</span><span class="w"> </span><span class="ss">&quot;_REMOTE_TABLE_QUERY_&quot;</span><span class="w"> </span><span class="p">(</span><span class="n">cost</span><span class="o">=</span><span class="mi">0</span><span class="p">.</span><span class="mi">00</span><span class="p">..</span><span class="mi">0</span><span class="p">.</span><span class="mi">00</span><span class="w"> </span><span class="k">rows</span><span class="o">=</span><span class="mi">30</span><span class="w"> </span><span class="n">width</span><span class="o">=</span><span class="mi">8</span><span class="p">)</span>
<span class="w"> </span><span class="k">Output</span><span class="p">:</span><span class="w"> </span><span class="n">customer1</span><span class="p">.</span><span class="n">c_custkey</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="n">Remote</span><span class="w"> </span><span class="n">query</span><span class="p">:</span><span class="w"> </span><span class="k">SELECT</span><span class="w"> </span><span class="n">c_custkey</span><span class="w"> </span><span class="k">FROM</span><span class="w"> </span><span class="k">ONLY</span><span class="w"> </span><span class="k">public</span><span class="p">.</span><span class="n">customer1</span><span class="w"> </span><span class="k">WHERE</span><span class="w"> </span><span class="k">true</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>
</li><li id="EN-US_TOPIC_0000001233883283__l1e58914990ad485797142265314fbed5">In a statement using <strong id="EN-US_TOPIC_0000001233883283__b842352706104821">FULL JOIN</strong>, if the column specified using <strong id="EN-US_TOPIC_0000001233883283__b842352706104830">JOIN</strong> does not support redistribution, the statement does not support pushdown.<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001233883283__s48a91c73351d4c1f8d4c6301c153ae7a"><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">explain</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">test_stream</span><span class="w"> </span><span class="n">t1</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">test_stream</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">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="w"> </span>
<span class="c1">------------------------------------------------------------------ Hash Full Join (cost=0.38..0.82 rows=30 width=24)</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="p">)::</span><span class="n">double</span><span class="w"> </span><span class="k">precision</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="k">Data</span><span class="w"> </span><span class="n">Node</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">test_stream</span><span class="w"> </span><span class="ss">&quot;_REMOTE_TABLE_QUERY_&quot;</span><span class="w"> </span><span class="p">(</span><span class="n">cost</span><span class="o">=</span><span class="mi">0</span><span class="p">.</span><span class="mi">00</span><span class="p">..</span><span class="mi">0</span><span class="p">.</span><span class="mi">00</span><span class="w"> </span><span class="k">rows</span><span class="o">=</span><span class="mi">30</span><span class="w"> </span><span class="n">width</span><span class="o">=</span><span class="mi">12</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="p">(</span><span class="n">cost</span><span class="o">=</span><span class="mi">0</span><span class="p">.</span><span class="mi">00</span><span class="p">..</span><span class="mi">0</span><span class="p">.</span><span class="mi">00</span><span class="w"> </span><span class="k">rows</span><span class="o">=</span><span class="mi">30</span><span class="w"> </span><span class="n">width</span><span class="o">=</span><span class="mi">12</span><span class="p">)</span>
<span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="k">Data</span><span class="w"> </span><span class="n">Node</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">test_stream</span><span class="w"> </span><span class="ss">&quot;_REMOTE_TABLE_QUERY_&quot;</span><span class="w"> </span><span class="p">(</span><span class="n">cost</span><span class="o">=</span><span class="mi">0</span><span class="p">.</span><span class="mi">00</span><span class="p">..</span><span class="mi">0</span><span class="p">.</span><span class="mi">00</span><span class="w"> </span><span class="k">rows</span><span class="o">=</span><span class="mi">30</span><span class="w"> </span><span class="n">width</span><span class="o">=</span><span class="mi">12</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="p">(</span><span class="mi">7</span><span class="w"> </span><span class="k">rows</span><span class="p">)</span>
</pre></div></td></tr></table></div>
</div>
</li><li id="EN-US_TOPIC_0000001233883283__l01feceb44159473f82d3b3501c466bac">Does not support array expression pushdown.<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001233883283__s6a28a8e91dc24bd3a5c110ac07a82577"><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">explain</span><span class="w"> </span><span class="k">verbose</span><span class="w"> </span><span class="k">select</span><span class="w"> </span><span class="nb">array</span><span class="p">[</span><span class="n">c_custkey</span><span class="p">,</span><span class="mi">1</span><span class="p">]</span><span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">customer1</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">c_custkey</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="w"> </span>
<span class="c1">------------------------------------------------------------------ Sort (cost=49.83..52.33 rows=30 width=8)</span>
<span class="w"> </span><span class="k">Output</span><span class="p">:</span><span class="w"> </span><span class="p">(</span><span class="nb">ARRAY</span><span class="p">[</span><span class="n">customer1</span><span class="p">.</span><span class="n">c_custkey</span><span class="p">,</span><span class="w"> </span><span class="mi">1</span><span class="p">::</span><span class="nb">bigint</span><span class="p">]),</span><span class="w"> </span><span class="n">customer1</span><span class="p">.</span><span class="n">c_custkey</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="n">customer1</span><span class="p">.</span><span class="n">c_custkey</span>
<span class="w"> </span><span class="o">-&gt;</span><span class="w"> </span><span class="k">Data</span><span class="w"> </span><span class="n">Node</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="ss">&quot;__REMOTE_SORT_QUERY__&quot;</span><span class="w"> </span><span class="p">(</span><span class="n">cost</span><span class="o">=</span><span class="mi">0</span><span class="p">.</span><span class="mi">00</span><span class="p">..</span><span class="mi">0</span><span class="p">.</span><span class="mi">00</span><span class="w"> </span><span class="k">rows</span><span class="o">=</span><span class="mi">30</span><span class="w"> </span><span class="n">width</span><span class="o">=</span><span class="mi">8</span><span class="p">)</span>
<span class="w"> </span><span class="k">Output</span><span class="p">:</span><span class="w"> </span><span class="p">(</span><span class="nb">ARRAY</span><span class="p">[</span><span class="n">customer1</span><span class="p">.</span><span class="n">c_custkey</span><span class="p">,</span><span class="w"> </span><span class="mi">1</span><span class="p">::</span><span class="nb">bigint</span><span class="p">]),</span><span class="w"> </span><span class="n">customer1</span><span class="p">.</span><span class="n">c_custkey</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="n">Remote</span><span class="w"> </span><span class="n">query</span><span class="p">:</span><span class="w"> </span><span class="k">SELECT</span><span class="w"> </span><span class="nb">ARRAY</span><span class="p">[</span><span class="n">c_custkey</span><span class="p">,</span><span class="w"> </span><span class="mi">1</span><span class="p">::</span><span class="nb">bigint</span><span class="p">],</span><span class="w"> </span><span class="n">c_custkey</span><span class="w"> </span><span class="k">FROM</span><span class="w"> </span><span class="k">ONLY</span><span class="w"> </span><span class="k">public</span><span class="p">.</span><span class="n">customer1</span><span class="w"> </span><span class="k">WHERE</span><span class="w"> </span><span class="k">true</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="mi">2</span>
<span class="p">(</span><span class="mi">7</span><span class="w"> </span><span class="k">rows</span><span class="p">)</span>
</pre></div></td></tr></table></div>
</div>
</li></ul>
</div>
<ul id="EN-US_TOPIC_0000001233883283__ul3250185264715"><li id="EN-US_TOPIC_0000001233883283__li9561459135111">The following table describes the scenarios where a statement containing <strong id="EN-US_TOPIC_0000001233883283__b14816125614531">WITH RECURSIVE</strong> cannot be pushed down in the current version, as well as the causes.
<div class="tablenoborder"><table cellpadding="4" cellspacing="0" summary="" id="EN-US_TOPIC_0000001233883283__table1337655119533" frame="border" border="1" rules="all"><thead align="left"><tr id="EN-US_TOPIC_0000001233883283__row17577551125316"><th align="left" class="cellrowborder" valign="top" width="11.18111811181118%" id="mcps1.3.4.1.2.1.4.1.1"><p id="EN-US_TOPIC_0000001233883283__p9577175118534">No.</p>
</th>
<th align="left" class="cellrowborder" valign="top" width="44.00440044004401%" id="mcps1.3.4.1.2.1.4.1.2"><p id="EN-US_TOPIC_0000001233883283__p7577351195319">Scenario</p>
</th>
<th align="left" class="cellrowborder" valign="top" width="44.81448144814482%" id="mcps1.3.4.1.2.1.4.1.3"><p id="EN-US_TOPIC_0000001233883283__p4577135105312">Cause of Not Supporting Pushdown</p>
</th>
</tr>
</thead>
<tbody><tr id="EN-US_TOPIC_0000001233883283__row175777514535"><td class="cellrowborder" valign="top" width="11.18111811181118%" headers="mcps1.3.4.1.2.1.4.1.1 "><p id="EN-US_TOPIC_0000001233883283__p135773515531">1</p>
</td>
<td class="cellrowborder" valign="top" width="44.00440044004401%" headers="mcps1.3.4.1.2.1.4.1.2 "><p id="EN-US_TOPIC_0000001233883283__p957714513536">The query contains foreign tables or HDFS tables.</p>
</td>
<td class="cellrowborder" valign="top" width="44.81448144814482%" headers="mcps1.3.4.1.2.1.4.1.3 "><p id="EN-US_TOPIC_0000001233883283__p12577125185319">LOG: SQL can't be shipped, reason: RecursiveUnion contains HDFS Table or ForeignScan is not shippable (In this table, <strong id="EN-US_TOPIC_0000001233883283__b565334716548">LOG</strong> describes the cause of not supporting pushdown.)</p>
<p id="EN-US_TOPIC_0000001233883283__p157957504466"></p>
<p id="EN-US_TOPIC_0000001233883283__p18577751175310">In the current version, queries containing foreign tables or HDFS tables do not support pushdown.</p>
</td>
</tr>
<tr id="EN-US_TOPIC_0000001233883283__row15771051175316"><td class="cellrowborder" valign="top" width="11.18111811181118%" headers="mcps1.3.4.1.2.1.4.1.1 "><p id="EN-US_TOPIC_0000001233883283__p45771851205313">2</p>
</td>
<td class="cellrowborder" valign="top" width="44.00440044004401%" headers="mcps1.3.4.1.2.1.4.1.2 "><p id="EN-US_TOPIC_0000001233883283__p257715117531">Multiple Node Groups</p>
</td>
<td class="cellrowborder" valign="top" width="44.81448144814482%" headers="mcps1.3.4.1.2.1.4.1.3 "><p id="EN-US_TOPIC_0000001233883283__p175771251145319">LOG: SQL can't be shipped, reason: With-Recursive under multi-nodegroup scenario is not shippable</p>
<p id="EN-US_TOPIC_0000001233883283__p112824412465"></p>
<p id="EN-US_TOPIC_0000001233883283__p14577851115318">In the current version, pushdown is supported only when all base tables are stored and computed in the same Node Group.</p>
</td>
</tr>
<tr id="EN-US_TOPIC_0000001233883283__row1557755118533"><td class="cellrowborder" valign="top" width="11.18111811181118%" headers="mcps1.3.4.1.2.1.4.1.1 "><p id="EN-US_TOPIC_0000001233883283__p2577155112535">3</p>
</td>
<td class="cellrowborder" valign="top" width="44.00440044004401%" headers="mcps1.3.4.1.2.1.4.1.2 "><pre class="screen" id="EN-US_TOPIC_0000001233883283__screen1991212594614">WITH recursive t_result AS (
SELECT dm,sj_dm,name,1 as level
FROM test_rec_part
WHERE sj_dm &gt; 10
UNION
SELECT t2.dm,t2.sj_dm,t2.name||' &gt; '||t1.name,t1.level+1
FROM t_result t1
JOIN test_rec_part t2 ON t2.sj_dm = t1.dm
)
SELECT * FROM t_result t;</pre>
</td>
<td class="cellrowborder" valign="top" width="44.81448144814482%" headers="mcps1.3.4.1.2.1.4.1.3 "><p id="EN-US_TOPIC_0000001233883283__p75771251175316">LOG: SQL can't be shipped, reason: With-Recursive does not contain "ALL" to bind recursive &amp; none-recursive branches</p>
<p id="EN-US_TOPIC_0000001233883283__p143524216462"></p>
<p id="EN-US_TOPIC_0000001233883283__p14577115125318"><strong id="EN-US_TOPIC_0000001233883283__b185081332175511">ALL</strong> is not used for <strong id="EN-US_TOPIC_0000001233883283__b6509173214552">UNION</strong>. In this case, the return result is deduplicated.</p>
</td>
</tr>
<tr id="EN-US_TOPIC_0000001233883283__row3577135115314"><td class="cellrowborder" valign="top" width="11.18111811181118%" headers="mcps1.3.4.1.2.1.4.1.1 "><p id="EN-US_TOPIC_0000001233883283__p13577135112536">4</p>
</td>
<td class="cellrowborder" valign="top" width="44.00440044004401%" headers="mcps1.3.4.1.2.1.4.1.2 "><pre class="screen" id="EN-US_TOPIC_0000001233883283__screen624945864520">WITH RECURSIVE x(id) AS
(
select count(1) from pg_class where oid=1247
UNION ALL
SELECT id+1 FROM x WHERE id &lt; 5
), y(id) AS
(
select count(1) from pg_class where oid=1247
UNION ALL
SELECT id+1 FROM x WHERE id &lt; 10
)
SELECT y.*, x.* FROM y LEFT JOIN x USING (id) ORDER BY 1;</pre>
</td>
<td class="cellrowborder" valign="top" width="44.81448144814482%" headers="mcps1.3.4.1.2.1.4.1.3 "><p id="EN-US_TOPIC_0000001233883283__p1757805165320">LOG: SQL can't be shipped, reason: With-Recursive contains system table is not shippable</p>
<p id="EN-US_TOPIC_0000001233883283__p021463914465"></p>
<p id="EN-US_TOPIC_0000001233883283__p857845175315">A base table contains the system catalog.</p>
</td>
</tr>
<tr id="EN-US_TOPIC_0000001233883283__row557885111539"><td class="cellrowborder" valign="top" width="11.18111811181118%" headers="mcps1.3.4.1.2.1.4.1.1 "><p id="EN-US_TOPIC_0000001233883283__p55781512534">5</p>
</td>
<td class="cellrowborder" valign="top" width="44.00440044004401%" headers="mcps1.3.4.1.2.1.4.1.2 "><pre class="screen" id="EN-US_TOPIC_0000001233883283__screen180511520455">WITH RECURSIVE t(n) AS (
VALUES (1)
UNION ALL
SELECT n+1 FROM t WHERE n &lt; 100
)
SELECT sum(n) FROM t;</pre>
</td>
<td class="cellrowborder" valign="top" width="44.81448144814482%" headers="mcps1.3.4.1.2.1.4.1.3 "><p id="EN-US_TOPIC_0000001233883283__p195788518532">LOG: SQL can't be shipped, reason: With-Recursive contains only values rte is not shippable</p>
<p id="EN-US_TOPIC_0000001233883283__p5138203044620"></p>
<p id="EN-US_TOPIC_0000001233883283__p105785513539">Only <strong id="EN-US_TOPIC_0000001233883283__b798712549557">VALUES</strong> is used for scanning base tables. In this case, the statement can be executed on the CN, and DNs are unnecessary.</p>
</td>
</tr>
<tr id="EN-US_TOPIC_0000001233883283__row125781951135316"><td class="cellrowborder" valign="top" width="11.18111811181118%" headers="mcps1.3.4.1.2.1.4.1.1 "><p id="EN-US_TOPIC_0000001233883283__p19578165115537">6</p>
</td>
<td class="cellrowborder" valign="top" width="44.00440044004401%" headers="mcps1.3.4.1.2.1.4.1.2 "><pre class="screen" id="EN-US_TOPIC_0000001233883283__screen690617467452">select a.ID,a.Name,
(
with recursive cte as (
select ID, PID, NAME from b where b.ID = 1
union all
select parent.ID,parent.PID,parent.NAME
from cte as child join b as parent on child.pid=parent.id
where child.ID = a.ID
)
select NAME from cte limit 1
) cName
from
(
select id, name, count(*) as cnt
from a group by id,name
) a order by 1,2;</pre>
</td>
<td class="cellrowborder" valign="top" width="44.81448144814482%" headers="mcps1.3.4.1.2.1.4.1.3 "><p id="EN-US_TOPIC_0000001233883283__p8578105116536">LOG: SQL can't be shipped, reason: With-Recursive recursive term correlated only is not shippable</p>
<p id="EN-US_TOPIC_0000001233883283__p6578151165311"></p>
<p id="EN-US_TOPIC_0000001233883283__p65781851135312">The correlation conditions of correlated subqueries are only in the recursion part, and the non-recursion part has no correlation condition.</p>
</td>
</tr>
<tr id="EN-US_TOPIC_0000001233883283__row1357812513538"><td class="cellrowborder" valign="top" width="11.18111811181118%" headers="mcps1.3.4.1.2.1.4.1.1 "><p id="EN-US_TOPIC_0000001233883283__p257812513534">7</p>
</td>
<td class="cellrowborder" valign="top" width="44.00440044004401%" headers="mcps1.3.4.1.2.1.4.1.2 "><pre class="screen" id="EN-US_TOPIC_0000001233883283__screen78295385457">WITH recursive t_result AS (
select * from(
SELECT dm,sj_dm,name,1 as level
FROM test_rec_part
WHERE sj_dm &lt; 10 order by dm limit 6 offset 2)
UNION all
SELECT t2.dm,t2.sj_dm,t2.name||' &gt; '||t1.name,t1.level+1
FROM t_result t1
JOIN test_rec_part t2 ON t2.sj_dm = t1.dm
)
SELECT * FROM t_result t;</pre>
</td>
<td class="cellrowborder" valign="top" width="44.81448144814482%" headers="mcps1.3.4.1.2.1.4.1.3 "><p id="EN-US_TOPIC_0000001233883283__p1657895116533">LOG: SQL can't be shipped, reason: With-Recursive contains conflict distribution in none-recursive(Replicate) recursive(Hash)</p>
<p id="EN-US_TOPIC_0000001233883283__p125786515535"></p>
<p id="EN-US_TOPIC_0000001233883283__p357815111536">The <strong id="EN-US_TOPIC_0000001233883283__b11321628103219">replicate</strong> plan is used for <strong id="EN-US_TOPIC_0000001233883283__b232272819327">limit</strong> in the non-recursion part but the <strong id="EN-US_TOPIC_0000001233883283__b133231128193213">hash</strong> plan is used in the recursion part, resulting in conflicts.</p>
</td>
</tr>
<tr id="EN-US_TOPIC_0000001233883283__row19578155116533"><td class="cellrowborder" valign="top" width="11.18111811181118%" headers="mcps1.3.4.1.2.1.4.1.1 "><p id="EN-US_TOPIC_0000001233883283__p1257825175312">8</p>
</td>
<td class="cellrowborder" valign="top" width="44.00440044004401%" headers="mcps1.3.4.1.2.1.4.1.2 "><pre class="screen" id="EN-US_TOPIC_0000001233883283__screen107153434519">with recursive cte as
(
select * from rec_tb4 where id&lt;4
union all
select h.id,h.parentID,h.name from
(
with recursive cte as
(
select * from rec_tb4 where id&lt;4
union all
select h.id,h.parentID,h.name from rec_tb4 h inner join cte c on h.id=c.parentID
)
SELECT id ,parentID,name from cte order by parentID
) h
inner join cte c on h.id=c.parentID
)
SELECT id ,parentID,name from cte order by parentID,1,2,3;</pre>
</td>
<td class="cellrowborder" valign="top" width="44.81448144814482%" headers="mcps1.3.4.1.2.1.4.1.3 "><p id="EN-US_TOPIC_0000001233883283__p1957918515536">LOG: SQL can't be shipped, reason: Recursive CTE references recursive CTE "cte"</p>
<p id="EN-US_TOPIC_0000001233883283__p1257975114534"></p>
<p id="EN-US_TOPIC_0000001233883283__p757955115537"><strong id="EN-US_TOPIC_0000001233883283__b17484115345718">recursive</strong> of multiple-layers are nested. That is, a <strong id="EN-US_TOPIC_0000001233883283__b8484115310571">recursive</strong> is nested in the recursion part of another <strong id="EN-US_TOPIC_0000001233883283__b3485853105710">recursive</strong>.</p>
</td>
</tr>
</tbody>
</table>
</div>
</li></ul>
<div class="section" id="EN-US_TOPIC_0000001233883283__s926a7f64d03546399fe529744b9bf420"><a name="EN-US_TOPIC_0000001233883283__s926a7f64d03546399fe529744b9bf420"></a><a name="s926a7f64d03546399fe529744b9bf420"></a><h4 class="sectiontitle">Functions That Do Not Support Pushdown</h4><p id="EN-US_TOPIC_0000001233883283__en-us_topic_0073253801_p46415143">This module describes the variability of functions. The function variability in <span id="EN-US_TOPIC_0000001233883283__text580873817">GaussDB(DWS)</span> is as follows:</p>
<ul id="EN-US_TOPIC_0000001233883283__u4cf8902e282149888445c009133ef0c1"><li id="EN-US_TOPIC_0000001233883283__l8d9214e235f44cbf9210ec2fc36a932a"><strong id="EN-US_TOPIC_0000001233883283__a2233b88e3db44d7ab82f2a05323d9899">IMMUTABLE</strong><p id="EN-US_TOPIC_0000001233883283__ad1bfe03bbb96481887f0fb81f9efae3b">Indicates that the function always returns the same result if the parameter values are the same.</p>
</li><li id="EN-US_TOPIC_0000001233883283__l82fd76b456844d5b89dd60209926708b"><strong id="EN-US_TOPIC_0000001233883283__adc0e4a252d2543918a6d896f8e8fd4aa">STABLE</strong><p id="EN-US_TOPIC_0000001233883283__acb720ec44f2845e9ac4d653bc97d622a">Indicates that the function cannot modify the database, and that within a single table scan it will consistently return the same result for the same parameter values, but that its result varies by SQL statements.</p>
</li><li id="EN-US_TOPIC_0000001233883283__l5dc0eecfc45d4fcf97b30b8e480eb3e4"><strong id="EN-US_TOPIC_0000001233883283__ac97a434ad96a49698c67c1d8203d0883">VOLATILE</strong><p id="EN-US_TOPIC_0000001233883283__a07e40e581fd7433eab84cc2df6c62be1">Indicates that the function value can change even within a single table scan, so no optimizations can be made.</p>
</li></ul>
<p id="EN-US_TOPIC_0000001233883283__p138737571444">The volatility of a function can be obtained by querying its <strong id="EN-US_TOPIC_0000001233883283__b655615345281">provolatile</strong> column in <strong id="EN-US_TOPIC_0000001233883283__b1019710541287">pg_proc</strong>. The value <strong id="EN-US_TOPIC_0000001233883283__b226955711286">i</strong> indicates immutable, <strong id="EN-US_TOPIC_0000001233883283__b143551986294">s</strong> indicates stable, and <strong id="EN-US_TOPIC_0000001233883283__b58151512192912">v</strong> indicates volatile. The valid values of the <strong id="EN-US_TOPIC_0000001233883283__b940914203018">proshippable</strong> column in <strong id="EN-US_TOPIC_0000001233883283__b199940200305">pg_proc</strong> are <strong id="EN-US_TOPIC_0000001233883283__b94301437183012">t</strong>, <strong id="EN-US_TOPIC_0000001233883283__b15091843153016">f</strong>, and <strong id="EN-US_TOPIC_0000001233883283__b58732045153020">NULL</strong>. This column and the <strong id="EN-US_TOPIC_0000001233883283__b7942754173016">provolatile</strong> column together describe whether a function is pushed down.</p>
<ul id="EN-US_TOPIC_0000001233883283__ul5942013342"><li id="EN-US_TOPIC_0000001233883283__li794217113413">If the <strong id="EN-US_TOPIC_0000001233883283__b53211202316">provolatile</strong> of a function is <strong id="EN-US_TOPIC_0000001233883283__b6643142843116">i</strong>, the function can be pushed down regardless of the value of <strong id="EN-US_TOPIC_0000001233883283__b1490074733113">proshippable</strong>.</li><li id="EN-US_TOPIC_0000001233883283__li93511247344">If the <strong id="EN-US_TOPIC_0000001233883283__b154815573310">provolatile</strong> of a function is <strong id="EN-US_TOPIC_0000001233883283__b7133172143414">s</strong> or <strong id="EN-US_TOPIC_0000001233883283__b620413343">v</strong>, the function can be pushed only if the value of <strong id="EN-US_TOPIC_0000001233883283__b7227531183416">proshippable</strong> is <strong id="EN-US_TOPIC_0000001233883283__b144134163411">t</strong>.</li><li id="EN-US_TOPIC_0000001233883283__li75383114261">CTEs containing random are not pushed down, because pushdown may lead to incorrect results.</li></ul>
<p id="EN-US_TOPIC_0000001233883283__p03923417284">For a UDF, you can specify the values of <strong id="EN-US_TOPIC_0000001233883283__b19476183534012">provolatile</strong> and <strong id="EN-US_TOPIC_0000001233883283__b11359183815403">proshippable</strong> during its creation. For details, see CREATE FUNCTION.</p>
<p id="EN-US_TOPIC_0000001233883283__en-us_topic_0073253801_p4307190">In scenarios where a function does not support pushdown, perform one of the following as required:</p>
<ul id="EN-US_TOPIC_0000001233883283__ue6d8aebeb4414c74b78ae9a2c90b0713"><li id="EN-US_TOPIC_0000001233883283__l96b1808533d245378a910b37b606c794">If it is a system function, replace it with a functionally equivalent one.</li><li id="EN-US_TOPIC_0000001233883283__l47e12567a05641c899b7f7a6d27146f9">If it is a UDF function, check whether its <strong id="EN-US_TOPIC_0000001233883283__b62387169410">provolatile</strong> and <strong id="EN-US_TOPIC_0000001233883283__b205341618124113">proshippable</strong> are correctly defined.</li></ul>
</div>
<div class="section" id="EN-US_TOPIC_0000001233883283__s4aff811245ab4e0c94c679f9cec1e34f"><h4 class="sectiontitle">Example: UDF</h4><p id="EN-US_TOPIC_0000001233883283__ac258b7315a5b4b4ba60406e817643f61">Define a user-defined function that generates fixed output for a certain input as the <strong id="EN-US_TOPIC_0000001233883283__b8423527069275">immutable</strong> type.</p>
<p id="EN-US_TOPIC_0000001233883283__ad5f1edf4e457457d886582f796fdaad7">Use the TPCDS sales information as an example. You need to define a function to obtain the discount information.</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001233883283__s4930e216877944d8b72f67309d65759a"><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">CREATE</span><span class="w"> </span><span class="k">FUNCTION</span><span class="w"> </span><span class="n">func_percent_2</span><span class="w"> </span><span class="p">(</span><span class="nb">NUMERIC</span><span class="p">,</span><span class="w"> </span><span class="nb">NUMERIC</span><span class="p">)</span><span class="w"> </span><span class="k">RETURNS</span><span class="w"> </span><span class="nb">NUMERIC</span>
<span class="k">AS</span><span class="w"> </span><span class="s1">'SELECT $1 / $2 WHERE $2 &gt; 0.01'</span>
<span class="k">LANGUAGE</span><span class="w"> </span><span class="k">SQL</span>
<span class="k">VOLATILE</span><span class="p">;</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001233883283__a40a3150af410495d83f84ba72ea15b53">Run the following statement:</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001233883283__s7446e152385640cd9628f32469479449"><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="n">func_percent_2</span><span class="p">(</span><span class="n">ss_sales_price</span><span class="p">,</span><span class="w"> </span><span class="n">ss_list_price</span><span class="p">)</span>
<span class="k">FROM</span><span class="w"> </span><span class="n">store_sales</span><span class="p">;</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001233883283__aaa31e3d54c5c4c0b975f6b6067644fbc">The execution plan is as follows:</p>
<p id="EN-US_TOPIC_0000001233883283__af28cbc18c9204a84899e01cf1aca216e"><span><img id="EN-US_TOPIC_0000001233883283__en-us_topic_0073253801_en-us_topic_0062578361_image59542993192021" src="figure/en-us_image_0000001188642250.png"></span></p>
<p id="EN-US_TOPIC_0000001233883283__a24970052dfd0446a8671f8ba32f11071"><strong id="EN-US_TOPIC_0000001233883283__b84235270616757">func_percent_2</strong> is not pushed down, and <strong id="EN-US_TOPIC_0000001233883283__b842352706161024">ss_sales_price</strong> and <strong id="EN-US_TOPIC_0000001233883283__b842352706161029">ss_list_price</strong> are executed on a CN. In this case, a large amount of resources on the CN is consumed, and the performance deteriorates as a result.</p>
<p id="EN-US_TOPIC_0000001233883283__a12deb253c10c435ab5a0dec78b077b48">In this example, the function returns certain output when certain input is entered. Therefore, we can modify the function to the following one:</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001233883283__s85af9def9ca849d8a60a58cc27234bd6"><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">CREATE</span><span class="w"> </span><span class="k">FUNCTION</span><span class="w"> </span><span class="n">func_percent_1</span><span class="w"> </span><span class="p">(</span><span class="nb">NUMERIC</span><span class="p">,</span><span class="w"> </span><span class="nb">NUMERIC</span><span class="p">)</span><span class="w"> </span><span class="k">RETURNS</span><span class="w"> </span><span class="nb">NUMERIC</span>
<span class="k">AS</span><span class="w"> </span><span class="s1">'SELECT $1 / $2 WHERE $2 &gt; 0.01'</span>
<span class="k">LANGUAGE</span><span class="w"> </span><span class="k">SQL</span>
<span class="k">IMMUTABLE</span><span class="p">;</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001233883283__a51da557ce6a649ceb2be38756c02799f">Run the following statement:</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001233883283__sc7edf8798a3e425e9dac07cc5db927e7"><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="n">func_percent_1</span><span class="p">(</span><span class="n">ss_sales_price</span><span class="p">,</span><span class="w"> </span><span class="n">ss_list_price</span><span class="p">)</span>
<span class="k">FROM</span><span class="w"> </span><span class="n">store_sales</span><span class="p">;</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001233883283__a558dd69905214b25996eda6c24772004">The execution plan is as follows:</p>
<p id="EN-US_TOPIC_0000001233883283__p1088115559455"><span><img id="EN-US_TOPIC_0000001233883283__image7469856124612" src="figure/en-us_image_0000001233681851.png"></span></p>
<p id="EN-US_TOPIC_0000001233883283__aa074b3e67976460c8a8c36410910e082"><strong id="EN-US_TOPIC_0000001233883283__b1149480969195022">func_percent_1</strong> is pushed down to DNs for quicker execution. (In TPCDS 1000X, where three CNs and 18 DNs are used, the query efficiency is improved by over 100 times).</p>
</div>
<div class="section" id="EN-US_TOPIC_0000001233883283__s5975ca61abd0403ea28382892baa5cf5"><h4 class="sectiontitle">Example 2: Pushing Down the Sorting Operation</h4><p id="EN-US_TOPIC_0000001233883283__p12921516133211">For details, see <a href="dws_04_0478.html">Case: Pushing Down Sort Operations to DNs</a>.</p>
</div>
</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>