forked from docs/doc-exports
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>
201 lines
32 KiB
HTML
201 lines
32 KiB
HTML
<a name="EN-US_TOPIC_0000001188163704"></a><a name="EN-US_TOPIC_0000001188163704"></a>
|
|
|
|
<h1 class="topictitle1">Skew Hints</h1>
|
|
<div id="body1543482317963"><div class="section" id="EN-US_TOPIC_0000001188163704__section290819468377"><h4 class="sectiontitle">Function</h4><p id="EN-US_TOPIC_0000001188163704__p164213954412">Theses hints specify redistribution keys containing skew data and skew values, and are used to optimize redistribution involving Join or HashAgg.</p>
|
|
</div>
|
|
<div class="section" id="EN-US_TOPIC_0000001188163704__section530131664410"><h4 class="sectiontitle">Syntax</h4><ul id="EN-US_TOPIC_0000001188163704__ul4920124610417"><li id="EN-US_TOPIC_0000001188163704__li1192094616410">Specify single-table skew.<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188163704__screen67171647938"><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="n">skew</span><span class="p">(</span><span class="k">table</span><span class="w"> </span><span class="p">(</span><span class="k">column</span><span class="p">)</span><span class="w"> </span><span class="p">[(</span><span class="n">value</span><span class="p">)])</span>
|
|
</pre></div></td></tr></table></div>
|
|
|
|
</div>
|
|
</li><li id="EN-US_TOPIC_0000001188163704__li209211046745">Specify intermediate result skew.<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188163704__screen14923573417"><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="n">skew</span><span class="p">((</span><span class="n">join_rel</span><span class="p">)</span><span class="w"> </span><span class="p">(</span><span class="k">column</span><span class="p">)</span><span class="w"> </span><span class="p">[(</span><span class="n">value</span><span class="p">)])</span>
|
|
</pre></div></td></tr></table></div>
|
|
|
|
</div>
|
|
</li></ul>
|
|
</div>
|
|
<div class="section" id="EN-US_TOPIC_0000001188163704__section41303128143838"><h4 class="sectiontitle">Parameter Description</h4><ul id="EN-US_TOPIC_0000001188163704__ul7813152810126"><li id="EN-US_TOPIC_0000001188163704__li98131128181220"><strong id="EN-US_TOPIC_0000001188163704__b179821130201818">table</strong> specifies the table where skew occurs.</li><li id="EN-US_TOPIC_0000001188163704__li948751319356"><strong id="EN-US_TOPIC_0000001188163704__b18488191393511">join_rel</strong> specifies two or more joined tables. For example, <strong id="EN-US_TOPIC_0000001188163704__b1851613545912">(t1 t2)</strong> indicates that the result of joining <strong id="EN-US_TOPIC_0000001188163704__b13734195115915">t1</strong> and <strong id="EN-US_TOPIC_0000001188163704__b1041517499592">t2</strong> tables contains skew data.</li><li id="EN-US_TOPIC_0000001188163704__li451542111339"><strong id="EN-US_TOPIC_0000001188163704__b1851519213337">column</strong> specifies one or more columns where skew occurs.</li><li id="EN-US_TOPIC_0000001188163704__li51430225337"><strong id="EN-US_TOPIC_0000001188163704__b514392283314">value</strong> specifies one or more skew values.</li></ul>
|
|
</div>
|
|
<div class="note" id="EN-US_TOPIC_0000001188163704__note133365763113"><img src="public_sys-resources/note_3.0-en-us.png"><span class="notetitle"> </span><div class="notebody"><ul id="EN-US_TOPIC_0000001188163704__ul3357282517550"><li id="EN-US_TOPIC_0000001188163704__li14959916114719">Skew hints are used only if redistribution is required and the specified skew information matches the redistribution information.</li><li id="EN-US_TOPIC_0000001188163704__li9346203318118">Skew hints are controlled by the GUC parameter <a href="dws_04_0909.html#EN-US_TOPIC_0000001188482092__section1211182712176">skew_option</a>. If the parameter is disabled, skew hints cannot be used for solving skew.</li><li id="EN-US_TOPIC_0000001188163704__li3371996917550">Currently, skew hints support only the table relationships of the ordinary table and subquery types. Hints can be specified for base tables, subqueries, and <strong id="EN-US_TOPIC_0000001188163704__b09644618206">WITH ... AS</strong> clauses. Unlike other hints, a subquery can be used in skew hints regardless of whether it is pulled up.</li><li id="EN-US_TOPIC_0000001188163704__li665513134485">Use an alias (if any) to specify a table where data skew occurs.</li></ul>
|
|
<ul id="EN-US_TOPIC_0000001188163704__ul481942317312"><li id="EN-US_TOPIC_0000001188163704__li38181823123116">You can use a name or an alias to specify a skew column as long as it is not ambiguous. The columns in skew hints cannot be expressions. If data skew occurs in the redistribution that uses an expression as a redistribution key, set the redistribution key as a new column and specify the column in skew hints.</li><li id="EN-US_TOPIC_0000001188163704__li411213364439">The number of skew values must be an integer multiple of the number of columns. Skew values must be grouped based on the column sequence, with each group containing a maximum of 10 values. You can specify duplicate values to group skew columns having different number of skew values. For example, the <strong id="EN-US_TOPIC_0000001188163704__b2260164012201">c1</strong> and <strong id="EN-US_TOPIC_0000001188163704__b1489164219206">c2</strong> columns of the <strong id="EN-US_TOPIC_0000001188163704__b1793024912200">t1</strong> table contains skew data. The skew value of the <strong id="EN-US_TOPIC_0000001188163704__b24781915182113">c1</strong> column is <strong id="EN-US_TOPIC_0000001188163704__b889271762113">a1</strong>, and the skew values of the <strong id="EN-US_TOPIC_0000001188163704__b231982720216">c2</strong> column are <strong id="EN-US_TOPIC_0000001188163704__b53261030172112">b1</strong> and <strong id="EN-US_TOPIC_0000001188163704__b116761332192110">b2</strong>. In this case, the skew hint is <strong id="EN-US_TOPIC_0000001188163704__b660935419218">skew(t1 (c1 c2) ((a1 b1)(a1 b2)))</strong>. <strong id="EN-US_TOPIC_0000001188163704__b7218191551717">(a1 b1)</strong> is a value group, where <strong id="EN-US_TOPIC_0000001188163704__b1821951511719">NULL</strong> is allowed as a skew value. Each hint can contain a maximum of 10 groups and the number of groups should be an integer multiple of the number of columns.</li><li id="EN-US_TOPIC_0000001188163704__li4800458194620">In the redistribution optimization of Join, a skew value must be specified for skew hints. The skew value can be left empty for HashAgg.</li><li id="EN-US_TOPIC_0000001188163704__li699511486534">If multiple tables, columns, or values are specified, separate items of the same type with spaces.</li><li id="EN-US_TOPIC_0000001188163704__li1130155717549">The type of skew values cannot be forcibly converted in hints. To specify a string, enclose it with single quotation marks (' ').</li></ul>
|
|
</div></div>
|
|
<p id="EN-US_TOPIC_0000001188163704__p11571335134810">Example:</p>
|
|
<ul id="EN-US_TOPIC_0000001188163704__ul14835192215556"><li id="EN-US_TOPIC_0000001188163704__li108352227558">Specify single-table skew.<p id="EN-US_TOPIC_0000001188163704__p183121031115512"><a name="EN-US_TOPIC_0000001188163704__li108352227558"></a><a name="li108352227558"></a>Each skew hint describes the skew information of one table relationship. To describe the skews of multiple table relationships in a query, specify multiple skew hints.</p>
|
|
<p id="EN-US_TOPIC_0000001188163704__p17972182411553">Skew hints have the following formats:</p>
|
|
<ul id="EN-US_TOPIC_0000001188163704__ul13579114317550"><li id="EN-US_TOPIC_0000001188163704__li10579104320556">One skew value in one column: <strong id="EN-US_TOPIC_0000001188163704__b11856203073917">skew(t (c1) (v1))</strong><p id="EN-US_TOPIC_0000001188163704__p93051478551">Description: The <strong id="EN-US_TOPIC_0000001188163704__b1871133464017">v1</strong> value in the <strong id="EN-US_TOPIC_0000001188163704__b95301144124019">c1</strong> column of the <strong id="EN-US_TOPIC_0000001188163704__b736852114017">t</strong> table relationship causes skew in query execution.</p>
|
|
</li><li id="EN-US_TOPIC_0000001188163704__li357994313556">Multiple skew values in one column: <strong id="EN-US_TOPIC_0000001188163704__b1177912342423">skew(t (c1) (v1 v2 v3 ...))</strong><p id="EN-US_TOPIC_0000001188163704__p1871394845515">Description: Values including <strong id="EN-US_TOPIC_0000001188163704__b12349134115426">v1,</strong> <strong id="EN-US_TOPIC_0000001188163704__b691914434425">v2</strong>, and <strong id="EN-US_TOPIC_0000001188163704__b13759494429">v3</strong> in the <strong id="EN-US_TOPIC_0000001188163704__b874692544318">c1</strong> column of the <strong id="EN-US_TOPIC_0000001188163704__b13001131184317">t</strong> table relationship cause skew in query execution.</p>
|
|
</li><li id="EN-US_TOPIC_0000001188163704__li20579104314552">Multiple columns, each having one skew value: <strong id="EN-US_TOPIC_0000001188163704__b893116312444">skew(t (c1 c2) (v1 v2))</strong><p id="EN-US_TOPIC_0000001188163704__p3727114905518">Description: The <strong id="EN-US_TOPIC_0000001188163704__b621812515453">v1</strong> value in the <strong id="EN-US_TOPIC_0000001188163704__b18218112518451">c1</strong> column and the <strong id="EN-US_TOPIC_0000001188163704__b2087418438451">v2</strong> value in the <strong id="EN-US_TOPIC_0000001188163704__b6874104374517">c2</strong> column of the <strong id="EN-US_TOPIC_0000001188163704__b1621952513452">t</strong> table relationship cause skew in query execution.</p>
|
|
</li><li id="EN-US_TOPIC_0000001188163704__li1257913434557">Multiple columns, each having multiple skew values: <strong id="EN-US_TOPIC_0000001188163704__b247142420462">skew(t (c1 c2) ((v1 v2) (v3 v4) (v5 v6) ...))</strong><p id="EN-US_TOPIC_0000001188163704__p10891125045516">Description: Values including <strong id="EN-US_TOPIC_0000001188163704__b7846153611460">v1,</strong> <strong id="EN-US_TOPIC_0000001188163704__b11846436124617">v3</strong>, and <strong id="EN-US_TOPIC_0000001188163704__b15847113614468">v5</strong> in the <strong id="EN-US_TOPIC_0000001188163704__b5847236174614">c1</strong> column and values including <strong id="EN-US_TOPIC_0000001188163704__b1145145234618">v2,</strong> <strong id="EN-US_TOPIC_0000001188163704__b1645115219468">v4</strong>, and <strong id="EN-US_TOPIC_0000001188163704__b1245195215468">v6</strong> in the <strong id="EN-US_TOPIC_0000001188163704__b1746195218463">c2</strong> column of the <strong id="EN-US_TOPIC_0000001188163704__b6847103694614">t</strong> table relationship cause skew in query execution.</p>
|
|
<div class="notice" id="EN-US_TOPIC_0000001188163704__note19227161962210"><span class="noticetitle"><img src="public_sys-resources/notice_3.0-en-us.png"> </span><div class="noticebody"><p id="EN-US_TOPIC_0000001188163704__p208541936144516">In the last format, parentheses for skew value groups can be omitted, for example, <strong id="EN-US_TOPIC_0000001188163704__b34119561542">skew(t (c1 c2) (v1 v2 v3 v4 v5 v6 ...))</strong>. In a skew hint, either use parentheses for all skew value groups or for none of them.</p>
|
|
<p id="EN-US_TOPIC_0000001188163704__p1311818193483">Otherwise, a syntax error will be generated. For example, <strong id="EN-US_TOPIC_0000001188163704__b721034317915">skew(t (c1 c2) (v1 v2 v3 v4 (v5 v6) ...))</strong> will generate an error.</p>
|
|
</div></div>
|
|
</li></ul>
|
|
</li></ul>
|
|
<ul id="EN-US_TOPIC_0000001188163704__ul5152161214149"><li id="EN-US_TOPIC_0000001188163704__li99931711562">Specify intermediate result skew.<p id="EN-US_TOPIC_0000001188163704__p7630132275617"><a name="EN-US_TOPIC_0000001188163704__li99931711562"></a><a name="li99931711562"></a>If data skew does not occur in base tables but in an intermediate result during query execution, specify skew hints of the intermediate result to solve the skew. The format is <strong id="EN-US_TOPIC_0000001188163704__b4148653144912">skew((t1 t2) (c1) (v1))</strong>.</p>
|
|
<p id="EN-US_TOPIC_0000001188163704__p11167102515567">Description: Data skew occurs after the table relationships <strong id="EN-US_TOPIC_0000001188163704__b4759164053817">t1</strong> and <strong id="EN-US_TOPIC_0000001188163704__b8761340143816">t2</strong> are joined. The <strong id="EN-US_TOPIC_0000001188163704__b2761174043819">c1</strong> column of the <strong id="EN-US_TOPIC_0000001188163704__b2076194063819">t1</strong> table contains skew data and its skew value is <strong id="EN-US_TOPIC_0000001188163704__b9763164023811">v1</strong>.</p>
|
|
<p id="EN-US_TOPIC_0000001188163704__p59151383568"><strong id="EN-US_TOPIC_0000001188163704__b105218408521">c1</strong> can exist only in a table relationship of <strong id="EN-US_TOPIC_0000001188163704__b12398184815217">join_rel</strong>. If there is another column having the same name, use aliases to avoid ambiguity.</p>
|
|
</li></ul>
|
|
<div class="section" id="EN-US_TOPIC_0000001188163704__section99281150122819"><h4 class="sectiontitle">Suggestion</h4><ul id="EN-US_TOPIC_0000001188163704__ul19827192311618"><li id="EN-US_TOPIC_0000001188163704__li208275234618">For a multi-level query, write the hint on the layer where data skew occurs.</li><li id="EN-US_TOPIC_0000001188163704__li684316261356">For a listed subquery, you can specify the subquery name in a hint. If you know data skew occurs on which base table, directly specify the table.</li><li id="EN-US_TOPIC_0000001188163704__li19827323764">Aliases are preferred when you specify a table or column in a hint.</li></ul>
|
|
</div>
|
|
<div class="section" id="EN-US_TOPIC_0000001188163704__section780913135614"><h4 class="sectiontitle">Examples</h4><p id="EN-US_TOPIC_0000001188163704__p13554162643619">Specify single-table skew.</p>
|
|
<ul id="EN-US_TOPIC_0000001188163704__ul4727174618186"><li id="EN-US_TOPIC_0000001188163704__li185061372569">Specify hints in the original query.<p id="EN-US_TOPIC_0000001188163704__p6242133885619"><a name="EN-US_TOPIC_0000001188163704__li185061372569"></a><a name="li185061372569"></a>For example, the original query is as follows:</p>
|
|
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188163704__screen1347124316443"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal"> 1</span>
|
|
<span class="normal"> 2</span>
|
|
<span class="normal"> 3</span>
|
|
<span class="normal"> 4</span>
|
|
<span class="normal"> 5</span>
|
|
<span class="normal"> 6</span>
|
|
<span class="normal"> 7</span>
|
|
<span class="normal"> 8</span>
|
|
<span class="normal"> 9</span>
|
|
<span class="normal">10</span>
|
|
<span class="normal">11</span>
|
|
<span class="normal">12</span>
|
|
<span class="normal">13</span>
|
|
<span class="normal">14</span>
|
|
<span class="normal">15</span>
|
|
<span class="normal">16</span>
|
|
<span class="normal">17</span>
|
|
<span class="normal">18</span>
|
|
<span class="normal">19</span>
|
|
<span class="normal">20</span>
|
|
<span class="normal">21</span>
|
|
<span class="normal">22</span>
|
|
<span class="normal">23</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">explain</span>
|
|
<span class="k">with</span><span class="w"> </span><span class="n">customer_total_return</span><span class="w"> </span><span class="k">as</span>
|
|
<span class="p">(</span><span class="k">select</span><span class="w"> </span><span class="n">sr_customer_sk</span><span class="w"> </span><span class="k">as</span><span class="w"> </span><span class="n">ctr_customer_sk</span>
|
|
<span class="p">,</span><span class="n">sr_store_sk</span><span class="w"> </span><span class="k">as</span><span class="w"> </span><span class="n">ctr_store_sk</span>
|
|
<span class="p">,</span><span class="k">sum</span><span class="p">(</span><span class="n">SR_FEE</span><span class="p">)</span><span class="w"> </span><span class="k">as</span><span class="w"> </span><span class="n">ctr_total_return</span>
|
|
<span class="k">from</span><span class="w"> </span><span class="n">store_returns</span>
|
|
<span class="p">,</span><span class="n">date_dim</span>
|
|
<span class="k">where</span><span class="w"> </span><span class="n">sr_returned_date_sk</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">d_date_sk</span>
|
|
<span class="k">and</span><span class="w"> </span><span class="n">d_year</span><span class="w"> </span><span class="o">=</span><span class="mi">2000</span>
|
|
<span class="k">group</span><span class="w"> </span><span class="k">by</span><span class="w"> </span><span class="n">sr_customer_sk</span>
|
|
<span class="p">,</span><span class="n">sr_store_sk</span><span class="p">)</span>
|
|
<span class="w"> </span><span class="k">select</span><span class="w"> </span><span class="n">c_customer_id</span>
|
|
<span class="k">from</span><span class="w"> </span><span class="n">customer_total_return</span><span class="w"> </span><span class="n">ctr1</span>
|
|
<span class="p">,</span><span class="n">store</span>
|
|
<span class="p">,</span><span class="n">customer</span>
|
|
<span class="k">where</span><span class="w"> </span><span class="n">ctr1</span><span class="p">.</span><span class="n">ctr_total_return</span><span class="w"> </span><span class="o">></span><span class="w"> </span><span class="p">(</span><span class="k">select</span><span class="w"> </span><span class="k">avg</span><span class="p">(</span><span class="n">ctr_total_return</span><span class="p">)</span><span class="o">*</span><span class="mi">1</span><span class="p">.</span><span class="mi">2</span>
|
|
<span class="k">from</span><span class="w"> </span><span class="n">customer_total_return</span><span class="w"> </span><span class="n">ctr2</span>
|
|
<span class="k">where</span><span class="w"> </span><span class="n">ctr1</span><span class="p">.</span><span class="n">ctr_store_sk</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">ctr2</span><span class="p">.</span><span class="n">ctr_store_sk</span><span class="p">)</span>
|
|
<span class="k">and</span><span class="w"> </span><span class="n">s_store_sk</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">ctr1</span><span class="p">.</span><span class="n">ctr_store_sk</span>
|
|
<span class="k">and</span><span class="w"> </span><span class="n">s_state</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="s1">'NM'</span>
|
|
<span class="k">and</span><span class="w"> </span><span class="n">ctr1</span><span class="p">.</span><span class="n">ctr_customer_sk</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">c_customer_sk</span>
|
|
<span class="k">order</span><span class="w"> </span><span class="k">by</span><span class="w"> </span><span class="n">c_customer_id</span>
|
|
<span class="k">limit</span><span class="w"> </span><span class="mi">100</span><span class="p">;</span>
|
|
</pre></div></td></tr></table></div>
|
|
|
|
</div>
|
|
<p id="EN-US_TOPIC_0000001188163704__p168241747298"><span><img id="EN-US_TOPIC_0000001188163704__image198241340293" src="figure/en-us_image_0000001233681873.png"></span></p>
|
|
<p id="EN-US_TOPIC_0000001188163704__p1964013358219">Specify the hints of HashAgg in the inner <strong id="EN-US_TOPIC_0000001188163704__b630818333111">with</strong> clause and of the outer Hash Join. The query containing hints is as follows:</p>
|
|
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188163704__screen194951433184320"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal"> 1</span>
|
|
<span class="normal"> 2</span>
|
|
<span class="normal"> 3</span>
|
|
<span class="normal"> 4</span>
|
|
<span class="normal"> 5</span>
|
|
<span class="normal"> 6</span>
|
|
<span class="normal"> 7</span>
|
|
<span class="normal"> 8</span>
|
|
<span class="normal"> 9</span>
|
|
<span class="normal">10</span>
|
|
<span class="normal">11</span>
|
|
<span class="normal">12</span>
|
|
<span class="normal">13</span>
|
|
<span class="normal">14</span>
|
|
<span class="normal">15</span>
|
|
<span class="normal">16</span>
|
|
<span class="normal">17</span>
|
|
<span class="normal">18</span>
|
|
<span class="normal">19</span>
|
|
<span class="normal">20</span>
|
|
<span class="normal">21</span>
|
|
<span class="normal">22</span>
|
|
<span class="normal">23</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">explain</span>
|
|
<span class="k">with</span><span class="w"> </span><span class="n">customer_total_return</span><span class="w"> </span><span class="k">as</span>
|
|
<span class="p">(</span><span class="k">select</span><span class="w"> </span><span class="cm">/*+ skew(store_returns(sr_store_sk sr_customer_sk)) */</span><span class="n">sr_customer_sk</span><span class="w"> </span><span class="k">as</span><span class="w"> </span><span class="n">ctr_customer_sk</span>
|
|
<span class="p">,</span><span class="n">sr_store_sk</span><span class="w"> </span><span class="k">as</span><span class="w"> </span><span class="n">ctr_store_sk</span>
|
|
<span class="p">,</span><span class="k">sum</span><span class="p">(</span><span class="n">SR_FEE</span><span class="p">)</span><span class="w"> </span><span class="k">as</span><span class="w"> </span><span class="n">ctr_total_return</span>
|
|
<span class="k">from</span><span class="w"> </span><span class="n">store_returns</span>
|
|
<span class="p">,</span><span class="n">date_dim</span>
|
|
<span class="k">where</span><span class="w"> </span><span class="n">sr_returned_date_sk</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">d_date_sk</span>
|
|
<span class="k">and</span><span class="w"> </span><span class="n">d_year</span><span class="w"> </span><span class="o">=</span><span class="mi">2000</span>
|
|
<span class="k">group</span><span class="w"> </span><span class="k">by</span><span class="w"> </span><span class="n">sr_customer_sk</span>
|
|
<span class="p">,</span><span class="n">sr_store_sk</span><span class="p">)</span>
|
|
<span class="w"> </span><span class="k">select</span><span class="w"> </span><span class="cm">/*+ skew(ctr1(ctr_customer_sk)(11))*/</span><span class="w"> </span><span class="n">c_customer_id</span>
|
|
<span class="k">from</span><span class="w"> </span><span class="n">customer_total_return</span><span class="w"> </span><span class="n">ctr1</span>
|
|
<span class="p">,</span><span class="n">store</span>
|
|
<span class="p">,</span><span class="n">customer</span>
|
|
<span class="k">where</span><span class="w"> </span><span class="n">ctr1</span><span class="p">.</span><span class="n">ctr_total_return</span><span class="w"> </span><span class="o">></span><span class="w"> </span><span class="p">(</span><span class="k">select</span><span class="w"> </span><span class="k">avg</span><span class="p">(</span><span class="n">ctr_total_return</span><span class="p">)</span><span class="o">*</span><span class="mi">1</span><span class="p">.</span><span class="mi">2</span>
|
|
<span class="k">from</span><span class="w"> </span><span class="n">customer_total_return</span><span class="w"> </span><span class="n">ctr2</span>
|
|
<span class="k">where</span><span class="w"> </span><span class="n">ctr1</span><span class="p">.</span><span class="n">ctr_store_sk</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">ctr2</span><span class="p">.</span><span class="n">ctr_store_sk</span><span class="p">)</span>
|
|
<span class="k">and</span><span class="w"> </span><span class="n">s_store_sk</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">ctr1</span><span class="p">.</span><span class="n">ctr_store_sk</span>
|
|
<span class="k">and</span><span class="w"> </span><span class="n">s_state</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="s1">'NM'</span>
|
|
<span class="k">and</span><span class="w"> </span><span class="n">ctr1</span><span class="p">.</span><span class="n">ctr_customer_sk</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">c_customer_sk</span>
|
|
<span class="k">order</span><span class="w"> </span><span class="k">by</span><span class="w"> </span><span class="n">c_customer_id</span>
|
|
<span class="k">limit</span><span class="w"> </span><span class="mi">100</span><span class="p">;</span>
|
|
</pre></div></td></tr></table></div>
|
|
|
|
</div>
|
|
<p id="EN-US_TOPIC_0000001188163704__p491032201810">The hints indicate that the <strong id="EN-US_TOPIC_0000001188163704__b171021514128">group by</strong> in the inner <strong id="EN-US_TOPIC_0000001188163704__b189605461215">with</strong> clause contains skew data during redistribution by HashAgg, corresponding to the original Hash Agg operators 10 and 21; and that the <strong id="EN-US_TOPIC_0000001188163704__b10833125618139">ctr_customer_sk</strong> column in the outer <strong id="EN-US_TOPIC_0000001188163704__b20386021417">ctr1</strong> table contains skew data during redistribution by Hash Join, corresponding to operator 6 in the original plan. The optimized plan is as follows:</p>
|
|
<p id="EN-US_TOPIC_0000001188163704__p15340104812278"><span><img id="EN-US_TOPIC_0000001188163704__image3340124812715" src="figure/en-us_image_0000001233761947.png"></span></p>
|
|
<p id="EN-US_TOPIC_0000001188163704__p35873872152236">To solve data skew in the redistribution, Hash Agg is changed to double-level Agg operators and the redistribution operators used by Hash Join are changed in the optimized plan.</p>
|
|
</li></ul>
|
|
</div>
|
|
<ul id="EN-US_TOPIC_0000001188163704__ul158125416184"><li id="EN-US_TOPIC_0000001188163704__li36611151125615">Modify the query and then specify hints.<p id="EN-US_TOPIC_0000001188163704__p145361352185616"><a name="EN-US_TOPIC_0000001188163704__li36611151125615"></a><a name="li36611151125615"></a>For example, the original query and its plan are as follows:</p>
|
|
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188163704__screen206121055105113"><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">explain</span><span class="w"> </span><span class="k">select</span><span class="w"> </span><span class="k">count</span><span class="p">(</span><span class="o">*</span><span class="p">)</span><span class="w"> </span><span class="k">from</span><span class="w"> </span><span class="n">store_sales_1</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">round</span><span class="p">(</span><span class="n">ss_list_price</span><span class="p">);</span>
|
|
</pre></div></td></tr></table></div>
|
|
|
|
</div>
|
|
<p id="EN-US_TOPIC_0000001188163704__p430515361280"><span><img id="EN-US_TOPIC_0000001188163704__image8305103612280" src="figure/en-us_image_0000001188163830.png"></span></p>
|
|
<p id="EN-US_TOPIC_0000001188163704__p8875256145913">Columns in hints do not support expressions. To specify hints, rewrite the query as several subqueries. The rewritten query and its plan are as follows:</p>
|
|
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188163704__screen1962513418118"><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">explain</span><span class="w"> </span>
|
|
<span class="k">select</span><span class="w"> </span><span class="k">count</span><span class="p">(</span><span class="o">*</span><span class="p">)</span><span class="w"> </span>
|
|
<span class="k">from</span><span class="w"> </span><span class="p">(</span><span class="k">select</span><span class="w"> </span><span class="n">round</span><span class="p">(</span><span class="n">ss_list_price</span><span class="p">),</span><span class="n">ss_hdemo_sk</span>
|
|
<span class="k">from</span><span class="w"> </span><span class="n">store_sales_1</span><span class="p">)</span><span class="n">tmp</span><span class="p">(</span><span class="n">a</span><span class="p">,</span><span class="n">ss_hdemo_sk</span><span class="p">)</span><span class="w"> </span>
|
|
<span class="k">group</span><span class="w"> </span><span class="k">by</span><span class="w"> </span><span class="n">a</span><span class="p">;</span>
|
|
</pre></div></td></tr></table></div>
|
|
|
|
</div>
|
|
<p id="EN-US_TOPIC_0000001188163704__p1978041252917"><span><img id="EN-US_TOPIC_0000001188163704__image15779112142913" src="figure/en-us_image_0000001188163828.png"></span></p>
|
|
<p id="EN-US_TOPIC_0000001188163704__p118651731845">Ensure that the service logic is not changed during the rewriting.</p>
|
|
<p id="EN-US_TOPIC_0000001188163704__p0533241750">Specify hints in the rewritten query as follows:</p>
|
|
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188163704__screen6416469111"><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">explain</span><span class="w"> </span>
|
|
<span class="k">select</span><span class="w"> </span><span class="cm">/*+ skew(tmp(a)) */</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">round</span><span class="p">(</span><span class="n">ss_list_price</span><span class="p">),</span><span class="n">ss_hdemo_sk</span>
|
|
<span class="k">from</span><span class="w"> </span><span class="n">store_sales_1</span><span class="p">)</span><span class="n">tmp</span><span class="p">(</span><span class="n">a</span><span class="p">,</span><span class="n">ss_hdemo_sk</span><span class="p">)</span><span class="w"> </span>
|
|
<span class="k">group</span><span class="w"> </span><span class="k">by</span><span class="w"> </span><span class="n">a</span><span class="p">;</span>
|
|
</pre></div></td></tr></table></div>
|
|
|
|
</div>
|
|
<p id="EN-US_TOPIC_0000001188163704__p633451914716"><span><img id="EN-US_TOPIC_0000001188163704__image13334419573" src="figure/en-us_image_0000001188323802.png"></span></p>
|
|
<p id="EN-US_TOPIC_0000001188163704__p1329514175113">The plan shows that after Hash Agg is changed to double-layer Agg operators, redistributed data is greatly reduced and redistribution time shortened.</p>
|
|
<p id="EN-US_TOPIC_0000001188163704__p1452543111226">You can specify hints in columns in a subquery, for example:</p>
|
|
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188163704__screen3934194816238"><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">explain</span><span class="w"> </span>
|
|
<span class="k">select</span><span class="w"> </span><span class="cm">/*+ skew(tmp(b)) */</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">round</span><span class="p">(</span><span class="n">ss_list_price</span><span class="p">)</span><span class="w"> </span><span class="n">b</span><span class="p">,</span><span class="n">ss_hdemo_sk</span>
|
|
<span class="k">from</span><span class="w"> </span><span class="n">store_sales_1</span><span class="p">)</span><span class="n">tmp</span><span class="p">(</span><span class="n">a</span><span class="p">,</span><span class="n">ss_hdemo_sk</span><span class="p">)</span><span class="w"> </span>
|
|
<span class="k">group</span><span class="w"> </span><span class="k">by</span><span class="w"> </span><span class="n">a</span><span class="p">;</span>
|
|
</pre></div></td></tr></table></div>
|
|
|
|
</div>
|
|
</li></ul>
|
|
</div>
|
|
<div>
|
|
<div class="familylinks">
|
|
<div class="parentlink"><strong>Parent topic:</strong> <a href="dws_04_0454.html">Hint-based Tuning</a></div>
|
|
</div>
|
|
</div>
|
|
|