1055 lines
66 KiB
HTML
1055 lines
66 KiB
HTML
<?xml version="1.0" encoding="utf-8"?>
|
|
<!DOCTYPE html PUBLIC "-//W3C//DTD XHTML 1.0 Transitional//EN"
|
|
"http://www.w3.org/TR/xhtml1/DTD/xhtml1-transitional.dtd">
|
|
<html xmlns="http://www.w3.org/1999/xhtml" lang="en-US" xml:lang="en-us">
|
|
<head>
|
|
<meta http-equiv="Content-Type" content="text/html; charset=utf-8" />
|
|
<meta name="dc.language" scheme="rfc1766" content="en-us" />
|
|
<!-- All rights reserved. Licensed Materials Property of IBM -->
|
|
<!-- US Government Users Restricted Rights -->
|
|
<!-- Use, duplication or disclosure restricted by -->
|
|
<!-- GSA ADP Schedule Contract with IBM Corp. -->
|
|
<meta name="dc.date" scheme="iso8601" content="2005-09-19" />
|
|
<meta name="copyright" content="(C) Copyright IBM Corporation 1998, 2006" />
|
|
<meta name="security" content="public" />
|
|
<meta name="Robots" content="index,follow"/>
|
|
<meta http-equiv="PICS-Label" content='(PICS-1.1 "http://www.icra.org/ratingsv02.html" l gen true r (cz 1 lz 1 nz 1 oz 1 vz 1) "http://www.rsac.org/ratingsv01.html" l gen true r (n 0 s 0 v 0 l 0) "http://www.classify.org/safesurf/" l gen true r (SS~~000 1))' />
|
|
<meta name="keywords" content="arithmetic operations, date and time, DATE, time,
|
|
timestamp, operation, precedence, level, precedence of operation, expression,
|
|
evaluation order, order of evaluation, CASE expression, in CASE specification,
|
|
searched-when-clause, simple-when-clause, result-expression, search-condition,
|
|
division by zero, CAST specification, in CAST specification, NULL,
|
|
parameter-marker, typed parameter marker, typed paramter marker, data-type,
|
|
OLAP specifications, in OLAP specification, RANK, DENSE_RANK, ROW_NUMBER,
|
|
partition-by-clause, order-by-clause, sort-key-expression, ASC clause,
|
|
DESC clause, NULLS FIRST clause, NULLS LAST clause, ORDER OF clause,
|
|
sequence reference, NEXT VALUE, PREVIOUS VALUE, in sequence reference,
|
|
nextval-expression, prevval-expression, sequence-name" />
|
|
<title>Datetime arithmetic in SQL</title>
|
|
<link rel="stylesheet" type="text/css" href="ibmidwb.css" />
|
|
<link rel="stylesheet" type="text/css" href="ic.css" />
|
|
</head>
|
|
<body>
|
|
<a id="Top_Of_Page" name="Top_Of_Page"></a><!-- Java sync-link -->
|
|
<script language = "Javascript" src = "../rzahg/synch.js" type="text/javascript"></script>
|
|
|
|
|
|
<a name="datetimearith"></a>
|
|
<h3 id="datetimearith"><a href="rbafzmst02.htm#ToC_267">Datetime arithmetic in SQL</a></h3><a id="idx708" name="idx708"></a>
|
|
<p>The only arithmetic operations that can be performed on datetime values
|
|
are addition and subtraction. If a datetime value is the operand of addition,
|
|
the other operand must be a duration. The specific rules governing the use
|
|
of the addition operator with datetime values follow: </p>
|
|
<ul>
|
|
<li>If one operand is a date, the other operand must be a date duration or
|
|
labeled duration of years, months, or days.</li>
|
|
<li>If one operand is a time, the other operand must be a time duration or
|
|
a labeled duration of hours, minutes, or seconds.</li>
|
|
<li>If one operand is a timestamp, the other operand must be a duration. Any
|
|
type of duration is valid.</li>
|
|
<li>Neither operand of the addition operator can be an untyped parameter marker.</li></ul>
|
|
<p>The rules for the use of the subtraction operator on datetime values are
|
|
not the same as those for addition because a datetime value cannot be subtracted
|
|
from a duration, and because the operation of subtracting two datetime values
|
|
is not the same as the operation of subtracting a duration from a datetime
|
|
value. The specific rules governing the use of the subtraction operator with
|
|
datetime values follow: </p>
|
|
<ul>
|
|
<li>If the first operand is a date, the second operand must be a date, a date
|
|
duration, a string representation of a date, or a labeled duration of years,
|
|
months, or days.</li>
|
|
<li>If the second operand is a date, the first operand must be a date, or
|
|
a string representation of a date.</li>
|
|
<li>If the first operand is a time, the second operand must be a time, a time
|
|
duration, a string representation of a time, or a labeled duration of hours,
|
|
minutes, or seconds.</li>
|
|
<li>If the second operand is a time, the first operand must be a time, or
|
|
string representation of a time.</li>
|
|
<li>If the first operand is a timestamp, the second operand must be a timestamp,
|
|
a string representation of a timestamp, or a duration.</li>
|
|
<li>If the second operand is a timestamp, the first operand must be a timestamp
|
|
or a string representation of a timestamp.</li>
|
|
<li>Neither operand of the subtraction operator can be an untyped parameter
|
|
marker.</li></ul>
|
|
<a name="wq361"></a>
|
|
<h4 id="wq361">Date arithmetic</h4><a id="idx709" name="idx709"></a>
|
|
<p>Dates can be subtracted, incremented, or decremented.</p>
|
|
<a name="wq362"></a>
|
|
<h5 id="wq362">Subtracting dates</h5>
|
|
<p>The result of subtracting one date (DATE2) from another (DATE1) is a date
|
|
duration that specifies the number of years, months, and days between the
|
|
two dates. The data type of the result is DECIMAL(8,0). If DATE1 is greater
|
|
than or equal to DATE2, DATE2 is subtracted from DATE1. If DATE1 is less than
|
|
DATE2, however, DATE1 is subtracted from DATE2, and the sign of the result
|
|
is made negative. The following procedural description clarifies the steps
|
|
involved in the operation RESULT = DATE1 - DATE2. </p>
|
|
<div class="lines">If DAY(DATE2) <= DAY(DATE1)<br />
|
|
then DAY(RESULT) = DAY(DATE1) - DAY(DATE2).<br />
|
|
<br />
|
|
If DAY(DATE2) > DAY(DATE1)<br />
|
|
then DAY(RESULT) = N + DAY(DATE1) - DAY(DATE2)<br />
|
|
where N = the last day of MONTH(DATE2).<br />
|
|
MONTH(DATE2) is then incremented by 1.<br />
|
|
<br />
|
|
If MONTH(DATE2) <= MONTH(DATE1)<br />
|
|
then MONTH(RESULT) = MONTH(DATE1) - MONTH(DATE2).<br />
|
|
<br />
|
|
If MONTH(DATE2) > MONTH(DATE1)<br />
|
|
then MONTH(RESULT) = 12 + MONTH(DATE1) - MONTH(DATE2).<br />
|
|
YEAR(DATE2) is then incremented by 1.<br />
|
|
<br />
|
|
YEAR(RESULT) = YEAR(DATE1) - YEAR(DATE2).<br />
|
|
</div>
|
|
<p>For example, the result of DATE('3/15/2000') - '12/31/1999'
|
|
is 215 (or, a duration of 0 years, 2 months, and 15 days).</p>
|
|
<a name="wq363"></a>
|
|
<h5 id="wq363">Incrementing and decrementing dates</h5>
|
|
<p>The result of adding a duration to a date, or of subtracting a duration
|
|
from a date, is itself a date. (For the purposes of this operation, a month
|
|
denotes the equivalent of a calendar page. Adding months to a date, then,
|
|
is like turning the pages of a calendar, starting with the page on which the
|
|
date appears.) The result must fall between the dates January 1, 0001
|
|
and December 31, 9999 inclusive. If a duration of years is added or subtracted,
|
|
only the year portion of the date is affected. The month is unchanged, as
|
|
is the day unless the result would be February 29 of a non-leap-year.
|
|
In this case, the day is changed to 28, an SQLSTATE of '01506' is assigned
|
|
to the RETURNED_SQLSTATE condition area item in the SQL Diagnostics Area (or
|
|
SQLWARN6 in the SQLCA is set to 'W') to indicate the end-of-month adjustment.</p>
|
|
<p>Similarly, if a duration of months is added or subtracted, only months
|
|
and, if necessary, years are affected. The day portion of the date is unchanged
|
|
unless the result would be invalid (September 31, for example). In this case,
|
|
the day is set to the last day of the month, and SQLWARN6 in the SQLCA is
|
|
set to 'W' to indicate the end-of-month adjustment.</p>
|
|
<p>Adding or subtracting a duration of days will, of course, affect the day
|
|
portion of the date, and potentially the month and year. Adding a labeled
|
|
duration of DAYS will not cause an end-of-month adjustment.</p>
|
|
<p>Date durations, whether positive or negative, may also be added to and
|
|
subtracted from dates. As with labeled durations, the result is a valid date,
|
|
and a warning indicator is set in the SQLCA whenever an end-of-month adjustment
|
|
is necessary.</p>
|
|
<p>When a positive date duration is added to a date, or a negative date duration
|
|
is subtracted from a date, the date is incremented by the specified number
|
|
of years, months, and days, in that order. Thus DATE1 + X, where X is a positive
|
|
DECIMAL(8,0) number, is equivalent to the expression: </p>
|
|
<ul class="simple">
|
|
<li>DATE1 + YEAR(X) YEARS + MONTH(X) MONTHS + DAY(X) DAYS</li></ul>
|
|
<p>When a positive date duration is subtracted from a date, or a negative
|
|
date duration is added to a date, the date is decremented by the specified
|
|
number of days, months, and years, in that order. Thus, DATE1 - X, where X
|
|
is a positive DECIMAL(8,0) number, is equivalent to the expression: </p>
|
|
<ul class="simple">
|
|
<li>DATE1 - DAY(X) DAYS - MONTH(X) MONTHS - YEAR(X) YEARS</li></ul>
|
|
<p>When adding durations to dates, adding one month to a given date gives
|
|
the same date one month later <span class="italic">unless</span> that date does
|
|
not exist in the later month. In that case, the date is set to that of the
|
|
last day of the later month. For example, January 28 plus one month gives
|
|
February 28; and one month added to January 29, 30, or 31 results in either
|
|
February 28 or, for a leap year, February 29.</p>
|
|
<a name="wq364"></a>
|
|
<div class="notetitle" id="wq364">Note:</div>
|
|
<div class="notebody">If one or more months is added to a given date and then the
|
|
same number of months is subtracted from the result, the final date is not
|
|
necessarily the same as the original date.
|
|
<p>Also note that logically equivalent
|
|
expressions may not produce the same result. For example:</p>
|
|
<ul class="simple">
|
|
<li>(DATE('2002–01–31') + 1 MONTH) + 1 MONTH will result in a
|
|
date of 2002–03–28.</li></ul><p class="indatacontent">does not produce the same result as</p>
|
|
<ul class="simple">
|
|
<li>DATE('2002–01–31') + 2 MONTHS will result in a date of 2002–03–31.</li></ul></div>
|
|
<p>The order in which labeled date durations are added to and subtracted from
|
|
dates can affect the results. For compatibility with the results of adding
|
|
or subtracting date durations, a specific order must be used. When labeled
|
|
date durations are added to a date, specify them in the order of YEARS + MONTHS
|
|
+ DAYS. When labeled date durations are subtracted from a date, specify them
|
|
in the order of DAYS - MONTHS - YEARS. For example, to add one year and one
|
|
day to a date, specify:</p>
|
|
<ul class="simple">
|
|
<li>DATE1 + 1 YEAR + 1 DAY</li></ul><p class="indatacontent">To subtract one year, one month, and one day from a date, specify:</p>
|
|
<ul class="simple">
|
|
<li>DATE1 - 1 DAY - 1 MONTH - 1 YEAR</li></ul>
|
|
<a name="wq365"></a>
|
|
<h4 id="wq365">Time arithmetic</h4><a id="idx710" name="idx710"></a>
|
|
<p>Times can be subtracted, incremented, or decremented.</p>
|
|
<a name="wq366"></a>
|
|
<h5 id="wq366">Subtracting times</h5>
|
|
<p>The result of subtracting one time (TIME2) from another (TIME1) is a time
|
|
duration that specifies the number of hours, minutes, and seconds between
|
|
the two times. The data type of the result is DECIMAL(6,0). If TIME1 is greater
|
|
than or equal to TIME2, TIME2 is subtracted from TIME1. If TIME1 is less than
|
|
TIME2, however, TIME1 is subtracted from TIME2, and the sign of the result
|
|
is made negative. The following procedural description clarifies the steps
|
|
involved in the operation RESULT = TIME1 - TIME2. </p>
|
|
<div class="lines">If SECOND(TIME2) <= SECOND(TIME1)<br />
|
|
then SECOND(RESULT) = SECOND(TIME1) - SECOND(TIME2).<br />
|
|
<br />
|
|
If SECOND(TIME2) > SECOND(TIME1)<br />
|
|
then SECOND(RESULT) = 60 + SECOND(TIME1) - SECOND(TIME2).<br />
|
|
MINUTE(TIME2) is then incremented by 1.<br />
|
|
<br />
|
|
If MINUTE(TIME2) <= MINUTE(TIME1)<br />
|
|
then MINUTE(RESULT) = MINUTE(TIME1) - MINUTE(TIME2).<br />
|
|
<br />
|
|
If MINUTE(TIME2) > MINUTE(TIME1)<br />
|
|
then MINUTE(RESULT) = 60 + MINUTE(TIME1) - MINUTE(TIME2).<br />
|
|
HOUR(TIME2) is then incremented by 1.<br />
|
|
<br />
|
|
HOUR(RESULT) = HOUR(TIME1) - HOUR(TIME2).<br />
|
|
</div>
|
|
<p>For example, the result of TIME('11:02:26') - '00:32:56'
|
|
is 102930 (a duration of 10 hours, 29 minutes, and 30 seconds).</p>
|
|
<a name="wq367"></a>
|
|
<h5 id="wq367">Incrementing and decrementing times</h5>
|
|
<p>The result of adding a duration to a time, or of subtracting a duration
|
|
from a time, is itself a time. Any overflow or underflow of hours is discarded,
|
|
thereby ensuring that the result is always a time. If a duration of hours
|
|
is added or subtracted, only the hours portion of the time is affected. The
|
|
minutes and seconds are unchanged.</p>
|
|
<p>Similarly, if a duration of minutes is added or subtracted, only minutes
|
|
and, if necessary, hours are affected. The seconds portion of the time is
|
|
unchanged.</p>
|
|
<p>Adding or subtracting a duration of seconds will, of course, affect the
|
|
seconds portion of the time, and potentially the minutes and hours.</p>
|
|
<p>Time durations, whether positive or negative, also can be added to and
|
|
subtracted from times. The result is a time that has been incremented or decremented
|
|
by the specified number of hours, minutes, and seconds, in that order. <tt class="xph">TIME1 + X</tt>, where "X" is a DECIMAL(6,0) number, is equivalent
|
|
to the expression: </p>
|
|
<pre class="xmp"> TIME1 + HOUR(X) HOURS + MINUTE(X) MINUTES + SECOND(X) SECONDS</pre>
|
|
<a name="wq368"></a>
|
|
<h4 id="wq368">Timestamp arithmetic</h4><a id="idx711" name="idx711"></a>
|
|
<p>Timestamps can be subtracted, incremented, or decremented.</p>
|
|
<a name="wq369"></a>
|
|
<h5 id="wq369">Subtracting timestamps</h5>
|
|
<p>The result of subtracting one timestamp (TS2) from another (TS1) is a timestamp
|
|
duration that specifies the number of years, months, days, hours, minutes,
|
|
seconds, and microseconds between the two timestamps. The data type of the
|
|
result is DECIMAL(20,6). If TS1 is greater than or equal to TS2, TS2 is subtracted
|
|
from TS1. If TS1 is less than TS2, however, TS1 is subtracted from TS2 and
|
|
the sign of the result is made negative. The following procedural description
|
|
clarifies the steps involved in the operation RESULT = TS1 - TS2. </p>
|
|
<div class="lines">If MICROSECOND(TS2) <= MICROSECOND(TS1)<br />
|
|
then MICROSECOND(RESULT) = MICROSECOND(TS1) -<br />
|
|
MICROSECOND(TS2).<br />
|
|
<br />
|
|
If MICROSECOND(TS2) >MICROSECOND(TS1)<br />
|
|
then MICROSECOND(RESULT) = 1000000 +<br />
|
|
MICROSECOND(TS1) - MICROSECOND(TS2)<br />
|
|
and SECOND(TS2) is incremented by 1.<br />
|
|
<br />
|
|
The seconds and minutes part of the timestamps are subtracted as specified<br />
|
|
in the rules for subtracting times.<br />
|
|
<br />
|
|
If HOUR(TS2) <= HOUR(TS1)<br />
|
|
then HOUR(RESULT) = HOUR(TS1) - HOUR(TS2).<br />
|
|
<br />
|
|
If HOUR(TS2) > HOUR(TS1)<br />
|
|
then HOUR(RESULT) = 24 + HOUR(TS1) - HOUR(TS2)<br />
|
|
and DAY(TS2) is incremented by 1.<br />
|
|
<br />
|
|
The date part of the timestamps is subtracted as specified<br />
|
|
in the rules for subtracting dates.<br />
|
|
<br />
|
|
</div>
|
|
<a name="wq370"></a>
|
|
<h5 id="wq370">Incrementing and decrementing timestamps</h5><a id="idx712" name="idx712"></a>
|
|
<p>The result of adding a duration to a timestamp, or of subtracting a duration
|
|
from a timestamp, is itself a timestamp. Date and time arithmetic is performed
|
|
as previously defined, except that an overflow or underflow of hours is carried
|
|
into the date part of the result, which must be within the range of valid
|
|
dates. Microseconds overflow into seconds.</p>
|
|
<a name="wq371"></a>
|
|
<h3 id="wq371"><a href="rbafzmst02.htm#ToC_277">Precedence of operations</a></h3><a id="idx713" name="idx713"></a><a id="idx714" name="idx714"></a><a id="idx715" name="idx715"></a><a id="idx716" name="idx716"></a><a id="idx717" name="idx717"></a>
|
|
<p>Expressions within parentheses are evaluated first. When the order of evaluation
|
|
is not specified by parentheses, exponentiation is applied after prefix operators
|
|
(such as -, unary minus) and before multiplication and division. Multiplication
|
|
and division are applied before addition and subtraction. Operators at the
|
|
same precedence level are applied from left to right. The following table
|
|
shows the priority of all operators.</p>
|
|
<a name="wq372"></a>
|
|
<table id="wq372" width="100%" summary="" border="1" frame="border" rules="none">
|
|
<thead valign="bottom">
|
|
<tr>
|
|
<th id="wq373" width="20%" align="center" valign="bottom"><span class="bold">Priority</span></th>
|
|
<th id="wq374" width="79%" align="left" valign="bottom"><span class="bold">Operators</span></th>
|
|
</tr>
|
|
</thead>
|
|
<tbody valign="top">
|
|
<tr>
|
|
<td align="center" valign="top" headers="wq373">1</td>
|
|
<td align="left" valign="top" headers="wq374">+, - (when used for signed numeric values)</td>
|
|
</tr>
|
|
<tr>
|
|
<td align="center" valign="top" headers="wq373">2</td>
|
|
<td align="left" valign="top" headers="wq374">**</td>
|
|
</tr>
|
|
<tr>
|
|
<td align="center" valign="top" headers="wq373">3</td>
|
|
<td align="left" valign="top" headers="wq374">*, /, CONCAT, ||</td>
|
|
</tr>
|
|
<tr>
|
|
<td align="center" valign="top" headers="wq373">4</td>
|
|
<td align="left" valign="top" headers="wq374">+, - (when used between two operands)</td>
|
|
</tr>
|
|
</tbody>
|
|
</table>
|
|
<p><span class="italic">Example 1:</span> In this example, the first operation
|
|
is the addition in (SALARY + BONUS) because it is within parenthesis. The
|
|
second operation is multiplication because it is at a higher precedence level
|
|
than the second addition operator and it is to the left of the division operator.
|
|
The third operation is division because it is at a higher precedence level
|
|
than the second addition operator. Finally, the remaining addition is performed.</p>
|
|
<p></p>
|
|
<pre class="cgraphic"> 1.10 * (SALARY + BONUS) + SALARY / :VAR3
|
|
^ ^ ^ ^
|
|
*** *** *** ***
|
|
|2| |1| |4| |3|
|
|
*-* *-* *-* *-*</pre>
|
|
<p><span class="italic">Example 2:</span> In this example, the first operation
|
|
(CONCAT) combines the character strings in the variables YYYYMM and DD into
|
|
a string representing a date. The second operation (-) then subtracts that
|
|
date from the date being processed in DATECOL. The result is a date duration
|
|
that indicates the time elapsed between the two dates.</p>
|
|
<p></p>
|
|
<pre class="cgraphic"> DATECOL - :YYYYMM CONCAT :DD
|
|
^ ^
|
|
*** ***
|
|
|2| |1|
|
|
*-* *-*</pre>
|
|
<a name="caseexp"></a>
|
|
<h3 id="caseexp"><a href="rbafzmst02.htm#ToC_278">CASE expressions</a></h3><a id="idx718" name="idx718"></a><a id="idx719" name="idx719"></a>
|
|
<a href="rbafzmstdatetimearith.htm#syncase"><img src="c.gif" alt="Click to skip syntax diagram" /></a>
|
|
<a name="wq375"></a>
|
|
<div class="fignone" id="wq375">
|
|
<pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn23.htm"
|
|
border="0" /></span><a href="#skipsyn-22"><img src="c.gif" alt="Skip visual syntax diagram"
|
|
border="0" /></a> .-ELSE NULL---------------.
|
|
>>-CASE--+-<span class="italic">searched-when-clause</span>-+--+-------------------------+--END-><
|
|
'-<span class="italic">simple-when-clause</span>---' '-ELSE--<span class="italic">result-expression</span>-'
|
|
|
|
searched-when-clause:
|
|
|
|
.-----------------------------------------------------.
|
|
V |
|
|
|----WHEN--<span class="italic">search-condition</span>--THEN--+-<span class="italic">result-expression</span>-+-+------|
|
|
'-NULL--------------'
|
|
|
|
simple-when-clause:
|
|
|
|
|--<span class="italic">expression</span>--------------------------------------------------->
|
|
|
|
.-----------------------------------------------.
|
|
V |
|
|
>----WHEN--<span class="italic">expression</span>--THEN--+-<span class="italic">result-expression</span>-+-+------------|
|
|
'-NULL--------------'
|
|
|
|
</pre>
|
|
<a name="skipsyn-22" id="skipsyn-22"></a></div>
|
|
<a name="syncase"></a>
|
|
<p id="syncase">CASE expressions allow an expression to be selected based
|
|
on the evaluation of one or more conditions. In general, the value of the <var class="pv">case-expression</var> is the value of the <var class="pv">result-expression</var> following
|
|
the first (leftmost) <var class="pv">when-clause</var> that evaluates to true. If no <var class="pv">when-clause</var> evaluates to true and the ELSE keyword is present then the
|
|
result is the value of the ELSE <var class="pv">result-expression</var> or NULL. If no <var class="pv">when-clause</var> evaluates to true and the ELSE keyword is not present then
|
|
the result is NULL. Note that when a <var class="pv">when-clause</var> evaluates to unknown
|
|
(because of nulls), the <var class="pv">when-clause</var> is not true and hence is treated
|
|
the same way as a <var class="pv">when-clause</var> that evaluates to false.</p>
|
|
<dl class="parml">
|
|
<dt class="bold"><var class="pv">searched-when-clause</var></dt><a id="idx720" name="idx720"></a>
|
|
<dd>Specifies a <var class="pv">search-condition</var> that is applied to each row or
|
|
group of table data presented for evaluation, and the result when that condition
|
|
is true.
|
|
</dd>
|
|
<dt class="bold"><var class="pv">simple-when-clause</var></dt><a id="idx721" name="idx721"></a>
|
|
<dd>Specifies that the value of the <var class="pv">expression</var> prior to the first
|
|
WHEN keyword is tested for equality with the value of the <var class="pv">expression</var> that
|
|
follows each WHEN keyword. It also specifies the result when that condition
|
|
is true.
|
|
<p>The data type of the <var class="pv">expression</var> prior to the first WHEN
|
|
keyword:</p>
|
|
<ul>
|
|
<li>must be compatible with the data types of the <var class="pv">expression</var> that
|
|
follows each WHEN keyword.</li>
|
|
<li>must not include a function that is non-deterministic or has an external
|
|
action.</li></ul>
|
|
</dd>
|
|
<dt class="bold"><var class="pv">result-expression</var> <span class="base">or</span> NULL</dt><a id="idx722" name="idx722"></a>
|
|
<dd>Specifies the value that follows the THEN keyword and ELSE keywords.
|
|
There must be at least one <var class="pv">result-expression</var> in the CASE expression
|
|
with a defined data type. NULL cannot be specified for every case.
|
|
<p>All <var class="pv">result-expressions</var> must have compatible data types, where the attributes
|
|
of the result are determined based on the <a href="rbafzmstopcomb.htm#opcomb">Rules for result data types</a>.</p>
|
|
</dd>
|
|
<dt class="bold"><var class="pv">search-condition</var></dt><a id="idx723" name="idx723"></a>
|
|
<dd>Specifies a condition that is true, false, or unknown about a row or
|
|
group of table data.
|
|
<p>The <var class="pv">search-condition</var> must not include a subquery
|
|
in an EXISTS or IN predicate.</p>
|
|
</dd>
|
|
</dl>
|
|
<p>There are two scalar functions, NULLIF and COALESCE, that are specialized
|
|
to handle a subset of the functionality provided by CASE. The following table
|
|
shows the equivalent expressions using CASE or these functions.</p>
|
|
<a name="truth"></a>
|
|
<table id="truth" width="100%" summary="" border="1" frame="border" rules="all">
|
|
<caption>Table 25. Equivalent CASE Expressions</caption>
|
|
<thead valign="bottom">
|
|
<tr>
|
|
<th id="wq376" width="66%" align="left" valign="bottom">CASE Expression</th>
|
|
<th id="wq377" width="33%" align="left" valign="bottom">Equivalent Expression</th>
|
|
</tr>
|
|
</thead>
|
|
<tbody valign="top">
|
|
<tr>
|
|
<td align="left" valign="bottom" headers="wq376">CASE WHEN e1=e2 THEN NULL ELSE e1 END</td>
|
|
<td align="left" valign="bottom" headers="wq377">NULLIF(e1,e2)</td>
|
|
</tr>
|
|
<tr>
|
|
<td align="left" valign="bottom" headers="wq376">CASE WHEN e1 IS NOT NULL THEN e1 ELSE
|
|
e2 END</td>
|
|
<td align="left" valign="bottom" headers="wq377">COALESCE(e1,e2)</td>
|
|
</tr>
|
|
<tr>
|
|
<td align="left" valign="bottom" headers="wq376">CASE WHEN e1 IS NOT NULL THEN e1 ELSE
|
|
COALESCE(e2,...,eN) END</td>
|
|
<td align="left" valign="bottom" headers="wq377">COALESCE(e1,e2,...,eN)</td>
|
|
</tr>
|
|
</tbody>
|
|
</table>
|
|
<a name="wq378"></a>
|
|
<h4 id="wq378">Examples</h4>
|
|
<ul>
|
|
<li>If the first character of a department number is a division in the organization,
|
|
then a CASE expression can be used to list the full name of the division to
|
|
which each employee belongs:
|
|
<pre class="xmp"> <span class="bold">SELECT</span> EMPNO, LASTNAME,
|
|
<span class="bold">CASE</span> <span class="bold">SUBSTR</span>(WORKDEPT,1,1)
|
|
<span class="bold">WHEN</span> 'A' <span class="bold">THEN</span> 'Administration'
|
|
<span class="bold">WHEN</span> 'B' <span class="bold">THEN</span> 'Human Resources'
|
|
<span class="bold">WHEN</span> 'C' <span class="bold">THEN</span> 'Accounting'
|
|
<span class="bold">WHEN</span> 'D' <span class="bold">THEN</span> 'Design'
|
|
<span class="bold">WHEN</span> 'E' <span class="bold">THEN</span> 'Operations'
|
|
<span class="bold">END</span>
|
|
<span class="bold">FROM</span> EMPLOYEE</pre></li>
|
|
<li>The number of years of education are used in the EMPLOYEE table to give
|
|
the education level. A CASE expression can be used to group these and to show
|
|
the level of education.
|
|
<pre class="xmp"> <span class="bold">SELECT</span> EMPNO, FIRSTNME, MIDINIT, LASTNAME,
|
|
<span class="bold">CASE</span>
|
|
<span class="bold">WHEN</span> EDLEVEL < 15 <span class="bold">THEN</span> 'SECONDARY'
|
|
<span class="bold">WHEN</span> EDLEVEL < 19 <span class="bold">THEN</span> 'COLLEGE'
|
|
<span class="bold">ELSE</span> 'POST GRADUATE'
|
|
<span class="bold">END</span>
|
|
<span class="bold">FROM</span> EMPLOYEE</pre></li><a id="idx724" name="idx724"></a>
|
|
<li>Another interesting example of CASE statement usage is in protecting from
|
|
division by 0 errors. For example, the following code finds the employees
|
|
who earn more than 25% of their income from commission, but who are not fully
|
|
paid on commission:
|
|
<pre class="xmp"> <span class="bold">SELECT</span> EMPNO, WORKDEPT, SALARY+COMM
|
|
<span class="bold">FROM</span> EMPLOYEE
|
|
<span class="bold">WHERE (CASE WHEN</span> SALARY=0 <span class="bold">THEN NULL</span>
|
|
<span class="bold"> ELSE</span> COMM/SALARY
|
|
<span class="bold"> END)</span> > 0.25
|
|
</pre></li>
|
|
<li>The following CASE expressions are equivalent:
|
|
<pre class="xmp"> <span class="bold">SELECT</span> LASTNAME,
|
|
<span class="bold">CASE</span>
|
|
<span class="bold">WHEN</span> LASTNAME = 'Haas' <span class="bold">THEN</span> 'President'
|
|
<span class="bold">...</span>
|
|
<span class="bold">ELSE</span> 'Unknown'
|
|
<span class="bold">END</span>
|
|
<span class="bold">FROM</span> EMPLOYEE
|
|
|
|
<span class="bold">SELECT</span> LASTNAME,
|
|
<span class="bold">CASE</span> LASTNAME
|
|
<span class="bold">WHEN</span> 'Haas' <span class="bold">THEN</span> 'President'
|
|
<span class="bold">...</span>
|
|
<span class="bold">ELSE</span> 'Unknown'
|
|
<span class="bold">END</span>
|
|
<span class="bold">FROM</span> EMPLOYEE
|
|
</pre></li></ul>
|
|
<a name="cast"></a>
|
|
<h3 id="cast"><a href="rbafzmst02.htm#ToC_280">CAST specification</a></h3><a id="idx725" name="idx725"></a><a id="idx726" name="idx726"></a>
|
|
<a href="rbafzmstdatetimearith.htm#syncast"><img src="c.gif" alt="Click to skip syntax diagram" /></a>
|
|
<pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn24.htm"
|
|
border="0" /></span><a href="#skipsyn-23"><img src="c.gif" alt="Skip visual syntax diagram"
|
|
border="0" /></a>>>-CAST--(--+-<span class="italic">expression</span>-------+--AS--<span class="italic">data-type</span>--)-------------><
|
|
+-NULL-------------+
|
|
'-<span class="italic">parameter-marker</span>-'
|
|
|
|
data-type:
|
|
|
|
|--+-<span class="italic">built-in-type</span>-+--------------------------------------------|
|
|
'-<span class="italic">distinct-type</span>-'
|
|
|
|
</pre>
|
|
<a name="skipsyn-23" id="skipsyn-23"></a>
|
|
<a name="wq379"></a>
|
|
<div class="fignone" id="wq379">
|
|
<pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn25.htm"
|
|
border="0" /></span><a href="#skipsyn-24"><img src="c.gif" alt="Skip visual syntax diagram"
|
|
border="0" /></a>built-in-type:
|
|
|
|
|--+-+---SMALLINT---+-----------------------------------------------------------------+--|
|
|
| +-+-INTEGER-+--+ |
|
|
| | '-INT-----' | |
|
|
| '---BIGINT-----' |
|
|
| .-(5,0)------------------------. |
|
|
+-+-+-DECIMAL-+-+--+------------------------------+--------------------------------+
|
|
| | '-DEC-----' | | .-,0--------. | |
|
|
| '-NUMERIC-----' '-(--<span class="italic">integer</span>--+-----------+--)-' |
|
|
| '-<span class="italic">, integer</span>-' |
|
|
| .-(--53--)------. |
|
|
+-+-FLOAT--+---------------+-+-----------------------------------------------------+
|
|
| | '-(--<span class="italic">integer</span>--)-' | |
|
|
| +-REAL---------------------+ |
|
|
| | .-PRECISION-. | |
|
|
| '-DOUBLE--+-----------+----' |
|
|
| .-(--1--)-------. |
|
|
+-+-+-+-CHARACTER-+--+---------------+----------+--+----------------+------------+-+
|
|
| | | '-CHAR------' '-(--<span class="italic">integer</span>--)-' | +-FOR BIT DATA---+ | |
|
|
| | '-+-+-CHARACTER-+--VARYING-+--(--<span class="italic">integer</span>--)-' +-FOR SBCS DATA--+ | |
|
|
| | | '-CHAR------' | +-FOR MIXED DATA-+ | |
|
|
| | '-VARCHAR----------------' '-<span class="italic">ccsid-clause</span>---' | |
|
|
| | .-(--1M--)-------------. | |
|
|
| '---+-CLOB-------------------+----+----------------------+--+----------------+-' |
|
|
| +-CHAR LARGE OBJECT------+ '-(--<span class="italic">integer</span>--+---+--)-' +-FOR SBCS DATA--+ |
|
|
| '-CHARACTER LARGE OBJECT-' +-K-+ +-FOR MIXED DATA-+ |
|
|
| +-M-+ '-<span class="italic">ccsid-clause</span>---' |
|
|
| '-G-' |
|
|
| .-(--1--)-------. |
|
|
+-+---GRAPHIC----+---------------+-------+--+--------------+-----------------------+
|
|
| | '-(--<span class="italic">integer</span>--)-' | '-<span class="italic">ccsid-clause</span>-' |
|
|
| +-+-GRAPHIC VARYING-+--(--<span class="italic">integer</span>--)---+ |
|
|
| | '-VARGRAPHIC------' | |
|
|
| | .-(--1M--)-------------. | |
|
|
| '---DBCLOB----+----------------------+-' |
|
|
| '-(--<span class="italic">integer</span>--+---+--)-' |
|
|
| +-K-+ |
|
|
| +-M-+ |
|
|
| '-G-' |
|
|
| .-(--1--)-------. |
|
|
+-+-+-BINARY--+---------------+---------+-----------------+------------------------+
|
|
| | | '-(--<span class="italic">integer</span>--)-' | | |
|
|
| | '-+-BINARY VARYING-+--(--<span class="italic">integer</span>--)-' | |
|
|
| | '-VARBINARY------' | |
|
|
| | .-(--1M--)-------------. | |
|
|
| '---+-BLOB----------------+----+----------------------+-' |
|
|
| '-BINARY LARGE OBJECT-' '-(--<span class="italic">integer</span>--+---+--)-' |
|
|
| +-K-+ |
|
|
| +-M-+ |
|
|
| '-G-' |
|
|
+-+-DATE-------------------+-------------------------------------------------------+
|
|
| | .-(--0--)-. | |
|
|
| +-TIME--+---------+------+ |
|
|
| | .-(--6--)-. | |
|
|
| '-TIMESTAMP--+---------+-' |
|
|
| .-(--200--)-----. |
|
|
+-----DATALINK--+---------------+--+--------------+--------------------------------+
|
|
| '-(--<span class="italic">integer</span>--)-' '-<span class="italic">ccsid-clause</span>-' |
|
|
'---ROWID--------------------------------------------------------------------------'
|
|
|
|
ccsid-clause:
|
|
|
|
.-NOT NORMALIZED-.
|
|
|--CCSID--<span class="italic">integer</span>--+----------------+---------------------------|
|
|
'-NORMALIZED-----'
|
|
|
|
</pre>
|
|
<a name="skipsyn-24" id="skipsyn-24"></a></div>
|
|
<a name="syncast"></a>
|
|
<p id="syncast">The CAST specification returns the cast operand (the first
|
|
operand) cast to the type specified by the <var class="pv">data-type</var>. If the data
|
|
type of either operand is a distinct type, the privileges held by the authorization
|
|
ID of the statement must include USAGE authority on the distinct type. </p>
|
|
<dl class="parml">
|
|
<dt class="bold"><var class="pv">expression</var></dt>
|
|
<dd>Specifies that the cast operand is an expression other than NULL or
|
|
a parameter marker. The result is the argument value converted to the specified
|
|
target data type.
|
|
<p>The supported casts are shown in <a href="rbafzmstcastdt.htm#opcast">Table 13</a>, where the first column represents the data type of the cast
|
|
operand (source data type) and the data types across the top represent the
|
|
target data type of the CAST specification. If the cast is not supported,
|
|
an error is returned.</p>
|
|
<p>When casting character or graphic strings to a
|
|
character or graphic string with a different length, a warning is returned
|
|
if truncation of other than trailing blanks occurs.</p>
|
|
</dd>
|
|
<dt class="bold">NULL</dt><a id="idx727" name="idx727"></a>
|
|
<dd>Specifies that the cast operand is the null value. The result is a null
|
|
value that has the specified <var class="pv">data-type</var>.
|
|
</dd>
|
|
<dt class="bold"><var class="pv">parameter-marker</var></dt><a id="idx728" name="idx728"></a><a id="idx729" name="idx729"></a><a id="idx730" name="idx730"></a>
|
|
<dd>A parameter marker (specified as a question mark character) is normally
|
|
considered an expression, but is documented separately in this case because
|
|
it has a special meaning. If the cast operand is a <var class="pv">parameter-marker</var>,
|
|
the specified <var class="pv">data-type</var> is considered a promise that the replacement
|
|
will be assignable to the specified <var class="pv">data-type</var> (using storage assignment
|
|
rules, see <a href="rbafzmstch2bas.htm#ch2bas">Assignments and comparisons</a>). Such a parameter marker is called a <var class="pv">typed parameter marker</var>. Typed parameter markers will be treated like
|
|
any other typed value for the purpose of DESCRIBE of a select list or for
|
|
column assignment.
|
|
</dd>
|
|
<dt class="bold"><var class="pv">data-type</var> </dt><a id="idx731" name="idx731"></a>
|
|
<dd>Specifies the data type of the result. If the data type is not qualified,
|
|
the SQL path is used to find the appropriate data type. For more information,
|
|
see <a href="rbafzmstch2nam.htm#qualun2">Unqualified function, procedure, specific, and distinct type names</a>. For a description of <span class="italic">data-type</span>, see <a href="rbafzmsthctabl.htm#hctabl">CREATE TABLE</a>. (For portability across operating systems,
|
|
when specifying a floating-point data type, use REAL or DOUBLE instead of
|
|
FLOAT.)
|
|
<p>Restrictions on the supported data types are based on the specified
|
|
cast operand.</p>
|
|
<ul>
|
|
<li>For a cast operand that is an <var class="pv">expression</var>, see <a href="rbafzmstcastdt.htm#opcast">Table 13</a> for the target data types that are supported based on the data
|
|
type of the cast operand.</li>
|
|
<li>For a cast operand that is the keyword NULL, the target data type can
|
|
be any data type.</li>
|
|
<li>For a cast operand that is a parameter marker, the target data type can
|
|
be any data type. If the data type is a distinct type, the application that
|
|
uses the parameter marker will use the source data type of the distinct type.</li></ul>
|
|
<p>If the CCSID attribute is not specified, then:</p>
|
|
<ul>
|
|
<li>If the <span class="italic">data-type</span> is BINARY, VARBINARY, or BLOB,
|
|
a CCSID of 65535 is used.</li>
|
|
<li>If FOR BIT DATA is specified, a CCSID of 65535 is used.</li>
|
|
<li>If the <var class="pv">expression</var> is a character or graphic string, and the <span class="italic">data-type</span> is CHAR, VARCHAR, or CLOB:
|
|
<ul>
|
|
<li>If FOR SBCS DATA is specified, the single-byte CCSID associated with the
|
|
CCSID of the <var class="pv">expression</var> is used.</li>
|
|
<li>If FOR MIXED DATA is specified, the mixed-byte CCSID associated with the
|
|
CCSID of the <var class="pv">expression</var> is used.</li>
|
|
<li>Otherwise, the CCSID of the <var class="pv">expression</var> is used.</li></ul></li>
|
|
<li>If the <var class="pv">expression</var> is a character or graphic string, and the <span class="italic">data-type</span> is GRAPHIC, VARGRAPHIC, or DBCLOB; the double-byte
|
|
CCSID associated with the CCSID of the <var class="pv">expression</var> is used.</li>
|
|
<li>Otherwise, the default CCSID of the current server is used.</li></ul>
|
|
<p>If the CCSID attribute is specified, the data will converted to
|
|
that CCSID. If NORMALIZED is specified, the data will be normalized.</p>
|
|
</dd>
|
|
</dl>
|
|
<p>For information on which casts between data types are supported and the
|
|
rules for casting to a data type see <a href="rbafzmstcastdt.htm#castdt">Casting between data types</a>.</p>
|
|
<a name="wq380"></a>
|
|
<h4 id="wq380">Examples</h4>
|
|
<ul>
|
|
<li>An application is only interested in the integer portion of the SALARY
|
|
column (defined as DECIMAL(9,2)) from the EMPLOYEE table. The following CAST
|
|
specification will convert the SALARY column to INTEGER.
|
|
<pre class="xmp"><span class="bold">SELECT</span> EMPNO, <span class="bold">CAST(</span>SALARY <span class="bold">AS</span> INTEGER)
|
|
<span class="bold">FROM</span> EMPLOYEE </pre></li>
|
|
<li>Assume that two distinct types exist. T_AGE was sourced on SMALLINT and
|
|
is the data type for the AGE column in the PERSONNEL table. R_YEAR was sourced
|
|
on INTEGER and is the data type for the RETIRE_YEAR column in the same table.
|
|
The following UPDATE statement could be prepared.
|
|
<pre class="xmp"><span class="bold">UPDATE</span> PERSONNEL <span class="bold">SET</span> RETIRE_YEAR <span class="bold">= ?</span>
|
|
<span class="bold">WHERE</span> AGE = <span class="bold">CAST( ? AS</span> T_AGE <span class="bold">)</span> </pre>
|
|
<p>The first parameter is an untyped parameter marker
|
|
that would have a data type of R_YEAR. An explicit CAST specification is not
|
|
required in this case because the parameter marker value is assigned to the
|
|
distinct type.</p>
|
|
<p>The second parameter marker is a typed parameter marker
|
|
that is cast to distinct type T_AGE. An explicit CAST specification is required
|
|
in this case because the parameter marker value is compared to the distinct
|
|
type.</p></li></ul>
|
|
<a name="olapexp"></a>
|
|
<h3 id="olapexp"><a href="rbafzmst02.htm#ToC_282">OLAP specifications</a></h3><a id="idx732" name="idx732"></a><a id="idx733" name="idx733"></a>
|
|
<a href="rbafzmstdatetimearith.htm#synolap"><img src="c.gif" alt="Click to skip syntax diagram" /></a>
|
|
<a name="wq381"></a>
|
|
<div class="fignone" id="wq381">
|
|
<pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn26.htm"
|
|
border="0" /></span><a href="#skipsyn-25"><img src="c.gif" alt="Skip visual syntax diagram"
|
|
border="0" /></a>OLAP-specification:
|
|
|
|
|--+-<span class="italic">ranking-specification</span>---+----------------------------------|
|
|
'-<span class="italic">numbering-specification</span>-'
|
|
|
|
ranking-specification:
|
|
|
|
|--+-RANK-------+--(--)--OVER--(--+-------------------------+--<span class="italic">window-order-clause</span>--)--|
|
|
'-DENSE_RANK-' '-<span class="italic">window-partition-clause</span>-'
|
|
|
|
numbering-specification:
|
|
|
|
|--ROW_NUMBER--(--)--OVER--(--+-------------------------+--+---------------------+--)--|
|
|
'-<span class="italic">window-partition-clause</span>-' '-<span class="italic">window-order-clause</span>-'
|
|
|
|
window-partition-clause:
|
|
|
|
.-,-----------------------.
|
|
V |
|
|
|--PARTITION BY----<span class="italic">partitioning-expression</span>-+--------------------|
|
|
|
|
window-order-clause:
|
|
|
|
|--ORDER BY----------------------------------------------------->
|
|
|
|
.-,--------------------------------------------------.
|
|
| .-NULLS LAST-. |
|
|
V .-ASC--+------------+---. |
|
|
>----+-<span class="italic">sort-key-expression</span>--+-----------------------+-+-+-------|
|
|
| +-ASC NULLS FIRST-------+ |
|
|
| | .-NULLS FIRST-. | |
|
|
| +-DESC--+-------------+-+ |
|
|
| '-DESC NULLS LAST-------' |
|
|
'-ORDER OF--<span class="italic">table-designator</span>---------------------'
|
|
|
|
</pre>
|
|
<a name="skipsyn-25" id="skipsyn-25"></a></div>
|
|
<a name="synolap"></a>
|
|
<p id="synolap">On-Line Analytical Processing (OLAP) specifications
|
|
provide the ability to return ranking, row numbering, and existing aggregate
|
|
function information as a scalar value in a query result. An OLAP specification
|
|
can be included in an expression in a <var class="pv">select-list</var> or the ORDER BY
|
|
clause of a <var class="pv">select-statement</var>. The query result to which the OLAP
|
|
specification is applied is the result table of the innermost subselect that
|
|
includes the OLAP specification.</p>
|
|
<p>An OLAP specification is not valid in a WHERE, VALUES, GROUP
|
|
BY, HAVING, or SET clause, and an OLAP specification is not valid in the JOIN
|
|
ON <var class="pv">join-condition</var>. An OLAP specification cannot be used as an argument
|
|
of an aggregate function.</p>
|
|
<p>When invoking an OLAP specification, a window is
|
|
specified that defines the rows over which the function is applied, and in
|
|
what order. When used with an aggregate function, the applicable rows can
|
|
be further refined, relative to the current row, as either a range or a number
|
|
of rows preceding and following the current row. For example, within a partition
|
|
by month, an average can be calculated over the previous three month period.</p>
|
|
<p>The data type of the result of RANK, DENSE_RANK, or ROW_NUMBER is BIGINT.
|
|
The result cannot be null.</p>
|
|
<dl class="parml">
|
|
<dt class="bold">RANK <span>or</span> DENSE_RANK</dt>
|
|
<dd>Specifies that the ordinal rank of a row within the window is to be
|
|
computed. Rows that are not distinct with respect to the ordering within
|
|
their window are assigned the same rank. The results of ranking may be defined
|
|
with or without gaps in the numbers resulting from duplicate values.
|
|
<dl class="parml">
|
|
<dt class="bold">RANK</dt><a id="idx734" name="idx734"></a>
|
|
<dd>Specifies that the rank of a row is defined as 1 plus the number of
|
|
rows that strictly precede the row. Thus, if two or more rows are not distinct
|
|
with respect to the ordering, then there will be one or more gaps in the sequential
|
|
rank numbering.
|
|
</dd>
|
|
<dt class="bold">DENSE_RANK</dt><a id="idx735" name="idx735"></a>
|
|
<dd>Specifies that the rank of a row is defined as 1 plus the number of
|
|
preceding rows that are distinct with respect to the ordering. Therefore,
|
|
there will be no gaps in the sequential rank numbering.
|
|
</dd>
|
|
</dl>
|
|
</dd>
|
|
<dt class="bold">ROW_NUMBER</dt><a id="idx736" name="idx736"></a>
|
|
<dd>Specifies that a sequential row number is to be computed for the row
|
|
within the window defined by the ordering, starting with 1 for the first row.
|
|
If the ORDER BY clause is not specified in the window, the row numbers are
|
|
assigned to the rows in arbitrary order, as returned by the subselect (not
|
|
according to any ORDER BY clause in the (<var class="pv">select-statement</var>).
|
|
</dd>
|
|
<dt class="bold">PARTITION BY <var class="pv">(partitioning-expression,...)</var></dt><a id="idx737" name="idx737"></a>
|
|
<dd>Defines the partition within which the function is applied. A <var class="pv">partitioning-expression</var> is an expression used in defining the partitioning of the result set.
|
|
Each column name referenced in a <var class="pv">partitioning-expression</var> must unambiguously
|
|
reference a result set column of the OLAP specification subselect statement.
|
|
A <var class="pv">partitioning-expression</var> cannot include a <var class="pv">scalar-fullselect</var> or any function that is not deterministic or has an external action.
|
|
</dd>
|
|
<dt class="bold">ORDER BY <var class="pv">(sort-key-expression,...)</var></dt><a id="idx738" name="idx738"></a>
|
|
<dd>Defines the ordering of rows within a partition that determines the
|
|
value of the OLAP specification (it does not define the ordering of the query
|
|
result set).
|
|
</dd>
|
|
<dt class="bold"><var class="pv">sort-key-expression</var></dt><a id="idx739" name="idx739"></a>
|
|
<dd>An expression used in defining the ordering of the rows within a window
|
|
partition. Each column name referenced in a <var class="pv">sort-key-expression</var> must
|
|
unambiguously reference a column of the result set of the subselect, including
|
|
the OLAP specification. A <var class="pv">sort-key-expression</var> cannot include a <var class="pv">scalar-fullselect</var> or any function that is not deterministic or that has
|
|
an external action. This clause is required for the RANK and DENSE_RANK functions.
|
|
</dd>
|
|
<dt class="bold">ASC</dt><a id="idx740" name="idx740"></a>
|
|
<dd>Uses the values of the <var class="pv">sort-key-expression</var> in ascending order.
|
|
</dd>
|
|
<dt class="bold">DESC</dt><a id="idx741" name="idx741"></a>
|
|
<dd>Uses the values of the <var class="pv">sort-key-expression</var> in descending order.
|
|
</dd>
|
|
<dt class="bold">NULLS FIRST</dt><a id="idx742" name="idx742"></a>
|
|
<dd>The window ordering considers null values before all non-null values
|
|
in the sort order.
|
|
</dd>
|
|
<dt class="bold">NULLS LAST</dt><a id="idx743" name="idx743"></a>
|
|
<dd>The window ordering considers null values after all non-null values
|
|
in the sort order.
|
|
</dd>
|
|
<dt class="bold">ORDER OF <var class="pv">table-designator</var></dt><a id="idx744" name="idx744"></a>
|
|
<dd>Specifies that the same ordering used in <var class="pv">table-designator</var> should
|
|
be applied to the result table of the subselect. There must be a table reference
|
|
matching <var class="pv">table-designator</var> in the FROM clause of the subselect that
|
|
specifies this clause and the table reference must identify a <var class="pv">nested-table-expression</var> or <var class="pv">common-table-expression</var>. The subselect (or fullselect) corresponding
|
|
to the specified <var class="pv">table-designator</var> must include an ORDER BY clause
|
|
that is dependent on the data. The ordering that is applied is the same as
|
|
if the columns of the ORDER BY clause in the nested subselect (or fullselect)
|
|
were included in the outer subselect (or fullselect), and these columns were
|
|
specified in place of the ORDER OF clause.
|
|
</dd>
|
|
</dl>
|
|
<p>An OLAP specification is not allowed if the query specifies:</p>
|
|
<ul>
|
|
<li>lateral correlation,</li>
|
|
<li>a sort sequence,</li>
|
|
<li>an operation that requires CCSID conversion,</li>
|
|
<li>a UTF-8 or UTF-16 argument in a CHARACTER_LENGTH, POSITION, or SUBSTRING
|
|
scalar function,</li>
|
|
<li>a distributed table,</li>
|
|
<li>a table with a read trigger, or</li>
|
|
<li>a logical file built over multiple physical file members.</li></ul>
|
|
<a name="wq382"></a>
|
|
<h4 id="wq382">Notes</h4>
|
|
<p><span class="bold">Syntax alternatives:</span> DENSERANK can be specified in
|
|
place of DENSE_RANK, and ROWNUMBER can be specified in place of ROW_NUMBER.</p>
|
|
<a name="wq383"></a>
|
|
<h4 id="wq383">Examples</h4>
|
|
<ul>
|
|
<li>Display the ranking of employees, in order by surname, according to their
|
|
total salary (based on salary plus bonus) that have a total salary more than
|
|
$30,000:
|
|
<pre class="xmp"> <span class="bold">SELECT</span> EMPNO, LASTNAME, FIRSTNME, SALARY+BONUS AS TOTAL_SALARY,
|
|
<span class="bold">RANK() OVER (ORDER BY</span> SALARY+BONUS <span class="bold">DESC) AS</span> RANK_SALARY
|
|
<span class="bold">FROM</span> EMPLOYEE
|
|
<span class="bold">WHERE</span> SALARY+BONUS > 30000
|
|
<span class="bold">ORDER BY</span> LASTNAME</pre>Note that
|
|
if the result is to be ordered by the ranking, then replace ORDER BY LASTNAME
|
|
with:
|
|
<pre class="xmp"> <span class="bold">ORDER BY</span> RANK_SALARY</pre>or:
|
|
<pre class="xmp"> <span class="bold">ORDER BY RANK() OVER (ORDER BY</span> SALARY+BONUS <span class="bold">DESC)</span></pre></li>
|
|
<li>Rank the departments according to their average total salary:
|
|
<pre class="xmp"> <span class="bold">SELECT</span> WORKDEPT, <span class="bold">AVG(</span>SALARY+BONUS<span class="bold">) AS</span> AVG_TOTAL_SALARY,
|
|
<span class="bold">RANK() OVER (ORDER BY AVG(</span> SALARY+BONUS<span class="bold">) DESC) AS</span> RANK_AVG_SAL
|
|
<span class="bold">FROM</span> EMPLOYEE
|
|
<span class="bold">GROUP BY</span> WORKDEPT
|
|
<span class="bold">ORDER BY</span> RANK_AVG_SAL</pre></li>
|
|
<li>Rank the employees within a department according to their education level.
|
|
Having multiple employees with the same rank in the department should not
|
|
increase the next ranking value:
|
|
<pre class="xmp"> <span class="bold">SELECT</span> WORKDEPT, EMPNO, LASTNAME, FIRSTNME, EDLEVEL,
|
|
<span class="bold">DENSE_RANK() OVER (PARTITION BY</span> WORKDEPT <span class="bold">ORDER BY</span> EDLEVEL <span class="bold">DESC) AS</span> RANK_EDLEVEL
|
|
<span class="bold">FROM</span> EMPLOYEE
|
|
<span class="bold">ORDER BY</span> WORKDEPT, LASTNAME
|
|
</pre></li>
|
|
<li>Provide row numbers in the result of a query:
|
|
<pre class="xmp"> <span class="bold">SELECT ROW_NUMBER() OVER (ORDER BY</span> WORKDEPT, LASTNAME <span class="bold">) AS</span> NUMBER,
|
|
LASTNAME, SALARY
|
|
<span class="bold">FROM</span> EMPLOYEE
|
|
<span class="bold">ORDER BY</span> WORKDEPT, LASTNAME</pre></li>
|
|
<li>List the top five wage earners:
|
|
<pre class="xmp"> <span class="bold">SELECT</span> EMPNO, LASTNAME, FIRSTNME, TOTAL_SALARY, RANK_SALARY
|
|
<span class="bold">FROM (SELECT</span> EMPNO, LASTNAME, FIRSTNME, SALARY+BONUS <span class="bold">AS</span> TOTAL_SALARY,
|
|
<span class="bold">RANK() OVER (ORDER BY</span> SALARY+BONUS <span class="bold">DESC) AS</span> RANK_SALARY
|
|
<span class="bold">FROM</span> EMPLOYEE<span class="bold">) AS</span> RANKED_EMPLOYEE
|
|
<span class="bold">WHERE</span> RANK_SALARY < 6
|
|
<span class="bold">ORDER BY</span> RANK_SALARY </pre>Note
|
|
that a nested table expression was used to first compute the result, including
|
|
the rankings, before the rank could be used in the WHERE clause. A common
|
|
table expression could also have been used.</li></ul>
|
|
<a name="seqref"></a>
|
|
<h3 id="seqref"><a href="rbafzmst02.htm#ToC_285">Sequence reference</a></h3><a id="idx745" name="idx745"></a><a id="idx746" name="idx746"></a><a id="idx747" name="idx747"></a><a id="idx748" name="idx748"></a>
|
|
<a href="rbafzmstdatetimearith.htm#syncase"><img src="c.gif" alt="Click to skip syntax diagram" /></a>
|
|
<a name="wq384"></a>
|
|
<div class="fignone" id="wq384">
|
|
<pre class="cgraphic"><span><img src="c.gif" alt="Read syntax diagram" longdesc="rbafzmstsyn27.htm"
|
|
border="0" /></span><a href="#skipsyn-26"><img src="c.gif" alt="Skip visual syntax diagram"
|
|
border="0" /></a>sequence-reference:
|
|
|
|
|--+-<span class="italic">nextval-expression</span>-+---------------------------------------|
|
|
'-<span class="italic">prevval-expression</span>-'
|
|
|
|
nextval-expression:
|
|
|
|
|--NEXT VALUE--FOR--<span class="italic">sequence-name</span>-------------------------------|
|
|
|
|
prevval-expression:
|
|
|
|
|--PREVIOUS VALUE--FOR--<span class="italic">sequence-name</span>---------------------------|
|
|
|
|
</pre>
|
|
<a name="skipsyn-26" id="skipsyn-26"></a></div>
|
|
<p>A sequence is referenced by using the NEXT VALUE and PREVIOUS VALUE expressions
|
|
specifying the name of the sequence.</p>
|
|
<dl class="parml">
|
|
<dt class="bold"><var class="pv">nextval-expression</var></dt><a id="idx749" name="idx749"></a>
|
|
<dd>A NEXT VALUE expression generates and returns the next value for a specified
|
|
sequence. A new value is generated for a sequence when a NEXT VALUE expression
|
|
specifies the name of the sequence. However, if there are multiple instances
|
|
of a NEXT VALUE expression specifying the same sequence name within a query,
|
|
the sequence value is incremented only once for each row of the result, and
|
|
all instances of NEXT VALUE return the same value for a row of the result.
|
|
NEXT VALUE is a non-deterministic expression with external actions since it
|
|
causes the sequence value to be incremented.
|
|
<p>When the next value for the
|
|
sequence is generated, if the maximum value for an ascending sequence or the
|
|
minimum value for a descending sequence of the logical range of the sequence
|
|
is exceeded and the NO CYCLE option is in effect, then an error is returned.</p>
|
|
<p>The data type and length attributes of the result of a NEXT VALUE expression
|
|
are the same as for the specified sequence. The result cannot be null.</p>
|
|
</dd>
|
|
<dt class="bold"><var class="pv">prevval-expression</var></dt><a id="idx750" name="idx750"></a>
|
|
<dd>A PREVIOUS VALUE expression returns the most recently generated value
|
|
for the specified sequence for a previous statement within the current application
|
|
process. This value can be repeatedly referenced by using PREVIOUS VALUE expressions
|
|
and specifying the name of the sequence. There may be multiple instances of
|
|
PREVIOUS VALUE expressions specifying the same sequence name within a single
|
|
statement and they all return the same value.
|
|
<p>A PREVIOUS VALUE expression
|
|
can be used only if a NEXT VALUE expression specifying the same sequence name
|
|
has already been referenced in the current application process.</p>
|
|
<p>The
|
|
data type and length attributes of the result of a PREVIOUS VALUE expression
|
|
are the same as for the specified sequence. The result cannot be null.</p>
|
|
</dd>
|
|
<dt class="bold"><var class="pv">sequence-name</var></dt><a id="idx751" name="idx751"></a>
|
|
<dd>Identifies the sequence to be referenced. The <var class="pv">sequence-name</var> must
|
|
identify a sequence that exists at the current server.
|
|
</dd>
|
|
</dl>
|
|
<a name="wq385"></a>
|
|
<h4 id="wq385">Notes</h4>
|
|
<p><span class="bold">Authorization:</span> If a sequence is referenced in a statement,
|
|
the privileges held by the authorization ID of the statement must include
|
|
at least one of the following:</p>
|
|
<ul>
|
|
<li>For the sequence identified in the statement,
|
|
<ul>
|
|
<li>The USAGE privilege on the sequence, and</li>
|
|
<li>The system authority *EXECUTE on the library containing the sequence</li></ul></li>
|
|
<li>Administrative authority</li></ul>
|
|
<p>For information on the system authorities corresponding to SQL privileges,
|
|
see <a href="rbafzmstgntseqp.htm#eqtables">Corresponding System Authorities When Checking Privileges to a Sequence</a>.</p>
|
|
<p><span class="bold">Generating values with NEXT VALUE:</span> When a value is
|
|
generated for a sequence, that value is consumed, and the next time that a
|
|
value is requested, a new value will be generated. This is true even when
|
|
the statement containing the NEXT VALUE expression fails or is rolled back.</p>
|
|
<p><span class="bold">Scope of PREVIOUS VALUE:</span> The PREVIOUS
|
|
VALUE value persists until the next value is generated for the sequence in
|
|
the current session, the sequence is dropped or altered, or the application
|
|
session ends. The value is unaffected by COMMIT or ROLLBACK statements.</p>
|
|
<p><span class="bold">Use as a Unique Key Value:</span> The same sequence number
|
|
can be used as a unique key value in two separate tables by referencing the
|
|
sequence number with a NEXT VALUE expression for the first row (this generates
|
|
the sequence value), and a PREVIOUS VALUE expression for the other rows (the
|
|
instance of PREVIOUS VALUE refers to the sequence value most recently generated
|
|
in the current session), as shown below:</p>
|
|
<pre class="xmp"> <span class="bold">INSERT INTO</span> ORDER <span class="bold">(</span>ORDERNO, CUSTNO<span class="bold">)</span>
|
|
<span class="bold">VALUES (NEXT VALUE FOR</span> ORDER_SEQ, 123456<span class="bold">)</span>
|
|
|
|
<span class="bold">INSERT INTO</span> LINE_ITEM <span class="bold">(</span>ORDERNO, PARTNO, QUANTITY<span class="bold">)</span>
|
|
<span class="bold">VALUES (PREVIOUS VALUE FOR</span> ORDER_SEQ, 987654, 1<span class="bold">)</span></pre>
|
|
<p><span class="bold">Allowed use of NEXT VALUE and PREVIOUS VALUE:</span> NEXT
|
|
VALUE and PREVIOUS VALUE expressions can be specified in the following places: </p>
|
|
<ul>
|
|
<li>Within the the <var class="pv">select-clause</var> of a SELECT statement or SELECT
|
|
INTO statement as long as the statement does not contain a DISTINCT keyword,
|
|
a GROUP BY clause, an ORDER BY clause, a UNION keyword, an INTERSECT keyword,
|
|
or EXCEPT keyword</li>
|
|
<li>Within a VALUES clause of an INSERT statement</li>
|
|
<li>Within the <var class="pv">select-clause</var> of the fullselect of an INSERT statement</li>
|
|
<li>Within the SET clause of a searched or positioned UPDATE statement, though
|
|
NEXT VALUE cannot be specified in the <var class="pv">select-clause</var> of the subselect
|
|
of an expression in the SET clause
|
|
<p>A PREVIOUS VALUE expression
|
|
can be specified anywhere within a SET clause of an UPDATE statement, but
|
|
a NEXT VALUE expression can be specified only in a SET clause if it is not
|
|
within the <var class="pv">select-clause</var> of the fullselect of an expression. For
|
|
example, the following uses of sequence expressions are supported:</p>
|
|
<pre class="xmp"> <span class="bold">UPDATE</span> T <span class="bold">SET </span>C1 = <span class="bold">(SELECT PREVIOUS VALUE FOR</span> S1 <span class="bold">FROM </span>T<span class="bold">)</span>
|
|
|
|
<span class="bold">UPDATE</span> T <span class="bold">SET </span>C1 = <span class="bold">PREVIOUS VALUE FOR</span> S1
|
|
|
|
<span class="bold">UPDATE</span> T <span class="bold">SET </span>C1 = <span class="bold">NEXT VALUE FOR</span> S1
|
|
</pre><p class="indatacontent">The following use of a sequence expression is not supported:</p>
|
|
<pre class="xmp"> <span class="bold">UPDATE</span> T <span class="bold">SET </span>C1 = <span class="bold">(SELECT NEXT VALUE FOR</span> S1 <span class="bold">FROM </span>T<span class="bold">)</span>
|
|
</pre></li>
|
|
<li>Within an <var class="pv">assignment-statement</var>, except within the <var class="pv">select-clause</var> of the subselect of an expression. The following uses of sequence expressions
|
|
are supported:
|
|
<pre class="xmp"> <span class="bold">SET</span> :ORDERNUM = <span class="bold">NEXT VALUE FOR</span> INVOICE
|
|
|
|
<span class="bold">SET</span> :ORDERNUM = <span class="bold">PREVIOUS VALUE FOR</span> INVOICE
|
|
</pre>The following use of a sequence expression is not supported:
|
|
<pre class="xmp"> <span class="bold">SET</span> :X = <span class="bold">(SELECT NEXT VALUE FOR</span> S1 <span class="bold">FROM </span>T<span class="bold">)</span>
|
|
|
|
<span class="bold">SET</span> :X = <span class="bold">(SELECT PREVIOUS VALUE FOR</span> S1 <span class="bold">FROM </span>T<span class="bold">)</span>
|
|
</pre></li>
|
|
<li>Within a VALUES or VALUES INTO statement though not within
|
|
the <var class="pv">select-clause</var> of the fullselect of an expression</li>
|
|
<li>Within the <var class="pv">SQL-routine-body</var> of a CREATE PROCEDURE statement</li>
|
|
<li>Within the <var class="pv">SQL-routine-body</var> of a CREATE FUNCTION statement</li>
|
|
<li>Within the <var class="pv">SQL-trigger-body</var> of a CREATE TRIGGER statement (PREVIOUS
|
|
VALUE is not allowed)</li></ul>
|
|
<p><span class="bold">Restrictions on the use of NEXT VALUE and PREVIOUS VALUE:</span> NEXT VALUE and PREVIOUS VALUE expressions cannot be specified in the
|
|
following places: </p>
|
|
<ul>
|
|
<li>Within a materialized query table definition in a CREATE TABLE or ALTER
|
|
TABLE statement</li>
|
|
<li>Within a CHECK constraint</li>
|
|
<li>Within a view definition</li></ul><p class="indatacontent">In addition, the NEXT VALUE expression cannot be specified in the following
|
|
places:</p>
|
|
<ul>
|
|
<li>CASE expression</li>
|
|
<li>Parameter list of an aggregate function</li>
|
|
<li>Subquery in a context other than those explicitly allowed</li>
|
|
<li>SELECT statement for which the outer SELECT contains a DISTINCT operator
|
|
or a GROUP BY clause</li>
|
|
<li>SELECT statement for which the outer SELECT is combined with another SELECT
|
|
statement using the UNION, INTERSECT, or EXCEPT operator</li>
|
|
<li>Join condition of a join</li>
|
|
<li>Nested table expression</li>
|
|
<li>Parameter list of a table function</li>
|
|
<li><var class="pv">select-clause</var> of the fullselect of an expression in
|
|
the SET clause of an UPDATE statement</li>
|
|
<li>WHERE clause of the outermost SELECT statement or a DELETE, or UPDATE
|
|
statement</li>
|
|
<li>ORDER BY clause of the outermost SELECT statement</li>
|
|
<li>IF, WHILE, DO . . . UNTIL, or CASE statements in an SQL routine</li></ul>
|
|
<a name="seqrefcsr"></a>
|
|
<p id="seqrefcsr"><span class="bold">Using sequence expressions with a cursor:</span> Normally, a SELECT
|
|
NEXT VALUE FOR ORDER_SEQ FROM T1 would produce a result table containing
|
|
as many generated values from the sequence ORDER_SEQ as the number of rows
|
|
retrieved from T1. A reference to a NEXT VALUE expression in the SELECT statement
|
|
of a cursor refers to a value that is generated for a row of the result table.
|
|
A sequence value is generated for a NEXT VALUE expression each time a row
|
|
is retrieved.</p>
|
|
<p>If blocking is done at a client in a DRDA® environment, sequence values may get
|
|
generated at the DB2® server before the processing of an application's FETCH
|
|
statement. If the client application does not explicitly FETCH all the rows
|
|
that have been retrieved from the database, the application will never see
|
|
all those generated values of the sequence (as many as the rows that were
|
|
not FETCHed). These values may constitute a gap in the sequence.</p>
|
|
<p>A reference to the PREVIOUS VALUE expression in a SELECT statement
|
|
of a cursor is evaluated at OPEN time. In other words, a reference to the
|
|
PREVIOUS VALUE expression in the SELECT statement of a cursor refers to the
|
|
last value generated by this application process for the specified sequence
|
|
prior to the opening of the cursor. Once evaluated at OPEN time, the value
|
|
returned by PREVIOUS VALUE within the body of the cursor will not change from
|
|
FETCH to FETCH, even if NEXT VALUE is invoked within the body of the cursor.
|
|
After the cursor is closed, the value of PREVIOUS VALUE will be the last NEXT
|
|
VALUE generated by the application process.</p>
|
|
<p><span class="bold">Syntax alternatives:</span> The keywords NEXTVAL and PREVVAL
|
|
can be used as alternatives for NEXT VALUE and PREVIOUS VALUE respectively.</p>
|
|
<a name="wq386"></a>
|
|
<h4 id="wq386">Examples</h4>
|
|
<ul>
|
|
<li>Assume that there is a table called ORDER, and that a sequence called
|
|
ORDER_SEQ is created as follows:
|
|
<pre class="xmp"> <span class="bold">CREATE SEQUENCE</span> ORDER_SEQ
|
|
<span class="bold">START WITH</span> 1
|
|
<span class="bold">INCREMENT BY</span> 1
|
|
<span class="bold">NO MAXVALUE</span>
|
|
<span class="bold">NO CYCLE</span>
|
|
<span class="bold">CACHE</span> 24</pre>Following are some
|
|
examples of how to generate an ORDER_SEQ sequence number with a NEXT VALUE
|
|
expression:
|
|
<pre class="xmp"> <span class="bold">INSERT INTO</span> ORDER <span class="bold">(</span>ORDERNO, CUSTNO<span class="bold">)</span>
|
|
<span class="bold">VALUES (NEXT VALUE FOR</span> ORDER_SEQ, 123456<span class="bold">)</span>
|
|
|
|
<span class="bold">UPDATE</span> ORDER
|
|
<span class="bold">SET</span> ORDERNO = <span class="bold">NEXT VALUE FOR</span> ORDER_SEQ
|
|
<span class="bold">WHERE</span> CUSTNO = 123456
|
|
|
|
<span class="bold">VALUES NEXT VALUE FOR</span> ORDER
|
|
<span class="bold">INTO</span> :HV_SEQ
|
|
</pre></li></ul>
|
|
<hr /><br />
|
|
[ <a href="#Top_Of_Page">Top of Page</a> | <a href="rbafzmstch2expr.htm">Previous Page</a> | <a href="rbafzmstch2pred.htm">Next Page</a> | <a href="rbafzmst02.htm#wq1">Contents</a> |
|
|
<a href="rbafzmstindex.htm#index">Index</a> ]
|
|
|
|
<a id="Bot_Of_Page" name="Bot_Of_Page"></a>
|
|
</body>
|
|
</html>
|