doc-exports/docs/dws/dev/dws_04_0488.html
Lu, Huayi a24ca60074 DWS DEVELOPER 811 version
Reviewed-by: Hasko, Vladimir <vladimir.hasko@t-systems.com>
Co-authored-by: Lu, Huayi <luhuayi@huawei.com>
Co-committed-by: Lu, Huayi <luhuayi@huawei.com>
2023-01-19 13:37:49 +00:00

70 lines
12 KiB
HTML

<a name="EN-US_TOPIC_0000001098814544"></a><a name="EN-US_TOPIC_0000001098814544"></a>
<h1 class="topictitle1">Case: Rewriting SQL Statements and Eliminating Prune Interference</h1>
<div id="body8662426"><div class="section" id="EN-US_TOPIC_0000001098814544__sa622744249414a04b2eabd54f17d72b2"><h4 class="sectiontitle">Symptom</h4><p id="EN-US_TOPIC_0000001098814544__abd929ebf1d5a44ed94a67f5049e52b53">In a test at a site, <strong id="EN-US_TOPIC_0000001098814544__b7906109195218">ddw_f10_op_cust_asset_mon</strong> is a partitioned table and the partition key is <strong id="EN-US_TOPIC_0000001098814544__b990714916529">year_mth</strong> whose value is a combined string of month and year values.</p>
<p id="EN-US_TOPIC_0000001098814544__a9d944745b6784724aa609cf05727aece">The following figure shows the tested SQL statements:</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001098814544__s70b80a4b4dd045e7a8c3dd0d04f516c8"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal">1</span>
<span class="normal">2</span>
<span class="normal">3</span>
<span class="normal">4</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">select</span><span class="w"> </span>
<span class="w"> </span><span class="k">count</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">t_ddw_f10_op_cust_asset_mon</span><span class="w"> </span><span class="n">b1</span><span class="w"></span>
<span class="k">where</span><span class="w"> </span><span class="n">b1</span><span class="p">.</span><span class="n">year_mth</span><span class="w"> </span><span class="k">between</span><span class="w"> </span><span class="n">to_char</span><span class="p">(</span><span class="n">add_months</span><span class="p">(</span><span class="n">to_date</span><span class="p">(</span><span class="s1">''</span><span class="mi">20170222</span><span class="s1">''</span><span class="p">,</span><span class="s1">'yyyymmdd'</span><span class="p">),</span><span class="w"> </span><span class="o">-</span><span class="mi">11</span><span class="p">),</span><span class="s1">'yyyymm'</span><span class="p">)</span><span class="w"> </span><span class="k">and</span><span class="w"> </span><span class="n">substr</span><span class="p">(</span><span class="s1">''</span><span class="mi">20170222</span><span class="s1">''</span><span class="p">,</span><span class="mi">1</span><span class="w"> </span><span class="p">,</span><span class="mi">6</span><span class="w"> </span><span class="p">);</span><span class="w"></span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001098814544__ad7c3fb1247e54d8ebf896188fbae5034">The test result shows the SQL Scan table takes 135s. This may be the performance bottleneck.</p>
<div class="note" id="EN-US_TOPIC_0000001098814544__n175a0db5d2ce40d5874748db84897e9a"><img src="public_sys-resources/note_3.0-en-us.png"><span class="notetitle"> </span><div class="notebody"><p id="EN-US_TOPIC_0000001098814544__a48ea0bf99e7d4b339493733b4058e6ae">add_months is a local adaptation function.</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001098814544__s1a55b0f51c8149e3b68af61fad56a546"><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">CREATE</span><span class="w"> </span><span class="k">OR</span><span class="w"> </span><span class="k">REPLACE</span><span class="w"> </span><span class="k">FUNCTION</span><span class="w"> </span><span class="n">ADD_MONTHS</span><span class="p">(</span><span class="nb">date</span><span class="p">,</span><span class="w"> </span><span class="nb">integer</span><span class="p">)</span><span class="w"> </span><span class="k">RETURNS</span><span class="w"> </span><span class="nb">date</span><span class="w"></span>
<span class="w"> </span><span class="k">AS</span><span class="w"> </span><span class="err">$$</span><span class="w"></span>
<span class="w"> </span><span class="k">SELECT</span><span class="w"></span>
<span class="w"> </span><span class="k">CASE</span><span class="w"> </span>
<span class="w"> </span><span class="k">WHEN</span><span class="w"> </span><span class="p">(</span><span class="k">EXTRACT</span><span class="p">(</span><span class="k">day</span><span class="w"> </span><span class="k">FROM</span><span class="w"> </span><span class="err">$</span><span class="mi">1</span><span class="p">)</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="k">EXTRACT</span><span class="p">(</span><span class="k">day</span><span class="w"> </span><span class="k">FROM</span><span class="w"> </span><span class="p">(</span><span class="n">date_trunc</span><span class="p">(</span><span class="s1">'month'</span><span class="p">,</span><span class="w"> </span><span class="err">$</span><span class="mi">1</span><span class="p">)</span><span class="w"> </span><span class="o">+</span><span class="w"> </span><span class="nb">INTERVAL</span><span class="w"> </span><span class="s1">'1 month - 1 day'</span><span class="p">)))</span><span class="w"> </span><span class="k">THEN</span><span class="w"></span>
<span class="w"> </span><span class="n">date_trunc</span><span class="p">(</span><span class="s1">'month'</span><span class="p">,</span><span class="w"> </span><span class="err">$</span><span class="mi">1</span><span class="p">)</span><span class="w"> </span><span class="o">+</span><span class="w"> </span><span class="k">CAST</span><span class="p">(</span><span class="err">$</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="o">||</span><span class="w"> </span><span class="s1">' month - 1 day'</span><span class="w"> </span><span class="k">as</span><span class="w"> </span><span class="nb">interval</span><span class="p">)</span><span class="w"></span>
<span class="w"> </span><span class="k">ELSE</span><span class="w"></span>
<span class="w"> </span><span class="err">$</span><span class="mi">1</span><span class="w"> </span><span class="o">+</span><span class="w"> </span><span class="k">CAST</span><span class="p">(</span><span class="err">$</span><span class="mi">2</span><span class="w"> </span><span class="o">||</span><span class="w"> </span><span class="s1">' month'</span><span class="w"> </span><span class="k">as</span><span class="w"> </span><span class="nb">interval</span><span class="p">)</span><span class="w"></span>
<span class="w"> </span><span class="k">END</span><span class="w"></span>
<span class="w"> </span><span class="err">$$</span><span class="w"></span>
<span class="w"> </span><span class="k">LANGUAGE</span><span class="w"> </span><span class="k">SQL</span><span class="w"></span>
<span class="w"> </span><span class="k">IMMUTABLE</span><span class="p">;</span><span class="w"></span>
</pre></div></td></tr></table></div>
</div>
</div></div>
</div>
<div class="section" id="EN-US_TOPIC_0000001098814544__s66b2c7c3ed1a4ede93232017c6486cb1"><h4 class="sectiontitle">Optimization</h4><p id="EN-US_TOPIC_0000001098814544__a0357035e73c34efb901438672bf78fce">According to the statement execution plan, the base table filter is displayed as follows:</p>
<pre class="screen" id="EN-US_TOPIC_0000001098814544__sd17c5e97909241bfa02a89ead64e8681"><em id="EN-US_TOPIC_0000001098814544__ab9a46cf02db541688e7b82b91c99df79">Filter: (((year_mth)::text &lt;= '201702'::text) AND ((year_mth)::text &gt;= to_char(add_months(to_date('20170222'::text, 'YYYYMMDD'::text), (-11)), 'YYYYMM'::text)))</em></pre>
<p id="EN-US_TOPIC_0000001098814544__a2290dcb066f64b2fb1501301afd41e1d">The query condition expression to_char(add_months(to_date(''20170222'','yyyymmdd'),-11),'yyyymm') exists in the filter condition, and this non-constant expression cannot be used for pruning. Therefore, all data of query statements in the partitioned tables is scanned.</p>
<p id="EN-US_TOPIC_0000001098814544__aa1a1faacede0438f91c39f212e73cfd9">to_date and to_char are stable functions as queried in the pg_proc. Based on the function behaviors described in Postgresql, this type of function cannot be converted into the Const value in the preprocessing phase, which is the root cause of preventing partition pruning.</p>
<p id="EN-US_TOPIC_0000001098814544__a504f74cb6018465db0dab1926ee238b8">Based on the preceding analysis, the optimization expression can be used for partition pruning, which is the key to performance optimization. The original SQL statements can be written to as follows:</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001098814544__s6713ae2ec8bb4140a9623ea38a7b5f2c"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal">1</span>
<span class="normal">2</span>
<span class="normal">3</span>
<span class="normal">4</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">select</span><span class="w"> </span>
<span class="w"> </span><span class="k">count</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">t_ddw_f10_op_cust_asset_mon</span><span class="w"> </span><span class="n">b1</span><span class="w"></span>
<span class="k">where</span><span class="w"> </span><span class="n">b1</span><span class="p">.</span><span class="n">year_mth</span><span class="w"> </span><span class="k">between</span><span class="p">(</span><span class="n">substr</span><span class="p">(</span><span class="n">ADD_MONTHS</span><span class="p">(</span><span class="s1">'20170222'</span><span class="p">::</span><span class="nb">date</span><span class="p">,</span><span class="w"> </span><span class="o">-</span><span class="mi">11</span><span class="p">),</span><span class="w"> </span><span class="mi">1</span><span class="p">,</span><span class="w"> </span><span class="mi">4</span><span class="p">)</span><span class="o">||</span><span class="n">substr</span><span class="p">(</span><span class="n">ADD_MONTHS</span><span class="p">(</span><span class="s1">'20170222'</span><span class="p">::</span><span class="nb">date</span><span class="p">,</span><span class="w"> </span><span class="o">-</span><span class="mi">11</span><span class="p">),</span><span class="w"> </span><span class="mi">6</span><span class="p">,</span><span class="w"> </span><span class="mi">2</span><span class="p">))</span><span class="w"> </span><span class="k">and</span><span class="w"> </span><span class="n">substr</span><span class="p">(</span><span class="s1">''</span><span class="mi">20170222</span><span class="s1">''</span><span class="p">,</span><span class="mi">1</span><span class="w"> </span><span class="p">,</span><span class="mi">6</span><span class="w"> </span><span class="p">);</span><span class="w"></span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001098814544__a48096dcd01c64d6cbd198af823a88e43">The execution time of modified SQL statements is reduced from 135s to 18s.</p>
</div>
</div>
<div>
<div class="familylinks">
<div class="parentlink"><strong>Parent topic:</strong> <a href="dws_04_0474.html">Optimization Cases</a></div>
</div>
</div>