doc-exports/docs/dws/tool/dws_16_0051.html
Lu, Huayi 27019c2991 DWS TOOL 830.201 version
Reviewed-by: Hasko, Vladimir <vladimir.hasko@t-systems.com>
Reviewed-by: Pruthi, Vineet <vineet.pruthi@t-systems.com>
Co-authored-by: Lu, Huayi <luhuayi@huawei.com>
Co-committed-by: Lu, Huayi <luhuayi@huawei.com>
2024-05-16 07:35:25 +00:00

243 lines
30 KiB
HTML

<a name="EN-US_TOPIC_0000001772536428"></a><a name="EN-US_TOPIC_0000001772536428"></a>
<h1 class="topictitle1">QUALIFY</h1>
<div id="body8662426"><p id="EN-US_TOPIC_0000001772536428__en-us_topic_0000001706105125_en-us_topic_0000001434790453_p65380183111151">In general, the <strong id="EN-US_TOPIC_0000001772536428__en-us_topic_0000001706105125_en-us_topic_0000001434790453_b61149764832243">QUALIFY</strong> clause is accompanied by analytic functions (window functions) such as CSUM(), MDIFF(), ROW_NUMBER() and RANK(). This is addressed using sub-query that contains the window functions specified in the <strong id="EN-US_TOPIC_0000001772536428__en-us_topic_0000001706105125_en-us_topic_0000001434790453_b28466223832243">QUALIFY</strong> clause. Migration tools support <strong id="EN-US_TOPIC_0000001772536428__en-us_topic_0000001706105125_en-us_topic_0000001434790453_b155885404532243">QUALIFY </strong>with<strong id="EN-US_TOPIC_0000001772536428__en-us_topic_0000001706105125_en-us_topic_0000001434790453_b65003584232243"> MDIFF()</strong>, <strong id="EN-US_TOPIC_0000001772536428__en-us_topic_0000001706105125_en-us_topic_0000001434790453_b134714484432243">RANK()</strong> and <strong id="EN-US_TOPIC_0000001772536428__en-us_topic_0000001706105125_en-us_topic_0000001434790453_b205437786532243">ROW_NUMBER()</strong>. <strong id="EN-US_TOPIC_0000001772536428__en-us_topic_0000001706105125_en-us_topic_0000001434790453_b81571516632243">QUALIFY</strong> is a Teradata extension and not an ANSI standard syntax. It is executed after the WHERE and GROUP BY clauses. QUALIFY must start in new line.</p>
<div class="note" id="EN-US_TOPIC_0000001772536428__en-us_topic_0000001706105125_en-us_topic_0000001434790453_note34855574612"><img src="public_sys-resources/note_3.0-en-us.png"><span class="notetitle"> </span><div class="notebody"><p id="EN-US_TOPIC_0000001772536428__en-us_topic_0000001706105125_en-us_topic_0000001434790453_p1428203955114">Migration tools support column name and/or expressions in the ORDER BY clause only if the column name and/or expression is explicitly included in the SELECT statement as well.</p>
</div></div>
<p id="EN-US_TOPIC_0000001772536428__en-us_topic_0000001706105125_en-us_topic_0000001434790453_p1575165925813"><strong id="EN-US_TOPIC_0000001772536428__en-us_topic_0000001706105125_en-us_topic_0000001434790453_b1875971554">Input: QUALIFY</strong></p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001772536428__en-us_topic_0000001706105125_en-us_topic_0000001434790453_screen18575145917580"><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">SELECT</span>
<span class="w"> </span><span class="n">CUSTOMER_ID</span>
<span class="w"> </span><span class="p">,</span><span class="n">CUSTOMER_NAME</span>
<span class="w"> </span><span class="k">FROM</span>
<span class="w"> </span><span class="n">CUSTOMER_T</span><span class="w"> </span><span class="n">QUALIFY</span><span class="w"> </span><span class="n">row_number</span><span class="p">(</span><span class="w"> </span><span class="p">)</span><span class="w"> </span><span class="n">Over</span><span class="p">(</span><span class="w"> </span><span class="n">partition</span><span class="w"> </span><span class="k">BY</span><span class="w"> </span><span class="n">CUSTOMER_ID</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">POSTAL_CODE</span><span class="w"> </span><span class="k">DESC</span><span class="w"> </span><span class="p">)</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="mi">1</span>
<span class="p">;</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001772536428__en-us_topic_0000001706105125_en-us_topic_0000001434790453_p7577859145812"><strong id="EN-US_TOPIC_0000001772536428__en-us_topic_0000001706105125_en-us_topic_0000001434790453_b1560814561174">Output</strong></p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001772536428__en-us_topic_0000001706105125_en-us_topic_0000001434790453_screen145778593582"><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></pre></div></td><td class="code"><div><pre><span></span><span class="k">SELECT</span>
<span class="w"> </span><span class="n">CUSTOMER_ID</span>
<span class="w"> </span><span class="p">,</span><span class="n">CUSTOMER_NAME</span>
<span class="w"> </span><span class="k">FROM</span>
<span class="w"> </span><span class="p">(</span>
<span class="w"> </span><span class="k">SELECT</span>
<span class="w"> </span><span class="n">CUSTOMER_ID</span>
<span class="w"> </span><span class="p">,</span><span class="n">CUSTOMER_NAME</span>
<span class="w"> </span><span class="p">,</span><span class="n">row_number</span><span class="p">(</span><span class="w"> </span><span class="p">)</span><span class="w"> </span><span class="n">Over</span><span class="p">(</span><span class="w"> </span><span class="n">partition</span><span class="w"> </span><span class="k">BY</span><span class="w"> </span><span class="n">CUSTOMER_ID</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">POSTAL_CODE</span><span class="w"> </span><span class="k">DESC</span><span class="w"> </span><span class="p">)</span><span class="w"> </span><span class="k">AS</span><span class="w"> </span><span class="n">ROW_NUM1</span>
<span class="w"> </span><span class="k">FROM</span>
<span class="w"> </span><span class="n">CUSTOMER_T</span>
<span class="w"> </span><span class="p">)</span><span class="w"> </span><span class="n">Q1</span>
<span class="w"> </span><span class="k">WHERE</span>
<span class="w"> </span><span class="n">Q1</span><span class="p">.</span><span class="n">ROW_NUM1</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>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001772536428__en-us_topic_0000001706105125_en-us_topic_0000001434790453_p37162314614"><strong id="EN-US_TOPIC_0000001772536428__en-us_topic_0000001706105125_en-us_topic_0000001434790453_b73221801132243">Input: QUALIFY</strong><strong id="EN-US_TOPIC_0000001772536428__en-us_topic_0000001706105125_en-us_topic_0000001434790453_b83413175232243"> with MDIFF and RANK</strong></p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001772536428__en-us_topic_0000001706105125_en-us_topic_0000001434790453_screen3716113110612"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal">1</span>
<span class="normal">2</span>
<span class="normal">3</span>
<span class="normal">4</span>
<span class="normal">5</span>
<span class="normal">6</span>
<span class="normal">7</span>
<span class="normal">8</span>
<span class="normal">9</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">SELECT</span>
<span class="w"> </span><span class="n">material_name</span>
<span class="w"> </span><span class="p">,</span><span class="n">unit_of_measure</span><span class="w"> </span><span class="o">*</span><span class="w"> </span><span class="n">standard_cost</span><span class="w"> </span><span class="k">AS</span><span class="w"> </span><span class="n">tot_cost</span>
<span class="w"> </span><span class="k">FROM</span>
<span class="w"> </span><span class="n">raw_material_t</span><span class="w"> </span><span class="n">m</span><span class="w"> </span><span class="k">LEFT</span><span class="w"> </span><span class="k">JOIN</span><span class="w"> </span><span class="n">supplies_t</span><span class="w"> </span><span class="n">s</span>
<span class="w"> </span><span class="k">ON</span><span class="w"> </span><span class="n">s</span><span class="p">.</span><span class="n">material_id</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">m</span><span class="p">.</span><span class="n">material_id</span><span class="w"> </span>
<span class="w"> </span><span class="n">QUALIFY</span><span class="w"> </span><span class="n">rank</span><span class="w"> </span><span class="p">(</span><span class="w"> </span><span class="p">)</span><span class="w"> </span><span class="n">over</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="n">tot_cost</span><span class="w"> </span><span class="k">DESC</span><span class="w"> </span><span class="p">)</span><span class="w"> </span><span class="k">IN</span><span class="w"> </span><span class="s1">'5'</span>
<span class="w"> </span><span class="k">OR</span><span class="w"> </span><span class="n">mdiff</span><span class="p">(</span><span class="w"> </span><span class="n">tot_cost</span><span class="w"> </span><span class="p">,</span><span class="mi">3</span><span class="w"> </span><span class="p">,</span><span class="n">material_name</span><span class="w"> </span><span class="p">)</span><span class="w"> </span><span class="k">IS</span><span class="w"> </span><span class="k">NULL</span>
<span class="p">;</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001772536428__en-us_topic_0000001706105125_en-us_topic_0000001434790453_p1771893118615"><strong id="EN-US_TOPIC_0000001772536428__en-us_topic_0000001706105125_en-us_topic_0000001434790453_b67189311367">Output</strong></p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001772536428__en-us_topic_0000001706105125_en-us_topic_0000001434790453_screen157186311067"><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="n">material_name</span>
<span class="w"> </span><span class="p">,</span><span class="n">tot_cost</span>
<span class="w"> </span><span class="k">FROM</span>
<span class="w"> </span><span class="p">(</span>
<span class="w"> </span><span class="k">SELECT</span>
<span class="w"> </span><span class="n">material_name</span>
<span class="w"> </span><span class="p">,</span><span class="n">unit_of_measure</span><span class="w"> </span><span class="o">*</span><span class="w"> </span><span class="n">standard_cost</span><span class="w"> </span><span class="k">AS</span><span class="w"> </span><span class="n">tot_cost</span>
<span class="w"> </span><span class="p">,</span><span class="n">rank</span><span class="w"> </span><span class="p">(</span><span class="w"> </span><span class="p">)</span><span class="w"> </span><span class="n">over</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="n">unit_of_measure</span><span class="w"> </span><span class="o">*</span><span class="w"> </span><span class="n">standard_cost</span><span class="w"> </span><span class="k">DESC</span><span class="w"> </span><span class="p">)</span><span class="w"> </span><span class="k">AS</span><span class="w"> </span><span class="n">ROW_NUM1</span>
<span class="w"> </span><span class="p">,</span><span class="n">unit_of_measure</span><span class="w"> </span><span class="o">*</span><span class="w"> </span><span class="n">standard_cost</span><span class="w"> </span><span class="o">-</span><span class="w"> </span><span class="p">(</span><span class="n">LAG</span><span class="p">(</span><span class="w"> </span><span class="n">unit_of_measure</span><span class="w"> </span><span class="o">*</span><span class="w"> </span><span class="n">standard_cost</span><span class="w"> </span><span class="p">,</span><span class="mi">3</span><span class="w"> </span><span class="p">,</span><span class="k">NULL</span><span class="w"> </span><span class="p">)</span><span class="w"> </span><span class="n">over</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="n">material_name</span><span class="w"> </span><span class="p">))</span><span class="w"> </span><span class="k">AS</span><span class="w"> </span><span class="n">ROW_NUM2</span>
<span class="w"> </span><span class="k">FROM</span>
<span class="w"> </span><span class="n">raw_material_t</span><span class="w"> </span><span class="n">m</span><span class="w"> </span><span class="k">LEFT</span><span class="w"> </span><span class="k">JOIN</span><span class="w"> </span><span class="n">supplies_t</span><span class="w"> </span><span class="n">s</span>
<span class="w"> </span><span class="k">ON</span><span class="w"> </span><span class="n">s</span><span class="p">.</span><span class="n">material_id</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">m</span><span class="p">.</span><span class="n">material_id</span>
<span class="w"> </span><span class="p">)</span><span class="w"> </span><span class="n">Q1</span>
<span class="w"> </span><span class="k">WHERE</span>
<span class="w"> </span><span class="n">Q1</span><span class="p">.</span><span class="n">ROW_NUM1</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="s1">'5'</span>
<span class="w"> </span><span class="k">OR</span><span class="w"> </span><span class="n">Q1</span><span class="p">.</span><span class="n">ROW_NUM2</span><span class="w"> </span><span class="k">IS</span><span class="w"> </span><span class="k">NULL</span>
<span class="p">;</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001772536428__en-us_topic_0000001706105125_en-us_topic_0000001434790453_p529584375710"><strong id="EN-US_TOPIC_0000001772536428__en-us_topic_0000001706105125_en-us_topic_0000001434790453_b194439251332243">Input: QUALIFY with ORDER BY having columns that do not exist in the SELECT list</strong></p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001772536428__en-us_topic_0000001706105125_en-us_topic_0000001434790453_screen529764310575"><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">SELECT</span><span class="w"> </span><span class="n">Postal_Code</span>
<span class="w"> </span><span class="k">FROM</span><span class="w"> </span><span class="n">db_pvfc9_std</span><span class="p">.</span><span class="n">Customer_t</span><span class="w"> </span><span class="n">t1</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">Customer_Name</span><span class="w"> </span><span class="p">,</span><span class="n">Postal_Code</span>
<span class="w"> </span><span class="n">QUALIFY</span><span class="w"> </span><span class="c1">---comments</span>
<span class="w"> </span><span class="p">(</span><span class="w"> </span><span class="n">Rank</span><span class="w"> </span><span class="p">(</span><span class="w"> </span><span class="nb">CHAR</span><span class="p">(</span><span class="n">Customer_Address</span><span class="p">)</span><span class="w"> </span><span class="k">DESC</span><span class="w"> </span><span class="p">)</span><span class="w"> </span><span class="p">)</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="mi">1</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">t1</span><span class="p">.</span><span class="n">Customer_Name</span><span class="p">;</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001772536428__en-us_topic_0000001706105125_en-us_topic_0000001434790453_p730384345720"><strong id="EN-US_TOPIC_0000001772536428__en-us_topic_0000001706105125_en-us_topic_0000001434790453_b12304134314575">Output</strong></p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001772536428__en-us_topic_0000001706105125_en-us_topic_0000001434790453_screen370115115713"><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></pre></div></td><td class="code"><div><pre><span></span><span class="k">SELECT</span><span class="w"> </span><span class="n">Postal_Code</span><span class="w"> </span><span class="k">FROM</span>
<span class="w"> </span><span class="p">(</span><span class="w"> </span><span class="k">SELECT</span><span class="w"> </span><span class="n">Customer_Name</span><span class="p">,</span><span class="w"> </span><span class="n">Postal_Code</span>
<span class="w"> </span><span class="p">,</span><span class="w"> </span><span class="n">Rank</span><span class="w"> </span><span class="p">()</span><span class="w"> </span><span class="n">over</span><span class="p">(</span><span class="w"> </span><span class="n">PARTITION</span><span class="w"> </span><span class="k">BY</span><span class="w"> </span><span class="n">Customer_Name</span><span class="p">,</span><span class="w"> </span><span class="n">Postal_Code</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="k">LENGTH</span><span class="p">(</span><span class="n">Customer_Address</span><span class="p">)</span><span class="w"> </span><span class="k">DESC</span><span class="w"> </span><span class="p">)</span><span class="w"> </span><span class="k">AS</span><span class="w"> </span><span class="n">Rank_col</span>
<span class="w"> </span><span class="k">FROM</span><span class="w"> </span><span class="n">db_pvfc9_std</span><span class="p">.</span><span class="n">Customer_t</span><span class="w"> </span><span class="n">t1</span>
<span class="w"> </span><span class="p">)</span><span class="w"> </span><span class="n">Q1</span>
<span class="w"> </span><span class="k">WHERE</span><span class="w"> </span><span class="cm">/*comments*/</span>
<span class="w"> </span><span class="n">Q1</span><span class="p">.</span><span class="n">Rank_col</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="mi">1</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">Q1</span><span class="p">.</span><span class="n">Customer_Name</span><span class="p">;</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001772536428__en-us_topic_0000001706105125_en-us_topic_0000001434790453_p3286173025820"><strong id="EN-US_TOPIC_0000001772536428__en-us_topic_0000001706105125_en-us_topic_0000001434790453_b24867913432243">Input: QUALIFY with COLUMN ALIAS - the corresponding column expression should not be added again in SELECT list.</strong></p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001772536428__en-us_topic_0000001706105125_en-us_topic_0000001434790453_screen10288630175812"><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">material_name</span><span class="p">,</span><span class="w"> </span><span class="n">unit_of_measure</span><span class="w"> </span><span class="o">*</span><span class="w"> </span><span class="n">standard_cost</span><span class="w"> </span><span class="k">as</span><span class="w"> </span><span class="n">tot_cost</span><span class="p">,</span>
<span class="w"> </span><span class="n">RANK</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">tot_cost</span><span class="w"> </span><span class="k">desc</span><span class="p">)</span><span class="w"> </span><span class="n">vendor_cnt</span>
<span class="w"> </span><span class="k">FROM</span><span class="w"> </span><span class="n">raw_material_t</span><span class="w"> </span><span class="n">m</span><span class="w"> </span><span class="k">left</span><span class="w"> </span><span class="k">join</span><span class="w"> </span><span class="n">supplies_t</span><span class="w"> </span><span class="n">s</span>
<span class="w"> </span><span class="k">ON</span><span class="w"> </span><span class="n">s</span><span class="p">.</span><span class="n">material_id</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">m</span><span class="p">.</span><span class="n">material_id</span>
<span class="w"> </span><span class="n">QUALIFY</span><span class="w"> </span><span class="n">vendor_cnt</span><span class="w"> </span><span class="o">&lt;</span><span class="w"> </span><span class="mi">5</span><span class="w"> </span><span class="k">or</span><span class="w"> </span><span class="n">MDIFF</span><span class="p">(</span><span class="n">tot_cost</span><span class="p">,</span><span class="w"> </span><span class="mi">3</span><span class="p">,</span><span class="w"> </span><span class="n">material_name</span><span class="p">)</span><span class="w"> </span><span class="k">IS</span><span class="w"> </span><span class="k">NULL</span><span class="p">;</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001772536428__en-us_topic_0000001706105125_en-us_topic_0000001434790453_p192921230105817"><strong id="EN-US_TOPIC_0000001772536428__en-us_topic_0000001706105125_en-us_topic_0000001434790453_b10292133016584">Output</strong></p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001772536428__en-us_topic_0000001706105125_en-us_topic_0000001434790453_screen182935302582"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal"> 1</span>
<span class="normal"> 2</span>
<span class="normal"> 3</span>
<span class="normal"> 4</span>
<span class="normal"> 5</span>
<span class="normal"> 6</span>
<span class="normal"> 7</span>
<span class="normal"> 8</span>
<span class="normal"> 9</span>
<span class="normal">10</span></pre></div></td><td class="code"><div><pre><span></span><span class="k">SELECT</span><span class="w"> </span><span class="n">material_name</span><span class="p">,</span><span class="w"> </span><span class="n">tot_cost</span><span class="p">,</span><span class="w"> </span><span class="n">vendor_cnt</span>
<span class="w"> </span><span class="k">FROM</span><span class="w"> </span><span class="p">(</span><span class="w"> </span><span class="k">SELECT</span><span class="w"> </span><span class="n">material_name</span>
<span class="w"> </span><span class="p">,</span><span class="w"> </span><span class="n">unit_of_measure</span><span class="w"> </span><span class="o">*</span><span class="w"> </span><span class="n">standard_cost</span><span class="w"> </span><span class="k">AS</span><span class="w"> </span><span class="n">tot_cost</span>
<span class="w"> </span><span class="p">,</span><span class="w"> </span><span class="n">rank</span><span class="w"> </span><span class="p">()</span><span class="w"> </span><span class="n">over</span><span class="w"> </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">tot_cost</span><span class="w"> </span><span class="k">DESC</span><span class="p">)</span><span class="w"> </span><span class="n">vendor_cnt</span>
<span class="w"> </span><span class="p">,</span><span class="w"> </span><span class="n">tot_cost</span><span class="w"> </span><span class="o">-</span><span class="w"> </span><span class="p">(</span><span class="w"> </span><span class="n">LAG</span><span class="p">(</span><span class="n">tot_cost</span><span class="w"> </span><span class="p">,</span><span class="mi">3</span><span class="w"> </span><span class="p">,</span><span class="k">NULL</span><span class="p">)</span><span class="w"> </span><span class="n">over</span><span class="w"> </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">material_name</span><span class="p">)</span><span class="w"> </span><span class="p">)</span><span class="w"> </span><span class="k">AS</span><span class="w"> </span><span class="n">anltfn</span>
<span class="w"> </span><span class="k">FROM</span><span class="w"> </span><span class="n">raw_material_t</span><span class="w"> </span><span class="n">m</span><span class="w"> </span><span class="k">LEFT</span><span class="w"> </span><span class="k">JOIN</span><span class="w"> </span><span class="n">supplies_t</span><span class="w"> </span><span class="n">s</span>
<span class="w"> </span><span class="k">ON</span><span class="w"> </span><span class="n">s</span><span class="p">.</span><span class="n">material_id</span><span class="w"> </span><span class="o">=</span><span class="w"> </span><span class="n">m</span><span class="p">.</span><span class="n">material_id</span>
<span class="w"> </span><span class="p">)</span><span class="w"> </span><span class="n">Q1</span>
<span class="w"> </span><span class="k">WHERE</span><span class="w"> </span><span class="n">Q1</span><span class="p">.</span><span class="n">vendor_cnt</span><span class="w"> </span><span class="o">&lt;</span><span class="w"> </span><span class="mi">5</span><span class="w"> </span><span class="k">OR</span><span class="w"> </span><span class="n">Q1</span><span class="p">.</span><span class="n">anltfn</span><span class="w"> </span><span class="k">IS</span><span class="w"> </span><span class="k">NULL</span>
<span class="w"> </span><span class="p">;</span>
</pre></div></td></tr></table></div>
</div>
<div class="section" id="EN-US_TOPIC_0000001772536428__en-us_topic_0000001706105125_en-us_topic_0000001434790453_section691684714476"><h4 class="sectiontitle">TITLE with QUALIFY</h4><p id="EN-US_TOPIC_0000001772536428__en-us_topic_0000001706105125_en-us_topic_0000001434790453_p158205016477"><strong id="EN-US_TOPIC_0000001772536428__en-us_topic_0000001706105125_en-us_topic_0000001434790453_b3313122514204">Input</strong></p>
</div>
<pre class="screen" id="EN-US_TOPIC_0000001772536428__en-us_topic_0000001706105125_en-us_topic_0000001434790453_screen462319614814">REPLACE VIEW ${STG_VIEW}.LP06_BMCLIINFP${v_Table_Suffix_Inc}
(
CLICLINBR
, CLICHNNAM
, CLICHNSHO
, CLICLIMNE
, CLIBNKCOD
)
AS
LOCKING ${STG_DATA}.LP06_BMCLIINFP${v_Table_Suffix_Inc} FOR ACCESS
SELECT
CLICLINBR (title ' VARCHAR(20)')
, CLICHNNAM (title ' VARCHAR(200)')
, CLICHNSHO (title ' VARCHAR(20)')
, CLICLIMNE (title ' VARCHAR(10)')
, CLIBNKCOD (title ' VARCHAR(11)')
FROM
${STG_DATA}.LP06_BMCLIINFP${v_Table_Suffix_Inc} s1
QUALIFY
ROW_NUMBER() OVER(PARTITION BY CLICLINBR ORDER BY CLICLINBR ) = 1
;</pre>
<p id="EN-US_TOPIC_0000001772536428__en-us_topic_0000001706105125_en-us_topic_0000001434790453_p5788102934717"><strong id="EN-US_TOPIC_0000001772536428__en-us_topic_0000001706105125_en-us_topic_0000001434790453_b174722032142013">Output</strong></p>
<pre class="screen" id="EN-US_TOPIC_0000001772536428__en-us_topic_0000001706105125_en-us_topic_0000001434790453_screen14715510154820">CREATE OR REPLACE VIEW ${STG_VIEW}.LP06_BMCLIINFP${v_Table_Suffix_Inc}
(
CLICLINBR
, CLICHNNAM
, CLICHNSHO
, CLICLIMNE
, CLIBNKCOD
)
AS
/* LOCKING ${STG_DATA}.LP06_BMCLIINFP${v_Table_Suffix_Inc} FOR ACCESS */
SELECT CLICLINBR
, CLICHNNAM
, CLICHNSHO
, CLICLIMNE
, CLIBNKCOD
FROM (
SELECT
CLICLINBR /* (title ' VARCHAR(20)') */
, CLICHNNAM /* (title ' VARCHAR(200)') */
, CLICHNSHO /* (title ' VARCHAR(20)') */
, CLICLIMNE /* (title ' VARCHAR(10)') */
, CLIBNKCOD /* (title ' VARCHAR(11)') */
, ROW_NUMBER() OVER(PARTITION BY CLICLINBR ORDER BY CLICLINBR ) AS ROWNUM1
FROM
${STG_DATA}.LP06_BMCLIINFP${v_Table_Suffix_Inc} s1 ) Q1
WHERE Q1.ROWNUM1 = 1
;</pre>
</div>
<div>
<div class="familylinks">
<div class="parentlink"><strong>Parent topic:</strong> <a href="dws_16_0049.html">Query Migration Operators</a></div>
</div>
</div>