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:
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:
Dates can be subtracted, incremented, or decremented.
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.
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).
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.
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.
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.
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.
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:
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:
When adding durations to dates, adding one month to a given date gives the same date one month later unless 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.
Also note that logically equivalent expressions may not produce the same result. For example:
does not produce the same result as
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:
To subtract one year, one month, and one day from a date, specify:
Times can be subtracted, incremented, or decremented.
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.
For example, the result of TIME('11:02:26') - '00:32:56' is 102930 (a duration of 10 hours, 29 minutes, and 30 seconds).
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.
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.
Adding or subtracting a duration of seconds will, of course, affect the seconds portion of the time, and potentially the minutes and hours.
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. TIME1 + X, where "X" is a DECIMAL(6,0) number, is equivalent to the expression:
TIME1 + HOUR(X) HOURS + MINUTE(X) MINUTES + SECOND(X) SECONDS
Timestamps can be subtracted, incremented, or decremented.
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.
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.
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.
Priority | Operators |
---|---|
1 | +, - (when used for signed numeric values) |
2 | ** |
3 | *, /, CONCAT, || |
4 | +, - (when used between two operands) |
Example 1: 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.
1.10 * (SALARY + BONUS) + SALARY / :VAR3 ^ ^ ^ ^ *** *** *** *** |2| |1| |4| |3| *-* *-* *-* *-*
Example 2: 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.
DATECOL - :YYYYMM CONCAT :DD ^ ^ *** *** |2| |1| *-* *-*
.-ELSE NULL---------------. >>-CASE--+-searched-when-clause-+--+-------------------------+--END->< '-simple-when-clause---' '-ELSE--result-expression-' searched-when-clause: .-----------------------------------------------------. V | |----WHEN--search-condition--THEN--+-result-expression-+-+------| '-NULL--------------' simple-when-clause: |--expression---------------------------------------------------> .-----------------------------------------------. V | >----WHEN--expression--THEN--+-result-expression-+-+------------| '-NULL--------------'
CASE expressions allow an expression to be selected based on the evaluation of one or more conditions. In general, the value of the case-expression is the value of the result-expression following the first (leftmost) when-clause that evaluates to true. If no when-clause evaluates to true and the ELSE keyword is present then the result is the value of the ELSE result-expression or NULL. If no when-clause evaluates to true and the ELSE keyword is not present then the result is NULL. Note that when a when-clause evaluates to unknown (because of nulls), the when-clause is not true and hence is treated the same way as a when-clause that evaluates to false.
The data type of the expression prior to the first WHEN keyword:
All result-expressions must have compatible data types, where the attributes of the result are determined based on the Rules for result data types.
The search-condition must not include a subquery in an EXISTS or IN predicate.
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.
CASE Expression | Equivalent Expression |
---|---|
CASE WHEN e1=e2 THEN NULL ELSE e1 END | NULLIF(e1,e2) |
CASE WHEN e1 IS NOT NULL THEN e1 ELSE e2 END | COALESCE(e1,e2) |
CASE WHEN e1 IS NOT NULL THEN e1 ELSE COALESCE(e2,...,eN) END | COALESCE(e1,e2,...,eN) |
SELECT EMPNO, LASTNAME, CASE SUBSTR(WORKDEPT,1,1) WHEN 'A' THEN 'Administration' WHEN 'B' THEN 'Human Resources' WHEN 'C' THEN 'Accounting' WHEN 'D' THEN 'Design' WHEN 'E' THEN 'Operations' END FROM EMPLOYEE
SELECT EMPNO, FIRSTNME, MIDINIT, LASTNAME, CASE WHEN EDLEVEL < 15 THEN 'SECONDARY' WHEN EDLEVEL < 19 THEN 'COLLEGE' ELSE 'POST GRADUATE' END FROM EMPLOYEE
SELECT EMPNO, WORKDEPT, SALARY+COMM FROM EMPLOYEE WHERE (CASE WHEN SALARY=0 THEN NULL ELSE COMM/SALARY END) > 0.25
SELECT LASTNAME, CASE WHEN LASTNAME = 'Haas' THEN 'President' ... ELSE 'Unknown' END FROM EMPLOYEE SELECT LASTNAME, CASE LASTNAME WHEN 'Haas' THEN 'President' ... ELSE 'Unknown' END FROM EMPLOYEE
>>-CAST--(--+-expression-------+--AS--data-type--)------------->< +-NULL-------------+ '-parameter-marker-' data-type: |--+-built-in-type-+--------------------------------------------| '-distinct-type-'
built-in-type: |--+-+---SMALLINT---+-----------------------------------------------------------------+--| | +-+-INTEGER-+--+ | | | '-INT-----' | | | '---BIGINT-----' | | .-(5,0)------------------------. | +-+-+-DECIMAL-+-+--+------------------------------+--------------------------------+ | | '-DEC-----' | | .-,0--------. | | | '-NUMERIC-----' '-(--integer--+-----------+--)-' | | '-, integer-' | | .-(--53--)------. | +-+-FLOAT--+---------------+-+-----------------------------------------------------+ | | '-(--integer--)-' | | | +-REAL---------------------+ | | | .-PRECISION-. | | | '-DOUBLE--+-----------+----' | | .-(--1--)-------. | +-+-+-+-CHARACTER-+--+---------------+----------+--+----------------+------------+-+ | | | '-CHAR------' '-(--integer--)-' | +-FOR BIT DATA---+ | | | | '-+-+-CHARACTER-+--VARYING-+--(--integer--)-' +-FOR SBCS DATA--+ | | | | | '-CHAR------' | +-FOR MIXED DATA-+ | | | | '-VARCHAR----------------' '-ccsid-clause---' | | | | .-(--1M--)-------------. | | | '---+-CLOB-------------------+----+----------------------+--+----------------+-' | | +-CHAR LARGE OBJECT------+ '-(--integer--+---+--)-' +-FOR SBCS DATA--+ | | '-CHARACTER LARGE OBJECT-' +-K-+ +-FOR MIXED DATA-+ | | +-M-+ '-ccsid-clause---' | | '-G-' | | .-(--1--)-------. | +-+---GRAPHIC----+---------------+-------+--+--------------+-----------------------+ | | '-(--integer--)-' | '-ccsid-clause-' | | +-+-GRAPHIC VARYING-+--(--integer--)---+ | | | '-VARGRAPHIC------' | | | | .-(--1M--)-------------. | | | '---DBCLOB----+----------------------+-' | | '-(--integer--+---+--)-' | | +-K-+ | | +-M-+ | | '-G-' | | .-(--1--)-------. | +-+-+-BINARY--+---------------+---------+-----------------+------------------------+ | | | '-(--integer--)-' | | | | | '-+-BINARY VARYING-+--(--integer--)-' | | | | '-VARBINARY------' | | | | .-(--1M--)-------------. | | | '---+-BLOB----------------+----+----------------------+-' | | '-BINARY LARGE OBJECT-' '-(--integer--+---+--)-' | | +-K-+ | | +-M-+ | | '-G-' | +-+-DATE-------------------+-------------------------------------------------------+ | | .-(--0--)-. | | | +-TIME--+---------+------+ | | | .-(--6--)-. | | | '-TIMESTAMP--+---------+-' | | .-(--200--)-----. | +-----DATALINK--+---------------+--+--------------+--------------------------------+ | '-(--integer--)-' '-ccsid-clause-' | '---ROWID--------------------------------------------------------------------------' ccsid-clause: .-NOT NORMALIZED-. |--CCSID--integer--+----------------+---------------------------| '-NORMALIZED-----'
The CAST specification returns the cast operand (the first operand) cast to the type specified by the data-type. 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.
The supported casts are shown in Table 13, 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.
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.
Restrictions on the supported data types are based on the specified cast operand.
If the CCSID attribute is not specified, then:
If the CCSID attribute is specified, the data will converted to that CCSID. If NORMALIZED is specified, the data will be normalized.
For information on which casts between data types are supported and the rules for casting to a data type see Casting between data types.
SELECT EMPNO, CAST(SALARY AS INTEGER) FROM EMPLOYEE
UPDATE PERSONNEL SET RETIRE_YEAR = ? WHERE AGE = CAST( ? AS T_AGE )
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.
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.
OLAP-specification: |--+-ranking-specification---+----------------------------------| '-numbering-specification-' ranking-specification: |--+-RANK-------+--(--)--OVER--(--+-------------------------+--window-order-clause--)--| '-DENSE_RANK-' '-window-partition-clause-' numbering-specification: |--ROW_NUMBER--(--)--OVER--(--+-------------------------+--+---------------------+--)--| '-window-partition-clause-' '-window-order-clause-' window-partition-clause: .-,-----------------------. V | |--PARTITION BY----partitioning-expression-+--------------------| window-order-clause: |--ORDER BY-----------------------------------------------------> .-,--------------------------------------------------. | .-NULLS LAST-. | V .-ASC--+------------+---. | >----+-sort-key-expression--+-----------------------+-+-+-------| | +-ASC NULLS FIRST-------+ | | | .-NULLS FIRST-. | | | +-DESC--+-------------+-+ | | '-DESC NULLS LAST-------' | '-ORDER OF--table-designator---------------------'
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 select-list or the ORDER BY clause of a select-statement. The query result to which the OLAP specification is applied is the result table of the innermost subselect that includes the OLAP specification.
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 join-condition. An OLAP specification cannot be used as an argument of an aggregate function.
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.
The data type of the result of RANK, DENSE_RANK, or ROW_NUMBER is BIGINT. The result cannot be null.
An OLAP specification is not allowed if the query specifies:
Syntax alternatives: DENSERANK can be specified in place of DENSE_RANK, and ROWNUMBER can be specified in place of ROW_NUMBER.
SELECT EMPNO, LASTNAME, FIRSTNME, SALARY+BONUS AS TOTAL_SALARY, RANK() OVER (ORDER BY SALARY+BONUS DESC) AS RANK_SALARY FROM EMPLOYEE WHERE SALARY+BONUS > 30000 ORDER BY LASTNAMENote that if the result is to be ordered by the ranking, then replace ORDER BY LASTNAME with:
ORDER BY RANK_SALARY
or:
ORDER BY RANK() OVER (ORDER BY SALARY+BONUS DESC)
SELECT WORKDEPT, AVG(SALARY+BONUS) AS AVG_TOTAL_SALARY, RANK() OVER (ORDER BY AVG( SALARY+BONUS) DESC) AS RANK_AVG_SAL FROM EMPLOYEE GROUP BY WORKDEPT ORDER BY RANK_AVG_SAL
SELECT WORKDEPT, EMPNO, LASTNAME, FIRSTNME, EDLEVEL, DENSE_RANK() OVER (PARTITION BY WORKDEPT ORDER BY EDLEVEL DESC) AS RANK_EDLEVEL FROM EMPLOYEE ORDER BY WORKDEPT, LASTNAME
SELECT ROW_NUMBER() OVER (ORDER BY WORKDEPT, LASTNAME ) AS NUMBER, LASTNAME, SALARY FROM EMPLOYEE ORDER BY WORKDEPT, LASTNAME
SELECT EMPNO, LASTNAME, FIRSTNME, TOTAL_SALARY, RANK_SALARY FROM (SELECT EMPNO, LASTNAME, FIRSTNME, SALARY+BONUS AS TOTAL_SALARY, RANK() OVER (ORDER BY SALARY+BONUS DESC) AS RANK_SALARY FROM EMPLOYEE) AS RANKED_EMPLOYEE WHERE RANK_SALARY < 6 ORDER BY RANK_SALARYNote 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.
sequence-reference: |--+-nextval-expression-+---------------------------------------| '-prevval-expression-' nextval-expression: |--NEXT VALUE--FOR--sequence-name-------------------------------| prevval-expression: |--PREVIOUS VALUE--FOR--sequence-name---------------------------|
A sequence is referenced by using the NEXT VALUE and PREVIOUS VALUE expressions specifying the name of the sequence.
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.
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.
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.
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.
Authorization: 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:
For information on the system authorities corresponding to SQL privileges, see Corresponding System Authorities When Checking Privileges to a Sequence.
Generating values with NEXT VALUE: 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.
Scope of PREVIOUS VALUE: 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.
Use as a Unique Key Value: 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:
INSERT INTO ORDER (ORDERNO, CUSTNO) VALUES (NEXT VALUE FOR ORDER_SEQ, 123456) INSERT INTO LINE_ITEM (ORDERNO, PARTNO, QUANTITY) VALUES (PREVIOUS VALUE FOR ORDER_SEQ, 987654, 1)
Allowed use of NEXT VALUE and PREVIOUS VALUE: NEXT VALUE and PREVIOUS VALUE expressions can be specified in the following places:
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 select-clause of the fullselect of an expression. For example, the following uses of sequence expressions are supported:
UPDATE T SET C1 = (SELECT PREVIOUS VALUE FOR S1 FROM T) UPDATE T SET C1 = PREVIOUS VALUE FOR S1 UPDATE T SET C1 = NEXT VALUE FOR S1
The following use of a sequence expression is not supported:
UPDATE T SET C1 = (SELECT NEXT VALUE FOR S1 FROM T)
SET :ORDERNUM = NEXT VALUE FOR INVOICE SET :ORDERNUM = PREVIOUS VALUE FOR INVOICEThe following use of a sequence expression is not supported:
SET :X = (SELECT NEXT VALUE FOR S1 FROM T) SET :X = (SELECT PREVIOUS VALUE FOR S1 FROM T)
Restrictions on the use of NEXT VALUE and PREVIOUS VALUE: NEXT VALUE and PREVIOUS VALUE expressions cannot be specified in the following places:
In addition, the NEXT VALUE expression cannot be specified in the following places:
Using sequence expressions with a cursor: 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.
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.
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.
Syntax alternatives: The keywords NEXTVAL and PREVVAL can be used as alternatives for NEXT VALUE and PREVIOUS VALUE respectively.
CREATE SEQUENCE ORDER_SEQ START WITH 1 INCREMENT BY 1 NO MAXVALUE NO CYCLE CACHE 24Following are some examples of how to generate an ORDER_SEQ sequence number with a NEXT VALUE expression:
INSERT INTO ORDER (ORDERNO, CUSTNO) VALUES (NEXT VALUE FOR ORDER_SEQ, 123456) UPDATE ORDER SET ORDERNO = NEXT VALUE FOR ORDER_SEQ WHERE CUSTNO = 123456 VALUES NEXT VALUE FOR ORDER INTO :HV_SEQ