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

63 lines
9.0 KiB
HTML

<a name="EN-US_TOPIC_0000001145814337"></a><a name="EN-US_TOPIC_0000001145814337"></a>
<h1 class="topictitle1">Case: Rewriting SQL and Deleting Subqueries (Case 2)</h1>
<div id="body8662426"><div class="section" id="EN-US_TOPIC_0000001145814337__s77a5bea19cdf4c43ac941d730acaf08b"><h4 class="sectiontitle">Symptom</h4><p id="EN-US_TOPIC_0000001145814337__a2ccd6de2bc0a41c083d41cec6fb0006c">On a site, the customer gave the feedback saying that the execution time of the following SQL statements lasted over one day and did not end:</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001145814337__saacc4b4578a74df29637639d9a185007"><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">UPDATE</span><span class="w"> </span><span class="n">calc_empfyc_c_cusr1</span><span class="w"> </span><span class="n">t1</span><span class="w"></span>
<span class="k">SET</span><span class="w"> </span><span class="n">ln_rec_count</span><span class="w"> </span><span class="o">=</span><span class="w"></span>
<span class="w"> </span><span class="p">(</span><span class="w"></span>
<span class="w"> </span><span class="k">SELECT</span><span class="w"> </span><span class="k">CASE</span><span class="w"> </span><span class="k">WHEN</span><span class="w"> </span><span class="k">current_date</span><span class="w"> </span><span class="o">-</span><span class="w"> </span><span class="n">ln_process_date</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">&lt;=</span><span class="w"> </span><span class="mi">12</span><span class="w"> </span><span class="k">THEN</span><span class="w"> </span><span class="mi">0</span><span class="w"> </span><span class="k">ELSE</span><span class="w"> </span><span class="n">t2</span><span class="p">.</span><span class="n">ln_rec_count</span><span class="w"> </span><span class="k">END</span><span class="w"> </span>
<span class="w"> </span><span class="k">FROM</span><span class="w"> </span><span class="n">calc_empfyc_c1_policysend_tmp</span><span class="w"> </span><span class="n">t2</span><span class="w"></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">ln_branch</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">ln_branch</span><span class="w"> </span><span class="k">AND</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">ls_policyno_cusr1</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">ls_policyno_cusr1</span><span class="w"></span>
<span class="p">)</span><span class="w"></span>
<span class="k">WHERE</span><span class="w"> </span><span class="n">dsign</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="s1">'1'</span><span class="w"></span>
<span class="k">AND</span><span class="w"> </span><span class="n">flag</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="s1">'1'</span><span class="w"></span>
<span class="k">AND</span><span class="w"> </span><span class="k">EXISTS</span><span class="w"></span>
<span class="w"> </span><span class="p">(</span><span class="k">SELECT</span><span class="w"> </span><span class="mi">1</span><span class="w"></span>
<span class="w"> </span><span class="k">FROM</span><span class="w"> </span><span class="n">calc_empfyc_c1_policysend_tmp</span><span class="w"> </span><span class="n">t2</span><span class="w"></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">ln_branch</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">ln_branch</span><span class="w"> </span><span class="k">AND</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">ls_policyno_cusr1</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">ls_policyno_cusr1</span><span class="w"></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_0000001145814337__a4001ba2f58e54f6285ba6ed4e57b24ed">The corresponding execution plan is as follows:</p>
<p id="EN-US_TOPIC_0000001145814337__a28c6c5fb584148dcad566ae821afd7f2"><span><img id="EN-US_TOPIC_0000001145814337__i49bbbce124f64026a8ed2de149bf2d8c" src="figure/en-us_image_0000001098655278.png"></span></p>
</div>
<div class="section" id="EN-US_TOPIC_0000001145814337__s47b45adcee9948298473deaf39641aee"><h4 class="sectiontitle">Optimization</h4><p id="EN-US_TOPIC_0000001145814337__aaf1660b0ca644d439cfa7ed5430679b4">SubPlan exists in the execution plan, and the calculation accounts for a large proportion in the SubPlan query. That is, SubPlan is a performance bottleneck.</p>
<p id="EN-US_TOPIC_0000001145814337__acbd62e048254444b91d5a49160acf3d1">Based on the SQL syntax, you can rewrite the SQL statements and delete SubPlan as follows:</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001145814337__s66c8d12008d0426baf0bd1e3e7f94018"><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">UPDATE</span><span class="w"> </span><span class="n">calc_empfyc_c_cusr1</span><span class="w"> </span><span class="n">t1</span><span class="w"></span>
<span class="k">SET</span><span class="w"> </span><span class="n">ln_rec_count</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="k">CASE</span><span class="w"> </span><span class="k">WHEN</span><span class="w"> </span><span class="k">current_date</span><span class="w"> </span><span class="o">-</span><span class="w"> </span><span class="n">ln_process_date</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">&lt;=</span><span class="w"> </span><span class="mi">12</span><span class="w"> </span><span class="k">THEN</span><span class="w"> </span><span class="mi">0</span><span class="w"> </span><span class="k">ELSE</span><span class="w"> </span><span class="n">t2</span><span class="p">.</span><span class="n">ln_rec_count</span><span class="w"> </span><span class="k">END</span><span class="w"></span>
<span class="k">FROM</span><span class="w"> </span><span class="n">calc_empfyc_c1_policysend_tmp</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">dsign</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="s1">'1'</span><span class="w"> </span><span class="k">AND</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">flag</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="s1">'1'</span><span class="w"> </span>
<span class="k">AND</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">ln_branch</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">ln_branch</span><span class="w"> </span><span class="k">AND</span><span class="w"> </span><span class="n">t1</span><span class="p">.</span><span class="n">ls_policyno_cusr1</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">ls_policyno_cusr1</span><span class="p">;</span><span class="w"></span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001145814337__a6b6bf0ad6a2d46a0ac439e86d8f2121d">The modified SQL statement task is complete within 50s.</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>