doc-exports/docs/dws/dev/dws_06_0047.html
Lu, Huayi e6fa411af0 DWS DEV 830.201 version
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:24:04 +00:00

348 lines
67 KiB
HTML
Raw Blame History

This file contains ambiguous Unicode characters

This file contains Unicode characters that might be confused with other characters. If you think that this is intentional, you can safely ignore this warning. Use the Escape button to reveal them.

<a name="EN-US_TOPIC_0000001188270552"></a><a name="EN-US_TOPIC_0000001188270552"></a>
<h1 class="topictitle1">Window Functions</h1>
<div id="body8662426"><p id="EN-US_TOPIC_0000001188270552__p183911130250">Regular aggregate functions return a single value calculated from values in a row, or group all rows into a single output row. Window functions perform a calculation across a set of rows and return a value for each row.</p>
<p id="EN-US_TOPIC_0000001188270552__p0965012599">A window function call represents the application of an aggregate-like function over some portion of the rows selected by a query. Therefore, aggregate functions (<a href="dws_06_0046.html">Aggregate Functions</a>) can also be used as window functions. A window function can scan all rows and display the raw data and aggregation analysis results at the same time.</p>
<div class="section" id="EN-US_TOPIC_0000001188270552__section5903162485815"><h4 class="sectiontitle">Precautions</h4><ul id="EN-US_TOPIC_0000001188270552__ul8783133135813"><li id="EN-US_TOPIC_0000001188270552__li107831633195815">Column-store tables support only the window functions <strong id="EN-US_TOPIC_0000001188270552__b1106388240112552">rank (expression)</strong> and <strong id="EN-US_TOPIC_0000001188270552__b1164483186112552">row_number (expression)</strong> and the aggregate functions <strong id="EN-US_TOPIC_0000001188270552__b1703412885112552">sum</strong>, <strong id="EN-US_TOPIC_0000001188270552__b1112248377112552">count</strong>, <strong id="EN-US_TOPIC_0000001188270552__b306313157112552">avg</strong>, <strong id="EN-US_TOPIC_0000001188270552__b335234293112552">min</strong>, and <strong id="EN-US_TOPIC_0000001188270552__b921847475112552">max</strong>. Row-store tables do not have such restrictions.</li><li id="EN-US_TOPIC_0000001188270552__li19667636115812">A single query can contain one or more window function expressions.</li><li id="EN-US_TOPIC_0000001188270552__li104846261954">Window functions can appear only in output columns. If you want to use the values of a window function for condition filtering, you need to nest the window function in the subquery and use the aliases of the window function expression at the outer layer for condition filtering. Example:<pre class="screen" id="EN-US_TOPIC_0000001188270552__screen630312281667">SELECT classid, id, score FROM(SELECT *, avg(score) OVER(PARTITION BY classid) as avg_score FROM score) WHERE score &gt;= avg_score;</pre>
</li><li id="EN-US_TOPIC_0000001188270552__li282713482510">In the query block where the window function is located, the <strong id="EN-US_TOPIC_0000001188270552__b514014399220">GROUP BY</strong> expression can be used for grouping and deduplication. In this case, the PARTITION BY clause in the window function must be a subset of the GROUP BY expression to ensure that the window function performs calculation on the deduplication result. The expression of the <strong id="EN-US_TOPIC_0000001188270552__b19991211967">ORDER BY</strong> clause must be a subset of the <strong id="EN-US_TOPIC_0000001188270552__b11591915765">GROUP BY</strong> expression or an aggregate function of an aggregate operation. Example:<pre class="screen" id="EN-US_TOPIC_0000001188270552__screen21996438617">SELECT classid,rank() OVER(PARTITION BY classid ORDER BY sum(score)) as avg_score FROM score GROUP BY classid, id;</pre>
</li></ul>
</div>
<div class="section" id="EN-US_TOPIC_0000001188270552__section20427155155215"><h4 class="sectiontitle">Syntax</h4><p id="EN-US_TOPIC_0000001188270552__p18216121153">A window function uses the <strong id="EN-US_TOPIC_0000001188270552__b2710656354">OVER</strong> clause to define a window. The <strong id="EN-US_TOPIC_0000001188270552__b373830180112552">OVER</strong> clause is used for grouping data and sorting the elements in a group. Window functions are used for generating sequence numbers for the values in the group.</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188270552__screen197441416641"><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="n">function_name</span><span class="w"> </span><span class="p">([</span><span class="n">expression</span><span class="w"> </span><span class="p">[,</span><span class="w"> </span><span class="n">expression</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="w"> </span><span class="p">(</span><span class="w"> </span><span class="n">window_definition</span><span class="w"> </span><span class="p">)</span><span class="w"> </span>
<span class="n">function_name</span><span class="w"> </span><span class="p">([</span><span class="n">expression</span><span class="w"> </span><span class="p">[,</span><span class="w"> </span><span class="n">expression</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="w"> </span><span class="n">window_name</span>
<span class="n">function_name</span><span class="w"> </span><span class="p">(</span><span class="w"> </span><span class="o">*</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="w"> </span><span class="n">window_definition</span><span class="w"> </span><span class="p">)</span><span class="w"> </span>
<span class="n">function_name</span><span class="w"> </span><span class="p">(</span><span class="w"> </span><span class="o">*</span><span class="w"> </span><span class="p">)</span><span class="w"> </span><span class="n">OVER</span><span class="w"> </span><span class="n">window_name</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001188270552__p774410160418"><strong id="EN-US_TOPIC_0000001188270552__b1062694973112">window_definition</strong> is defined as follows:</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188270552__screen67441616648"><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="p">[</span><span class="w"> </span><span class="n">existing_window_name</span><span class="w"> </span><span class="p">]</span><span class="w"> </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">expression</span><span class="w"> </span><span class="p">[,</span><span class="w"> </span><span class="p">...]</span><span class="w"> </span><span class="p">]</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">expression</span><span class="w"> </span><span class="p">[</span><span class="w"> </span><span class="k">ASC</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="k">DESC</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="k">USING</span><span class="w"> </span><span class="k">operator</span><span class="w"> </span><span class="p">]</span><span class="w"> </span><span class="p">[</span><span class="w"> </span><span class="n">NULLS</span><span class="w"> </span><span class="err">{</span><span class="w"> </span><span class="k">FIRST</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="k">LAST</span><span class="w"> </span><span class="err">}</span><span class="w"> </span><span class="p">]</span><span class="w"> </span><span class="p">[,</span><span class="w"> </span><span class="p">...]</span><span class="w"> </span><span class="p">]</span>
<span class="p">[</span><span class="w"> </span><span class="n">frame_clause</span><span class="w"> </span><span class="p">]</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001188270552__p15738823301">The <strong id="EN-US_TOPIC_0000001188270552__b2048042110138">PARTITION BY</strong> option specifies that rows with the same <strong id="EN-US_TOPIC_0000001188270552__b12776153131318">PARTITION BY</strong> expression value are grouped.</p>
<p id="EN-US_TOPIC_0000001188270552__p89114173578">The <strong id="EN-US_TOPIC_0000001188270552__b6305141801319">ORDER BY</strong> option is used to control the order in which the window function processes rows. <strong id="EN-US_TOPIC_0000001188270552__b17221659131319">ORDER BY</strong> must be followed by a column name. If <strong id="EN-US_TOPIC_0000001188270552__b559915184148">ORDER BY</strong> is followed by a number, the number is processed as a constant and does not sort the target column.</p>
<p id="EN-US_TOPIC_0000001188270552__p137445168414"><strong id="EN-US_TOPIC_0000001188270552__b95489411710">frame_clause</strong> is defined as follows:</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188270552__screen8744016741"><div class="highlight"><table class="highlighttable"><tr><td class="linenos"><div class="linenodiv"><pre><span class="normal">1</span>
<span class="normal">2</span></pre></div></td><td class="code"><div><pre><span></span><span class="p">[</span><span class="w"> </span><span class="n">RANGE</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="k">ROWS</span><span class="w"> </span><span class="p">]</span><span class="w"> </span><span class="n">frame_start</span><span class="w"> </span>
<span class="p">[</span><span class="w"> </span><span class="n">RANGE</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="k">ROWS</span><span class="w"> </span><span class="p">]</span><span class="w"> </span><span class="k">BETWEEN</span><span class="w"> </span><span class="n">frame_start</span><span class="w"> </span><span class="k">AND</span><span class="w"> </span><span class="n">frame_end</span>
</pre></div></td></tr></table></div>
</div>
<p id="EN-US_TOPIC_0000001188270552__p1223318232547">When you need to specify a window to calculate the results of all rows in a group, you need to specify the start row and end row of the window range. The window range supports the RANGE and ROWS modes. The ROWS mode specifies the window by the physical unit (row), and the RANGE mode specifies the window as the logical offset.</p>
<p id="EN-US_TOPIC_0000001188270552__p11672141313412">In <strong id="EN-US_TOPIC_0000001188270552__b26907464348">RANGE</strong> and <strong id="EN-US_TOPIC_0000001188270552__b149141149143410">ROWS</strong>, you can use <strong id="EN-US_TOPIC_0000001188270552__b319517103519">BETWEEN</strong> <em id="EN-US_TOPIC_0000001188270552__i1467413443516">frame_start</em> <strong id="EN-US_TOPIC_0000001188270552__b127558163514">AND</strong> <em id="EN-US_TOPIC_0000001188270552__i10146141193518">frame_end</em> to specify the window's first and last rows. If only <strong id="EN-US_TOPIC_0000001188270552__b13662102820171">frame_start</strong> is specified, <strong id="EN-US_TOPIC_0000001188270552__b20223154091710">frame_end</strong> is <strong id="EN-US_TOPIC_0000001188270552__b114501843171718">CURRENT ROW</strong> by default.</p>
<p id="EN-US_TOPIC_0000001188270552__p1463514155418">The values of <strong id="EN-US_TOPIC_0000001188270552__b544116517176">frame_start</strong> and <strong id="EN-US_TOPIC_0000001188270552__b197407545174">frame_end</strong> are as follows:</p>
<ul id="EN-US_TOPIC_0000001188270552__ul12235137135416"><li id="EN-US_TOPIC_0000001188270552__li82352735416"><strong id="EN-US_TOPIC_0000001188270552__b1145513715375">CURRENT ROW</strong>: The current row is used as the window frame's start or end point.</li><li id="EN-US_TOPIC_0000001188270552__li723518716549"><em id="EN-US_TOPIC_0000001188270552__i175722003392">N</em> <strong id="EN-US_TOPIC_0000001188270552__b15313420391">PRECEDING</strong>: The window frame starts from the <em id="EN-US_TOPIC_0000001188270552__i58831913134213">n</em>th row to the current row.</li><li id="EN-US_TOPIC_0000001188270552__li3975211184611"><strong id="EN-US_TOPIC_0000001188270552__b136975010438">UNBOUNDED PRECEDING</strong>: The window frame starts at the first row of the partition.</li><li id="EN-US_TOPIC_0000001188270552__li3235177145410"><em id="EN-US_TOPIC_0000001188270552__i20711428114619">N</em> <strong id="EN-US_TOPIC_0000001188270552__b87415281464">FOLLOWING</strong>: The window frame starts from the current row to the <em id="EN-US_TOPIC_0000001188270552__i157492874616">n</em>th row.</li><li id="EN-US_TOPIC_0000001188270552__li18235173544"><strong id="EN-US_TOPIC_0000001188270552__b121643412598">UNBOUNDED FOLLOWING</strong>: The window frame ends with the last row of the partition.</li></ul>
<p id="EN-US_TOPIC_0000001188270552__p19599219114"><em id="EN-US_TOPIC_0000001188270552__i1574410591903">frame_start</em> cannot be <strong id="EN-US_TOPIC_0000001188270552__b181951235009">UNBOUNDED FOLLOWING</strong>, <em id="EN-US_TOPIC_0000001188270552__i123772214111">frame_end</em> cannot be <strong id="EN-US_TOPIC_0000001188270552__b350918261019">UNBOUNDED PRECEDING</strong>, and <em id="EN-US_TOPIC_0000001188270552__i188188301610">frame_end</em> cannot be earlier than <em id="EN-US_TOPIC_0000001188270552__i569804310110">frame_start</em>. For example, <strong id="EN-US_TOPIC_0000001188270552__b09534578171">RANGE BETWEEN CURRENT ROW AND </strong><em id="EN-US_TOPIC_0000001188270552__i17954357151713">N</em><strong id="EN-US_TOPIC_0000001188270552__b13954657161715"> PRECEDING</strong> is not allowed.</p>
</div>
<div class="section" id="EN-US_TOPIC_0000001188270552__section964711317366"><h4 class="sectiontitle">RANK()</h4><p id="EN-US_TOPIC_0000001188270552__p863917310361">Description: The <strong id="EN-US_TOPIC_0000001188270552__b842352706135820">RANK</strong> function is used for generating non-consecutive sequence numbers for the values in each group. The same values have the same rank value but with sequence numbers.</p>
<p id="EN-US_TOPIC_0000001188270552__p136396310363">Return type: bigint</p>
<p id="EN-US_TOPIC_0000001188270552__p166401937367">Example:</p>
<p id="EN-US_TOPIC_0000001188270552__p112457351346">In the <strong id="EN-US_TOPIC_0000001188270552__b28541431102010">score(id, classid, score)</strong> table, the rows are student ID, class ID, and exam score.</p>
<p id="EN-US_TOPIC_0000001188270552__p9955185715716">Use the <strong id="EN-US_TOPIC_0000001188270552__b12593454121912">RANK</strong> function to sort student scores.</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188270552__screen564013312363"><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></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">score</span><span class="p">(</span><span class="n">id</span><span class="w"> </span><span class="nb">int</span><span class="p">,</span><span class="n">classid</span><span class="w"> </span><span class="nb">int</span><span class="p">,</span><span class="n">score</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">score</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="mi">1</span><span class="p">,</span><span class="mi">95</span><span class="p">),(</span><span class="mi">2</span><span class="p">,</span><span class="mi">2</span><span class="p">,</span><span class="mi">95</span><span class="p">),(</span><span class="mi">3</span><span class="p">,</span><span class="mi">2</span><span class="p">,</span><span class="mi">85</span><span class="p">),(</span><span class="mi">4</span><span class="p">,</span><span class="mi">1</span><span class="p">,</span><span class="mi">70</span><span class="p">),(</span><span class="mi">5</span><span class="p">,</span><span class="mi">2</span><span class="p">,</span><span class="mi">88</span><span class="p">),(</span><span class="mi">6</span><span class="p">,</span><span class="mi">1</span><span class="p">,</span><span class="mi">70</span><span class="p">);</span>
<span class="k">SELECT</span><span class="w"> </span><span class="n">id</span><span class="p">,</span><span class="w"> </span><span class="n">classid</span><span class="p">,</span><span class="w"> </span><span class="n">score</span><span class="p">,</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">score</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">score</span><span class="p">;</span>
<span class="w"> </span><span class="n">id</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">classid</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">score</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">rank</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="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">95</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">1</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="o">|</span><span class="w"> </span><span class="mi">95</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">1</span>
<span class="w"> </span><span class="mi">6</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="mi">70</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">5</span>
<span class="w"> </span><span class="mi">4</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="mi">70</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">5</span>
<span class="w"> </span><span class="mi">5</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">88</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">3</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">2</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">85</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">4</span>
<span class="p">(</span><span class="mi">6</span><span class="w"> </span><span class="k">rows</span><span class="p">)</span>
</pre></div></td></tr></table></div>
</div>
</div>
<div class="section" id="EN-US_TOPIC_0000001188270552__section66361377364"><h4 class="sectiontitle">ROW_NUMBER()</h4><p id="EN-US_TOPIC_0000001188270552__p3630107123612">Description: The <strong id="EN-US_TOPIC_0000001188270552__b842352706135830">ROW_NUMBER</strong> function is used for generating consecutive sequence numbers for the values in each group. The same values have different sequence numbers.</p>
<p id="EN-US_TOPIC_0000001188270552__p176301271368">Return type: bigint</p>
<p id="EN-US_TOPIC_0000001188270552__p106301076362">Example:</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188270552__screen141701757941"><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">id</span><span class="p">,</span><span class="w"> </span><span class="n">classid</span><span class="p">,</span><span class="w"> </span><span class="n">score</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">score</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">score</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">score</span><span class="w"> </span><span class="k">DESC</span><span class="p">;</span>
<span class="w"> </span><span class="n">id</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">classid</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">score</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">row_number</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="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">95</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">1</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="o">|</span><span class="w"> </span><span class="mi">95</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">2</span>
<span class="w"> </span><span class="mi">5</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">88</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">3</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">2</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">85</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">4</span>
<span class="w"> </span><span class="mi">6</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="mi">70</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">5</span>
<span class="w"> </span><span class="mi">4</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="mi">70</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">6</span>
<span class="p">(</span><span class="mi">6</span><span class="w"> </span><span class="k">rows</span><span class="p">)</span>
</pre></div></td></tr></table></div>
</div>
</div>
<div class="section" id="EN-US_TOPIC_0000001188270552__section157061183619"><h4 class="sectiontitle">DENSE_RANK()</h4><p id="EN-US_TOPIC_0000001188270552__p1456441113361">Description: The <strong id="EN-US_TOPIC_0000001188270552__b84235270614042">DENSE_RANK</strong> function is used for generating consecutive sequence numbers for the values in each group. The same values have the same rank value number and the same sequence number.</p>
<p id="EN-US_TOPIC_0000001188270552__p15564611153616">Return type: bigint</p>
<p id="EN-US_TOPIC_0000001188270552__p756481118364">Example:</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188270552__screen510514111451"><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">id</span><span class="p">,</span><span class="w"> </span><span class="n">classid</span><span class="p">,</span><span class="w"> </span><span class="n">score</span><span class="p">,</span><span class="n">DENSE_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">score</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">score</span><span class="p">;</span>
<span class="w"> </span><span class="n">id</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">classid</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">score</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">dense_rank</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="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">95</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">1</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="o">|</span><span class="w"> </span><span class="mi">95</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">1</span>
<span class="w"> </span><span class="mi">5</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">88</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">2</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">2</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">85</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">3</span>
<span class="w"> </span><span class="mi">6</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="mi">70</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">4</span>
<span class="w"> </span><span class="mi">4</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="mi">70</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">4</span>
<span class="p">(</span><span class="mi">6</span><span class="w"> </span><span class="k">rows</span><span class="p">)</span>
</pre></div></td></tr></table></div>
</div>
</div>
<div class="section" id="EN-US_TOPIC_0000001188270552__section1064716155363"><h4 class="sectiontitle">PERCENT_RANK()</h4><p id="EN-US_TOPIC_0000001188270552__p564081519369">Description: The <strong id="EN-US_TOPIC_0000001188270552__b84235270614218">PERCENT_RANK</strong> function is used for generating corresponding sequence numbers for the values in each group. That is, the function calculates the value according to the formula Sequence number = (<strong id="EN-US_TOPIC_0000001188270552__b84235270614258">Rank</strong> 1)/(<strong id="EN-US_TOPIC_0000001188270552__b84235270614420">Total rows</strong> 1). <strong id="EN-US_TOPIC_0000001188270552__b842352706165459">Rank</strong> is the corresponding sequence number generated based on the <strong id="EN-US_TOPIC_0000001188270552__b84235270614356">RANK</strong> function for the value and <strong id="EN-US_TOPIC_0000001188270552__b842352706165615">Total rows</strong> is the total number of elements in a group.</p>
<p id="EN-US_TOPIC_0000001188270552__p764015154365">Return type: double precision</p>
<p id="EN-US_TOPIC_0000001188270552__p96401915183611">Example:</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188270552__screen9723422483"><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">id</span><span class="p">,</span><span class="w"> </span><span class="n">classid</span><span class="p">,</span><span class="w"> </span><span class="n">score</span><span class="p">,</span><span class="n">PERCENT_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">score</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">score</span><span class="p">;</span>
<span class="w"> </span><span class="n">id</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">classid</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">score</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">percent_rank</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="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">95</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">0</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="o">|</span><span class="w"> </span><span class="mi">95</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">0</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">2</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">85</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="p">.</span><span class="mi">6</span>
<span class="w"> </span><span class="mi">4</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="mi">70</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="p">.</span><span class="mi">8</span>
<span class="w"> </span><span class="mi">5</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">88</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="p">.</span><span class="mi">4</span>
<span class="w"> </span><span class="mi">6</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="mi">70</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="p">.</span><span class="mi">8</span>
<span class="p">(</span><span class="mi">6</span><span class="w"> </span><span class="k">rows</span><span class="p">)</span>
</pre></div></td></tr></table></div>
</div>
</div>
<div class="section" id="EN-US_TOPIC_0000001188270552__section13687172012369"><h4 class="sectiontitle">CUME_DIST()</h4><p id="EN-US_TOPIC_0000001188270552__p4681192019363">Description: The <strong id="EN-US_TOPIC_0000001188270552__b84235270614522">CUME_DIST</strong> function is used for generating accumulative distribution sequence numbers for the values in each group. That is, the function calculates the value according to the following formula: Sequence number = Number of rows preceding or peer with current row/Total rows.</p>
<p id="EN-US_TOPIC_0000001188270552__p13681192012360">Return type: double precision</p>
<p id="EN-US_TOPIC_0000001188270552__p166811020163615">Example:</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188270552__screen1097116331195"><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">id</span><span class="p">,</span><span class="n">classid</span><span class="p">,</span><span class="n">score</span><span class="p">,</span><span class="n">CUME_DIST</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">score</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">score</span><span class="p">;</span>
<span class="w"> </span><span class="n">id</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">classid</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">score</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">cume_dist</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="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">95</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="p">.</span><span class="mi">333333333333333</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="o">|</span><span class="w"> </span><span class="mi">95</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="p">.</span><span class="mi">333333333333333</span>
<span class="w"> </span><span class="mi">5</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">88</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="p">.</span><span class="mi">5</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">2</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">85</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="p">.</span><span class="mi">666666666666667</span>
<span class="w"> </span><span class="mi">4</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="mi">70</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">1</span>
<span class="w"> </span><span class="mi">6</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="mi">70</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">6</span><span class="w"> </span><span class="k">rows</span><span class="p">)</span>
</pre></div></td></tr></table></div>
</div>
</div>
<div class="section" id="EN-US_TOPIC_0000001188270552__section366511247367"><h4 class="sectiontitle">NTILE(num_buckets integer)</h4><p id="EN-US_TOPIC_0000001188270552__p2662162423614">Description: The <strong id="EN-US_TOPIC_0000001188270552__b842352706162211">NTILE</strong> function is used for equally allocating sequential data sets to the buckets whose quantity is specified by <strong id="EN-US_TOPIC_0000001188270552__b842352706162335">num_buckets</strong> according to <strong id="EN-US_TOPIC_0000001188270552__b842352706162540">num_buckets integer</strong> and allocating the bucket number to each row. Divide the partition as equally as possible.</p>
<p id="EN-US_TOPIC_0000001188270552__p1666217242366">Return type: integer</p>
<p id="EN-US_TOPIC_0000001188270552__p1466282473615">Example:</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188270552__screen774231610318"><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">id</span><span class="p">,</span><span class="n">classid</span><span class="p">,</span><span class="n">score</span><span class="p">,</span><span class="n">NTILE</span><span class="p">(</span><span class="mi">3</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">score</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">score</span><span class="p">;</span>
<span class="w"> </span><span class="n">id</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">classid</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">score</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">ntile</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="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">95</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">1</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="o">|</span><span class="w"> </span><span class="mi">95</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">1</span>
<span class="w"> </span><span class="mi">5</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">88</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">2</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">2</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">85</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">2</span>
<span class="w"> </span><span class="mi">4</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="mi">70</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">3</span>
<span class="w"> </span><span class="mi">6</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="mi">70</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">6</span><span class="w"> </span><span class="k">rows</span><span class="p">)</span>
</pre></div></td></tr></table></div>
</div>
</div>
<div class="section" id="EN-US_TOPIC_0000001188270552__section3352182811368"><h4 class="sectiontitle">LAG(value any [, offset integer [, default any ]])</h4><p id="EN-US_TOPIC_0000001188270552__p13348228123610">Description: The <strong id="EN-US_TOPIC_0000001188270552__b842352706162813">LAG</strong> function is used for generating lag values for the corresponding values in each group. That is, the value of the row obtained by moving forward the row corresponding to the current value by <strong id="EN-US_TOPIC_0000001188270552__b842352706162951">offset</strong> (integer) is the sequence number. If the row does not exist after the moving, the result value is the default value. If omitted, <strong id="EN-US_TOPIC_0000001188270552__b842352706163652">offset</strong> defaults to <strong id="EN-US_TOPIC_0000001188270552__b842352706163658">1</strong> and <strong id="EN-US_TOPIC_0000001188270552__b84235270616374">default</strong> to <strong id="EN-US_TOPIC_0000001188270552__b84235270616378">null</strong>.</p>
<p id="EN-US_TOPIC_0000001188270552__p03481228173612">Return type: same as the parameter type</p>
<p id="EN-US_TOPIC_0000001188270552__p8348102863620">Example:</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188270552__screen1163492917716"><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">id</span><span class="p">,</span><span class="n">classid</span><span class="p">,</span><span class="n">score</span><span class="p">,</span><span class="n">LAG</span><span class="p">(</span><span class="n">id</span><span class="p">,</span><span class="mi">3</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">score</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">score</span><span class="p">;</span>
<span class="w"> </span><span class="n">id</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">classid</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">score</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">lag</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="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">95</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="o">|</span><span class="w"> </span><span class="mi">95</span><span class="w"> </span><span class="o">|</span>
<span class="w"> </span><span class="mi">5</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">88</span><span class="w"> </span><span class="o">|</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">2</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">85</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">1</span>
<span class="w"> </span><span class="mi">4</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="mi">70</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">2</span>
<span class="w"> </span><span class="mi">6</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="mi">70</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">5</span>
<span class="p">(</span><span class="mi">6</span><span class="w"> </span><span class="k">rows</span><span class="p">)</span>
</pre></div></td></tr></table></div>
</div>
</div>
<div class="section" id="EN-US_TOPIC_0000001188270552__section186541031193613"><h4 class="sectiontitle">LEAD(value any [, offset integer [, default any ]])</h4><p id="EN-US_TOPIC_0000001188270552__p665073143613">Description: The <strong id="EN-US_TOPIC_0000001188270552__b84235270616322">LEAD</strong> function is used for generating leading values for the corresponding values in each group. That is, the value of the row obtained by moving backward the row corresponding to the current value by <strong id="EN-US_TOPIC_0000001188270552__b842352706163530">offset</strong> (integer) is the sequence number. If the number of rows after the moving exceeds the total number for the current group, the result value is the default value. If omitted, <strong id="EN-US_TOPIC_0000001188270552__b1288919998">offset</strong> defaults to <strong id="EN-US_TOPIC_0000001188270552__b2552783">1</strong> and <strong id="EN-US_TOPIC_0000001188270552__b1450681344">default</strong> to <strong id="EN-US_TOPIC_0000001188270552__b809700846">null</strong>.</p>
<p id="EN-US_TOPIC_0000001188270552__p2650203115368">Return type: same as the parameter type</p>
<p id="EN-US_TOPIC_0000001188270552__p196506313368">Example:</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188270552__screen29532011279"><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">id</span><span class="p">,</span><span class="n">classid</span><span class="p">,</span><span class="n">score</span><span class="p">,</span><span class="n">LEAD</span><span class="p">(</span><span class="n">id</span><span class="p">,</span><span class="mi">3</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">score</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">score</span><span class="p">;</span>
<span class="w"> </span><span class="n">id</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">classid</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">score</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">lead</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="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">95</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">3</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="o">|</span><span class="w"> </span><span class="mi">95</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">4</span>
<span class="w"> </span><span class="mi">5</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">88</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">6</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">2</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">85</span><span class="w"> </span><span class="o">|</span>
<span class="w"> </span><span class="mi">4</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="mi">70</span><span class="w"> </span><span class="o">|</span>
<span class="w"> </span><span class="mi">6</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="mi">70</span><span class="w"> </span><span class="o">|</span>
<span class="p">(</span><span class="mi">6</span><span class="w"> </span><span class="k">rows</span><span class="p">)</span>
</pre></div></td></tr></table></div>
</div>
</div>
<div class="section" id="EN-US_TOPIC_0000001188270552__section123796357366"><h4 class="sectiontitle">FIRST_VALUE(value any)</h4><p id="EN-US_TOPIC_0000001188270552__p237723518365">Description: The <strong id="EN-US_TOPIC_0000001188270552__b196961930717">FIRST_VALUE</strong> function is used for returning the first value of each group.</p>
<p id="EN-US_TOPIC_0000001188270552__p337717356363">Return type: same as the parameter type</p>
<p id="EN-US_TOPIC_0000001188270552__p937710359367">Example:</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188270552__screen1488116610275"><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">id</span><span class="p">,</span><span class="n">classid</span><span class="p">,</span><span class="n">score</span><span class="p">,</span><span class="n">FIRST_VALUE</span><span class="p">(</span><span class="n">id</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">score</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">score</span><span class="p">;</span>
<span class="w"> </span><span class="n">id</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">classid</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">score</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">first_value</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="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">95</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">1</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="o">|</span><span class="w"> </span><span class="mi">95</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">1</span>
<span class="w"> </span><span class="mi">5</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">88</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">1</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">2</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">85</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">1</span>
<span class="w"> </span><span class="mi">4</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="mi">70</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">1</span>
<span class="w"> </span><span class="mi">6</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="mi">70</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">6</span><span class="w"> </span><span class="k">rows</span><span class="p">)</span>
</pre></div></td></tr></table></div>
</div>
</div>
<div class="section" id="EN-US_TOPIC_0000001188270552__section13877139103616"><h4 class="sectiontitle">LAST_VALUE(value any)</h4><p id="EN-US_TOPIC_0000001188270552__p1687563903613">Description: Returns the last value of each group.</p>
<p id="EN-US_TOPIC_0000001188270552__p387612396360">Return type: same as the parameter type</p>
<p id="EN-US_TOPIC_0000001188270552__p987611395365">Example:</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188270552__screen1238131022719"><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">id</span><span class="p">,</span><span class="n">classid</span><span class="p">,</span><span class="n">score</span><span class="p">,</span><span class="n">LAST_VALUE</span><span class="p">(</span><span class="n">id</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">score</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">score</span><span class="p">;</span>
<span class="w"> </span><span class="n">id</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">classid</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">score</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">last_value</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="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">95</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">2</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="o">|</span><span class="w"> </span><span class="mi">95</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">2</span>
<span class="w"> </span><span class="mi">5</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">88</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">5</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">2</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">85</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">3</span>
<span class="w"> </span><span class="mi">4</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="mi">70</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">6</span>
<span class="w"> </span><span class="mi">6</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="mi">70</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">6</span>
<span class="p">(</span><span class="mi">6</span><span class="w"> </span><span class="k">rows</span><span class="p">)</span>
</pre></div></td></tr></table></div>
</div>
</div>
<div class="section" id="EN-US_TOPIC_0000001188270552__section1485734383613"><h4 class="sectiontitle">NTH_VALUE(value any, nth integer)</h4><p id="EN-US_TOPIC_0000001188270552__p6856243133617">Description: The <em id="EN-US_TOPIC_0000001188270552__i77509711514">n</em>th row for a group is the returned value. If the row does not exist, <strong id="EN-US_TOPIC_0000001188270552__b84235270617511">NULL</strong> is returned by default.</p>
<p id="EN-US_TOPIC_0000001188270552__p138561943183617">Return type: same as the parameter type</p>
<p id="EN-US_TOPIC_0000001188270552__p18560436366">Example:</p>
<div class="codecoloring" codetype="Sql" id="EN-US_TOPIC_0000001188270552__screen313191332713"><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">id</span><span class="p">,</span><span class="n">classid</span><span class="p">,</span><span class="n">score</span><span class="p">,</span><span class="n">NTH_VALUE</span><span class="p">(</span><span class="n">id</span><span class="p">,</span><span class="mi">3</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">score</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">score</span><span class="p">;</span>
<span class="w"> </span><span class="n">id</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">classid</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">score</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="n">nth_value</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="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">95</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="o">|</span><span class="w"> </span><span class="mi">95</span><span class="w"> </span><span class="o">|</span>
<span class="w"> </span><span class="mi">5</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">88</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">5</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">2</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">85</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">5</span>
<span class="w"> </span><span class="mi">4</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="mi">70</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">5</span>
<span class="w"> </span><span class="mi">6</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="mi">70</span><span class="w"> </span><span class="o">|</span><span class="w"> </span><span class="mi">5</span>
<span class="p">(</span><span class="mi">6</span><span class="w"> </span><span class="k">rows</span><span class="p">)</span>
</pre></div></td></tr></table></div>
</div>
</div>
</div>
<div>
<div class="familylinks">
<div class="parentlink"><strong>Parent topic:</strong> <a href="dws_06_0027.html">Functions and Operators</a></div>
</div>
</div>