Files
doc-exports/docs/dws/umn/dws_03_2107.html
Lu, Huayi 95132e24fc DWS UMN 830.201_new version
Reviewed-by: Pruthi, Vineet <vineet.pruthi@t-systems.com>
Reviewed-by: Rechenburg, Matthias <matthias.rechenburg@t-systems.com>
Co-authored-by: Lu, Huayi <luhuayi@huawei.com>
Co-committed-by: Lu, Huayi <luhuayi@huawei.com>
2024-05-27 11:54:34 +00:00

348 lines
54 KiB
HTML

<a name="EN-US_TOPIC_0000001431826616"></a><a name="EN-US_TOPIC_0000001431826616"></a>
<h1 class="topictitle1">Solutions to Inconsistent GaussDB(DWS) Query Results</h1>
<div id="body0000001431826616"><p id="EN-US_TOPIC_0000001431826616__p8060118">In GaussDB(DWS), sometimes a SQL query may get different results. This problem is most likely caused by improper syntax or usage. To avoid this problem, use the syntax correctly. The following are some examples of query results inconsistency along with the solutions.</p>
<div class="section" id="EN-US_TOPIC_0000001431826616__section1711184216149"><h4 class="sectiontitle">Window Function Results Are Incompletely Sorted</h4><p id="EN-US_TOPIC_0000001431826616__p690416115324"><strong id="EN-US_TOPIC_0000001431826616__b290401173219">Scenario:</strong></p>
<div class="p" id="EN-US_TOPIC_0000001431826616__p1167154610318">In the window function <strong id="EN-US_TOPIC_0000001431826616__b2155510131">row_number()</strong>, column <strong id="EN-US_TOPIC_0000001431826616__b490714599136">c</strong> of table <strong id="EN-US_TOPIC_0000001431826616__b8110134121419">t3</strong> is queried after sorting. The two query results are different.<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001431826616__screen96151818101812"><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">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">order</span><span class="w"> </span><span class="k">by</span><span class="w"> </span><span class="mi">1</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="w"> </span><span class="n">a</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">b</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="k">c</span><span class="w"> </span>
<span class="c1">---+---+--- </span>
<span class="w"> </span><span class="mi">1</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">2</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">1</span><span class="w"> </span>
<span class="w"> </span><span class="mi">1</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">2</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">2</span><span class="w"> </span>
<span class="w"> </span><span class="mi">1</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">2</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">3</span>
<span class="p">(</span><span class="mi">3</span><span class="w"> </span><span class="k">rows</span><span class="p">)</span><span class="w"> </span>
<span class="k">SELECT</span><span class="w"> </span><span class="k">c</span><span class="p">,</span><span class="n">rn</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="k">c</span><span class="p">,</span><span class="n">row_number</span><span class="p">()</span><span class="w"> </span><span class="n">over</span><span class="p">(</span><span class="k">order</span><span class="w"> </span><span class="k">by</span><span class="w"> </span><span class="n">a</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">rn</span><span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">t3</span><span class="p">)</span><span class="w"> </span><span class="k">where</span><span class="w"> </span><span class="n">rn</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="mi">1</span><span class="p">;</span><span class="w"> </span>
<span class="w"> </span><span class="k">c</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">rn</span><span class="w"> </span>
<span class="c1">---+---- </span>
<span class="mi">1</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">1</span>
<span class="p">(</span><span class="mi">1</span><span class="w"> </span><span class="k">row</span><span class="p">)</span><span class="w"> </span>
<span class="k">SELECT</span><span class="w"> </span><span class="k">c</span><span class="p">,</span><span class="n">rn</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="k">c</span><span class="p">,</span><span class="n">row_number</span><span class="p">()</span><span class="w"> </span><span class="n">over</span><span class="p">(</span><span class="k">order</span><span class="w"> </span><span class="k">by</span><span class="w"> </span><span class="n">a</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">rn</span><span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">t3</span><span class="p">)</span><span class="w"> </span><span class="k">where</span><span class="w"> </span><span class="n">rn</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="mi">1</span><span class="p">;</span>
<span class="w"> </span><span class="k">c</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">rn</span><span class="w"> </span>
<span class="c1">---+---- </span>
<span class="w"> </span><span class="mi">3</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">1</span>
<span class="p">(</span><span class="mi">1</span><span class="w"> </span><span class="k">row</span><span class="p">)</span>
</pre></div></td></tr></table></div>
</div>
</div>
<p id="EN-US_TOPIC_0000001431826616__p18968115117314"><strong id="EN-US_TOPIC_0000001431826616__b14272641183013">Analysis:</strong></p>
<p id="EN-US_TOPIC_0000001431826616__p149019503315">As shown above, run <strong id="EN-US_TOPIC_0000001431826616__b129901048201410">select c,rn from (select c,row_number() over(order by a,b) as rn from t3) where rn = 1;</strong> twice, the results are different. That is because duplicate values <strong id="EN-US_TOPIC_0000001431826616__b787065791811">1</strong> and <strong id="EN-US_TOPIC_0000001431826616__b1216013194">2</strong> exist in the sorting columns <strong id="EN-US_TOPIC_0000001431826616__b1121024702320">a</strong> and <strong id="EN-US_TOPIC_0000001431826616__b68514507233">b</strong> of the window function while their values in column <strong id="EN-US_TOPIC_0000001431826616__b641412432411">c</strong> are different. As a result, when the first record is obtained based on the sorting result in columns <strong id="EN-US_TOPIC_0000001431826616__b6944191416254">a</strong> and <strong id="EN-US_TOPIC_0000001431826616__b2564181892513">b</strong>, the obtained data in column <strong id="EN-US_TOPIC_0000001431826616__b44176176264">c</strong> is random, as a result, the result sets are inconsistent.</p>
<p id="EN-US_TOPIC_0000001431826616__p13515579312"><strong id="EN-US_TOPIC_0000001431826616__b236185712314">Solution:</strong></p>
<div class="p" id="EN-US_TOPIC_0000001431826616__p141582542319">The values in column <strong id="EN-US_TOPIC_0000001431826616__b1267414457265">c</strong> need to be added to the sorting.<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001431826616__screen748310192201"><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="k">c</span><span class="p">,</span><span class="n">rn</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="k">c</span><span class="p">,</span><span class="n">row_number</span><span class="p">()</span><span class="w"> </span><span class="n">over</span><span class="p">(</span><span class="k">order</span><span class="w"> </span><span class="k">by</span><span class="w"> </span><span class="n">a</span><span class="p">,</span><span class="n">b</span><span class="p">,</span><span class="k">c</span><span class="p">)</span><span class="w"> </span><span class="k">as</span><span class="w"> </span><span class="n">rn</span><span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">t3</span><span class="p">)</span><span class="w"> </span><span class="k">where</span><span class="w"> </span><span class="n">rn</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="mi">1</span><span class="p">;</span>
<span class="w"> </span><span class="k">c</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">rn</span><span class="w"> </span>
<span class="c1">---+----</span>
<span class="w"> </span><span class="mi">1</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">1</span>
<span class="p">(</span><span class="mi">1</span><span class="w"> </span><span class="k">row</span><span class="p">)</span>
</pre></div></td></tr></table></div>
</div>
</div>
</div>
<div class="section" id="EN-US_TOPIC_0000001431826616__section1444612342115"><h4 class="sectiontitle">Using Sorting in Subviews/Subqueries</h4><p id="EN-US_TOPIC_0000001431826616__p178977983218"><strong id="EN-US_TOPIC_0000001431826616__b1582762016279">Scenario</strong></p>
<div class="p" id="EN-US_TOPIC_0000001431826616__p1893714613216">After table <strong id="EN-US_TOPIC_0000001431826616__b152899572284">test</strong> and view <strong id="EN-US_TOPIC_0000001431826616__b241217319292">v</strong> are created, the query results are inconsistent when sorting is used to query table <strong id="EN-US_TOPIC_0000001431826616__b1566501298">test</strong> in a subquery.<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001431826616__screen1976117526516"><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">CREATE</span><span class="w"> </span><span class="k">TABLE</span><span class="w"> </span><span class="n">test</span><span class="p">(</span><span class="n">a</span><span class="w"> </span><span class="nb">serial</span><span class="w"> </span><span class="p">,</span><span class="n">b</span><span class="w"> </span><span class="nb">int</span><span class="p">);</span>
<span class="k">INSERT</span><span class="w"> </span><span class="k">INTO</span><span class="w"> </span><span class="n">test</span><span class="p">(</span><span class="n">b</span><span class="p">)</span><span class="w"> </span><span class="k">VALUES</span><span class="p">(</span><span class="mi">1</span><span class="p">);</span>
<span class="k">INSERT</span><span class="w"> </span><span class="k">INTO</span><span class="w"> </span><span class="n">test</span><span class="p">(</span><span class="n">b</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="n">test</span><span class="p">;</span>
<span class="p">...</span>
<span class="k">INSERT</span><span class="w"> </span><span class="k">INTO</span><span class="w"> </span><span class="n">test</span><span class="p">(</span><span class="n">b</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="n">test</span><span class="p">;</span>
<span class="k">CREATE</span><span class="w"> </span><span class="k">VIEW</span><span class="w"> </span><span class="n">v</span><span class="w"> </span><span class="k">as</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</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">a</span><span class="p">;</span>
</pre></div></td></tr></table></div>
</div>
</div>
<p id="EN-US_TOPIC_0000001431826616__p9217161811613">Problem SQL:</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001431826616__screen158031363234"><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></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">v</span><span class="w"> </span><span class="k">limit</span><span class="w"> </span><span class="mi">1</span><span class="p">;</span>
<span class="w"> </span><span class="n">a</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">b</span>
<span class="c1">---+---</span>
<span class="w"> </span><span class="mi">3</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">1</span>
<span class="p">(</span><span class="mi">1</span><span class="w"> </span><span class="k">row</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="p">(</span><span class="k">select</span><span class="w"> </span><span class="o">*</span><span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">test</span><span class="w"> </span><span class="k">order</span><span class="w"> </span><span class="k">by</span><span class="w"> </span><span class="n">a</span><span class="p">)</span><span class="w"> </span><span class="k">limit</span><span class="w"> </span><span class="mi">10</span><span class="p">;</span>
<span class="w"> </span><span class="n">a</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">b</span>
<span class="c1">----+---</span>
<span class="w"> </span><span class="mi">14</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">1</span>
<span class="p">(</span><span class="mi">1</span><span class="w"> </span><span class="k">row</span><span class="p">)</span>
<span class="k">SELECT</span><span class="w"> </span><span class="o">*</span><span class="w"> </span><span class="k">FROM</span><span class="w"> </span><span class="n">test</span><span class="w"> </span><span class="k">order</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">limit</span><span class="w"> </span><span class="mi">10</span><span class="p">;</span>
<span class="w"> </span><span class="n">a</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">b</span>
<span class="c1">---+---</span>
<span class="w"> </span><span class="mi">1</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">1</span>
<span class="p">(</span><span class="mi">1</span><span class="w"> </span><span class="k">row</span><span class="p">)</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001431826616__p195441213163216"><strong id="EN-US_TOPIC_0000001431826616__b19389153552918">Analysis:</strong></p>
<p id="EN-US_TOPIC_0000001431826616__p97101529133120"><strong id="EN-US_TOPIC_0000001431826616__b867734312319">ORDER BY</strong> is invalid for subviews and subqueries.</p>
<p id="EN-US_TOPIC_0000001431826616__p2111191543211"><strong id="EN-US_TOPIC_0000001431826616__b1713493103114">Solution:</strong></p>
<p id="EN-US_TOPIC_0000001431826616__p16409327313">You are not advised to use <strong id="EN-US_TOPIC_0000001431826616__b132361455163114">ORDER BY</strong> in subviews and subqueries. To ensure that the results are in order, use <strong id="EN-US_TOPIC_0000001431826616__b1465110115329">ORDER BY</strong> in the outermost query.</p>
</div>
<div class="section" id="EN-US_TOPIC_0000001431826616__section2952812192814"><h4 class="sectiontitle">LIMIT in Subqueries</h4><p id="EN-US_TOPIC_0000001431826616__p7125111803215"><strong id="EN-US_TOPIC_0000001431826616__b7346194915328">Scenario</strong>: When <strong id="EN-US_TOPIC_0000001431826616__b12264410203615">LIMIT</strong> is used in a subquery, the two query results are inconsistent.</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001431826616__screen19213849112812"><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">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">a</span><span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">test</span><span class="w"> </span><span class="k">limit</span><span class="w"> </span><span class="mi">1</span><span class="w"> </span><span class="p">)</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">1</span><span class="p">;</span>
<span class="w"> </span><span class="n">a</span>
<span class="c1">---</span>
<span class="w"> </span><span class="mi">5</span>
<span class="p">(</span><span class="mi">1</span><span class="w"> </span><span class="k">row</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="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">test</span><span class="w"> </span><span class="k">limit</span><span class="w"> </span><span class="mi">1</span><span class="w"> </span><span class="p">)</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">1</span><span class="p">;</span>
<span class="w"> </span><span class="n">a</span>
<span class="c1">---</span>
<span class="w"> </span><span class="mi">1</span>
<span class="p">(</span><span class="mi">1</span><span class="w"> </span><span class="k">row</span><span class="p">)</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001431826616__p1098742219321"><strong id="EN-US_TOPIC_0000001431826616__b162023140335">Analysis:</strong></p>
<p id="EN-US_TOPIC_0000001431826616__p8581171418284">The LIMIT in the subquery causes random results to be obtained.</p>
<p id="EN-US_TOPIC_0000001431826616__p2508724193211"><strong id="EN-US_TOPIC_0000001431826616__b1750811241327">Solution:</strong></p>
<p id="EN-US_TOPIC_0000001431826616__p927685143114">To ensure the stability of the final query result, do not use <strong id="EN-US_TOPIC_0000001431826616__b83601637379">LIMIT</strong> in subqueries.</p>
</div>
<div class="section" id="EN-US_TOPIC_0000001431826616__section1817020238318"><h4 class="sectiontitle">Using String_agg</h4><p id="EN-US_TOPIC_0000001431826616__p165212346318"><strong id="EN-US_TOPIC_0000001431826616__b437115262374">Scenario</strong>: When <strong id="EN-US_TOPIC_0000001431826616__b2010962543916">string_agg</strong> is used to query the table <strong id="EN-US_TOPIC_0000001431826616__b28951818393">employee</strong>, the query results are inconsistent.</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001431826616__screen1594113269325"><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></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">employee</span><span class="p">;</span>
<span class="w"> </span><span class="n">empno</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">ename</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">job</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">mgr</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">hiredate</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">sal</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">comm</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">deptno</span><span class="w"> </span>
<span class="c1">-------+--------+---------+------+---------------------+-------+------+--------</span>
<span class="w"> </span><span class="mi">7654</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">MARTIN</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">SALEMAN</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">7698</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">2022</span><span class="o">-</span><span class="mi">11</span><span class="o">-</span><span class="mi">08</span><span class="w"> </span><span class="mi">00</span><span class="p">:</span><span class="mi">00</span><span class="p">:</span><span class="mi">00</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">12000</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">1400</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">30</span>
<span class="w"> </span><span class="mi">7566</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">JONES</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">MANAGER</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">7839</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">2022</span><span class="o">-</span><span class="mi">11</span><span class="o">-</span><span class="mi">08</span><span class="w"> </span><span class="mi">00</span><span class="p">:</span><span class="mi">00</span><span class="p">:</span><span class="mi">00</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">32000</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">0</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">20</span>
<span class="w"> </span><span class="mi">7499</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">ALLEN</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">SALEMAN</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">7698</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">2022</span><span class="o">-</span><span class="mi">11</span><span class="o">-</span><span class="mi">08</span><span class="w"> </span><span class="mi">00</span><span class="p">:</span><span class="mi">00</span><span class="p">:</span><span class="mi">00</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">16000</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">300</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">30</span>
<span class="p">(</span><span class="mi">3</span><span class="w"> </span><span class="k">rows</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="p">(</span><span class="k">select</span><span class="w"> </span><span class="n">deptno</span><span class="p">,</span><span class="w"> </span><span class="n">string_agg</span><span class="p">(</span><span class="n">ename</span><span class="p">,</span><span class="w"> </span><span class="s1">','</span><span class="p">)</span><span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">employee</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">deptno</span><span class="p">)</span><span class="w"> </span><span class="n">t1</span><span class="p">,</span><span class="w"> </span><span class="p">(</span><span class="k">select</span><span class="w"> </span><span class="n">deptno</span><span class="p">,</span><span class="w"> </span><span class="n">string_agg</span><span class="p">(</span><span class="n">ename</span><span class="p">,</span><span class="w"> </span><span class="s1">','</span><span class="p">)</span><span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">employee</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">deptno</span><span class="p">)</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">string_agg</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">string_agg</span><span class="p">;</span>
<span class="w"> </span><span class="k">count</span><span class="w"> </span>
<span class="c1">-------</span>
<span class="w"> </span><span class="mi">2</span>
<span class="p">(</span><span class="mi">1</span><span class="w"> </span><span class="k">row</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="p">(</span><span class="k">select</span><span class="w"> </span><span class="n">deptno</span><span class="p">,</span><span class="w"> </span><span class="n">string_agg</span><span class="p">(</span><span class="n">ename</span><span class="p">,</span><span class="w"> </span><span class="s1">','</span><span class="p">)</span><span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">employee</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">deptno</span><span class="p">)</span><span class="w"> </span><span class="n">t1</span><span class="p">,</span><span class="w"> </span><span class="p">(</span><span class="k">select</span><span class="w"> </span><span class="n">deptno</span><span class="p">,</span><span class="w"> </span><span class="n">string_agg</span><span class="p">(</span><span class="n">ename</span><span class="p">,</span><span class="w"> </span><span class="s1">','</span><span class="p">)</span><span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">employee</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">deptno</span><span class="p">)</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">string_agg</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">string_agg</span><span class="p">;</span>
<span class="w"> </span><span class="k">count</span><span class="w"> </span>
<span class="c1">-------</span>
<span class="w"> </span><span class="mi">1</span>
<span class="p">(</span><span class="mi">1</span><span class="w"> </span><span class="k">row</span><span class="p">)</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001431826616__p624614733312"><strong id="EN-US_TOPIC_0000001431826616__b5531104753613">Analysis:</strong></p>
<p id="EN-US_TOPIC_0000001431826616__p18361339202711">The <strong id="EN-US_TOPIC_0000001431826616__b91716344118">string_agg</strong> function is used to concatenate data in a group into one row. However, if you use <strong id="EN-US_TOPIC_0000001431826616__b71718374117">string_agg(ename, ',')</strong>, the order of concatenated results needs to be specified. For example, in the preceding statement, <strong id="EN-US_TOPIC_0000001431826616__b916113336417">select deptno, string_agg(ename, ',') from employee group by deptno;</strong></p>
<p id="EN-US_TOPIC_0000001431826616__p14404256123312">can output either of the following:</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001431826616__screen1531014519274"><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="mi">30</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">ALLEN</span><span class="p">,</span><span class="n">MARTIN</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001431826616__p1840445693318">Or:</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001431826616__screen69060483276"><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="mi">30</span><span class="w"> </span><span class="o">|</span><span class="n">MARTIN</span><span class="p">,</span><span class="n">ALLEN</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001431826616__p144041056123317">In the preceding scenario, the result of subquery <strong id="EN-US_TOPIC_0000001431826616__b18633105424615">t1</strong> may be different from that of subquery <strong id="EN-US_TOPIC_0000001431826616__b150135811463">t2</strong> when deptno is <strong id="EN-US_TOPIC_0000001431826616__b5596217472">30</strong>.</p>
<p id="EN-US_TOPIC_0000001431826616__p4402172117344"><strong id="EN-US_TOPIC_0000001431826616__b83618445368">Solution:</strong></p>
<p id="EN-US_TOPIC_0000001431826616__p4793102653419">Add <strong id="EN-US_TOPIC_0000001431826616__b588614412474">ORDER BY</strong> to <strong id="EN-US_TOPIC_0000001431826616__b9915123314712">String_agg</strong> to ensure that data is concatenated in sequence.</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001431826616__screen54057331348"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal">1</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">SELECT</span><span class="w"> </span><span class="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="p">(</span><span class="k">select</span><span class="w"> </span><span class="n">deptno</span><span class="p">,</span><span class="w"> </span><span class="n">string_agg</span><span class="p">(</span><span class="n">ename</span><span class="p">,</span><span class="w"> </span><span class="s1">','</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">ename</span><span class="w"> </span><span class="k">desc</span><span class="p">)</span><span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">employee</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">deptno</span><span class="p">)</span><span class="w"> </span><span class="n">t1</span><span class="w"> </span><span class="p">,(</span><span class="k">select</span><span class="w"> </span><span class="n">deptno</span><span class="p">,</span><span class="w"> </span><span class="n">string_agg</span><span class="p">(</span><span class="n">ename</span><span class="p">,</span><span class="w"> </span><span class="s1">','</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">ename</span><span class="w"> </span><span class="k">desc</span><span class="p">)</span><span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">employee</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">deptno</span><span class="p">)</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">string_agg</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">string_agg</span><span class="p">;</span>
</pre></div></td></tr></table></div>
</div>
</div>
<div class="section" id="EN-US_TOPIC_0000001431826616__section13161161993718"><h4 class="sectiontitle">Database Compatibility Mode</h4><p id="EN-US_TOPIC_0000001431826616__p19323115013304"><strong id="EN-US_TOPIC_0000001431826616__b1233718195482">Scenario:</strong> The query results of empty strings in the database are inconsistent.</p>
<p id="EN-US_TOPIC_0000001431826616__p16907124983713">database1 (TD-compatible):</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001431826616__screen17445756153718"><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="n">td</span><span class="o">=#</span><span class="w"> </span><span class="k">select</span><span class="w"> </span><span class="s1">''</span><span class="w"> </span><span class="k">is</span><span class="w"> </span><span class="k">null</span><span class="p">;</span>
<span class="w"> </span><span class="k">isnull</span><span class="w"> </span>
<span class="c1">--------</span>
<span class="w"> </span><span class="n">f</span>
<span class="p">(</span><span class="mi">1</span><span class="w"> </span><span class="k">row</span><span class="p">)</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001431826616__p8907114913370">database2 (ORA compatible):</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001431826616__screen28716016383"><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="n">ora</span><span class="o">=#</span><span class="w"> </span><span class="k">select</span><span class="w"> </span><span class="s1">''</span><span class="w"> </span><span class="k">is</span><span class="w"> </span><span class="k">null</span><span class="p">;</span>
<span class="w"> </span><span class="k">isnull</span><span class="w"> </span>
<span class="c1">--------</span>
<span class="w"> </span><span class="n">t</span>
<span class="p">(</span><span class="mi">1</span><span class="w"> </span><span class="k">row</span><span class="p">)</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001431826616__p424915117319"><strong id="EN-US_TOPIC_0000001431826616__b35763468484">Analysis:</strong></p>
<p id="EN-US_TOPIC_0000001431826616__p7191012153818">The empty string query results are different because the syntax of the empty string is different from that of the null string in different database compatibility.</p>
<p id="EN-US_TOPIC_0000001431826616__p91382027192013">Currently, GaussDB(DWS) supports three types of database compatibility: Oracle, TD, and MySQL. The syntax and behavior vary depending on the compatibility mode. For details about the compatibility differences, see "Syntax Compatibility Differences Among Oracle, Teradata, and MySQL" in <em id="EN-US_TOPIC_0000001431826616__i10368188164919">GaussDB(DWS) Developer Guide</em>.</p>
<p id="EN-US_TOPIC_0000001431826616__p1073714339389">Databases in different compatibility modes have different compatibility issues. You can run <strong id="EN-US_TOPIC_0000001431826616__b1593923775414">select datname, datcompatibility from pg_database;</strong> to check the database compatibility.</p>
<p id="EN-US_TOPIC_0000001431826616__p564181814393"><strong id="EN-US_TOPIC_0000001431826616__b129683583619">Solution:</strong></p>
<p id="EN-US_TOPIC_0000001431826616__p21281224173919">The problem is solved when the compatibility modes of the databases in the two environments are set to the same. The <strong id="EN-US_TOPIC_0000001431826616__b16470443185818">DBCOMPATIBILITY</strong> attribute of a database does not support <strong id="EN-US_TOPIC_0000001431826616__b931612005918">ALTER</strong>. You can only specify the same <strong id="EN-US_TOPIC_0000001431826616__b15782222155913">DBCOMPATIBILITY</strong> attribute when creating a database.</p>
</div>
<div class="section" id="EN-US_TOPIC_0000001431826616__section819201014524"><h4 class="sectiontitle">The configuration item <strong id="EN-US_TOPIC_0000001431826616__b949314417518">behavior_compat_options</strong> for database compatibility behaviors is configured inconsistently.</h4><p id="EN-US_TOPIC_0000001431826616__p26871451300"><strong id="EN-US_TOPIC_0000001431826616__b1260515274616">Scenario:</strong> The calculation results of the <strong id="EN-US_TOPIC_0000001431826616__b439564571">add_months</strong> function are inconsistent.</p>
<p id="EN-US_TOPIC_0000001431826616__p076861513520">database1:</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001431826616__screen9888184375220"><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="n">add_months</span><span class="p">(</span><span class="s1">'2018-02-28'</span><span class="p">,</span><span class="mi">3</span><span class="p">)</span><span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">dual</span><span class="p">;</span>
<span class="n">add_months</span>
<span class="c1">---------------------</span>
<span class="mi">2018</span><span class="o">-</span><span class="mi">05</span><span class="o">-</span><span class="mi">28</span><span class="w"> </span><span class="mi">00</span><span class="p">:</span><span class="mi">00</span><span class="p">:</span><span class="mi">00</span>
<span class="p">(</span><span class="mi">1</span><span class="w"> </span><span class="k">row</span><span class="p">)</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001431826616__p87681415175218">database2:</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001431826616__screen911110584524"><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="n">add_months</span><span class="p">(</span><span class="s1">'2018-02-28'</span><span class="p">,</span><span class="mi">3</span><span class="p">)</span><span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">dual</span><span class="p">;</span>
<span class="n">add_months</span>
<span class="c1">---------------------</span>
<span class="mi">2018</span><span class="o">-</span><span class="mi">05</span><span class="o">-</span><span class="mi">31</span><span class="w"> </span><span class="mi">00</span><span class="p">:</span><span class="mi">00</span><span class="p">:</span><span class="mi">00</span>
<span class="p">(</span><span class="mi">1</span><span class="w"> </span><span class="k">row</span><span class="p">)</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001431826616__p1176811515216"><strong id="EN-US_TOPIC_0000001431826616__b8712142363610">Analysis:</strong></p>
<p id="EN-US_TOPIC_0000001431826616__p83051155103611">Some behaviors may vary depending on the settings of the database compatibility configuration item <strong id="EN-US_TOPIC_0000001431826616__b42171646173717">behavior_compat_options</strong>. For details about the options of this item, see "GUC Parameters &gt; Miscellaneous Parameters &gt; behavior_compat_options" in <em id="EN-US_TOPIC_0000001431826616__i16515817124013">GaussDB(DWS) Developer Guide</em>..</p>
<p id="EN-US_TOPIC_0000001431826616__p47661133151214">The <strong id="EN-US_TOPIC_0000001431826616__b5776415113413">end_month_calculate</strong> in <strong id="EN-US_TOPIC_0000001431826616__b342533010347">behavior_compat_options</strong> controls the calculation logic of the <strong id="EN-US_TOPIC_0000001431826616__b1376144903414">add_months</strong> function. If this parameter is specified, and the <strong id="EN-US_TOPIC_0000001431826616__b26850374211135">Day</strong> of <strong id="EN-US_TOPIC_0000001431826616__b170464348211135">param1</strong> indicates the last day of a month shorter than <strong id="EN-US_TOPIC_0000001431826616__b58588793711135">result</strong>, the <strong id="EN-US_TOPIC_0000001431826616__b168201135011135">Day</strong> in the calculation result will equal that in <strong id="EN-US_TOPIC_0000001431826616__b208966607411135">result</strong>.</p>
<p id="EN-US_TOPIC_0000001431826616__p676817152523"><strong id="EN-US_TOPIC_0000001431826616__b128081449193313">Solution:</strong></p>
<p id="EN-US_TOPIC_0000001431826616__p276821517522">The <strong id="EN-US_TOPIC_0000001431826616__b582212010360">behavior_compat_options</strong> parameter must be configured consistently. This parameter is of the <strong id="EN-US_TOPIC_0000001431826616__b1136258144011">USERSET</strong> type and can be set at the session level or modified at the cluster level.</p>
</div>
<div class="section" id="EN-US_TOPIC_0000001431826616__section138586470458"><h4 class="sectiontitle">The attributes of the user-defined function are not properly set.</h4><p id="EN-US_TOPIC_0000001431826616__p152051542163016"><strong id="EN-US_TOPIC_0000001431826616__b460817173416">Scenario:</strong> When the customized function <strong id="EN-US_TOPIC_0000001431826616__b16288132213416">get_count()</strong> is invoked, the results are inconsistent.</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001431826616__screen6899536174618"><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">CREATE</span><span class="w"> </span><span class="k">FUNCTION</span><span class="w"> </span><span class="n">get_count</span><span class="p">()</span><span class="w"> </span><span class="k">returns</span><span class="w"> </span><span class="nb">int</span>
<span class="n">SHIPPABLE</span>
<span class="k">as</span><span class="w"> </span><span class="err">$$</span>
<span class="k">declare</span>
<span class="w"> </span><span class="k">result</span><span class="w"> </span><span class="nb">int</span><span class="p">;</span>
<span class="k">begin</span>
<span class="k">result</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">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">test</span><span class="p">);</span><span class="w"> </span><span class="c1">--test table is a hash table.</span>
<span class="w"> </span><span class="k">return</span><span class="w"> </span><span class="k">result</span><span class="p">;</span>
<span class="k">end</span><span class="p">;</span>
<span class="err">$$</span>
<span class="k">language</span><span class="w"> </span><span class="n">plpgsql</span><span class="p">;</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001431826616__p12249114111460">Call this function.</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001431826616__screen124141846144618"><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">SELECT</span><span class="w"> </span><span class="n">get_count</span><span class="p">();</span>
<span class="w"> </span><span class="n">get_count</span><span class="w"> </span>
<span class="c1">-----------</span>
<span class="w"> </span><span class="mi">2106</span>
<span class="p">(</span><span class="mi">1</span><span class="w"> </span><span class="k">row</span><span class="p">)</span>
<span class="k">SELECT</span><span class="w"> </span><span class="n">get_count</span><span class="p">()</span><span class="w"> </span><span class="k">FROM</span><span class="w"> </span><span class="n">t_src</span><span class="p">;</span>
<span class="w"> </span><span class="n">get_count</span><span class="w"> </span>
<span class="c1">-----------</span>
<span class="w"> </span><span class="mi">1032</span>
<span class="p">(</span><span class="mi">1</span><span class="w"> </span><span class="k">row</span><span class="p">)</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001431826616__p46879432488"><strong id="EN-US_TOPIC_0000001431826616__b15980357184315">Analysis:</strong></p>
<p id="EN-US_TOPIC_0000001431826616__p1550020245491">This function specifies the <strong id="EN-US_TOPIC_0000001431826616__b1657418159446">SHIPPABLE</strong> attribute. When a plan is generated, the function pushes it down to DNs for execution. The test table defined in the function is a hash table. Therefore, each DN has only part of the data in the table, the result returned by <strong id="EN-US_TOPIC_0000001431826616__b215372745319">select count(*) from test;</strong> is not the result of full data in the test table. The expected result changes after <strong id="EN-US_TOPIC_0000001431826616__b42261519165820">from</strong> is added.</p>
<p id="EN-US_TOPIC_0000001431826616__p96874435482"><strong id="EN-US_TOPIC_0000001431826616__b101301042143113">Solution:</strong></p>
<p id="EN-US_TOPIC_0000001431826616__p168714317484">Use either of the following methods (the first method is recommended):</p>
<ol id="EN-US_TOPIC_0000001431826616__ol6906154923117"><li id="EN-US_TOPIC_0000001431826616__li79061949203117">Change the function to not push down: <strong id="EN-US_TOPIC_0000001431826616__b289113185916">ALTER FUNCTION get_count() not shippable;</strong></li><li id="EN-US_TOPIC_0000001431826616__li29061499319">Change the table used in the function to a replication table. In this way, the full data of the table is stored on each DN. Even if the plan is pushed down to DNs for execution, the result set will be as expected.</li></ol>
</div>
<div class="section" id="EN-US_TOPIC_0000001431826616__section11173018505"><h4 class="sectiontitle">Using the Unlogged Table</h4><p id="EN-US_TOPIC_0000001431826616__p727773610304"><strong id="EN-US_TOPIC_0000001431826616__b317522419912">Scenario:</strong></p>
<p id="EN-US_TOPIC_0000001431826616__p478624917509">After an unlogged table is used and the cluster is restarted, the associated query result set is abnormal, and some data is missing in the unlogged table.</p>
<p id="EN-US_TOPIC_0000001431826616__p1978620492501"><strong id="EN-US_TOPIC_0000001431826616__b11889749171016">Analysis:</strong></p>
<p id="EN-US_TOPIC_0000001431826616__p1378614985016">If <strong id="EN-US_TOPIC_0000001431826616__b1527814191120">max_query_retry_times</strong> is set to <strong id="EN-US_TOPIC_0000001431826616__b3718143020147">0</strong> and the keyword <strong id="EN-US_TOPIC_0000001431826616__b11104153416146">UNLOGGED</strong> is specified during table creation, the created table will be an unlogged table. Data written to unlogged tables is not written to the write-ahead log, which makes them considerably faster than ordinary tables. However, an unlogged table is automatically truncated after a crash or unclean shutdown, incurring data loss risks. The contents of an unlogged table are also not replicated to standby servers. Any indexes created on an unlogged table are not automatically logged as well. If the cluster restarts unexpectedly (process restart, node fault, or cluster restart), some data in the memory is not flushed to disks in a timely manner, and some data is lost, causing the result set to be abnormal.</p>
<p id="EN-US_TOPIC_0000001431826616__p14616103383013"><strong id="EN-US_TOPIC_0000001431826616__b8617113323018">Solution:</strong></p>
<p id="EN-US_TOPIC_0000001431826616__p137861049155012">The security of unlogged tables cannot be ensured if the cluster goes faulty. In most cases, unlogged tables are only used as temporary tables. If a cluster is faulty, you need to rebuild the unlogged table or back up the data and import it to the database again to ensure that the data is normal.</p>
</div>
</div>
<div>
<div class="familylinks">
<div class="parentlink"><strong>Parent topic:</strong> <a href="dws_03_0065.html">Database Usage</a></div>
</div>
</div>