A scalar function can be used wherever an expression can be used. The restrictions on the use of aggregate functions do not apply to scalar functions, because a scalar function is applied to single parameter values rather than to sets of values. The argument of a scalar function can be a function. However, the restrictions that apply to the use of expressions and aggregate functions also apply when an expression or aggregate function is used within a scalar function. For example, the argument of a scalar function can be an aggregate function only if an aggregate function is allowed in the context in which the scalar function is used.
The result of the following SELECT statement has as many rows as there are employees in department D01:
SELECT EMPNO, LASTNAME, YEAR(CURRENT DATE - BIRTHDATE) FROM EMPLOYEE WHERE WORKDEPT = 'D01'
The ABS function returns the absolute value of a number.
The data type and length attribute of the result are the same as the data type and length attribute of the argument value, except that the result is a large integer if the argument value is a small integer, and the result is double-precision floating point if the argument value is single-precision floating point.
If the argument can be null, the result can be null; if the argument is null, the result is the null value.
Syntax alternatives: ABSVAL is a synonym for ABS. It is supported only for compatibility with previous DB2® releases.
SELECT ABS(:PROFIT) FROM SYSIBM.SYSDUMMY1Returns the value 50000.
The ACOS function returns the arc cosine of the argument as an angle expressed in radians. The ACOS and COS functions are inverse operations.
The data type of the result is double-precision floating point. If the argument can be null, the result can be null; if the argument is null, the result is the null value.
The result is greater than or equal to 0 and less than or equal to π.
SELECT ACOS(:ACOSINE) FROM SYSIBM.SYSDUMMY1Returns the approximate value 1.49.
The ADD_MONTHS function returns a date that represents expression plus numeric-expression months.
If expression is a character or graphic string, it must not be a CLOB or DBCLOB and its value must be a valid string representation of a date or timestamp. For the valid formats of string representations of dates and timestamps, see String representations of datetime values.
The result of the function is a date. If either argument can be null, the result can be null; if either argument is null, the result is the null value.
If expression is the last day of the month or if the resulting month has fewer days than the day component of expression, then the result is the last day of the resulting month. Otherwise, the result has the same day component as expression.
SET :ADD_MONTH = ADD_MONTHS(LAST_DAY(CURRENT_DATE), 1 )
The host variable ADD_MONTH is set with the value representing the end of February, 2000-02-29.
SET :ADD_MONTH = ADD_MONTHS(:DATE, 3)
The host variable ADD_MONTH is set with the value representing the day plus 3 months, 1965-10-27.
SET :DATEHV = DATE('2000-2-28') + 4 MONTHS SET :DATEHV ADD_MONTHS('2000-2-28', 4)
In both cases, the host variable DATEHV is set with the value '2000–06–28'.
Now consider the same examples but with the date '2000–2–29' as the argument.
SET :DATEHV = DATE('2000-2-29') + 4 MONTHS
The host variable DATEHV is set with the value '2000–06–29'.
SET :DATEHV ADD_MONTHS('2000-2-29', 4)
The host variable DATEHV is set with the value '2000–06–30'.
In this case, the ADD_MONTHS function returns the last day of the month, which is June 30, 2000, instead of June 29, 2000. The reason is that February 29 is the last day of the month. So, the ADD_MONTHS function returns the last day of June.
The ANTILOG function returns the anti-logarithm (base 10) of a number. The ANTILOG and LOG functions are inverse operations.
The data type of the result is double-precision floating point. If the argument can be null, the result can be null; if the argument is null, the result is the null value.
SELECT ANTILOG(:ALOG) FROM SYSIBM.SYSDUMMY1Returns the approximate value 31.62.
The ASIN function returns the arc sine of the argument as an angle expressed in radians. The ASIN and SIN functions are inverse operations.
The data type of the result is double-precision floating point. If the argument can be null, the result can be null; if the argument is null, the result is the null value.
The result is greater than or equal to -π /2 and less than or equal to π /2.
SELECT ASIN(:ASINE) FROM SYSIBM.SYSDUMMY1Returns the approximate value 1.50.
The ATAN function returns the arc tangent of the argument as an angle expressed in radians. The ATAN and TAN functions are inverse operations.
The data type of the result is double-precision floating point. If the argument can be null, the result can be null; if the argument is null, the result is the null value.
The result is greater than or equal to -π/2 and less than or equal to π/2.
SELECT ATAN(:ATANGENT) FROM SYSIBM.SYSDUMMY1Returns the approximate value 1.50.
The ATANH function returns the hyperbolic arc tangent of a number, in radians. The ATANH and TANH functions are inverse operations.
The data type of the result is double-precision floating point. If the argument can be null, the result can be null; if the argument is null, the result is the null value.
SELECT ATANH(:HATAN) FROM SYSIBM.SYSDUMMY1Returns the approximate value 1.50.
The ATAN2 function returns the arc tangent of x and y coordinates as an angle expressed in radians. The first and second arguments specify the x and y coordinates, respectively.
The data type of the result is double-precision floating point. If any argument can be null, the result can be null; if any argument is null, the result is the null value.
SELECT ATAN2(:HATAN2A,:HATAN2B) FROM SYSIBM.SYSDUMMY1Returns a double precision floating-point number with an approximate value of 1.1071487.
Numeric to Big Integer
>>---BIGINT----(--numeric-expression--)------------------------><
String to Big Integer
>>---BIGINT----(--string-expression--)-------------------------><
The BIGINT function returns a big integer representation of:
Numeric to Big Integer
If the argument is a numeric-expression, the result is the same number that would occur if the argument were assigned to a big integer column or variable. If the whole part of the argument is not within the range of big integers, an error is returned. The fractional part of the argument is truncated.
String to Big Integer
If the argument is a string-expression, the result is the same number that would result from CAST( string-expression AS BIGINT). Leading and trailing blanks are eliminated and the resulting string must conform to the rules for forming a floating-point, integer, or decimal constant. If the whole part of the argument is not within the range of big integers, an error is returned. Any fractional part of the argument is truncated.
The result of the function is a big integer. If the argument can be null, the result can be null; if the argument is null, the result is the null value.
Syntax alternatives: The CAST specification should be used for maximal portability. For more information, see CAST specification.
SELECT BIGINT(SALARY) FROM EMPLOYEE
The BINARY function returns a BINARY representation of a string of any type.
The result of the function is a fixed-length binary string. If the first argument can be null, the result can be null; if the first argument is null, the result is the null value.
If integer is not specified:
The actual length is the same as the length attribute of the result. If the length of the string-expression is less than the length of the result, the result is padded with hexadecimal zeroes up to the length of the result. If the length of the string-expression is greater than the length attribute of the result, truncation is performed. A warning (SQLSTATE 01004) is returned unless the first input argument is a character string and all the truncated characters are blanks, or the first input argument is a graphic string and all the truncated characters are double-byte blanks, or the first input argument is a binary string and all the truncated bytes are hexadecimal zeroes.
Syntax alternatives: When the length is specified, the CAST specification should be used for maximal portability. For more information, see CAST specification.
SELECT BINARY('This is a BINARY') FROM SYSIBM.SYSDUMMY1
The BIT_LENGTH function returns the length of a string expression in bits. See LENGTH , CHARACTER_LENGTH , and OCTET_LENGTH for similar functions.
The result of the function is DECIMAL(31). If the argument can be null, the result can be null; if the argument is null, the result is the null value.
The result is the number of bits (bytes * 8) in the argument. The length of a string includes trailing blanks. The length of a varying-length string is the actual length in bits (bytes * 8), not the maximum length.
SELECT BIT_LENGTH( C1 ) FROM T1Returns the value 160.
The BLOB function returns a BLOB representation of a string of any type.
The result of the function is a BLOB. If the first argument can be null, the result can be null; if the first argument is null, the result is the null value.
If integer is not specified:
The actual length of the result is the minimum of the length attribute of the result and the actual length of the expression (or twice the length of the expression when the input is graphic data). If the length of the string-expression is greater than the length attribute of the result, truncation is performed. A warning (SQLSTATE 01004) is returned unless the first input argument is a character string and all the truncated characters are blanks, or the first input argument is a graphic string and all the truncated characters are double-byte blanks, or the first input argument is a binary string and all the truncated bytes are hexadecimal zeroes.
Syntax alternatives: When the length is specified, the CAST specification should be used for maximal portability. For more information, see CAST specification.
SELECT BLOB('This is a BLOB') FROM SYSIBM.SYSDUMMY1
SELECT BLOB(:myclob_locator) FROM SYSIBM.SYSDUMMY1
SELECT BLOB( MAP_NAME CONCAT ': ' CONCAT TOPOGRAPHIC_MAP ) FROM ONTARIO_SERIES_4 WHERE TOPOGRAPHIC_MAP LIKE '%Pellow Island%'
The CEIL or CEILING function returns the smallest integer value that is greater than or equal to expression.
The result of the function has the same data type and length attribute of the argument except that the scale is 0 if the argument is DECIMAL or NUMERIC. For example, an argument with a data type of DECIMAL(5,5) will result in DECIMAL(5,0).
If the argument can be null, the result can be null; if the argument is null, the result is the null value.
SELECT CEIL(MAX(SALARY)/12 FROM EMPLOYEEThis example returns 4396.00 because the highest paid employee is Christine Haas who earns $52750.00 per year. Her average monthly salary before applying the CEIL function is 4395.83.
SELECT CEILING( 3.5), CEILING( 3.1), CEILING(-3.1), CEILING(-3.5), FROM SYSIBM.SYSDUMMY1This example returns:
04. 04. -03. -03.respectively.
Datetime to Character
>>-CHAR--(--datetime-expression--+--------------+--)----------->< '-,--+-ISO---+-' +-USA---+ +-EUR---+ +-JIS---+ '-LOCAL-'
Graphic to Character
>>-CHAR--(--graphic-expression--+------------+--)-------------->< '-,--integer-'
Character to Character
>>-CHAR--(--character-expression--+------------+--)------------>< '-,--integer-'
Integer to Character
>>-CHAR--(--integer-expression--)------------------------------><
Decimal to Character
>>-CHAR--(--decimal-expression--+----------------------+--)---->< '-,--decimal-character-'
Floating-point to Character
>>-CHAR---------------------------------------------------------> >--(--floating-point-expression--+----------------------+--)--->< '-,--decimal-character-'
The CHAR function returns a fixed-length character-string representation of:
The first argument must be a built-in data type other than a BINARY, VARBINARY, or BLOB.
The result of the function is a fixed-length character string. If the first argument can be null, the result can be null; if the first argument is null, the result is the null value.
Datetime to Character
The result is the character-string representation of the timestamp. The length of the result is 26.
Graphic to Character
If the second argument is not specified:
The actual length is the same as the length attribute of the result. If the length of the graphic-expression is less than the length of the result, the result is padded with blanks up to the length of the result. If the length of the graphic-expression is greater than the length attribute of the result, truncation is performed. A warning (SQLSTATE 01004) is returned unless the truncated characters were all blanks.
The CCSID of the string is the default CCSID of the current server.
Character to Character
If the second argument is not specified:
The actual length is the same as the length attribute of the result. If the length of the character-expression is less than the length of the result, the result is padded with blanks up to the length of the result. If the length of the character-expression is greater than the length attribute of the result, truncation is performed. A warning (SQLSTATE 01004) is returned unless the truncated characters were all blanks.
The CCSID of the string is the CCSID of the character-expression.
Integer to Character
The result is the fixed-length character-string representation of the argument in the form of an SQL integer constant. The result consists of n characters that are the significant digits that represent the value of the argument with a preceding minus sign if the argument is negative. The result is left justified.
The length of the result is 6. If the number of characters in the result is less than 6, then the result is padded on the right with blanks.
The length of the result is 11. If the number of characters in the result is less than 11, then the result is padded on the right with blanks.
The length of the result is 20. If the number of characters in the result is less than 20, then the result is padded on the right with blanks.
The CCSID of the string is the default SBCS CCSID at the current server.
Decimal to Character
The result is a fixed-length character string representation of the argument. The result includes a decimal character and up to p digits, where p is the precision of the decimal-expression with a preceding minus sign if the argument is negative. Leading zeros are not returned. Trailing zeros are returned.
The length of the result is 2+p where p is the precision of the decimal-expression. This means that a positive value will always include one trailing blank.
The CCSID of the string is the default SBCS CCSID at the current server.
Floating-point to Character
The result is a fixed-length character-string representation of the argument in the form of a floating-point constant. The length of the result is 24. If the argument is negative, the first character of the result is a minus sign. Otherwise, the first character is a digit. If the argument is zero, the result is 0E0. Otherwise, the result includes the smallest number of characters that can be used to represent the value of the argument such that the mantissa consists of a single digit other than zero followed by a period and a sequence of digits.
If the number of characters in the result is less than 24, then the result is padded on the right with blanks.
The CCSID of the string is the default SBCS CCSID at the current server.
Syntax alternatives: When the first argument is numeric, or the first argument is a string and the length argument is specified, the CAST specification should be used for maximal portability. For more information, see CAST specification.
SELECT CHAR(PRSTDATE, USA) FROM PROJECTResults in the value '12/25/1988'.
SELECT CHAR(PRSTDATE) FROM PROJECTResults in the value '12/25/88'.
SELECT CHAR(STARTING, USA) FROM CL_SCHEDResults in the value '5:12 PM'.
SELECT CHAR(STARTING + :HOUR_DUR, JIS) FROM CL_SCHEDResults in the value '10:12:00'.
SELECT CHAR(RECEIVED) FROM IN_TRAYResults in the value '1988-12-25-17.12.30.000000'.
SELECT CHAR(LASTNAME,10) FROM EMPLOYEEFor rows having a LASTNAME with a length greater than 10 characters (excluding trailing blanks), a warning (SQLSTATE 01004) that the value is truncated is returned.
SELECT CHAR(EDLEVEL) FROM EMPLOYEEAn EDLEVEL of 18 would be returned as the CHAR(6) value '18 ' (18 followed by 4 blanks).
SELECT CHAR(20000.25 - SALARY, ',') FROM EMPLOYEEA SALARY of 21150 returns the value '–1149,75 ' (–1149,75 followed by 3 blanks).
SELECT CHAR(:DOUBLE_NUM) FROM SYSIBM.SYSDUMMY1Results in the character value '-9.8765432100000002E-33 '.
The CHARACTER_LENGTH or CHAR_LENGTH function returns the length of a string expression. See LENGTH for a similar function.
If the argument is a UTF-8 or UTF-16 string, the query cannot contain:
The result of the function is a large integer. If the argument can be null, the result can be null; if the argument is null, the result is the null value.
If expression is a character string or graphic string, the result is the number of characters in the argument (not the number of bytes). A single character is either an SBCS, DBCS, or multiple-byte character. If expression is a binary string, the result is the number of bytes in the argument. The length of strings includes trailing blanks or hexadecimal zeroes. The length of a varying-length string is the actual length, not the maximum length.
SELECT CHARACTER_LENGTH(:ADDRESS) FROM SYSIBM.SYSDUMMY1Returns the value 18.
Character to CLOB
>>-CLOB (--character-expression---------------------------------> >--+--------------------------------+--)----------------------->< '-,--+-length--+--+------------+-' '-DEFAULT-' '-,--integer-'
Graphic to CLOB
>>-CLOB (--graphic-expression-----------------------------------> >--+--------------------------------+--)----------------------->< '-,--+-length--+--+------------+-' '-DEFAULT-' '-,--integer-'
Integer to CLOB
>>-CLOB--(--integer-expression--)------------------------------><
Decimal to CLOB
>>-CLOB--(--decimal-expression--+----------------------+--)---->< '-,--decimal-character-'
Floating-point to CLOB
>>-CLOB---------------------------------------------------------> >--(--floating-point-expression--+----------------------+--)--->< '-,--decimal-character-'
The CLOB function returns a character-string representation of:
The result of the function is a CLOB. If the first argument can be null, the result can be null; if the first argument is null, the result is the null value.
Character to CLOB
If the second argument is not specified or DEFAULT is specified:
The actual length of the result is the minimum of the length attribute of the result and the actual length of character-expression. If the length of the character-expression is greater than the length attribute of the result, truncation is performed. A warning (SQLSTATE 01004) is returned unless the truncated characters were all blanks.
If the third argument is not specified, the first argument must not have a CCSID of 65535:
Graphic to CLOB
If the second argument is not specified or DEFAULT is specified, the length attribute of the result is determined as follows (where n is the length attribute of the first argument):
The actual length of the result is the minimum of the length attribute of the result and the actual length of graphic-expression. If the length of the graphic-expression is greater than the length attribute of the result, truncation is performed. A warning (SQLSTATE 01004) is returned unless the truncated characters were all blanks.
If the third argument is not specified, the CCSID of the result is the default CCSID at the current server. If the default CCSID is mixed data, then the result is mixed data. If the default CCSID is SBCS data, then the result is SBCS data.
Integer to CLOB
The result is a varying-length character string of the argument in the form of an SQL integer constant. The result consists of n characters that are the significant digits that represent the value of the argument with a preceding minus sign if the argument is negative. The result is left justified.
The actual length of the result is the smallest number of characters that can be used to represent the value of the argument. Leading zeroes are not included. If the argument is negative, the first character of the result is a minus sign. Otherwise, the first character is a digit.
The CCSID of the result is the default SBCS CCSID at the current server.
Decimal to CLOB
The result is a varying-length character string representation of the argument. The result includes a decimal character and up to p digits, where p is the precision of the decimal-expression with a preceding minus sign if the argument is negative. Leading zeros are not returned. Trailing zeros are returned.
The length attribute of the result is 2+p where p is the precision of the decimal-expression. The actual length of the result is the smallest number of characters that can be used to represent the result, except that trailing characters are included. Leading zeros are not included. If the argument is negative, the result begins with a minus sign. Otherwise, the result begins with a digit.
The CCSID of the result is the default SBCS CCSID at the current server.
Floating-point to CLOB
The result is a varying-length character string representation of the argument in the form of a floating-point constant.
The length attribute of the result is 24. The actual length of the result is the smallest number of characters that can represent the value of the argument such that the mantissa consists of a single digit other than zero followed by the decimal-character and a sequence of digits. If the argument is negative, the first character of the result is a minus sign; otherwise, the first character is a digit. If the argument is zero, the result is 0E0.
The CCSID of the result is the default SBCS CCSID at the current server.
Syntax alternatives: When the first argument is numeric, or the first argument is a string and the length argument is specified, the CAST specification should be used for maximal portability. For more information, see CAST specification.
SELECT CLOB('This is a CLOB') FROM SYSIBM.SYSDUMMY1
The COALESCE function returns the value of the first non-null expression.
The arguments must be compatible. Character-string arguments are compatible with datetime values. For more information about data type compatibility, see Assignments and comparisons.
The arguments are evaluated in the order in which they are specified, and the result of the function is the first argument that is not null. The result can be null only if all arguments can be null, and the result is null only if all arguments are null.
The selected argument is converted, if necessary, to the attributes of the result. The attributes of the result are determined by all the operands as explained in Rules for result data types.
SELECT DEPTNO, DEPTNAME, COALESCE(MGRNO, 'ABSENT'), ADMRDEPT FROM DEPARTMENT
SELECT EMPNO, COALESCE(SALARY,0) FROM EMPLOYEE
The CONCAT function combines two arguments.
The arguments must be compatible. Character-string arguments are not compatible with datetime values. For more information about data type compatibility, see Assignments and comparisons.
The result of the function is a string that consists of the first argument string followed by the second. The data type of the result is determined by the data types of the arguments. For more information, see With the concatenation operator. If either argument can be null, the result can be null; if either argument is null, the result is the null value.
Syntax alternatives: The CONCAT function is identical to the CONCAT operator. For more information, see With the concatenation operator.
SELECT CONCAT(FIRSTNME, LASTNAME) FROM EMPLOYEE WHERE EMPNO ='000010'Returns the value 'CHRISTINEHAAS'.
The COS function returns the cosine of the argument, where the argument is an angle expressed in radians. The COS and ACOS functions are inverse operations.
The data type of the result is double-precision floating point. If the argument can be null, the result can be null; if the argument is null, the result is the null value.
SELECT COS(:COSINE) FROM SYSIBM.SYSDUMMY1Returns the approximate value 0.07.
The COSH function returns the hyperbolic cosine of the argument, where the argument is an angle expressed in radians.
The data type of the result is double-precision floating point. If the argument can be null, the result can be null; if the argument is null, the result is the null value.
SELECT COSH(:HCOS) FROM SYSIBM.SYSDUMMY1Returns the approximate value 2.35.
The COT function returns the cotangent of the argument, where the argument is an angle expressed in radians.
The data type of the result is double-precision floating point. If the argument can be null, the result can be null; if the argument is null, the result is the null value.
SELECT COT(:COTAN) FROM SYSIBM.SYSDUMMY1Returns the approximate value 0.07.
The CURDATE function returns a date based on a reading of the time-of-day clock when the SQL statement is executed at the current server. The value returned by the CURDATE function is the same as the value returned by the CURRENT DATE special register.
The data type of the result is a date. The result cannot be null.
If this function is used more than once within a single SQL statement, or used with the CURTIME or NOW scalar functions or the CURRENT_DATE, CURRENT_TIME, or CURRENT_TIMESTAMP special registers within a single statement, all values are based on a single clock reading.
Syntax alternatives: The CURRENT_DATE special register should be used for maximal portability. For more information, see Special registers.
SELECT CURDATE() FROM SYSIBM.SYSDUMMY1
The CURTIME function returns a time based on a reading of the time-of-day clock when the SQL statement is executed at the current server. The value returned by the CURTIME function is the same as the value returned by the CURRENT TIME special register.
The data type of the result is a time. The result cannot be null.
If this function is used more than once within a single SQL statement, or used with the CURDATE or NOW scalar functions or the CURRENT_DATE, CURRENT_TIME, or CURRENT_TIMESTAMP special registers within a single statement, all values are based on a single clock reading.
Syntax alternatives: The CURRENT_TIME special register should be used for maximal portability. For more information, see Special registers.
SELECT CURTIME() FROM SYSIBM.SYSDUMMY1
The DATABASE function returns the current server.
The result of the function is a VARCHAR(18). The result cannot be null.
The CCSID of the string is the default SBCS CCSID at the current server.
Syntax alternatives: The DATABASE function returns the same result as the CURRENT SERVER special register.
SELECT DATABASE( ) FROM SYSIBM.SYSDUMMY1Results in a value of 'RCHASGMA'.
The DATAPARTITIONNAME function returns the partition name of where a row is located. If the argument identifies a non-partitioned table, an empty string is returned. For more information about partitions, see the DB2 Multisystem book.
In SQL naming, the table name may be qualified. In system naming, the table name cannot be qualified.
If the argument identifies a view, common table expression, or derived table, the function returns the relational database name of its base table. If the argument identifies a view, common table expression, or derived table derived from more than one base table, the function returns the relational database name of the first table in the outer subselect of the view, common table expression, or derived table.
The argument must not identify a view, common table expression, or derived table whose outer subselect includes an aggregate function, a GROUP BY clause, a HAVING clause, a UNION clause, an INTERSECT clause, or DISTINCT clause. If the subselect contains a GROUP BY or HAVING clause, the DATAPARTITIONNAME function can only be specified in the WHERE clause or as an operand of an aggregate function. If the argument is a correlation name, the correlation name must not identify a correlated reference.
The data type of the result is VARCHAR(18). The result can be null.
The CCSID of the result is the default CCSID of the current server.
SELECT EMPNO, DATAPARTITIONNAME(X), DATAPARTITIONNAME(Y) FROM EMPLOYEE X, DEPARTMENT Y WHERE X.DEPTNO=Y.DEPTNO
The DATAPARTITIONNUM function returns the data partition number of a row. If the argument identifies a non-partitioned table, the value 0 is returned. For more information about data partitions, see the DB2 Multisystem book.
In SQL naming, the table name may be qualified. In system naming, the table name cannot be qualified.
If the argument identifies a view, common table expression, or derived table, the function returns the data partition number of its base table. If the argument identifies a view, common table expression, or derived table derived from more than one base table, the function returns the data partition number of the first table in the outer subselect of the view, common table expression, or derived table.
The argument must not identify a view, common table expression, or derived table whose outer subselect includes an aggregate function, a GROUP BY clause, a HAVING clause, a UNION clause, an INTERSECT clause, or DISTINCT clause. If the subselect contains a GROUP BY or HAVING clause, the DATAPARTITIONNUM function can only be specified in the WHERE clause or as an operand of an aggregate function. If the argument is a correlation name, the correlation name must not identify a correlated reference.
The data type of the result is a large integer. The result can be null.
SELECT DATAPARTITIONNUM(EMPLOYEE), LASTNAME FROM EMPLOYEE
The DATE function returns a date from a value.
The result of the function is a date. If the argument can be null, the result can be null; if the argument is null, the result is the null value.
The other rules depend on the data type of the argument:
The result is the date part of the timestamp.
The result is that date.
The result is the date that is n-1 days after January 1, 0001, where n is the integral part of the number.
The result is the date represented by the string or the date part of the timestamp value represented by the string.
When a string representation of a date is SBCS data with a CCSID that is not the same as the default CCSID for SBCS data, that value is converted to adhere to the default CCSID for SBCS data before it is interpreted and converted to a date value.
When a string representation of a date is mixed data with a CCSID that is not the same as the default CCSID for mixed data, that value is converted to adhere to the default CCSID for mixed data before it is interpreted and converted to a date value.
When a string representation of a date is graphic data, that value is converted to adhere to the default CCSID for SBCS data before it is interpreted and converted to a date value.
Syntax alternatives: When the argument is a date, timestamp, or character string, the CAST specification should be used for maximal portability. For more information, see CAST specification.
SELECT DATE(RECEIVED) FROM IN_TRAY WHERE SOURCE = 'BADAMSON'
Results in a date data type with a value of '1988-12-25'.
SELECT DATE('1988-12-25') FROM SYSIBM.SYSDUMMY1
Results in a date data type with a value of '1988-12-25'.
SELECT DATE('25.12.1988') FROM SYSIBM.SYSDUMMY1
Results in a date data type with a value of '1988-12-25'.
SELECT DATE(35) FROM SYSIBM.SYSDUMMY1
Results in a date data type with a value of '0001-02-04'.
The DAY function returns the day part of a value.
The result of the function is a large integer. If the argument can be null, the result can be null; if the argument is null, the result is the null value.
The other rules depend on the data type of the argument:
The result is the day part of the value, which is an integer between 1 and 31.
The result is the day part of the value, which is an integer between -99 and 99. A nonzero result has the same sign as the argument.
SELECT DAY(PRENDATE) INTO :END_DAY FROM PROJECT WHERE PROJNAME = 'WELD LINE PLANNING'Results in END_DAY being set to 15.
SELECT DAY( DATE('2000-03-15') - DATE('1999-12-31') ) FROM SYSIBM.SYSDUMMY1Results in the value 15.
Returns a mixed case character string containing the name of the day (e.g. Friday) for the day portion of the argument.
If expression is a character or graphic string, it must not be a CLOB or DBCLOB and its value must be a valid string representation of a date or timestamp. For the valid formats of string representations of dates and timestamps, see String representations of datetime values.
The result of the function is VARCHAR(100). If the argument can be null, the result can be null; if the argument is null, the result is the null value.
The CCSID of the result is the default CCSID of the current server.
National language considerations: The name of the day that is returned is based on the language used for messages in the job. This name of the day is retrieved from message CPX9034 in message file QCPFMSG in library *LIBL.
SELECT DAYNAME( '2003-01-02' ) FROM SYSIBM.SYSDUMMY1Results in 'Thursday'.
The DAYOFMONTH function returns an integer between 1 and 31 that represents the day of the month.
If expression is a character or graphic string, it must not be a CLOB or DBCLOB and its value must be a valid string representation of a date or timestamp. For the valid formats of string representations of dates and timestamps, see String representations of datetime values.
The result of the function is a large integer. If the argument can be null, the result can be null; if the argument is null, the result is the null value.
SELECT DAYOFMONTH(PRENDATE) INTO :END_DAY FROM PROJECT WHERE PROJNAME = 'WELD LINE PLANNING'Results in END_DAY being set to 15.
The DAYOFWEEK function returns an integer between 1 and 7 that represents the day of the week, where 1 is Sunday and 7 is Saturday. For another alternative, see DAYOFWEEK_ISO.
If expression is a character or graphic string, it must not be a CLOB or DBCLOB and its value must be a valid string representation of a date or timestamp. For the valid formats of string representations of dates and timestamps, see String representations of datetime values.
The result of the function is a large integer. If the argument can be null, the result can be null; if the argument is null, the result is the null value.
SELECT DAYOFWEEK(HIREDATE) INTO :DAY_OF_WEEK FROM EMPLOYEE WHERE EMPNO = '000010'Results in DAY_OF_WEEK being set to 6, which represents Friday.
SELECT DAYOFWEEK(CAST('10/11/1998' AS DATE)), DAYOFWEEK(TIMESTAMP('10/12/1998','01.02')), DAYOFWEEK(CAST(CAST('10/11/1998' AS DATE)) AS CHAR(20))), DAYOFWEEK(CAST(TIMESTAMP('10/12/1998','01.02') AS CHAR(20))), FROM SYSIBM.SYSDUMMY1
The DAYOFWEEK_ISO function returns an integer between 1 and 7 that represents the day of the week, where 1 is Monday and 7 is Sunday. For another alternative, see DAYOFWEEK.
If expression is a character or graphic string, it must not be a CLOB or DBCLOB and its value must be a valid string representation of a date or timestamp. For the valid formats of string representations of dates and timestamps, see String representations of datetime values.
The result of the function is a large integer. If the argument can be null, the result can be null; if the argument is null, the result is the null value.
SELECT DAYOFWEEK_ISO(HIREDATE) INTO :DAY_OF_WEEK FROM EMPLOYEE WHERE EMPNO = '000010'Results in DAY_OF_WEEK being set to 5, which represents Friday.
SELECT DAYOFWEEK_ISO(CAST('10/11/1998' AS DATE)), DAYOFWEEK_ISO(TIMESTAMP('10/12/1998','01.02')), DAYOFWEEK_ISO(CAST(CAST('10/11/1998' AS DATE)) AS CHAR(20))), DAYOFWEEK_ISO(CAST(TIMESTAMP('10/12/1998','01.02') AS CHAR(20))), FROM SYSIBM.SYSDUMMY1
The DAYOFYEAR function returns an integer between 1 and 366 that represents the day of the year where 1 is January 1.
If expression is a character or graphic string, it must not be a CLOB or DBCLOB and its value must be a valid string representation of a date or timestamp. For the valid formats of string representations of dates and timestamps, see String representations of datetime values.
The result of the function is a large integer. If the argument can be null, the result can be null; if the argument is null, the result is the null value.
SELECT AVG(DAYOFYEAR(HIREDATE)) INTO :AVG_DAY_OF_YEAR FROM EMPLOYEEResults in AVG_DAY_OF_YEAR being set to 197.
The DAYS function returns an integer representation of a date.
If expression is a character or graphic string, it must not be a CLOB or DBCLOB and its value must be a valid string representation of a date or timestamp. For the valid formats of string representations of dates and timestamps, see String representations of datetime values.
The result of the function is a large integer. If the argument can be null, the result can be null; if the argument is null, the result is the null value.
The result is 1 more than the number of days from January 1, 0001 to D, where D is the date that would occur if the DATE function were applied to the argument.
SELECT DAYS(PRENDATE) - DAYS(PRSTDATE) INTO :EDUCATION_DAYS FROM PROJECT WHERE PROJNO = 'IF2000'Results in EDUCATION_DAYS being set to 396.
SELECT SUM(DAYS(PRENDATE) - DAYS(PRSTDATE)) INTO :TOTAL_DAYS FROM PROJECT WHERE DEPTNO = 'E21'Results in TOTAL_DAYS being set to 1584.
Character to DBCLOB
>>-DBCLOB (--character-expression-------------------------------> >--+--------------------------------+--)----------------------->< '-,--+-length--+--+------------+-' '-DEFAULT-' '-,--integer-'
Graphic to DBCLOB
>>-DBCLOB (--graphic-expression---------------------------------> >--+--------------------------------+--)----------------------->< '-,--+-length--+--+------------+-' '-DEFAULT-' '-,--integer-'
Integer to DBCLOB
>>-DBCLOB--(--integer-expression--)----------------------------><
Decimal to DBCLOB
>>-DBCLOB--(--decimal-expression--+----------------------+--)-->< '-,--decimal-character-'
Floating-point to DBCLOB
>>-DBCLOB-------------------------------------------------------> >--(--floating-point-expression--+----------------------+--)--->< '-,--decimal-character-'
The DBCLOB function returns a graphic-string representation of:
The result of the function is a DBCLOB. If the first argument can be null, the result can be null; if the first argument is null, the result is the null value.
Character to DBCLOB
If the second argument is not specified or DEFAULT is specified:
The actual length of the result is the minimum of the length attribute of the result and the actual length of character-expression. If the length of the character-expression is greater than the length attribute of the result, truncation is performed. A warning (SQLSTATE 01004) is returned unless the truncated characters were all blanks.
In the following rules, S denotes one of the following:
If the third argument is not specified and the first argument is character, then the CCSID of the result is determined by a mixed CCSID. Let M denote that mixed CCSID. M is determined as follows:
The following table summarizes the result CCSID based on M.
M | Result CCSID | Description | DBCS Substitution Character |
---|---|---|---|
930 | 300 | Japanese EBCDIC | X'FEFE' |
933 | 834 | Korean EBCDIC | X'FEFE' |
935 | 837 | S-Chinese EBCDIC | X'FEFE' |
937 | 835 | T-Chinese EBCDIC | X'FEFE' |
939 | 300 | Japanese EBCDIC | X'FEFE' |
5026 | 4396 | Japanese EBCDIC | X'FEFE' |
5035 | 4396 | Japanese EBCDIC | X'FEFE' |
If the result is DBCS-graphic data, the equivalence of SBCS and DBCS characters depends on M. Regardless of the CCSID, every double-byte code point in the argument is considered a DBCS character, and every single-byte code point in the argument is considered an SBCS character with the exception of the EBCDIC mixed data shift codes X'0E' and X'0F'.
If the result is UTF-16 or UCS-2 graphic data, each character of the argument determines a character of the result. The nth character of the result is the UTF-16 or UCS-2 equivalent of the nth character of the argument.
Graphic to DBCLOB
If the second argument is not specified or DEFAULT is specified:
The actual length of the result is the minimum of the length attribute of the result and the actual length of graphic-expression. If the length of the graphic-expression is greater than the length attribute of the result, truncation is performed. A warning (SQLSTATE 01004) is returned unless the truncated characters were all blanks.
In the following rules, S denotes one of the following:
If the third argument is not specified, then the CCSID of the result is the same as the CCSID of the first argument.
Integer to DBCLOB
The result is a varying-length graphic string of the argument in the form of an SQL integer constant. The result consists of n characters that are the significant digits that represent the value of the argument with a preceding minus sign if the argument is negative. The result is left justified.
The actual length of the result is the smallest number of characters that can be used to represent the value of the argument. Leading zeroes are not included. If the argument is negative, the first character of the result is a minus sign. Otherwise, the first character is a digit.
The CCSID of the result is 1200 (UTF-16).
Decimal to DBCLOB
The result is a varying-length graphic string representation of the argument. The result includes a decimal character and up to p digits, where p is the precision of the decimal-expression with a preceding minus sign if the argument is negative. Leading zeros are not returned. Trailing zeros are returned.
The length attribute of the result is 2+p where p is the precision of the decimal-expression. The actual length of the result is the smallest number of characters that can be used to represent the result, except that trailing characters are included. Leading zeros are not included. If the argument is negative, the result begins with a minus sign. Otherwise, the result begins with a digit.
The CCSID of the result is 1200 (UTF-16).
Floating-point to DBCLOB
The result is a varying-length graphic string representation of the argument in the form of a floating-point constant.
The length attribute of the result is 24. The actual length of the result is the smallest number of characters that can represent the value of the argument such that the mantissa consists of a single digit other than zero followed by the decimal-character and a sequence of digits. If the argument is negative, the first character of the result is a minus sign; otherwise, the first character is a digit. If the argument is zero, the result is 0E0.
The CCSID of the result is 1200 (UTF-16).
Syntax alternatives: When the length attribute is specified, the CAST specification should be used for maximal portability. For more information, see CAST specification.
SELECT DBCLOB(VARGRAPHIC(FIRSTNME)) INTO :VAR_DESC FROM EMPLOYEE WHERE EMPNO = '000050'
The DBPARTITIONNAME function returns the relational database name (database partition name) of where a row is located. If the argument identifies a non-distributed table, an empty string is returned. For more information about partitions, see the DB2 Multisystem book.
In SQL naming, the table name may be qualified. In system naming, the table name cannot be qualified.
If the argument identifies a view, common table expression, or derived table, the function returns the relational database name of its base table. If the argument identifies a view, common table expression, or derived table derived from more than one base table, the function returns the partition name of the first table in the outer subselect of the view, common table expression, or derived table.
The argument must not identify a view, common table expression, or derived table whose outer subselect includes an aggregate function, a GROUP BY clause, a HAVING clause, a UNION clause, an INTERSECT clause, or DISTINCT clause. If the subselect contains a GROUP BY or HAVING clause, the DBPARTITIONNAME function can only be specified in the WHERE clause or as an operand of an aggregate function. If the argument is a correlation name, the correlation name must not identify a correlated reference.
The data type of the result is VARCHAR(18). The result can be null.
The CCSID of the result is the default CCSID of the current server.
Syntax alternatives: NODENAME is a synonym for DBPARTITIONNAME.
SELECT EMPNO, DBPARTITIONNAME(X), DBPARTITIONNAME(Y) FROM EMPLOYEE X, DEPARTMENT Y WHERE X.DEPTNO=Y.DEPTNO
The DBPARTITIONNUM function returns the node number (database partition number) of a row. If the argument identifies a non-distributed table, the value 0 is returned.42 For more information about nodes and node numbers, see the DB2 Multisystem book.
In SQL naming, the table name may be qualified. In system naming, the table name cannot be qualified.
If the argument identifies a view, common table expression, or derived table, the function returns the node number of its base table. If the argument identifies a view, common table expression, or derived table derived from more than one base table, the function returns the node number of the first table in the outer subselect of the view, common table expression, or derived table.
The argument must not identify a view, common table expression, or derived table whose outer subselect includes an aggregate function, a GROUP BY clause, a HAVING clause, a UNION clause, an INTERSECT clause, or DISTINCT clause. If the subselect contains a GROUP BY or HAVING clause, the DBPARTITIONNUM function can only be specified in the WHERE clause or as an operand of an aggregate function. If the argument is a correlation name, the correlation name must not identify a correlated reference.
The data type of the result is a large integer. The result can be null.
Syntax alternatives: NODENUMBER is a synonym for DBPARTITIONNUM.
SELECT DBPARTITIONNUM(EMPLOYEE), LASTNAME FROM EMPLOYEE
Numeric to Decimal
>>-+-DECIMAL-+--------------------------------------------------> '-DEC-----' >--(--numeric-expression--+----------------------------+--)---->< '-,--precision--+----------+-' '-,--scale-'
String to Decimal
>>-+-DECIMAL-+--------------------------------------------------> '-DEC-----' >--(--string-expression--+------------------------------------------------------+--)->< '-,--precision--+------------------------------------+-' '-,--scale--+----------------------+-' '-,--decimal-character-'
The DECIMAL function returns a decimal representation of:
Numeric to Decimal
The default for precision depends on the data type of the numeric-expression:
The result is the same number that would occur if the first argument were assigned to a decimal column or variable with a precision of p and a scale of s. An error is returned if the number of significant decimal digits required to represent the whole part of the number is greater than p-s.
String to Decimal
The result is the same number that would result from CAST(string-expression AS DECIMAL(p,s)). Digits are truncated from the end of the decimal number if the number of digits to the right of the decimal separator character is greater than the scale s. An error is returned if the number of significant digits to the left of the decimal character (the whole part of the number) in string-expression is greater than p-s. The default decimal character is not valid in the substring if the decimal-character argument is specified.
The result of the function is a decimal number with precision of p and scale of s, where p and s are the second and third arguments. If the first argument can be null, the result can be null; if the first argument is null, the result is the null value.
Syntax alternatives: When the precision is specified, the CAST specification should be used for maximal portability. For more information, see CAST specification.
SELECT EMPNO, DECIMAL(EDLEVEL,5,2) FROM EMPLOYEE
SELECT PRSTDATE + DECIMAL(:PERIOD,8) FROM PROJECT
UPDATE STAFF SET SALARY = DECIMAL(:newsalary, 9, 2, ',') WHERE ID = :empidThe value of SALARY becomes 21400.50.
>>-+-DECRYPT_BIT----+--(--encrypted-data--+----------------------------------------+--)->< +-DECRYPT_BINARY-+ '-,--+-password-string-+--+------------+-' +-DECRYPT_CHAR---+ '-DEFAULT---------' '-,--integer-' '-DECRYPT_DB-----'
The DECRYPT_BIT, DECRYPT_BINARY, DECRYPT_CHAR, and DECRYPT_DB functions return a value that is the result of decrypting encrypted data. The password used for decryption is either the password-string value or the ENCRYPTION PASSWORD value assigned by the SET ENCRYPTION PASSWORD statement.
The decryption functions can only decrypt values that are encrypted using the ENCRYPT_RC2 or ENCRYPT_TDES function.
If DECRYPT_CHAR is specified, integer must be a valid SBCS CCSID or mixed data CCSID. It cannot be 65535 (bit data). If the third argument is an SBCS CCSID, then the result is SBCS data. If the third argument is a mixed CCSID, then the result is mixed data. If the third argument is not specified then the CCSID of the result is the default CCSID of the current server.
If DECRYPT_DB is specified, integer must be a valid DBCS CCSID. If the third argument is not specified then the CCSID of the result is the DBCS CCSID associated with the default CCSID of the current server.
The data type of the result is determined by the function specified and the data type of the first argument as shown in the following table. If a cast from the actual type of the encrypted data to the function's result is not supported a warning or error is returned.
Function | Data Type of First Argument | Actual Data Type of Encrypted Data | Result |
---|---|---|---|
DECRYPT_BIT | CHAR FOR BIT DATA, VARCHAR FOR BIT DATA, BINARY, or VARBINARY | Character string | VARCHAR FOR BIT DATA |
DECRYPT_BIT | CHAR FOR BIT DATA, VARCHAR FOR BIT DATA, BINARY, or VARBINARY | Graphic string | Error or Warning ** |
DECRYPT_BIT | CHAR FOR BIT DATA, VARCHAR FOR BIT DATA, BINARY, or VARBINARY | Binary string | Error or Warning ** |
DECRYPT_BIT | BLOB | Any string | Error |
DECRYPT_BINARY | CHAR FOR BIT DATA, VARCHAR FOR BIT DATA, BINARY, or VARBINARY | Any string | VARBINARY |
DECRYPT_BINARY | BLOB | Any string | BLOB |
DECRYPT_CHAR | CHAR FOR BIT DATA, VARCHAR FOR BIT DATA, BINARY, or VARBINARY | Character string | VARCHAR |
DECRYPT_CHAR | CHAR FOR BIT DATA, VARCHAR FOR BIT DATA, BINARY, or VARBINARY | UCS-2 or UTF-16 graphic string | VARCHAR |
DECRYPT_CHAR | CHAR FOR BIT DATA, VARCHAR FOR BIT DATA, BINARY, or VARBINARY | Non-UCS-2 or non-UTF-16 graphic string | Error or Warning ** |
DECRYPT_CHAR | CHAR FOR BIT DATA, VARCHAR FOR BIT DATA, BINARY, or VARBINARY | Binary string | Error or Warning ** |
DECRYPT_CHAR | BLOB | Character string | CLOB |
DECRYPT_CHAR | BLOB | UCS-2 or UTF-16 graphic string | CLOB |
DECRYPT_CHAR | BLOB | Non-UCS-2 or non-UTF-16 graphic string | Error or Warning ** |
DECRYPT_CHAR | BLOB | Binary string | Error or Warning ** |
DECRYPT_DB | CHAR FOR BIT DATA, VARCHAR FOR BIT DATA, BINARY, or VARBINARY | UTF-8 character string or graphic string | VARGRAPHIC |
DECRYPT_DB | CHAR FOR BIT DATA, VARCHAR FOR BIT DATA, BINARY, or VARBINARY | Non-UTF-8 character string | Error or Warning ** |
DECRYPT_DB | CHAR FOR BIT DATA, VARCHAR FOR BIT DATA, BINARY, or VARBINARY | Binary string | Error or Warning ** |
DECRYPT_DB | BLOB | UTF-8 character string or graphic string | DBCLOB |
DECRYPT_DB | BLOB | Non-UTF-8 character string | Error or Warning ** |
DECRYPT_DB | BLOB | Binary string | Error or Warning ** |
Note:
** If the decryption function is in the select list of an outer subselect, a data mapping warning is returned. Otherwise an error is returned. For more information on data mapping warnings, see Assignments and comparisons. |
If the encrypted-data included a hint, the hint is not returned by the function. The length attribute of the result is the length attribute of the data type of encrypted-data minus 8 bytes. The actual length of the result is the length of the original string that was encrypted. If the encrypted-data includes bytes beyond the encrypted string, these bytes are not returned by the function.
If the argument can be null, the result can be null; if the argument is null, the result is the null value.
If the data is decrypted using a different CCSID than the originally encrypted value, expansion may occur when converting the decrypted value to this CCSID. In such situations, the encrypted-data should be cast to a varying-length string with a larger number of bytes.
Password protection: To prevent inadvertent access to the encryption password, do not specify password-string as a string constant in the source for a program, procedure, or function. Instead, use the ENCRYPTION PASSWORD special register or a host variable.
When connected to a remote relational database, the specified password itself is sent "in the clear". That is, the password itself is not encrypted. To protect the password in these cases, consider using a communications encryption mechanism such as IPSEC (or SSL if connecting between iSeries™ systems).
Syntax alternatives: For compatibility with previous versions of DB2, DECRYPT_BIN can be specified in place of DECRYPT_BIT.
SET ENCRYPTION PASSWORD = :pw INSERT INTO EMP1 (SSN) VALUES ENCRYPT_RC2( '289-46-8832' ) SELECT DECRYPT_CHAR( SSN) FROM EMP1The DECRYPT_CHAR function returns the original value '289-46-8832'.
INSERT INTO EMP1 (SSN) VALUES ENCRYPT_TDES( '289-46-8832', :pw) SELECT DECRYPT_CHAR( SSN, :pw) FROM EMP1The DECRYPT_CHAR function returns the original value '289-46-8832'.
The DEGREES function returns the number of degrees of the argument which is an angle expressed in radians.
The data type of the result is double-precision floating point. If the argument can be null, the result can be null; if the argument is null, the result is the null value.
SELECT DEGREES(:RAD) FROM SYSIBM.SYSDUMMY1Returns the approximate value 180.0.
The DIFFERENCE function returns a value from 0 to 4 representing the difference between the sounds of two strings based on applying the SOUNDEX function to the strings. A value of 4 is the best possible sound match.
The data type of the result is INTEGER. If any argument can be null, the result can be null; if any argument is null, the result is the null value.
SELECT DIFFERENCE('CONSTRAINT','CONSTANT'), SOUNDEX('CONSTRAINT'), SOUNDEX('CONSTANT') FROM SYSIBM.SYSDUMMY1Returns 4, C523, and C523. Since the two strings return the same SOUNDEX value, the difference is 4 (the highest value possible).
SELECT DIFFERENCE('CONSTRAINT','CONTRITE'), SOUNDEX('CONSTRAINT'), SOUNDEX('CONTRITE') FROM SYSIBM.SYSDUMMY1Returns 2, C523, and C536. In this case, the two strings return different SOUNDEX values, and hence, a lower difference value.
The DIGITS function returns a character-string representation of the absolute value of a number.
If the argument can be null, the result can be null; if the argument is null, the result is the null value.
The result of the function is a fixed-length character string representing the absolute value of the argument without regard to its scale. The result does not include a sign or a decimal point. Instead, it consists exclusively of digits, including, if necessary, leading zeros to fill out the string. The length of the string is:
The CCSID of the character string is the default SBCS CCSID at the current server.
SELECT DISTINCT SUBSTR(DIGITS(INTCOL),1,4) FROM TABLEX
SELECT DIGITS(COLUMNX) FROM TABLEXReturns the value '000628'.
The result is a string of length six (the precision of the column) with leading zeros padding the string out to this length. Neither sign nor decimal point appear in the result.
The DLCOMMENT function returns the comment value, if it exists, from a DataLink value.
The result of the function is VARCHAR(254). If the argument can be null, the result can be null; if the argument is null, the result is the null value.
The CCSID of the character string is the same as that of DataLink-expression.
stmtvar = "SELECT DATE_OF_GOAL, DESCRIPTION, DLCOMMENT(ARTICLES) FROM HOCKEY_GOALS WHERE BY_PLAYER = 'Maurice Richard' OR BY_PLAYER = 'Henri Richard' "; EXEC SQL PREPARE HOCKEY_STMT FROM :stmtvar;
INSERT INTO TBLA VALUES (DLVALUE('http://dlfs.almaden.ibm.com/x/y/a.b','URL','A comment'))then the following function operating on that value:
SELECT DLCOMMENT(COLA) FROM TBLAReturns the value 'A comment'.
The DLLINKTYPE function returns the link type value from a DataLink value.
The result of the function is VARCHAR(4). If the argument can be null, the result can be null; if the argument is null, the result is the null value.
The CCSID of the character string is the same as that of DataLink-expression.
INSERT INTO TABLA VALUES( DLVALUE('http://dlfs.almaden.ibm.com/x/y/a.b','URL','A comment') )then the following function operating on that value:
SELECT DLLINKTYPE(COLA) FROM TBLAReturns the value 'URL'.
The DLURLCOMPLETE function returns the complete URL value from a DataLink value with a link type of URL. The value is the same as what would be returned by the concatenation of DLURLSCHEME with '://', then DLURLSERVER, and then DLURLPATH. If the DataLink has an attribute of FILE LINK CONTROL and READ PERMISSION DB, the value includes a file access token.
If the argument can be null, the result can be null; if the argument is null, the result is the null value.
The result of the function is a varying-length string. The length attribute depends on the attributes of the DataLink:
If the DataLink value only includes the comment, the result returned is a zero length string.
The CCSID of the character string is the same as that of DataLink-expression.
INSERT INTO TABLA VALUES( DLVALUE('http://dlfs.almaden.ibm.com/x/y/a.b','URL','A comment') )then the following function operating on that value:
SELECT DLURLCOMPLETE(COLA) FROM TBLAReturns the value 'HTTP://DLFS.ALMADEN.IBM.COM/x/y/****************;a.b', where **************** represents the access token.
The DLURLPATH function returns the path and file name necessary to access a file within a given server from a DataLink value with a linktype of URL. When appropriate, the value includes a file access token.
If the argument can be null, the result can be null; if the argument is null, the result is the null value.
The result of the function is a varying-length string. The length attribute depends on the attributes of the DataLink:
If the DataLink value only includes the comment, the result returned is a zero length string.
The CCSID of the character string is the same as that of DataLink-expression.
INSERT INTO TABLA VALUES( DLVALUE('http://dlfs.almaden.ibm.com/x/y/a.b','URL','A comment') )then the following function operating on that value:
SELECT DLURLPATH(COLA) FROM TBLAReturns the value '/x/y/****************;a.b', where **************** represents the access token.
The DLURLPATHONLY function returns the path and file name necessary to access a file within a given server from a DataLink value with a linktype of URL. The value returned NEVER includes a file access token.
If the argument can be null, the result can be null; if the argument is null, the result is the null value.
The result of the function is a varying-length string with a length attribute of that is equal to the length attribute of the argument.
If the DataLink value only includes the comment, the result returned is a zero length string.
The CCSID of the character string is the same as that of DataLink-expression.
INSERT INTO TABLA VALUES( DLVALUE('http://dlfs.almaden.ibm.com/x/y/a.b','URL','A comment') )then the following function operating on that value:
SELECT DLURLPATHONLY(COLA) FROM TBLAReturns the value '/x/y/a.b'.
The DLURLSCHEME function returns the scheme from a DataLink value with a linktype of URL. The value will always be in upper case.
The result of the function is VARCHAR(20). If the argument can be null, the result can be null; if the argument is null, the result is the null value.
If the DataLink value only includes the comment, the result returned is a zero length string.
The CCSID of the character string is the same as that of DataLink-expression.
INSERT INTO TABLA VALUES( DLVALUE('http://dlfs.almaden.ibm.com/x/y/a.b','URL','A comment') )then the following function operating on that value:
SELECT DLURLSCHEME(COLA) FROM TBLAReturns the value 'HTTP'.
The DLURLSERVER function returns the file server from a DataLink value with a linktype of URL. The value will always be in upper case.
If the argument can be null, the result can be null; if the argument is null, the result is the null value.
The result of the function is a varying-length string with a length attribute of that is equal to the length attribute of the argument.
If the DataLink value only includes the comment, the result returned is a zero length string.
The CCSID of the character string is the same as that of DataLink-expression.
INSERT INTO TABLA VALUES( DLVALUE('http://dlfs.almaden.ibm.com/x/y/a.b','URL','A comment') )then the following function operating on that value:
SELECT DLURLSERVER(COLA) FROM TBLAReturns the value 'DLFS.ALMADEN.IBM.COM'.
>>-DLVALUE--(--data-location--+-------------------------------------------+--)->< '-,--linktype-string--+-------------------+-' '-,--comment-string-'
The DLVALUE function returns a DataLink value. When the function is on the right hand side of a SET clause in an UPDATE statement or is in a VALUES clause in an INSERT statement, it usually also creates a link to a file. However, if only a comment is specified (in which case the data-location is a zero-length string), the DataLink value is created with empty linkage attributes so there is no file link.
The comment-string cannot be the null value. If a comment-string is not specified, the comment-string is the empty string.
If the first argument can be null, the result can be null; if the first argument is null, the result is the null value.
The result of the function is a DataLink value.
The CCSID of the DataLink is the same as that of data-location except in the following cases:
CCSID of data-location | CCSID of comment-string | Result CCSID |
---|---|---|
65535 | 65535 | Job Default CCSID |
65535 | non-65535 | comment-string CCSID (unless the CCSID is 290, 930, 5026, 905, 1026, or 13488 where the CCSID will then be further modified as described in the following rows.) |
290 | any | 4396 |
930 or 5026 | any | 939 |
905 or 1026 | any | 500 |
1200 | any | 500 |
13488 | any | 500 |
When defining a DataLink value using this function, consider the maximum length of the target of the value. For example, if a column is defined as DataLink(200), then the maximum length of the data-location plus the comment is 200 bytes.
INSERT INTO HOCKEY_GOALS VALUES('Maurice Richard', 'Montreal canadian', '?', 'Boston Bruins, '1952-04-24', 'Winning goal in game 7 of Stanley Cup final', DLVALUE(:url_article), DLVALUE(:url_snapshot, 'URL', :url_snapshot_comment), DLVALUE('', 'URL', :url_movie_comment) )
Numeric to Double
>>-+-DOUBLE_PRECISION-+--(--numeric-expression--)-------------->< '-DOUBLE-----------'
String to Double
>>-+-DOUBLE_PRECISION-+--(--string-expression--)--------------->< '-DOUBLE-----------'
The DOUBLE_PRECISION and DOUBLE functions return a floating-point representation of:
Numeric to Double
The result is the same number that would occur if the expression were assigned to a double-precision floating-point column or variable.
String to Double
If the argument is a string-expression, the result is the same number that would result from CAST( string-expression AS DOUBLE PRECISION). Leading and trailing blanks are eliminated and the resulting string must conform to the rules for forming a floating-point, integer, or decimal constant.
The single-byte character constant that must be used to delimit the decimal digits in string-expression from the whole part of the number is the default decimal point. For more information, see Decimal point.
The result of the function is a double-precision floating-point number. If the argument can be null, the result can be null; if the argument is null, the result is the null value.
Syntax alternatives: FLOAT is a synonym for DOUBLE_PRECISION and DOUBLE.
The CAST specification should be used for maximal portability. For more information, see CAST specification.
SELECT EMPNO, DOUBLE_PRECISION(SALARY)/COMM FROM EMPLOYEE WHERE COMM > 0
>>-ENCRYPT_RC2--(--data-string--+----------------------------------------+--)->< '-,--password-string--+----------------+-' '-,--hint-string-'
The ENCRYPT_RC2 function returns a value that is the result of encrypting data-string using the RC2 encryption algorithm. The password used for decryption is either the password-string value or the encryption password value (assigned by the SET ENCRYPTION PASSWORD statement).
The length attribute for the data type of data-string must be less than m - MOD(m,8) - n - 1, where m is the maximum length of the result data type and n is the amount of overhead necessary to encrypt the value.
The data type of the result is determined by the first argument as shown in the following table:
Data Type of the First Argument | Data Type of the Result |
---|---|
BINARY or VARBINARY | VARBINARY |
CHAR, VARCHAR, GRAPHIC, or VARGRAPHIC | VARCHAR FOR BIT DATA |
BLOB, CLOB, or DBCLOB | BLOB |
The length attribute of the result depends on the arguments that are specified:
The actual length of the result is the actual length of data-string plus the actual length of the hint plus n, where n (the amount of overhead necessary to encrypt the value) is 8 bytes (or 16 bytes if data-string is a LOB or different CCSID values are used for the data-string, the password, or the hint). The actual length of the hint is zero if hint-string is not specified as a function argument or on the SET ENCRYPTION PASSWORD statement.
If the argument can be null, the result can be null; if the argument is null, the result is the null value.
Note that the encrypted result is longer than the data-string value. Therefore, when assigning encrypted values, ensure that the target is declared with sufficient size to contain the entire encrypted value.
Password protection: To prevent inadvertent access to the encryption password, do not specify password-string as a string constant in the source for a program, procedure, or function. Instead, use the SET ENCRYPTION PASSWORD statement or a host variable.
When connected to a remote relational database, the specified password itself is sent "in the clear". That is, the password itself is not encrypted. To protect the password in these cases, consider using a communications encryption mechanism such as IPSEC (or SSL if connecting between iSeries systems).
Encryption algorithm: The internal encryption algorithm used is RC2 block cipher with padding, the 128 bit secret key is derived from the password using a MD5 message digest.
Encryption passwords and data: It is the user's responsibility to perform password management. Once the data is encrypted only the password used to encrypt it can be used to decrypt it. Be careful when using CHAR variables to set password values as they may be padded with blanks. The encrypted result may contain a null terminator and other non-printable characters.
Table column definition: When defining columns and distinct types to contain encrypted data:
Any assignment or cast to a column without one of these data types or with a length shorter than the suggested data length may result in an assignment error or, if the assignment is successful, a failure and lost data when the data is subsequently decrypted. Blanks are valid encrypted data values that may be truncated when stored in a column that is too short.
Some sample column length calculations:
Maximum length of non-encrypted data 6 bytes 8 bytes 8 bytes (or 16 bytes) Number of bytes to the next 8 byte boundary 2 bytes -------- Encrypted data column length 16 bytes (or 32 bytes) Maximum length of non-encrypted data 32 bytes 8 bytes 8 bytes (or 16 bytes) Number of bytes to the next 8 byte boundary 8 bytes -------- Encrypted data column length 48 bytes (or 56 bytes)
Administration of encrypted data: Encrypted data can only be decrypted on servers that support the decryption functions that correspond to the ENCRYPT_RC2 function. Hence, replication of columns with encrypted data should only be done to servers that support the decryption functions.
Syntax alternatives: For compatibility with previous versions of DB2, ENCRYPT can be specified in place of ENCRYPT_RC2.
SET ENCRYPTION PASSWORD = 'Ben123' INSERT INTO EMP1 (SSN) VALUES ENCRYPT_RC2( '289-46-8832' )
INSERT INTO EMP1 (SSN) VALUES ENCRYPT_RC2( '289-46-8832', 'Ben123' )
INSERT INTO EMP1 (SSN) VALUES ENCRYPT_RC2( '289-46-8832', 'Pacific', 'Ocean' )
>>-ENCRYPT_TDES--(--data-string--+----------------------------------------+--)->< '-,--password-string--+----------------+-' '-,--hint-string-'
The ENCRYPT_TDES function returns a value that is the result of encrypting data-string using the Triple DES encryption algorithm. The password used for decryption is either the password-string value or the encryption password value (assigned by the SET ENCRYPTION PASSWORD statement).
The length attribute for the data type of data-string must be less than m - MOD(m,8) - n - 1, where m is the maximum length of the result data type and n is the amount of overhead necessary to encrypt the value.
The data type of the result is determined by the first argument as shown in the following table:
Data Type of the First Argument | Data Type of the Result |
---|---|
BINARY or VARBINARY | VARBINARY |
CHAR, VARCHAR, GRAPHIC, or VARGRAPHIC | VARCHAR FOR BIT DATA |
BLOB, CLOB, or DBCLOB | BLOB |
The length attribute of the result depends on the arguments that are specified:
The actual length of the result is the actual length of data-string plus the actual length of the hint plus n, where n (the amount of overhead necessary to encrypt the value) is 16 bytes (or 24 bytes if data-string is a LOB or different CCSID values are used for the data-string, the password, or the hint). The actual length of the hint is zero if hint-string is not specified as a function argument or on the SET ENCRYPTION PASSWORD statement.
If the argument can be null, the result can be null; if the argument is null, the result is the null value.
Note that the encrypted result is longer than the data-string value. Therefore, when assigning encrypted values, ensure that the target is declared with sufficient size to contain the entire encrypted value.
Password protection: To prevent inadvertent access to the encryption password, do not specify password-string as a string constant in the source for a program, procedure, or function. Instead, use the SET ENCRYPTION PASSWORD statement or a host variable.
When connected to a remote relational database, the specified password itself is sent "in the clear". That is, the password itself is not encrypted. To protect the password in these cases, consider using a communications encryption mechanism such as IPSEC (or SSL if connecting between iSeries systems).
Encryption algorithm: The internal encryption algorithm used is Triple DES block cipher with padding, the 128 bit secret key is derived from the password using a SHA1 message digest.
Encryption passwords and data: It is the user's responsibility to perform password management. Once the data is encrypted only the password used to encrypt it can be used to decrypt it. Be careful when using CHAR variables to set password values as they may be padded with blanks. The encrypted result may contain a null terminator and other non-printable characters.
Table column definition: When defining columns and distinct types to contain encrypted data:
Any assignment or cast to a column without one of these data types or with a length shorter than the suggested data length may result in an assignment error or, if the assignment is successful, a failure and lost data when the data is subsequently decrypted. Blanks are valid encrypted data values that may be truncated when stored in a column that is too short.
Some sample column length calculations:
Maximum length of non-encrypted data 6 bytes 16 bytes 16 bytes (or 24 bytes) Number of bytes to the next 8 byte boundary 2 bytes -------- Encrypted data column length 24 bytes (or 32 bytes) Maximum length of non-encrypted data 32 bytes 16 bytes 16 bytes (or 24 bytes) Number of bytes to the next 8 byte boundary 8 bytes -------- Encrypted data column length 56 bytes (or 64 bytes)
Administration of encrypted data: Encrypted data can only be decrypted on servers that support the decryption functions that correspond to the ENCRYPT_TDES function. Hence, replication of columns with encrypted data should only be done to servers that support the decryption functions.
SET ENCRYPTION PASSWORD = 'Ben123' INSERT INTO EMP1 (SSN) VALUES ENCRYPT_TDES( '289-46-8832' )
INSERT INTO EMP1 (SSN) VALUES ENCRYPT_TDES( '289-46-8832', 'Ben123' )
INSERT INTO EMP1 (SSN) VALUES ENCRYPT_TDES( '289-46-8832', 'Pacific', 'Ocean' )
The EXP function returns a value that is the base of the natural logarithm (e) raised to a power specified by the argument. The EXP and LN functions are inverse operations.
The data type of the result is double-precision floating point. If the argument can be null, the result can be null; if the argument is null, the result is the null value.
SELECT EXP(:E) FROM SYSIBM.SYSDUMMY1Returns the approximate value 31.62.
Extract Date Values
>>-EXTRACT--(--+-YEAR--+--FROM--+-date-expression------+--)---->< +-MONTH-+ '-timestamp-expression-' '-DAY---'
Extract Time Values
>>-EXTRACT--(--+-HOUR---+--FROM--+-time-expression------+--)--->< +-MINUTE-+ '-timestamp-expression-' '-SECOND-'
The EXTRACT function returns a specified portion of a datetime value.
Extract Date Values
If expression is a character or graphic string, it must not be a CLOB or DBCLOB and its value must be a valid character-string or graphic-string representation of a date. For the valid formats of string representations of dates, see String representations of datetime values.
If expression is a character or graphic string, it must not be a CLOB or DBCLOB and its value must be a valid character-string or graphic-string representation of a timestamp. For the valid formats of string representations of timestamps, see String representations of datetime values.
Extract Time Values
DECIMAL((DAY(expression) + DECIMAL(MICROSECOND(expression),12,6)/1000000), 8,6)For more information, see SECOND and MICROSECOND.
If expression is a character string, it must not be a CLOB and its value must be a valid character-string representation of a time. For the valid formats of string representations of times, see String representations of datetime values.
If expression is a character string, it must not be a CLOB and its value must be a valid character-string representation of a timestamp. For the valid formats of string representations of timestamps, see String representations of datetime values.
The data type of the result of the function depends on the part of the datetime value that is specified:
If the argument can be null, the result can be null; if the argument is null, the result is the null value.
SELECT EXTRACT( MONTH FROM PRSTDATE ) FROM PROJECTResults in the value 12.
Numeric to Float
>>-FLOAT--(--numeric-expression--)-----------------------------><
String to Float
>>-FLOAT--(--string-expression--)------------------------------><
The FLOAT function returns a floating point representation of a number or string.
FLOAT is a synonym for the DOUBLE_PRECISION and DOUBLE functions. For more information, see DOUBLE_PRECISION or DOUBLE.
The FLOOR function returns the largest integer value less than or equal to expression.
The result of the function has the same data type and length attribute of the argument except that the scale is 0 if the argument is a decimal number. For example, an argument with a data type of DECIMAL(5,5) will result in DECIMAL(5,0).
If the argument can be null, the result can be null; if the argument is null, the result is the null value.
SELECT FLOOR(SALARY) FROM EMPLOYEE
SELECT FLOOR( 3.5), FLOOR( 3.1), FLOOR(-3.1), FLOOR(-3.5), FROM SYSIBM.SYSDUMMY1This example returns:
3. 3. -4. -4.respectively.
The GENERATE_UNIQUE function returns a bit data character string 13 bytes long (CHAR(13) FOR BIT DATA) that is unique compared to any other execution of the same function. The function is defined as not-deterministic.
The result of the function is a unique value that includes the internal form of the Universal Time, Coordinated (UTC) and the iSeries system serial number. The result cannot be null.
The result of this function can be used to provide unique values in a table. Each successive value will be greater than the previous value, providing a sequence that can be used within a table. The sequence is based on the time when the function was executed. This function differs from using the special register CURRENT TIMESTAMP in that a unique value is generated for each row of a multiple row insert statement or an insert statement with a fullselect.
The timestamp value that is part of the result of this function can be determined using the TIMESTAMP function with the result of GENERATE_UNIQUE as an argument.
CREATE TABLE EMP_UPDATE (UNIQUE_ID VARCHAR(13) FOR BIT DATA, EMPNO CHAR(6), TEXT VARCHAR(1000)) INSERT INTO EMP_UPDATE VALUES (GENERATE_UNIQUE(), '000020', 'Update entry 1...') INSERT INTO EMP_UPDATE VALUES (GENERATE_UNIQUE(), '000050', 'Update entry 2...')
This table will have a unique identifier for each row provided that the UNIQUE_ID column is always set using GENERATE_UNIQUE. This can be done by introducing a trigger on the table.
CREATE TRIGGER EMP_UPDATE_UNIQUE NO CASCADE BEFORE INSERT ON EMP_UPDATE REFERENCING NEW AS NEW_UPD FOR EACH ROW MODE DB2SQL SET NEW_UPD.UNIQUE_ID = GENERATE_UNIQUE()
With this trigger, the previous INSERT statements that were used to populate the table can be issued without specifying a value for the UNIQUE_ID column:
INSERT INTO (EMPNO, TEXT) EMP_UPDATE VALUES ('000020', 'Update entry 1...') INSERT INTO (EMPNO, TEXT) EMP_UPDATE VALUES ('000050', 'Update entry 2...')
The timestamp (in UTC) for when a row was added to EMP_UPDATE can be returned using:
SELECT TIMESTAMP(UNIQUE_ID), EMPNO, TEXT FROM EMP_UPDATE
Therefore, the table does not need a timestamp column to record when a row is inserted.
The GETHINT function will return the password hint if one is found in the encrypted-data. A password hint is a phrase that will help data owners remember passwords (For example, 'Ocean' as a hint to remember 'Pacific').
The data type of the result is VARCHAR(32). The actual length of the result is the actual length of the hint that was provided when the data was encrypted.
The result can be null. If the argument is null or if a hint was not added to the encrypted-data by the ENCRYPT_RC2 or ENCRYPT_TDES function, the result is the null value.
The CCSID of the result is the default CCSID of the current server.
INSERT INTO EMP1 (SSN) VALUES ENCRYPT_RC2( '289-46-8832', 'Pacific', 'Ocean' ) SELECT GETHINT( SSN ) FROM EMP1The GETHINT function returns the original hint value 'Ocean'.
Character to Graphic
>>-GRAPHIC--(--character-expression-----------------------------> >--+--------------------------------+--)----------------------->< '-,--+-length--+--+------------+-' '-DEFAULT-' '-,--integer-'
Graphic to Graphic
>>-GRAPHIC--(--graphic-expression-------------------------------> >--+--------------------------------+--)----------------------->< '-,--+-length--+--+------------+-' '-DEFAULT-' '-,--integer-'
Integer to Graphic
>>-GRAPHIC--(--integer-expression--)---------------------------><
Decimal to GRAPHIC
>>-GRAPHIC------------------------------------------------------> >--(--decimal-expression--+----------------------+--)---------->< '-,--decimal-character-'
Floating-point to GRAPHIC
>>-GRAPHIC------------------------------------------------------> >--(--floating-point-expression--+----------------------+--)--->< '-,--decimal-character-'
The GRAPHIC function returns a fixed-length graphic-string representation of a string expression.
The result of the function is a fixed-length graphic string (GRAPHIC).
If the expression can be null, the result can be null. If the expression is null, the result is the null value.
Character to Graphic
If length is not specified, or if DEFAULT is specified, the length attribute of the result is the same as the length attribute of the first argument.
Each character of the argument determines a character of the result. If the length attribute of the resulting fixed-length string is less than the actual length of the first argument, truncation is performed and no warning is returned.
If integer is not specified then the CCSID of the result is determined by a mixed CCSID. Let M denote that mixed CCSID.
In the following rules, S denotes one of the following:
M is determined as follows:
The following table summarizes the result CCSID based on M.
M | Result CCSID | Description | DBCS Substitution Character |
---|---|---|---|
930 | 300 | Japanese EBCDIC | X'FEFE' |
933 | 834 | Korean EBCDIC | X'FEFE' |
935 | 837 | S-Chinese EBCDIC | X'FEFE' |
937 | 835 | T-Chinese EBCDIC | X'FEFE' |
939 | 300 | Japanese EBCDIC | X'FEFE' |
5026 | 4396 | Japanese EBCDIC | X'FEFE' |
5035 | 4396 | Japanese EBCDIC | X'FEFE' |
The equivalence of SBCS and DBCS characters depends on M. Regardless of the CCSID, every double-byte code point in the argument is considered a DBCS character, and every single-byte code point in the argument is considered an SBCS character with the exception of the EBCDIC mixed data shift codes X'0E' and X'0F'.
Graphic to Graphic
If the second argument is not specified, or if DEFAULT is specified, the length attribute of the result is the same as the length attribute of the first argument.
If the length of the graphic-expression is greater than the length attribute of the result, truncation is performed. A warning (SQLSTATE 01004) is returned unless the truncated characters were all blanks.
If integer is not specified then the CCSID of the result is the CCSID of the first argument.
Integer to Graphic
The result is a fixed-length graphic string of the argument in the form of an SQL integer constant. The result consists of n characters that are the significant digits that represent the value of the argument with a preceding minus sign if the argument is negative. It is left justified.
The result is the smallest number of characters that can be used to represent the value of the argument. Leading zeroes are not included. If the argument is negative, the first character of the result is a minus sign. Otherwise, the first character is a digit.
The CCSID of the result is 1200 (UTF-16).
Decimal to Graphic
The result is a fixed-length graphic string representation of the argument. The result includes a decimal character and up to p digits, where p is the precision of the decimal-expression with a preceding minus sign if the argument is negative. Leading zeros are not returned. Trailing zeros are returned.
The length attribute of the result is 2+p where p is the precision of the decimal-expression. The result is the smallest number of characters that can be used to represent the result. Leading zeros are not included. If the argument is negative, the result begins with a minus sign. Otherwise, the result begins with a digit.
The CCSID of the result is 1200 (UTF-16).
Floating-point to Graphic
The result is a fixed-length graphic string representation of the argument in the form of a floating-point constant.
The length attribute of the result is 24. The result is the smallest number of characters that can represent the value of the argument such that the mantissa consists of a single digit other than zero followed by the decimal-character and a sequence of digits. If the argument is negative, the first character of the result is a minus sign; otherwise, the first character is a digit. If the argument is zero, the result is 0E0.
The CCSID of the result is 1200 (UTF-16).
Syntax alternatives: If the length attribute is specified, the CAST specification should be used for maximal portability. For more information, see CAST specification.
SELECT GRAPHIC( VARGRAPHIC(FIRSTNME)) INTO :DESC FROM EMPLOYEE WHERE EMPNO = '000050'
The HASH function returns the partition number of a set of values. Also see the PARTITION function. For more information about partition numbers, see the DB2 Multisystem book.
The result of the function is a large integer with a value between 0 and 1023.
If any of the arguments are null, the result is zero. The result cannot be null.
SELECT HASH(EMPNO, LASTNAME) FROM EMPLOYEE
The HASHED_VALUE function returns the partition map index number of a row obtained by applying the hashing function on the partitioning key value of the row. Also see the HASH function. If the argument identifies a non-distributed table, the value 0 is returned. For more information about partition maps and partitioning keys, see the DB2 Multisystem book.
In SQL naming, the table name may be qualified. In system naming, the table name cannot be qualified.
If the argument identifies a view, common table expression, or derived table, the function returns the partition map index number of its base table. If the argument identifies a view, common table expression, or derived table derived from more than one base table, the function returns the partition map index number of the first table in the outer subselect of the view, common table expression, or derived table.
The argument must not identify a view, common table expression, or derived table whose outer subselect includes an aggregate function, a GROUP BY clause, a HAVING clause, a UNION clause, an INTERSECT clause, or DISTINCT clause. If the subselect contains a GROUP BY or HAVING clause, the HASHED_VALUE function can only be specified in the WHERE clause or as an operand of an aggregate function. If the argument is a correlation name, the correlation name must not identify a correlated reference.
The data type of the result is a large integer with a value between 0 and 1023. The result can be null.
Syntax alternatives: PARTITION is a synonym for HASHED_VALUE.
SELECT EMPNO FROM EMPLOYEE WHERE HASHED_VALUE(EMPLOYEE) = 100
The HEX function returns a hexadecimal representation of a value.
The result of the function is a character string. If the argument can be null, the result can be null; if the argument is null, the result is the null value.
The result is a string of hexadecimal digits, the first two digits represent the first byte of the argument, the next two digits represent the second byte of the argument, and so forth. If the argument is a datetime value, the result is the hexadecimal representation of the internal form of the argument.44
If the argument is not a graphic string, the actual length of the result is twice the length of the argument. If the argument is a graphic string, the actual length of the result is four times the length of the argument. The length of the argument is the value that would be returned if the argument were passed to the LENGTH scalar function. For more information, see LENGTH.
The data type and length attribute of the result depends on the attributes of the argument:
The length attribute of the result cannot be greater than the product-specific length attribute of CHAR or VARCHAR. See Table 78 for more information.
The CCSID of the string is the default SBCS CCSID at the current server.
SELECT FIRSTNME, MIDINIT, LASTNAME, HEX(EDLEVEL) FROM EMPLOYEE
The HOUR function returns the hour part of a value.
The result of the function is a large integer. If the argument can be null, the result can be null; if the argument is null, the result is the null value.
The other rules depend on the data type of the argument:
The result is the hour part of the value, which is an integer between 0 and 24.
The result is the hour part of the value, which is an integer between -99 and 99. A nonzero result has the same sign as the argument.
SELECT * FROM CL_SCHED WHERE HOUR(STARTING) BETWEEN 12 AND 17
IDENTITY_VAL_LOCAL is a non-deterministic function that returns the most recently assigned value for an identity column.
The function has no input parameters. The result is a DECIMAL(31,0) regardless of the actual data type of the identity column that the result value corresponds to.
The value returned is the value that was assigned to the identity column of the table identified in the most recent INSERT statement for a table containing an identity column. The INSERT statement has to be issued at the same level; that is, the value has to be available locally within the level at which it was assigned until replaced by the next assigned value. A new level is initiated when a trigger, function, or stored procedure is invoked. A trigger condition is at the same level as the associated triggered action.
The assigned value can be a value supplied by the user (if the identity column is defined as GENERATED BY DEFAULT) or an identity value that was generated by the database manager.
The result can be null. The result is null if an INSERT statement has not been issued for a table containing an identity column at the current processing level. This includes invoking the function in a before or after insert trigger.
The result of the IDENTITY_VAL_LOCAL function is not affected by the following statements:
The following notes explain the behavior of the function when it is invoked in various situations:
Do not use the IDENTITY_VAL_LOCAL function in the triggered action of a before insert trigger. The result of invoking the IDENTITY_VAL_LOCAL function from within the triggered action of a before insert trigger is the null value. The value for the identity column of the table for which the trigger is defined cannot be obtained by invoking the IDENTITY_VAL_LOCAL function within the triggered action of a before insert trigger. However, the value for the identity column can be obtained in the triggered action by referencing the trigger transition variable for the identity column.
The result of invoking the IDENTITY_VAL_LOCAL function in the triggered action of an after insert trigger is the value assigned to an identity column of the table identified in the most recent INSERT statement invoked in the same triggered action for a table containing an identity column. If an INSERT statement for a table containing an identity column was not executed within the same triggered action before invoking the IDENTITY_VAL_LOCAL function, then the function returns a null value.
CREATE TABLE EMPLOYEE (EMPNO INTEGER GENERATED ALWAYS AS IDENTITY, NAME CHAR(30), SALARY DECIMAL(5,2), DEPT SMALLINT) INSERT INTO EMPLOYEE (NAME, SALARY, DEPTNO) VALUES('Rupert', 989.99, 50) VALUES IDENTITY_VAL_LOCAL() INTO :IVAR
CREATE TABLE T1 (C1 SMALLINT GENERATED ALWAYS AS IDENTITY, C2 SMALLINT) CREATE TABLE T2 (C1 DECIMAL(15,0) GENERATED BY DEFAULT AS IDENTITY ( START WITH 10 ) , C2 SMALLINT) INSERT INTO T1 ( C2 ) VALUES(5) INSERT INTO T1 ( C2 ) VALUES(5) SELECT * FROM T1
C1 | C2 |
---|---|
1 | 5 |
2 | 5 |
VALUES IDENTITY_VAL_LOCAL() INTO :IVAR
At this point, the IDENTITY_VAL_LOCAL function would return a value of 2 in IVAR. The following INSERT statement inserts a single row into T2 where column C2 gets a value of 2 from the IDENTITY_VAL_LOCAL function.
INSERT INTO T2 ( C2 ) VALUES( IDENTITY_VAL_LOCAL() ) SELECT * FROM T2 WHERE C1 = DECIMAL( IDENTITY_VAL_LOCAL(), 15, 0)
C1 | C2 |
---|---|
10 | 2 |
Invoking the IDENTITY_VAL_LOCAL function after this INSERT would result in a value of 10, which is the value generated by the database manager for column C1 of T2. Assume another single row is inserted into T2. For the following INSERT statement, the database manager assigns a value of 13 to identity column C1 and gives C2 a value of 10 from IDENTITY_VAL_LOCAL. Thus, C2 is given the last identity value that was inserted into T2.
INSERT INTO T2 ( C2, C1 ) VALUES( IDENTITY_VAL_LOCAL(), 13 ) SELECT * FROM T2 WHERE C1 = DECIMAL( IDENTITY_VAL_LOCAL(), 15, 0)
C1 | C2 |
---|---|
13 | 10 |
CREATE TABLE T3 (C1 SMALLINT GENERATED BY DEFAULT AS IDENTITY, C2 SMALLINT)
For the following INSERT statement, specify a value of 25 for the C2 column, and the database manager generates a value of 1 for C1, the identity column. This establishes 1 as the value that will be returned on the next invocation of the IDENTITY_VAL_LOCAL function.
INSERT INTO T3 ( C2 ) VALUES( 25 )
In the following INSERT statement, the IDENTITY_VAL_LOCAL function is invoked to provide a value for the C2 column. A value of 1 (the identity value assigned to the C1 column of the first row) is assigned to the C2 column, and the database manager generates a value of 2 for C1, the identity column. This establishes 2 as the value that will be returned on the next invocation of the IDENTITY_VAL_LOCAL function.
INSERT INTO T3 ( C2 ) VALUES( IDENTITY_VAL_LOCAL() )
In the following INSERT statement, the IDENTITY_VAL_LOCAL function is again invoked to provide a value for the C2 column, and the user provides a value of 11 for C1, the identity column. A value of 2 (the identity value assigned to the C1 column of the second row) is assigned to the C2 column. The assignment of 11 to C1 establishes 11 as the value that will be returned on the next invocation of the IDENTITY_VAL_LOCAL function.
INSERT INTO T3 ( C2, C1 ) VALUES( IDENTITY_VAL_LOCAL(), 11 )
After the 3 INSERT statements have been processed, table T3 contains the following:
C1 | C2 |
---|---|
1 | 25 |
2 | 1 |
11 | 2 |
The contents of T3 illustrate that the expressions in the VALUES clause are evaluated before the assignments for the columns of the INSERT statement. Thus, an invocation of an IDENTITY_VAL_LOCAL function invoked from a VALUES clause of an INSERT statement uses the most recently assigned value for an identity column in a previous INSERT statement.
The IFNULL function returns the value of the first non-null expression.
The IFNULL function is identical to the COALESCE scalar function with two arguments. For more information, see COALESCE.
SELECT EMPNO, IFNULL(SALARY,0) FROM EMPLOYEE
Returns a string where length characters have been deleted from source-string beginning at start and where insert-string has been inserted into source-string beginning at start.
The data type of the result of the function depends on the data type of the first and fourth arguments. The result data type is the same as if the two arguments were concatenated except that the result is always a varying-length string. For more information see Conversion rules for operations that combine strings.
The length attribute of the result depends on the arguments:
L1 - MIN((L1-V2 + 1), V3) + L4where:
L1 is the length attribute of source-string V2 is the value of start V3 is the value of length L4 is the length attribute of insert-string
If the length attribute of the result exceeds the maximum for the result data type, an error is returned.
The actual length of the result is:
A1 - MIN((A1 -V2 + 1), V3) + A4
where:
A1 is the actual length of source-string V2 is the value of start V3 is the value of length A4 is the actual length of insert-string
If the actual length of the result string exceeds the maximum for the result data type, an error is returned.
If any argument can be null, the result can be null; if any argument is null, the result is the null value.
The CCSID of the result is determined by the CCSID of source-string and insert-string. The resulting CCSID is the same as if the two arguments were concatenated. For more information, see Conversion rules for operations that combine strings.
SELECT CHAR(INSERT('INSERTING', 4, 2, 'IS'), 10), CHAR(INSERT('INSERTING', 4, 0, 'IS'), 10), CHAR(INSERT('INSERTING', 4, 2, ''), 10) FROM SYSIBM.SYSDUMMY1This example returns 'INSISTING ', 'INSISERTIN', and 'INSTING '.
SELECT CHAR(INSERT('INSERTING', 1, 0, 'XX'), 10), CHAR(INSERT('INSERTING', 1, 1, 'XX'), 10), CHAR(INSERT('INSERTING', 1, 2, 'XX'), 10), CHAR(INSERT('INSERTING', 1, 3, 'XX'), 10) FROM SYSIBM.SYSDUMMY1This example returns 'XXINSERTIN', 'XXNSERTING', 'XXSERTING ', and 'XXERTING '.
SELECT CHAR(INSERT('ABCABC', 7, 0, 'XX'), 10) FROM SYSIBM.SYSDUMMY1This example returns 'ABCABCXX '.
Numeric to Integer
>>-+-INTEGER-+--(--numeric-expression--)----------------------->< '-INT-----'
String to Integer
>>-+-INTEGER-+--(--string-expression--)------------------------>< '-INT-----'
The INTEGER function returns an integer representation of:
Numeric to Integer
If the argument is a numeric-expression, the result is the same number that would occur if the argument were assigned to a large integer column or variable. If the whole part of the argument is not within the range of integers, an error is returned. The fractional part of the argument is truncated.
String to Integer
If the argument is a string-expression, the result is the same number that would result from CAST( string-expression AS INTEGER). Leading and trailing blanks are eliminated and the resulting string must conform to the rules for forming a floating-point, integer, or decimal constant. If the whole part of the argument is not within the range of integers, an error is returned. Any fractional part of the argument is truncated.
The result of the function is a large integer. If the argument can be null, the result can be null; if the argument is null, the result is the null value.
Syntax alternatives: The CAST specification should be used for maximal portability. For more information, see CAST specification.
SELECT INTEGER(SALARY / EDLEVEL), SALARY, EDLEVEL, EMPNO FROM EMPLOYEE
The JULIAN_DAY function returns an integer value representing a number of days from January 1, 4713 B.C. (the start of the Julian date calendar) to the date specified in the argument.
The result of the function is a large integer. If the argument can be null, the result can be null; if the argument is null, the result is the null value.
SELECT JULIAN_DAY(HIREDATE) INTO :JDAY FROM EMPLOYEE WHERE EMPNO = '000010'The result is that JDAY is set to 2438762.
SELECT JULIAN_DAY('1998-01-01') INTO :JDAY FROM SYSIBM.SYSDUMMY1The result is that JDAY is set to 2450815.
The LAND function returns a string that is the logical 'AND' of the argument strings. This function takes the first argument string, does an AND operation with the next string, and then continues to do AND operations with each successive argument using the previous result. If a character-string or graphic-string argument is encountered that is shorter than the previous result, it is padded with blanks. If a binary-string argument is encountered that is shorter than the previous result, it is padded with hexadecimal zeros.
The arguments must be compatible.
The arguments are converted, if necessary, to the attributes of the result. The attributes of the result are determined as follows:
If an argument can be null, the result can be null; if an argument is null, the result is the null value.
The CCSID of the result is 65535.
SELECT LAND(:L1,:L2,:L3) FROM SYSIBM.SYSDUMMY1Returns the value X'A0B00040'.
The LAST_DAY scalar function returns a date that represents the last day of the month indicated by expression.
If expression is a character or graphic string, it must not be a CLOB or DBCLOB and its value must be a valid string representation of a date or timestamp. For the valid formats of string representations of dates and timestamps, see String representations of datetime values.
The result of the function is a date. If either argument can be null, the result can be null; if either argument is null, the result is the null value.
SET :END_OF_MONTH = LAST_DAY(CURRENT_DATE)
The host variable END_OF_MONTH is set with the value representing the end of the current month. If the current day is 2000-02-10, then END_OF_MONTH is set to 2000-02-29.
SET :END_OF_MONTH = CHAR(LAST_DAY('1965-07-07'), EUR)
The host variable END_OF_MONTH is set with the value '31.07.1965'.
SELECT LAST_DAY('2000-04-24') FROM SYSIBM.SYSDUMMY1
Returns '2000–04–30' which is the last day of April in 2000.
The LCASE function returns a string in which all the characters have been converted to lowercase characters, based on the CCSID of the argument.
The LCASE function is identical to the LOWER function. For more information, see LOWER.
The LEFT function returns the leftmost integer characters of expression.
If expression is a character string, the result is a character string, and each character is one byte. If expression is a graphic string, the result is a graphic string, and each character is a DBCS, UTF-16, or UCS-2 character. If expression is a binary string, the result is a binary string, and each character is one byte.
A substring of expression is zero or more contiguous characters of expression. If expression is a graphic string, a character is a DBCS, UTF–16, or UCS-2 character. If expression is a character string or binary string, a character is a byte.45
The expression is effectively padded on the right with the necessary number of blank characters (or hexadecimal zeroes for binary strings) so that the specified substring of expression always exists.
The result of the function is a varying-length string with a length attribute that is the same as the length attribute of expression and a data type that depends on the data type of expression:
Data type of expression | Data type of the Result |
---|---|
CHAR or VARCHAR | VARCHAR |
CLOB | CLOB |
GRAPHIC or VARGRAPHIC | VARGRAPHIC |
DBCLOB | DBCLOB |
BINARY or VARBINARY | VARBINARY |
BLOB | BLOB |
The actual length of the result is integer.
If any argument can be null, the result can be null; if any argument is null, the result is the null value.
The CCSID of the result is the same as that of expression.
SELECT LEFT(:NAME, :FIRSTNAME_LEN) FROM SYSIBM.SYSDUMMY1Returns the value 'KATIE'
The LENGTH function returns the length of a value. See CHARACTER_LENGTH, OCTET_LENGTH, and BIT_LENGTH for similar functions.
The result of the function is a large integer. If the argument can be null, the result can be null; if the argument is null, the result is the null value.
The result is the length of the argument. The length of strings includes blanks. The length of a varying-length string is the actual length, not the length attribute.
The length of a graphic string is the number of double-byte characters (the number of bytes divided by 2). The length of all other values is the number of bytes used to represent the value:
SELECT LENGTH(:ADDRESS) FROM SYSIBM.SYSDUMMY1Returns the value 18.
SELECT LENGTH(PRSTDATE) FROM PROJECTReturns the value 4.
SELECT LENGTH(CHAR(PRSTDATE, EUR)) FROM PROJECTReturns the value 10.
The LN function returns the natural logarithm of a number. The LN and EXP functions are inverse operations.
The data type of the result is double-precision floating point. If the argument can be null, the result can be null; if the argument is null, the result is the null value.
SELECT LN(:NATLOG) FROM SYSIBM.SYSDUMMY1Returns the approximate value 3.45.
The LNOT function returns a string that is the logical NOT of the argument string.
The data type and length attribute of the result is the same as the data type and length attribute of the argument value. If the argument is a varying-length string, the actual length of the result is the same as the actual length of the argument value. If the argument can be null, the result can be null; if the argument is null, the result is the null value.
The CCSID of the result is 65535.
SELECT LNOT(:L1) FROM SYSIBM.SYSDUMMY1Returns the value X'0F0F'.
The LOCATE function returns the starting position of the first occurrence of one string (called the search-string) within another string (called the source-string). If the search-string is not found and neither argument is null, the result is zero. If the search-string is found, the result is a number from 1 to the actual length of the source-string. If the optional start is specified, it indicates the character position in the source-string at which the search is to begin.
If start is specified, the function is similar to:
POSSTR( SUBSTR(source-string,start) , search-string ) + start - 1
If start is not specified, the function is equivalent to:
POSSTR( source-string , search-string )
For more information, see POSITION or POSSTR.
The result of the function is a large integer. If any of the arguments can be null, the result can be null; if any of the arguments is null, the result is the null value.
If the CCSID of the search-string is different than the CCSID of the source-string, it is converted to the CCSID of the source-string.
If a sort sequence other than *HEX is in effect when the statement that contains the LOCATE function is executed and the arguments are SBCS data, mixed data, or Unicode data, then the result is obtained by comparing weighted values for each value in the set. The weighted values are based on the sort sequence. An ICU sort sequence table may not be specified with the LOCATE function.
SELECT RECEIVED, SUBJECT, LOCATE('GOOD', NOTE_TEXT) FROM IN_TRAY WHERE LOCATE('GOOD', NOTE_TEXT) <> 0
The LOG10 function returns the common logarithm (base 10) of a number. The LOG10 and ANTILOG functions are inverse operations.
The data type of the result is double-precision floating point. If the argument can be null, the result can be null; if the argument is null, the result is the null value.
Syntax alternatives: LOG is a synonym for LOG10. It is supported only for compatibility with previous DB2 releases. LOG10 should be used instead of LOG because some database managers and applications implement LOG as the natural logarithm of a number instead of the common logarithm of a number.
SELECT LOG10(:L) FROM SYSIBM.SYSDUMMY1Returns the approximate value 1.49.
The LOR function returns a string that is the logical OR of the argument strings. This function takes the first argument string, does an OR operation with the next string, and then continues to do OR operations for each successive argument using the previous result. If a character-string or graphic-string argument is encountered that is shorter than the previous result, it is padded with blanks. If a binary-string argument is encountered that is shorter than the previous result, it is padded with hexadecimal zeros.
The arguments must be compatible.
The arguments are converted, if necessary, to the attributes of the result. The attributes of the result are determined as follows:
If an argument can be null, the result can be null; if an argument is null, the result is the null value.
The CCSID of the result is 65535.
SELECT LOR(:L1,:L2,:L3) FROM SYSIBM.SYSDUMMY1Returns the value X'F1F1400F'.
The LOWER function returns a string in which all the characters have been converted to lowercase characters, based on the CCSID of the argument. Only SBCS, UTF-16, and UCS-2 graphic characters are converted. The characters A-Z are converted to a-z, and characters with diacritical marks are converted to their lowercase equivalent, if any. Refer to the UCS-2 level 1 mapping tables section of the Globalization topic in the iSeries Information Center for a description of the monocasing tables that are used for this translation.
The result of the function has the same data type, length attribute, actual length, and CCSID as the argument. If the argument can be null, the result can be null. If the argument is null, the result is the null value.
When LOWER is specified in a query, the query cannot contain:
Syntax alternatives: LCASE is a synonym for LOWER.
SELECT LOWER(:NAME) FROM SYSIBM.SYSDUMMY1The result is the value 'christine smith'.
The LTRIM function removes blanks or hexadecimal zeros from the beginning of an expression. 46
The data type of the result depends on the data type of expression:
Data type of expression | Data type of the Result |
---|---|
CHAR or VARCHAR | VARCHAR |
CLOB | CLOB |
GRAPHIC or VARGRAPHIC | VARGRAPHIC |
DBCLOB | DBCLOB |
BINARY or VARBINARY | VARBINARY |
BLOB | BLOB |
The length attribute of the result is the same as the length attribute of expression. The actual length of the result is the length of expression minus the number of bytes removed. If all characters are removed, the result is an empty string.
If the first argument can be null, the result can be null; if the first argument is null, the result is the null value.
The CCSID of the result is the same as that of the string.
SELECT LTRIM(:HELLO) FROM SYSIBM.SYSDUMMY1Results in: 'Hello'.
The MAX scalar function returns the maximum value in a set of values.
The arguments must be compatible. Character-string arguments are compatible with datetime values. The arguments cannot be DataLink values.
The result of the function is the largest argument value. The result can be null if at least one argument can be null; the result is the null value if one of the arguments is null.
The selected argument is converted, if necessary, to the attributes of the result. The attributes of the result are determined by all the operands as explained in Rules for result data types.
If a sort sequence other than *HEX is in effect when the statement is executed and the arguments are SBCS data, mixed data, or Unicode data, the weighted values of the strings are compared instead of the actual values. The weighted values are based on the sort sequence.
SELECT MAX(:M1,:M2,:M3) FROM SYSIBM.SYSDUMMY1Returns the value 6.25.
SELECT MAX(:M1,:M2,:M3) FROM SYSIBM.SYSDUMMY1Returns the value 'AA A'.
The MICROSECOND function returns the microsecond part of a value.
The result of the function is a large integer. If the argument can be null, the result can be null; if the argument is null, the result is the null value.
The other rules depend on the data type of the argument:
The result is the microsecond part of the value, which is an integer between 0 and 999999.
The result is the microsecond part of the value, which is an integer between -999999 and 999999. A nonzero result has the same sign as the argument.
SELECT * FROM TABLEA WHERE MICROSECOND(TS1) <> 0 AND SECOND(TS1) = SECOND(TS2)
The MIDNIGHT_SECONDS function returns an integer value that is greater than or equal to 0 and less than or equal to 86 400® representing the number of seconds between midnight and the time value specified in the argument.
The result of the function is large integer. If the argument can be null, the result can be null; if the argument is null, the result is the null value.
SELECT MIDNIGHT_SECONDS(:XTIME1), MIDNIGHT_SECONDS(:XTIME2) FROM SYSIBM.SYSDUMMY1This example returns 60 and 47410. Because there are 60 seconds in a minute and 3600 seconds in an hour, 00:01:00 is 60 seconds after midnight ((60 * 1) + 0), and 13:10:10 is 47410 seconds ((3600 * 13) + (60 * 10) + 10).
SELECT MIDNIGHT_SECONDS('24:00:00'), MIDNIGHT_SECONDS('00:00:00') FROM SYSIBM.SYSDUMMY1This example returns 86400 and 0. Although these two values represent the same point in time, different values are returned.
The MIN scalar function returns the minimum value in a set of values.
The arguments must be compatible. Character-string arguments are compatible with datetime values. The arguments cannot be DataLink values.
The result of the function is the smallest argument value. The result can be null if at least one argument can be null; the result is the null value if one of the arguments is null.
The selected argument is converted, if necessary, to the attributes of the result. The attributes of the result are determined by all the operands as explained in Rules for result data types.
If a sort sequence other than *HEX is in effect when the statement is executed and the arguments are SBCS data, mixed data, or Unicode data, the weighted values of the strings are compared instead of the actual values. The weighted values are based on the sort sequence.
SELECT MIN(:M1,:M2,:M3) FROM SYSIBM.SYSDUMMY1Returns the value 4.50.
SELECT MIN(:M1,:M2,:M3) FROM SYSIBM.SYSDUMMY1Returns the value 'AA '.
The MINUTE function returns the minute part of a value.
The result of the function is a large integer. If the argument can be null, the result can be null; if the argument is null, the result is the null value.
The other rules depend on the data type of the argument:
The result is the minute part of the value, which is an integer between 0 and 59.
The result is the minute part of the value, which is an integer between -99 and 99. A nonzero result has the same sign as the argument.
SELECT * FROM CL_SCHED WHERE HOUR(ENDING - STARTING) = 0 AND MINUTE(ENDING - STARTING) < 50
The MOD function divides the first argument by the second argument and returns the remainder.
The formula used to calculate the remainder is:
MOD(x,y) = x - (x/y) * y
where x/y is the truncated integer result of the division. The result is negative only if first argument is negative.
If an argument can be null, the result can be null; if an argument is null, the result is the null value.
The attributes of the result are determined as follows:
The operation is performed in floating point; the operands having been first converted to double-precision floating-point numbers, if necessary.
An operation involving a floating-point number and an integer is performed with a temporary copy of the integer that has been converted to double-precision floating point. An operation involving a floating-point number and a decimal number is performed with a temporary copy of the decimal number that has been converted to double-precision floating point. The result of a floating-point operation must be within the range of floating-point numbers.
SELECT MOD(:M1,:M2) FROM SYSIBM.SYSDUMMY1Returns the value 1.
SELECT MOD(:M1,:M2) FROM SYSIBM.SYSDUMMY1Returns the value 0.60.
SELECT MOD(:M1,:M2) FROM SYSIBM.SYSDUMMY1Returns the value 1.50.
The MONTH function returns the month part of a value.
The result of the function is a large integer. If the argument can be null, the result can be null; if the argument is null, the result is the null value.
The other rules depend on the data type of the argument:
The result is the month part of the value, which is an integer between 1 and 12.
The result is the month part of the value, which is an integer between -99 and 99. A nonzero result has the same sign as the argument.
SELECT * FROM EMPLOYEE WHERE MONTH(BIRTHDATE) = 12
Returns a mixed case character string containing the name of the month (e.g. January) for the month portion of the argument.
If expression is a character or graphic string, it must not be a CLOB or DBCLOB and its value must be a valid string representation of a date or timestamp. For the valid formats of string representations of dates and timestamps, see String representations of datetime values.
The result of the function is VARCHAR(100). If the argument can be null, the result can be null; if the argument is null, the result is the null value.
The CCSID of the result is the default CCSID of the current server.
National language considerations: The name of the month that is returned is based on the language used for messages in the job. This name of the month is retrieved from message CPX3BC0 in message file QCPFMSG in library *LIBL.
SELECT MONTHNAME( '2003-01-02' ) FROM SYSIBM.SYSDUMMY1Results in 'January'.
The MULTIPLY_ALT scalar function returns the product of the two arguments as a decimal value. It is provided as an alternative to the multiplication operator, especially when the sum of the precisions of the arguments exceeds 63.
The result of the function is a DECIMAL. The precision and scale of the result are determined as follows, using the symbols p and s to denote the precision and scale of the first argument, and the symbols p' and s' to denote the precision and scale of the second argument.
For information on the values of p, s, ms, and mp, see Decimal arithmetic in SQL.
The result can be null if at least one argument can be null; the result is the null value if one of the arguments is null.
The MULTIPLY_ALT function is a better choice than the multiplication operator when performing decimal arithmetic where a scale of at least 3 is desired and the sum of the precisions exceeds 63. In these cases, the internal computation is performed so that overflows are avoided and then assigned to the result type value using truncation for any loss of scale in the final result. Note that the possibility of overflow of the final result is still possible when the scale is 3.
The following table compares the result types using MULTIPLY_ALT and the multiplication operator when the maximum precision is 31 and the maximum scale is 31:
Type of Argument 1 | Type of Argument 2 | Result using MULTIPLY_ALT | Result using multiplication operator |
---|---|---|---|
DECIMAL(31,3) | DECIMAL(15,8) | DECIMAL(31,3) | DECIMAL(31,11) |
DECIMAL(26,23) | DECIMAL(10,1) | DECIMAL(31,19) | DECIMAL(31,24) |
DECIMAL(18,17) | DECIMAL(20,19) | DECIMAL(31,29) | DECIMAL(31,31) |
DECIMAL(16,3) | DECIMAL(17,8) | DECIMAL(31,9) | DECIMAL(31,11) |
DECIMAL(26,5) | DECIMAL(11,0) | DECIMAL(31,3) | DECIMAL(31,5) |
DECIMAL(21,1) | DECIMAL(15,1) | DECIMAL(31,2) | DECIMAL(31,2) |
SELECT MULTIPLY_ALT(98765432109876543210987.654,5.43210987) FROM SYSIBM.SYSDUMMY1Returns the value 536504678578875294857887.5277415.
Note that the complete product of these two numbers is 536504678578875294857887.52774154498, but the last 4 digits are truncated to match the scale of the result data type. Using the multiplication operator with the same values will cause an arithmetic overflow, since the result data type is DECIMAL(31,11) and the result value has 24 digits left of the decimal, but the result data type only supports 20 digits.
The NEXT_DAY function returns a timestamp that represents the first weekday, named by string-expression, that is later than the date expression. If expression is a timestamp or valid string representation of a timestamp, the timestamp value has the same hours, minutes, seconds, and microseconds as expression. If expression is a date, or a valid string representation of a date, then the hours, minutes, seconds, and microseconds value of the result is 0.
If expression is a character or graphic string, it must not be a CLOB or DBCLOB and its value must be a valid string representation of a date or timestamp. For the valid formats of string representations of dates and timestamps, see String representations of datetime values.
Day of Week | Abbreviation |
---|---|
MONDAY | MON |
TUESDAY | TUE |
WEDNESDAY | WED |
THURSDAY | THU |
FRIDAY | FRI |
SATURDAY | SAT |
SUNDAY | SUN |
The result of the function is a timestamp. If either argument can be null, the result can be null; if either argument is null, the result is the null value.
The CCSID of the result is the default CCSID of the current server.
National language considerations: The values of the days of the week (or abbreviations) in string-expression may either be the US English values listed in the table above or the values based on the language used for messages in the job. The non-abbreviated name of the day is retrieved from message CPX9034 in message file QCPFMSG in library *LIBL. The abbreviated name of the day is retrieved from message CPX9039 in message file QCPFMSG in library *LIBL.
Applications that need to run in many different language environments may want to consider using US English values since they will always be accepted in the NEXT_DAY function.
SET :NEXTDAY = NEXT_DAY(CURRENT_DATE, 'TUESDAY')
The host variable NEXTDAY is set with the value of '2000–04–25–00.00.00.000000', assuming that the value of the CURRENT_DATE special register is '2000–04–24'.
SET :NEXTDAY = NEXT_DAY(LAST_DAY(CURRENT_TIMESTAMP), :DAYHV)
The host variable NEXTDAY is set with the value of '2000-05-01-12.01.01.123456', assuming that the value of the CURRENT_TIMESTAMP special register is '2000-04-24-12.01.01.123456'.
SELECT NEXT_DAY('2000-04-24', 'TUESDAY') FROM SYSIBM.SYSDUMMY1
Returns '2000-04-25-00.00.00.000000', which is the Tuesday following '2000-04-24'.
The NOW function returns a timestamp based on a reading of the time-of-day clock when the SQL statement is executed at the current server. The value returned by the NOW function is the same as the value returned by the CURRENT_TIMESTAMP special register. If this function is used more than once within a single SQL statement, or used with the CURDATE or CURTIME scalar functions or the CURRENT_DATE, CURRENT_TIME, or CURRENT_TIMESTAMP special registers within a single statement, all values are based on a single clock reading.
The data type of the result is a timestamp. The result cannot be null.
Syntax alternatives: The CURRENT_TIMESTAMP special register should be used for maximal portability. For more information, see Special registers.
SELECT NOW() FROM SYSIBM.SYSDUMMY1
The NULLIF function returns a null value if the arguments compare equal, otherwise it returns the value of the first argument.
The attributes of the result are the attributes of the first argument. The result can be null. The result is null if the first argument is null or if both arguments are equal.
The result of using NULLIF(e1,e2) is the same as using the expression
CASE WHEN e1=e2 THEN NULL ELSE e1 END
Note that when e1=e2 evaluates to unknown (because one or both arguments is NULL), CASE expressions consider this not true. Therefore, in this situation, NULLIF returns the value of the first operand, e1.
SELECT NULLIF (:PROFIT + :CASH, :LOSSES ) FROM SYSIBM.SYSDUMMY1Returns the null value.
The OCTET_LENGTH function returns the length of a string expression in octets (bytes). See LENGTH and CHARACTER_LENGTH for similar functions.
The result of the function is DECIMAL(31). If the argument can be null, the result can be null; if the argument is null, the result is the null value.
The result is the number of octets (bytes) in the argument. The length of a string includes trailing blanks. The length of a varying-length string is the actual length in octets (bytes), not the maximum length.
SELECT OCTET_LENGTH( C1 ) FROM T1Returns the value 20.
Returns the value of π 3.141592653589793. There are no arguments.
The result of the function is double-precision floating-point. The result cannot be null.
SELECT PI()*10 FROM SYSIBM.SYSDUMMY1
>>-+-POSITION--(--search-string--IN--source-string--)-+-------->< '-POSSTR--(--source-string--,--search-string--)----'
The POSITION and POSSTR functions return the starting position of the first occurrence of one string (called the search-string) within another string (called the source-string). If the search-string is not found and neither argument is null, the result is zero. If the search-string is found, the result is a number from 1 to the actual length of the source-string. See the related function, LOCATE.
If either argument is a UTF-8 or UTF-16 string, the query cannot contain:
The result of the function is a large integer. If either of the arguments can be null, the result can be null. If either of the arguments is null, the result is the null value.
The POSITION function operates on a character basis. The POSSTR function operates on a strict byte-count basis. It is recommended that if either the search-string or source-string contains mixed data, POSITION should be used instead of POSSTR. Because POSSTR operates on a strict byte-count basis, if the search-string or source-string contains mixed data, the search-string will only be found if any shift-in and shift-out characters are also found in the source-string in exactly the same positions. Because POSITION operates on a character-string basis, any shift-in and shift-out characters are not required to be in exactly the same position and their only significance is to indicate which characters are SBCS and which characters are DBCS.
If the CCSID of the search-string is different than the CCSID of the source-string, it is converted to the CCSID of the source-string.
If a sort sequence other than *HEX is in effect when the statement that contains the POSSTR or POSITION function is executed and the arguments are SBCS data, mixed data, or Unicode data, then the result is obtained by comparing weighted values for each value in the set. The weighted values are based on the sort sequence. An ICU sort sequence table may not be specified with the POSSTR or POSITION function.
If the search-string has a length of zero, the result returned by the function is 1. Otherwise:
SELECT RECEIVED, SUBJECT, POSSTR(NOTE_TEXT, 'GOOD') FROM IN_TRAY WHERE POSSTR(NOTE_TEXT, 'GOOD') <> 0
The POWER function returns the result of raising the first argument to the power of the second argument. 48
The result of the function is a double-precision floating-point number. If both arguments are 0, the result is 1. If an argument can be null, the result can be null; if an argument is null, the result is the null value.
SELECT POWER(2,:HPOWER) FROM SYSIBM.SYSDUMMY1Returns the value 8.
The QUARTER function returns an integer between 1 and 4 that represents the quarter of the year in which the date resides. For example, any dates in January, February, or March will return the integer 1.
If expression is a character or graphic string, it must not be a CLOB or DBCLOB and its value must be a valid string representation of a date or timestamp. For the valid formats of string representations of dates and timestamps, see String representations of datetime values.
The result of the function is a large integer. If the argument can be null, the result can be null; if the argument is null, the result is the null value.
SELECT QUARTER(PRENDATE) INTO :QUART FROM PROJECT WHERE PROJNO = 'PL2100'Results in QUART being set to 3.
The RADIANS function returns the number of radians for an argument that is expressed in degrees.
The data type of the result is double-precision floating point. If the argument can be null, the result can be null; if the argument is null, the result is the null value.
SELECT RADIANS(:HDEG) FROM SYSIBM.SYSDUMMY1Returns a double precision floating-point number with an approximate value of 3.1415926536.
The RAISE_ERROR function causes the statement that invokes the function to return an error with the specified SQLSTATE (along with SQLCODE -438) and error condition. The RAISE_ERROR function always returns NULL with an undefined data type.
If the SQLSTATE does not conform to these rules, an error is returned.
If an SQLCA is used,
Since the data type of the result of RAISE_ERROR is undefined, it may only be used where parameter markers are allowed. To use this function in a context where parameter markers are not allowed (such as alone in a select list), you must use a cast specification to give a data type to the null value that is returned. The RAISE_ERROR function cannot be used with CASE expressions.
CREATE TRIGGER EMPISRT1 AFTER INSERT ON EMPLOYEE REFERENCING NEW AS N FOR EACH ROW MODE DB2SQL BEGIN ATOMIC IF N.BONUS > 20000 THEN VALUES( RAISE_ERROR( 'ZZZZZ', 'Incorrect bonus' ) ); END IF; END
The RAND function returns a floating point value between 0 and 1.
The data type of the result is double-precision floating point. If the argument can be null, the result can be null; if the argument is null, the result is the null value.
A specific seed value will produce the same sequence of random numbers for a specific instance of a RAND function in a query each time the query is executed. If a seed value is not specified, a different sequence of random numbers is produced each time the query is executed.
RAND is a non-deterministic function.
SELECT RAND(:HRAND) FROM SYSIBM.SYSDUMMY1Returns a random floating-point number between 0 and 1, such as the approximate value .0121398.
SELECT RAND(:HRAND) * 10 FROM SYSIBM.SYSDUMMY1
Numeric to Real
>>-REAL--(--numeric-expression--)------------------------------><
String to Real
>>-REAL--(--string-expression--)-------------------------------><
The REAL function returns a single-precision floating-point representation of:
Numeric to Real
The result is the same number that would occur if the argument were assigned to a single-precision floating-point column or variable. If the numeric value of the argument is not within the range of single-precision floating-point, an error is returned.
String to Real
If the argument is a string-expression, the result is the same number that would result from CAST( string-expression AS REAL). Leading and trailing blanks are eliminated and the resulting string must conform to the rules for forming a floating-point, integer, or decimal constant. If the numeric value of the argument is not within the range of single-precision floating-point, an error is returned.
The single-byte character constant that must be used to delimit the decimal digits in string-expression from the whole part of the number is the default decimal point. For more information, see Decimal point.
The result of the function is a single-precision floating-point number. If the argument can be null, the result can be null; if the argument is null, the result is the null value.
Syntax alternatives: The CAST specification should be used for maximal portability. For more information, see CAST specification.
SELECT EMPNO, REAL(SALARY)/COMM FROM EMPLOYEE WHERE COMM > 0
The REPEAT function returns a string composed of expression repeated integer times.
The data type of the result of the function depends on the data type of the first argument:
Data type of string-expression | Data type of the Result |
---|---|
CHAR or VARCHAR or any numeric type | VARCHAR |
CLOB | CLOB |
GRAPHIC or VARGRAPHIC | VARGRAPHIC |
DBCLOB | DBCLOB |
BINARY or VARBINARY | VARBINARY |
BLOB | BLOB |
If integer is a constant, the length attribute of the result is the length attribute of string-expression times integer. Otherwise, the length attribute depends on the data type of the result:
If the length attribute of the result exceeds the maximum for the result data type, an error is returned.
The actual length of the result is the actual length of string-expression times integer. If the actual length of the result string exceeds the maximum for the return type, an error is returned.
If either argument can be null, the result can be null; if either argument is null, the result is the null value.
The CCSID of the result is the CCSID of string-expression.49
SELECT REPEAT('abc', 2) FROM SYSIBM.SYSDUMMY1
SELECT CHAR( REPEAT('REPEAT THIS', 5), 60) FROM SYSIBM.SYSDUMMY1This example results in 'REPEAT THISREPEAT THISREPEAT THISREPEAT THISREPEAT THIS '.
SELECT LENGTH( REPEAT('REPEAT THIS', 0) ) FROM SYSIBM.SYSDUMMY1
SELECT LENGTH( REPEAT('', 5) ) FROM SYSIBM.SYSDUMMY1
The REPLACE function replaces all occurrences of search-string in source-string with replace-string. If search-string is not found in source-string, source-string is returned unchanged.
source-string, search-string, and replace-string must be compatible. For more information about data type compatibility, see Assignments and comparisons.
The data type of the result of the function depends on the data type of the arguments. The result data type is the same as if the three arguments were concatenated except that the result is always a varying-length string. For more information see Conversion rules for operations that combine strings.
The length attribute of the result depends on the arguments:
(L3 * L1)
(L3 * (L1/L2)) + MOD(L1,L2)
where:
L1 is the length attribute of source-string L2 is the length attribute of search-string L3 is the length attribute of replace-string
If the length attribute of the result exceeds the maximum for the result data type, an error is returned.
The actual length of the result is the actual length of source-string plus the number of occurrences of search-string that exist in source-string multiplied by the actual length of replace-string minus the actual length of search-string. If the actual length of the result string exceeds the maximum for the result data type, an error is returned.
If any argument can be null, the result can be null; if any argument is null, the result is the null value.
The CCSID of the result is determined by the CCSID of source-string, search-string, and replace-string. The resulting CCSID is the same as if the three arguments were concatenated. For more information, see Conversion rules for operations that combine strings.
SELECT CHAR(REPLACE( 'DINING', 'N', 'VID' ), 10), FROM SYSIBM.SYSDUMMY1The result is the string 'DIVIDIVIDG'.
SELECT REPLACE( 'ABCXYZ', 'ABC', '' ) FROM SYSIBM.SYSDUMMY1The result is the string 'XYZ'.
SELECT REPLACE( 'ABCCABCC', 'ABC', 'AB') ) FROM SYSIBM.SYSDUMMY1The result is the string 'ABCABC'.
The RIGHT function returns the rightmost integer characters of expression.
If expression is a character string, the result is a character string, and each character is one byte. If expression is a graphic string, the result is a graphic string, and each character is a DBCS, UTF-16, or UCS-2 character. If expression is a binary string, the result is a binary string, and each character is one byte.
A substring of expression is zero or more contiguous characters of expression. If expression is a graphic string, a character is a DBCS, UTF-16, or UCS-2 character. If expression is a character string or binary string, a character is a byte.50
The expression is effectively padded on the right with the necessary number of blank characters (or hexadecimal zeroes for binary strings) so that the specified substring of expression always exists.
The result of the function is a varying-length string with a length attribute that is the same as the length attribute of expression and a data type that depends on the data type of expression:
Data type of expression | Data type of the Result |
---|---|
CHAR or VARCHAR | VARCHAR |
CLOB | CLOB |
GRAPHIC or VARGRAPHIC | VARGRAPHIC |
DBCLOB | DBCLOB |
BINARY or VARBINARY | VARBINARY |
BLOB | BLOB |
The actual length of the result is integer.
If any argument can be null, the result can be null; if any argument is null, the result is the null value.
The CCSID of the result is the same as that of expression.
SELECT RIGHT( :ALPHA, 3) FROM SYSIBM.SYSDUMMY1Returns the value 'DEF', which are the three rightmost characters in ALPHA.
SELECT RIGHT( 'ABCABC', 0) FROM SYSIBM.SYSDUMMY1
The ROUND function returns expression–1 rounded to some number of places to the right or left of the decimal point.
If expression–2 is positive, expression–1 is rounded to the expression–2 number of places to the right of the decimal point.
If expression–2 is negative, expression–1 is rounded to 1 + (the absolute value of expression–2) number of places to the left of the decimal point. If the absolute value of expression–2 is greater than the number of digits to the left of the decimal point, the result is 0. (For example, ROUND(748.58,-4) returns 0.)
If expression–1 is positive, a digit value of 5 is rounded to the next higher positive number. If expression–1 is negative, a digit value of 5 is rounded to the next lower negative number.
The data type and length attribute of the result are the same as the data type and length attribute of the first argument, except that precision is increased by one if expression–1 is DECIMAL or NUMERIC and the precision is less than the maximum precision (mp). For example, an argument with a data type of DECIMAL(5,2) will result in DECIMAL(6,2). An argument with a data type of DECIMAL(63,2) will result in DECIMAL(63,2).
If either argument can be null, the result can be null. If either argument is null, the result is the null value.
SELECT ROUND(873.726, 2), ROUND(873.726, 1), ROUND(873.726, 0), ROUND(873.726, -1), ROUND(873.726, -2), ROUND(873.726, -3), ROUND(873.726, -4) FROM SYSIBM.SYSDUMMY1Returns the following values, respectively:
0873.730 0873.700 0874.000 0870.000 0900.000 1000.000 0000.000
SELECT ROUND( 3.5, 0), ROUND( 3.1, 0), ROUND(-3.1, 0), ROUND(-3.5, 0) FROM SYSIBM.SYSDUMMY1
Returns the following examples, respectively:
04.0 03.0 -03.0 -04.0
The ROWID function casts a character string to a row ID.
If the actual length of string-expression is less than 40, the result is not padded. If the actual length of string-expression is greater than 40, the result is truncated. If non-blank characters are truncated, a warning is returned.
The length attribute of the result is 40. The actual length of the result is the length of string-expression.
The result of the function is a row ID. If the argument can be null, the result can be null; if the argument is null, the result is the null value.
Syntax alternatives: The CAST specification should be used for maximal portability. For more information, see CAST specification.
SELECT EMPNO FROM EMPLOYEE WHERE EMP_ROWID = ROWID(X'F0DFD230E3C0D80D81C201AA0A280100000000000203')
The RRN function returns the relative record number of a row.
In SQL naming, the table name may be qualified. In system naming, the table name cannot be qualified.
If the argument identifies a view, common table expression, or derived table, the function returns the relative record number of its base table. If the argument identifies a view, common table expression, or derived table derived from more than one base table, the function returns the relative record number of the first table in the outer subselect of the view, common table expression, or derived table.
If the argument identifies a distributed table, the function returns the relative record number of the row on the node where the row is located. If the argument identifies a partitioned table, the function returns the relative record number of the row in the partition where the row is located. This means that RRN will not be unique for each row of a partitioned or distributed table.
The argument must not identify a view, common table expression, or derived table whose outer subselect includes an aggregate function, a GROUP BY clause, a HAVING clause, a UNION clause, an INTERSECT clause, or DISTINCT clause. The RRN function cannot be specified in a SELECT clause if the subselect contains an aggregate function, a GROUP BY clause, or a HAVING clause. If the argument is a correlation name, the correlation name must not identify a correlated reference.
The data type of the result is a decimal with precision 15 and scale 0. The result can be null.
SELECT RRN(EMPLOYEE), LASTNAME FROM EMPLOYEE WHERE DEPTNO = 20
The RTRIM function removes blanks or hexadecimal zeroes from the end of a string expression. 51
The data type of the result depends on the data type of string-expression:
Data type of string-expression | Data type of the Result |
---|---|
CHAR or VARCHAR | VARCHAR |
CLOB | CLOB |
GRAPHIC or VARGRAPHIC | VARGRAPHIC |
DBCLOB | DBCLOB |
BINARY or VARBINARY | VARBINARY |
BLOB | BLOB |
The length attribute of the result is the same as the length attribute of string-expression. The actual length of the result is the length of the expression minus the number of bytes removed. If all characters are removed, the result is an empty string.
If the first argument can be null, the result can be null; if the first argument is null, the result is the null value.
The CCSID of the result is the same as that of the string.
SELECT RTRIM(:HELLO) FROM SYSIBM.SYSDUMMY1Results in: 'Hello'.
The SECOND function returns the seconds part of a value.
The result of the function is a large integer. If the argument can be null, the result can be null; if the argument is null, the result is the null value.
The other rules depend on the data type of the argument:
The result is the seconds part of the value, which is an integer between 0 and 59.
The result is the seconds part of the value, which is an integer between -99 and 99. A nonzero result has the same sign as the argument.
SELECT SECOND(:TIME_DUR) FROM SYSIBM.SYSDUMMY1Returns the value 45.
SELECT SECOND(RECEIVED) FROM IN_TRAYReturns the value 30.
The SIGN function returns an indicator of the sign of expression. The returned value is:
The result has the same data type and length attribute as the argument, except that precision is increased by one if the argument is DECIMAL or NUMERIC and the scale of the argument is equal to its precision. For example, an argument with a data type of DECIMAL(5,5) will result in DECIMAL(6,5). If the precision is already the maximum precision (mp), the scale will be decreased by one. For example, DECIMAL(63,63) will result in DECIMAL(63,62).
If the argument can be null, the result can be null; if the argument is null, the result is the null value.
SELECT SIGN(:PROFIT) FROM EMPLOYEEReturns the value 1.
The SIN function returns the sine of the argument, where the argument is an angle expressed in radians. The SIN and ASIN functions are inverse operations.
The data type of the result is double-precision floating point. If the argument can be null, the result can be null; if the argument is null, the result is the null value.
SELECT SIN(:SINE) FROM SYSIBM.SYSDUMMY1Returns the approximate value 0.99.
The SINH function returns the hyperbolic sine of the argument, where the argument is an angle expressed in radians.
The data type of the result is double-precision floating point. If the argument can be null, the result can be null; if the argument is null, the result is the null value.
SELECT SINH(:HSINE) FROM SYSIBM.SYSDUMMY1Returns the approximate value 2.12.
Numeric to Smallint
>>-SMALLINT--(--numeric-expression--)--------------------------><
String to Smallint
>>-SMALLINT--(--string-expression--)---------------------------><
The SMALLINT function returns a small integer representation of
Numeric to Smallint
The result is the same number that would occur if the argument were assigned to a small integer column or variable. If the whole part of the argument is not within the range of small integers, an error is returned. The fractional part of the argument is truncated.
String to Smallint
If the argument is a string-expression, the result is the same number that would result from CAST( string-expression AS SMALLINT). Leading and trailing blanks are eliminated and the resulting string must conform to the rules for forming a floating-point, integer, or decimal constant. If the whole part of the argument is not within the range of small integers, an error is returned. Any fractional part of the argument is truncated.
The result of the function is a small integer. If the argument can be null, the result can be null. If the argument is null, the result is the null value.
Syntax alternatives: The CAST specification should be used for maximal portability. For more information, see CAST specification.
SELECT SMALLINT(SALARY / EDLEVEL), SALARY, EDLEVEL, EMPNO FROM EMPLOYEE
The SOUNDEX function returns a 4 character code representing the sound of the words in the argument. The result can be used to compare with the sound of other strings.
The data type of the result is CHAR(4). If the argument can be null, the result can be null; if the argument is null, the result is the null value.
The CCSID of the result is the default CCSID of the current server.
The SOUNDEX function is useful for finding strings for which the sound is known but the precise spelling is not. It makes assumptions about the way that letters and combinations of letters sound that can help to search out words with similar sounds. The comparison can be done directly or by passing the strings as arguments to the DIFFERENCE function. For more information, see DIFFERENCE.
SELECT EMPNO, LASTNAME FROM EMPLOYEE WHERE SOUNDEX(LASTNAME) = SOUNDEX('Loucesy')Returns the row:
000110 LUCCHESSI
The SPACE function returns a character string that consists of the number of SBCS blanks that the argument specifies.
The expression specifies the number of SBCS blanks for the result, and it must be between 0 and 32740. If expression is a constant, it must not be the constant 0.
The result of the function is a varying-length character string (VARCHAR) that contains SBCS data.
If expression is a constant, the length attribute of the result is the constant. Otherwise, the length attribute of the result is 4000. The actual length of the result is the value of expression. The actual length of the result must not be greater than the length attribute of the result.
If the argument can be null, the result can be null; if the argument is null, the result is the null value.
The CCSID is the default CCSID for SBCS data of the job.
SELECT SPACE(5) FROM SYSIBM.SYSDUMMY1
The SQRT function returns the square root of a number.
The data type of the result is double-precision floating point. If the argument can be null, the result can be null; if the argument is null, the result is the null value.
SELECT SQRT(:SQUARE) FROM SYSIBM.SYSDUMMY1Returns the approximate value 3.00.
>>-STRIP--(--expression--+-----------------------------------------+--)->< '-+-,--BOTH-----+--+--------------------+-' +-,--B--------+ '-,--strip-character-' +-,--LEADING--+ +-,--L--------+ +-,--TRAILING-+ '-,--T--------'
The STRIP function removes blanks or another specified character from the end and/or beginning of a string expression.
The STRIP function is identical to the TRIM scalar function. For more information, see TRIM.
>>-+-+-SUBSTR----+--(--expression--,--start--+-----------+--)---+->< | '-SUBSTRING-' '-,--length-' | '-SUBSTRING--(--expression--FROM--start--+--------------+--)-' '- FOR--length-'
The SUBSTR and SUBSTRING functions return a substring of a string.
Expression must be any built-in numeric or string data type. A numeric argument is cast to a character string before evaluating the function. For more information on converting numeric to a character string, see VARCHAR. If expression is a character string, the result of the function is a character string. If it is a graphic string, the result of the function is a graphic string. If it is a binary string, the result of the function is a binary string.
A substring of expression is zero or more contiguous characters of expression. If expression is a graphic string, a character is a DBCS, UTF-16, or UCS-2 character. If expression is a character string and the function is SUBSTRING, a character is a character that may consist of one or more bytes. If expression is a character string and the function is SUBSTR, a character is a byte.52 If expression is a binary string, a character is a byte.
If the function is SUBSTRING and the argument is a UTF-8 or UTF-16 string, the query cannot contain:
If SUBSTR is specified and length is explicitly specified, expression is effectively padded on the right with the necessary number of blank characters so that the specified substring of expression always exists. Hexadecimal zeroes are used as the padding character when expression is a binary string.
If SUBSTRING is specified and length is explicitly specified, padding is not performed.
If expression is a fixed-length string, omission of length is an implicit specification of LENGTH(expression) - start + 1, which is the number of characters (or bytes) from the start character (or byte) to the last character (or byte) of expression. If expression is a varying-length string, omission of length is an implicit specification of zero or LENGTH(expression) - start + 1, whichever is greater. If the resulting length is zero, the result is the empty string.
The data type of the result depends on the data type of expression and whether the function is a SUBSTR or SUBSTRING:
Data type of expression | Data Type of the Result for SUBSTRING | Data Type of the Result for SUBSTR |
---|---|---|
CHAR or VARCHAR | VARCHAR | CHAR, if:
|
CLOB | CLOB | CLOB |
GRAPHIC or VARGRAPHIC | VARGRAPHIC | GRAPHIC, if:
|
DBCLOB | DBCLOB | DBCLOB |
BINARY or VARBINARY | VARBINARY | BINARY, if:
|
BLOB | BLOB | BLOB |
If the SUBSTRING function is specified, the length attribute of the result is equal to the length attribute of expression.
If the SUBSTR function is specified and expression is not a LOB, the length attribute of the result depends on length, start, and the attributes of expression.
In all other cases, the length attribute of the result is the same as the length attribute of expression. (Remember that if the actual length of expression is less than the value for start, the actual length of the substring is zero.)
If any argument of the SUBSTR function can be null, the result can be null; if any argument is null, the result is the null value.
The CCSID of the result is the same as that of expression.
SELECT SUBSTR(:NAME, :SURNAME_POS) FROM SYSIBM.SYSDUMMY1Returns the value 'AUSTIN'.
SELECT SUBSTR(:NAME, :SURNAME_POS, 1) FROM SYSIBM.SYSDUMMY1Returns the value 'A'.
SELECT * FROM PROJECT WHERE SUBSTR(PROJNAME,1,10) = 'OPERATION 'The space at the end of the constant is necessary to preclude initial words such as 'OPERATIONS'.
The TAN function returns the tangent of the argument, where the argument is an angle expressed in radians. The TAN and ATAN functions are inverse operations.
The data type of the result is double-precision floating point. If the argument can be null, the result can be null; if the argument is null, the result is the null value.
SELECT TAN(:TANGENT) FROM SYSIBM.SYSDUMMY1Returns the approximate value 14.10.
The TANH function returns the hyperbolic tangent of the argument, where the argument is an angle expressed in radians. The TANH and ATANH functions are inverse operations.
The data type of the result is double-precision floating point. If the argument can be null, the result can be null; if the argument is null, the result is the null value.
SELECT TANH(:HTANGENT) FROM SYSIBM.SYSDUMMY1Returns the approximate value 0.90.
The TIME function returns a time from a value.
If expression is a character or graphic string, it must not be a CLOB or DBCLOB and its value must be a valid string representation of a time or timestamp. For the valid formats of string representations of times and timestamps, see String representations of datetime values.
The result of the function is a time. If the argument can be null, the result can be null; if the argument is null, the result is the null value.
The other rules depend on the data type of the argument:
The result is that time.
The result is the time part of the timestamp.
The result is the time or time part of the timestamp represented by the character string. When a string representation of a time is SBCS with a CCSID that is not the same as the default CCSID for SBCS data, that value is converted to adhere to the default CCSID for SBCS data before it is interpreted and converted to a time value.
When a string representation of a time is mixed data with a CCSID that is not the same as the default CCSID for mixed data, that value is converted to adhere to the default CCSID for mixed data before it is interpreted and converted to a time value.
Syntax alternatives: The CAST specification should be used for maximal portability. For more information, see CAST specification.
SELECT * FROM IN_TRAY WHERE TIME(RECEIVED) >= CURRENT TIME + 1 HOUR
The TIMESTAMP function returns a timestamp from its argument or arguments.
If both arguments are specified, the first argument must be an expression that returns a value of one of the following built-in data types: a date, a character string, or a graphic string. If expression-1 is a character or graphic string, it must not be a CLOB or DBCLOB and its value must be a valid string representation of a date.
If expression-2 is a character or graphic string, it must not be a CLOB or DBCLOB and its value must be a valid string representation of a time. For the valid formats of string representations of times, see String representations of datetime values.
The result of the function is a timestamp. If either argument can be null, the result can be null; if either argument is null, the result is the null value.
The other rules depend on whether the second argument is specified:
The result is a timestamp with the date specified by the first argument and the time specified by the second argument. The microsecond part of the timestamp is zero.
The result is that timestamp.
The result is the timestamp represented by that character string. If the argument is a character string of length 14, the timestamp has a microsecond part of zero.
When a string representation of a date, time, or timestamp is SBCS data with a CCSID that is not the same as the default CCSID for SBCS data, that value is converted to adhere to the default CCSID for SBCS data before it is interpreted and converted to a timestamp value.
When a string representation of a date, time, or timestamp is mixed data with a CCSID that is not the same as the default CCSID for mixed data, that value is converted to adhere to the default CCSID for mixed data before it is interpreted and converted to a timestamp value.
Syntax alternatives: If only one argument is specified, the CAST specification should be used for maximal portability. For more information, see CAST specification.
SELECT TIMESTAMP( DATE('1988-12-25'), TIME('17.12.30') ) FROM SYSIBM.SYSDUMMY1Returns the value '1988-12-25-17.12.30.000000'.
Returns a timestamp value based on date, time, or timestamp argument. If the argument is a date, it inserts zero for the time and microseconds parts of the timestamp. If the argument is a time, it inserts the value of CURRENT DATE for the date part of the timestamp and zero for the microseconds part of the timestamp.
If expression is a character or graphic string, it must not be a CLOB or DBCLOB and its value must be a valid string representation of a date, time, or timestamp. For the valid formats of string representations of dates, times, and timestamps, see String representations of datetime values.
The result of the function is a timestamp. If the argument can be null, the result can be null; if the argument is null, the result is the null value.
When a string representation of a date, time, or timestamp is SBCS data with a CCSID that is not the same as the default CCSID for SBCS data, that value is converted to adhere to the default CCSID for SBCS data before it is interpreted and converted to a timestamp value.
When a string representation of a date, time, or timestamp is mixed data with a CCSID that is not the same as the default CCSID for mixed data, that value is converted to adhere to the default CCSID for mixed data before it is interpreted and converted to a timestamp value.
Syntax alternatives: The CAST specification should be used for maximal portability. For more information, see CAST specification.
SELECT TIMESTAMP_ISO( DATE( '1988-12-25' ) ) FROM SYSIBM.SYSDUMMY1Returns the value '1988-12-25-00.00.00.000000'.
The TIMESTAMPDIFF function returns an estimated number of intervals of the type defined by the first argument, based on the difference between two timestamps.
1 | Fractions of a second |
2 | Seconds |
4 | Minutes |
8 | Hours |
16 | Days |
32 | Weeks |
64 | Months |
128 | Quarters |
256 | Years |
If string-expression is a character or graphic string, it must not be a CLOB or DBCLOB.
The result of the function is an integer. If either argument can be null, the result can be null; if either argument is null, the result is the null value.
The following assumptions may be used in estimating the difference:
These assumptions are used when converting the information in the second argument, which is a timestamp duration, to the interval type specified in the first argument. The returned estimate may vary by a number of days. For example, if the number of days (interval 16) is requested for a difference in timestamps for '1997-03-01-00.00.00' and '1997-02-01-00.00.00', the result is 30. This is because the difference between the timestamps is 1 month so the assumption of 30 days in a month applies.
SELECT TIMESTAMPDIFF(64, CAST(CURRENT_TIMESTAMP-CAST(BIRTHDATE AS TIMESTAMP) AS CHAR(22))) AS AGE_IN_MONTHS FROM EMPLOYEE
>>-TRANSLATE----------------------------------------------------> >--(--expression--+----------------------------------------------+--)->< '-,--to-string--+----------------------------+-' '-,--from-string--+--------+-' '-,--pad-'
The TRANSLATE function returns a value in which one or more characters in expression may have been converted into other characters.
If the length attribute of the to-string is less than the length attribute of the from-string, then the to-string is padded to the longer length using either the pad character if it is specified or a blank if a pad character is not specified. If the length attribute of the to-string is greater than the length attribute of the from-string, the extra characters in to-string are ignored without warning.
The string must be any built-in numeric or string constant. A numeric argument is cast to a character string before evaluating the function. For more information on converting numeric to a character string, see VARCHAR. A character string argument must have an actual length that is not greater than 256.
If there are duplicate characters in from-string, the first one scanning from the left is used and no warning is issued. The default value for from-string is a string starting with the character X'00' and ending with the character X'FF' (decimal 255).
If the first argument is a UTF-16, UCS-2, or UTF-8 string, no other arguments may be specified.
If only the first argument is specified, the SBCS characters of the argument are converted to uppercase, based on the CCSID of the argument. Only SBCS characters are converted. The characters a-z are converted to A-Z, and characters with diacritical marks are converted to their uppercase equivalent, if any. If the first argument is UTF–16, UCS-2, or UTF-8, the alphabetic UTF-16, UCS-2, or UTF-8 characters are converted to uppercase. Refer to the UCS-2 level 1 mapping tables section of the Globalization topic in the iSeries Information Center for a description of the monocasing tables that are used for this conversion.
If more than one argument is specified, the result string is built character by character from expression, converting characters in from-string to the corresponding character in to-string. For each character in expression, the same character is searched for in from-string. If the character is found to be the nth character in from-string, the resulting string will contain the nth character from to-string. If to-string is less than n characters long, the resulting string will contain the pad character. If the character is not found in from-string, it is moved to the result string unconverted.
Conversion is done on a byte basis and, if used improperly, may result in an invalid mixed string. The SRTSEQ attribute does not apply to the TRANSLATE function.
The result of the function has the same data type, length attribute, actual length, and CCSID as the argument. If the first argument can be null, the result can be null. If the argument is null, the result is the null value.
When TRANSLATE is specified in a query, the query cannot contain:
SELECT TRANSLATE('abcdef') FROM SYSIBM.SYSDUMMY1Returns the value 'ABCDEF'.
SELECT TRANSLATE( )
FROM SYSIBM.SYSDUMMY1
Returns the value
SELECT TRANSLATE(:SITE, '$', 'L') FROM SYSIBM.SYSDUMMY1Returns the value 'Pivabiska $ake Place'.
SELECT TRANSLATE(:SITE, '$$', 'Ll') FROM SYSIBM.SYSDUMMY1
Returns the value 'Pivabiska $ake P$ace'.
SELECT TRANSLATE(:SITE, 'pLA', 'Place', '.') FROM SYSIBM.SYSDUMMY1
Returns the value 'pivAbiskA LAk. pLA..'.
>>-TRIM--(--+-----------------------------------------+--expression--)->< | .-BOTH-----. | '-+----------+--+-----------------+--FROM-' +-B--------+ '-strip-character-' +-LEADING--+ +-L--------+ +-TRAILING-+ '-T--------'
The TRIM function removes blanks or another specified character from the end or beginning of a string expression.
The first argument, if specified, indicates whether characters are removed from the end or beginning of the string. If the first argument is not specified, then the characters are removed from both the end and the beginning of the string.
The data type of the result depends on the data type of expression:
Data type of expression | Data type of the Result |
---|---|
CHAR or VARCHAR | VARCHAR |
CLOB | CLOB |
GRAPHIC or VARGRAPHIC | VARGRAPHIC |
DBCLOB | DBCLOB |
BINARY or VARBINARY | VARBINARY |
BLOB | BLOB |
The length attribute of the result is the same as the length attribute of expression. The actual length of the result is the length of the expression minus the number of bytes removed. If all characters are removed, the result is an empty string.
If the first argument can be null, the result can be null; if the first argument is null, the result is the null value.
The CCSID of the result is the same as that of the string.
The SRTSEQ attribute does not apply to the TRIM function.
SELECT TRIM(:HELLO), TRIM( TRAILING FROM :HELLO) FROM SYSIBM.SYSDUMMY1Results in 'Hello' and ' Hello' respectively.
SELECT TRIM( L '0' FROM :BALANCE ) FROM SYSIBM.SYSDUMMY1Results in: '345.50'
SELECT TRIM( BOTH FROM )
FROM SYSIBM.SYSDUMMY1
Results in:
The TRUNCATE function returns expression–1 truncated to some number of places to the right or left of the decimal point.
If expression–2 is not negative, expression–1 is truncated to the expression–2 number of places to the right of the decimal point.
If expression–2 is negative, expression–1 is truncated to the absolute value of (expression–2+1) number of places to the left of the decimal point.
If the absolute value of expression–2 is larger than the number of digits to the left of the decimal point, the result is 0. For example, TRUNCATE(748.58,-4) = 0.
The data type and length attribute of the result are the same as the data type and length attribute of the first argument.
If either argument can be null, the result can be null. If either argument is null, the result is the null value.
SELECT TRUNCATE(MAX(SALARY/12, 2) FROM EMPLOYEEBecause the highest paid employee in the sample employee table earns $52750.00 per year, the example returns the value 4395.83.
SELECT TRUNCATE(873.726, 2), TRUNCATE(873.726, 1), TRUNCATE(873.726, 0), TRUNCATE(873.726, -1), TRUNCATE(873.726, -2), TRUNCATE(873.726, -3) FROM SYSIBM.SYSDUMMY1
Returns the following values respectively:
0873.720 0873.700 0873.000 0870.000 0800.000 0000.000
SELECT TRUNCATE( 3.5, 0), TRUNCATE( 3.1, 0), TRUNCATE(-3.1, 0), TRUNCATE(-3.5, 0) FROM SYSIBM.SYSDUMMY1
This example returns:
3.0 3.0 -3.0 -3.0
respectively.
The UCASE function returns a string in which all the characters have been converted to uppercase characters, based on the CCSID of the argument.
The UCASE function is identical to the UPPER function. For more information, see UPPER.
The UPPER function returns a string in which all the characters have been converted to uppercase characters, based on the CCSID of the argument. Only SBCS, UTF-16, and UCS-2 graphic characters are converted. The characters a-z are converted to A-Z, and characters with diacritical marks are converted to their uppercase equivalent, if any. Refer to the UCS-2 level 1 mapping tables section of the Globalization topic in the iSeries Information Center for a description of the monocasing tables that are used for this translation.
The result of the function has the same data type, length attribute, actual length, and CCSID as the argument. If the argument can be null, the result can be null; if the argument is null, the result is the null value.
When UPPER is specified in a query, the query cannot contain:
Syntax alternatives: UCASE is a synonym for UPPER.
SELECT UPPER('abcdef') FROM SYSIBM.SYSDUMMY1Returns the value 'ABCDEF'.
SELECT UPPER( )
FROM SYSIBM.SYSDUMMY1
Returns the value:
The VALUE function returns the value of the first non-null expression.
The VALUE function is identical to the COALESCE scalar function. For more information, see COALESCE.
Syntax alternatives: COALESCE should be used for conformance to the SQL 1999 standard.
The VARBINARY function returns a VARBINARY representation of a string of any type.
The result of the function is VARBINARY. If the first argument can be null, the result can be null; if the first argument is null, the result is the null value.
If integer is not specified:
The actual length of the result is the minimum of the length attribute of the result and the actual length of the expression (or twice the length of the expression when the input is graphic data). If the length of the string-expression is greater than the length attribute of the result, truncation is performed. A warning (SQLSTATE 01004) is returned unless the first input argument is a character string and all the truncated characters are blanks, or the first input argument is a graphic string and all the truncated characters are double-byte blanks, or the first input argument is a binary string and all the truncated bytes are hexadecimal zeroes.
Syntax alternatives: When the length is specified, the CAST specification should be used for maximal portability. For more information, see CAST specification.
SELECT VARBINARY('This is a VARBINARY') FROM SYSIBM.SYSDUMMY1
Datetime to Varchar
>>-VARCHAR--(--datetime-expression--+--------------+--)-------->< '-,--+-ISO---+-' +-USA---+ +-EUR---+ +-JIS---+ '-LOCAL-'
Character to Varchar
>>-VARCHAR (--character-expression------------------------------> >--+--------------------------------+--)----------------------->< '-,--+-length--+--+------------+-' '-DEFAULT-' '-,--integer-'
Graphic to Varchar
>>-VARCHAR (--graphic-expression--------------------------------> >--+--------------------------------+--)----------------------->< '-,--+-length--+--+------------+-' '-DEFAULT-' '-,--integer-'
Integer to Varchar
>>-VARCHAR--(--integer-expression--)---------------------------><
Decimal to Varchar
>>-VARCHAR------------------------------------------------------> >--(--decimal-expression--+----------------------+--)---------->< '-,--decimal-character-'
Floating-point to Varchar
>>-VARCHAR------------------------------------------------------> >--(--floating-point-expression--+----------------------+--)--->< '-,--decimal-character-'
The VARCHAR function returns a character-string representation of:
The result of the function is a varying-length string. If the first argument can be null, the result can be null; if the first argument is null, the result is the null value.
Datetime to Character
The result is the character-string representation of the timestamp. The length attribute and actual length of the result is 26.
Character to Varchar
If the second argument is not specified or DEFAULT is specified:
The actual length of the result is the minimum of the length attribute of the result and the actual length of character-expression. If the length of the character-expression is greater than the length attribute of the result, truncation is performed. A warning (SQLSTATE 01004) is returned unless the truncated characters were all blanks.
If the third argument is not specified then:
Graphic to Varchar
If the second argument is not specified or DEFAULT is specified, the length attribute of the result is determined as follows (where n is the length attribute of the first argument):
The actual length of the result is the minimum of the length attribute of the result and the actual length of graphic-expression. If the length of the character-expression is greater than the length attribute of the result, truncation is performed. A warning (SQLSTATE 01004) is returned unless the truncated characters were all blanks.
If the third argument is not specified, the CCSID of the result is the default CCSID at the current server. If the default CCSID is mixed data, then the result is mixed data. If the default CCSID is SBCS data, then the result is SBCS data.
Integer to Varchar
The result is a varying-length character string of the argument in the form of an SQL integer constant. The result consists of n characters that are the significant digits that represent the value of the argument with a preceding minus sign if the argument is negative. It is left justified.
The actual length of the result is the smallest number of characters that can be used to represent the value of the argument. Leading zeroes are not included. If the argument is negative, the first character of the result is a minus sign. Otherwise, the first character is a digit.
The CCSID of the result is the default SBCS CCSID at the current server.
Decimal to Varchar
The result is a varying-length character string representation of the argument. The result includes a decimal character and up to p digits, where p is the precision of the decimal-expression with a preceding minus sign if the argument is negative. Leading zeros are not returned. Trailing zeros are returned.
The length attribute of the result is 2+p where p is the precision of the decimal-expression. The actual length of the result is the smallest number of characters that can be used to represent the result, except that trailing characters are included. Leading zeros are not included. If the argument is negative, the result begins with a minus sign. Otherwise, the result begins with a digit.
The CCSID of the result is the default SBCS CCSID at the current server.
Floating-point to Varchar
The result is a varying-length character string representation of the argument in the form of a floating-point constant.
The length attribute of the result is 24. The actual length of the result is the smallest number of characters that can represent the value of the argument such that the mantissa consists of a single digit other than zero followed by the decimal-character and a sequence of digits. If the argument is negative, the first character of the result is a minus sign; otherwise, the first character is a digit. If the argument is zero, the result is 0E0.
The CCSID of the result is the default SBCS CCSID at the current server.
Syntax alternatives: If the length attribute is specified, the CAST specification should be used for maximal portability. For more information, see CAST specification.
SELECT VARCHAR(EMPNO,10) INTO :VARHV FROM EMPLOYEE
The VARCHAR_FORMAT function returns a character representation of a timestamp in the format indicated by format-string.
If expression is a character or graphic string, it must not be a CLOB or DBCLOB and its value must be a valid string representation of a timestamp. For the valid formats of string representations of timestamps, see String representations of datetime values.
Leading and trailing blanks are removed from expression, and the resulting substring is interpreted as a timestamp using the format specified by format-string.
'YYYY-MM-DD HH24:MI:SS'
where:
The result is the varying-length character string that contains the argument in the format specified by format-string. format-string also determines the length attribute and actual length of the result. If either argument can be null, the result can be null; if either argument is null, the result is the null value.
The CCSID of the result is the default SBCS CCSID of the current server.
Syntax alternatives: TO_CHAR is a synonym for VARCHAR_FORMAT.
SELECT VARCHAR_FORMAT(RECEIVED,'YYYY-MM-DD HH24:MI:SS') INTO :TVAR FROM CORPDATA.IN_TRAY
Character to Vargraphic
>>-VARGRAPHIC--(--character-expression--------------------------> >--+--------------------------------+--)----------------------->< '-,--+-length--+--+------------+-' '-DEFAULT-' '-,--integer-'
Graphic to Vargraphic
>>-VARGRAPHIC--(--graphic-expression----------------------------> >--+--------------------------------+--)----------------------->< '-,--+-length--+--+------------+-' '-DEFAULT-' '-,--integer-'
Integer to Vargraphic
>>-VARGRAPHIC--(--integer-expression--)------------------------><
Decimal to Vargraphic
>>-VARGRAPHIC---------------------------------------------------> >--(--decimal-expression--+----------------------+--)---------->< '-,--decimal-character-'
Floating-point to Vargraphic
>>-VARGRAPHIC---------------------------------------------------> >--(--floating-point-expression--+----------------------+--)--->< '-,--decimal-character-'
The VARGRAPHIC function returns a graphic-string representation of
The result of the function is a varying-length graphic string (VARGRAPHIC).
If the expression can be null, the result can be null. If the expression is null, the result is the null value. If the expression is an empty string or the EBCDIC string X'0E0F', the result is an empty string.
Character to Graphic
If the second argument is not specified, or if DEFAULT is specified, the length attribute of the result is the same as the length attribute of the first argument, except if the expression is an empty string or the EBCDIC string X'0E0F', the length attribute of the result is 1.
The actual length of the result depends on the number of characters in the argument. Each character of the argument determines a character of the result. If the length attribute of the resulting varying-length string is less than the actual length of the first argument, truncation is performed and no warning is returned.
If integer is not specified then the CCSID of the result is determined by a mixed CCSID. Let M denote that mixed CCSID.
In the following rules, S denotes one of the following:
M is determined as follows:
The following table summarizes the result CCSID based on M.
M | Result CCSID | Description | DBCS Substitution Character |
---|---|---|---|
930 | 300 | Japanese EBCDIC | X'FEFE' |
933 | 834 | Korean EBCDIC | X'FEFE' |
935 | 837 | S-Chinese EBCDIC | X'FEFE' |
937 | 835 | T-Chinese EBCDIC | X'FEFE' |
939 | 300 | Japanese EBCDIC | X'FEFE' |
5026 | 4396 | Japanese EBCDIC | X'FEFE' |
5035 | 4396 | Japanese EBCDIC | X'FEFE' |
The equivalence of SBCS and DBCS characters depends on M. Regardless of the CCSID, every double-byte code point in the argument is considered a DBCS character, and every single-byte code point in the argument is considered an SBCS character with the exception of the EBCDIC mixed data shift codes X'0E' and X'0F'.
Graphic to Vargraphic
If the second argument is not specified, or if DEFAULT is specified, the length attribute of the result is the same as the length attribute of the first argument, except if the expression is an empty string, the length attribute of the result is 1.
The actual length of the result depends on the number of characters in graphic-expression. If the length of graphic-expression is greater than the length specified, the result is truncated and no warning is returned.
If integer is not specified then the CCSID of the result is the CCSID of the first argument.
Integer to Vargraphic
The result is a varying-length graphic string of the argument in the form of an SQL integer constant. The result consists of n characters that are the significant digits that represent the value of the argument with a preceding minus sign if the argument is negative. It is left justified.
The actual length of the result is the smallest number of characters that can be used to represent the value of the argument. Leading zeroes are not included. If the argument is negative, the first character of the result is a minus sign. Otherwise, the first character is a digit.
The CCSID of the result is 1200 (UTF-16).
Decimal to Vargraphic
The result is a varying-length graphic string representation of the argument. The result includes a decimal character and up to p digits, where p is the precision of the decimal-expression with a preceding minus sign if the argument is negative. Leading zeros are not returned. Trailing zeros are returned.
The length attribute of the result is 2+p where p is the precision of the decimal-expression. The actual length of the result is the smallest number of characters that can be used to represent the result, except that trailing characters are included. Leading zeros are not included. If the argument is negative, the result begins with a minus sign. Otherwise, the result begins with a digit.
The CCSID of the result is 1200 (UTF-16).
Floating-point to Vargraphic
The result is a varying-length graphic string representation of the argument in the form of a floating-point constant.
The length attribute of the result is 24. The actual length of the result is the smallest number of characters that can represent the value of the argument such that the mantissa consists of a single digit other than zero followed by the decimal-character and a sequence of digits. If the argument is negative, the first character of the result is a minus sign; otherwise, the first character is a digit. If the argument is zero, the result is 0E0.
The CCSID of the result is 1200 (UTF-16).
Syntax alternatives: If the first argument is graphic-expression and the length attribute is specified, the CAST specification should be used for maximal portability. For more information, see CAST specification.
SELECT VARGRAPHIC(FIRSTNME) INTO :VAR_DESC FROM EMPLOYEE WHERE EMPNO = '000050'
The WEEK function returns an integer between 1 and 54 that represents the week of the year. The week starts with Sunday, and January 1 is always in the first week.
If expression is a character or graphic string, it must not be a CLOB or DBCLOB and its value must be a valid string representation of a date or timestamp. For the valid formats of string representations of dates and timestamps, see String representations of datetime values.
The result of the function is a large integer. If the argument can be null, the result can be null; if the argument is null, the result is the null value.
SELECT WEEK(PRENDATE) INTO :WEEK FROM PROJECT WHERE PROJNO = 'PL2100'Results in WEEK being set to 38.
SELECT DATE_1, WEEK(DATE_1) FROM XResults in the following list shows what is returned by the WEEK function for various dates.
1997-12-28 53 1997-12-31 53 1998-01-01 1 1999-01-01 1 1999-01-04 2 1999-12-31 53 2000-01-01 1 2000-01-03 2
The WEEK_ISO function returns an integer between 1 and 53 that represents the week of the year. The week starts with Monday. Week 1 is the first week of the year to contain a Thursday, which is equivalent to the first week containing January 4. Thus, it is possible to have up to 3 days at the beginning of the year appear as the last week of the previous year or to have up to 3 days at the end of a year appear as the first week of the next year.
If expression is a character or graphic string, it must not be a CLOB or DBCLOB and its value must be a valid string representation of a date or timestamp. For the valid formats of string representations of dates and timestamps, see String representations of datetime values.
The result of the function is a large integer. If the argument can be null, the result can be null; if the argument is null, the result is the null value.
SELECT WEEK_ISO(PRENDATE) INTO :WEEK FROM PROJECT WHERE PROJNO = 'AD3100'Results in WEEK being set to 5.
SELECT DATE_1, WEEK_ISO(DATE_1) FROM XResults in the following:
1997-12-28 52 1997-12-31 1 1998-01-01 1 1999-01-01 53 1999-01-04 1 1999-12-31 52 2000-01-01 52 2000-01-03 1
The XOR function returns a string that is the logical XOR of the argument strings. This function takes the first argument string, does an XOR operation with the next string, and then continues to do XOR operations for each successive argument using the previous result. If an argument is encountered that is shorter than the previous result, it is padded with blanks.
The arguments must be compatible.
The arguments are converted, if necessary, to the attributes of the result. The attributes of the result are determined as follows:
If an argument can be null, the result can be null; if an argument is null, the result is the null value.
The CCSID of the result is 65535.
SELECT XOR(:L1,:L2,:L3) FROM SYSIBM.SYSDUMMY1Returns the value X'1111404F'.
The YEAR function returns the year part of a value.
The result of the function is a large integer. If the argument can be null, the result can be null; if the argument is null, the result is the null value.
The other rules depend on the data type of the argument:
The result is the year part of the value, which is an integer between 1 and 9999.
The result is the year part of the value, which is an integer between -9999 and 9999. A nonzero result has the same sign as the argument.
SELECT * FROM PROJECT WHERE YEAR(PRSTDATE) = YEAR(PRENDATE)
SELECT * FROM PROJECT WHERE YEAR(PRENDATE - PRSTDATE) < 1
Numeric to Zoned Decimal
>>-ZONED--------------------------------------------------------> >--(--numeric-expression--+--------------------------------------------+--)->< '-,--precision-integer--+------------------+-' '-,--scale-integer-'
String to Zoned Decimal
>>-ZONED--------------------------------------------------------> >--(--string-expression--+------------------------------------------------------+--)->< '-,--precision--+------------------------------------+-' '-,--scale--+----------------------+-' '-,--decimal-character-'
The ZONED function returns a zoned decimal representation of:
The result of the function is a zoned decimal number with precision of p and scale of s, where p and s are the second and third arguments. If the first argument can be null, the result can be null; if the first argument is null, the result is the null value.
Numeric to Zoned Decimal
The default for precision depends on the data type of the numeric-expression:
The result is the same number that would occur if the first argument were assigned to a decimal column or variable with a precision of p and a scale of s. An error is returned if the number of significant decimal digits required to represent the whole part of the number is greater than p-s.
String to Zoned Decimal
If the argument is a string-expression, the result is the same number that would result from CAST( string-expression AS NUMERIC(precision, scale)). Leading and trailing blanks are eliminated and the resulting string must conform to the rules for forming a floating-point, integer, or decimal constant. If the whole part of the argument is not within the range of decimal with the specified precision, an error is returned. Any fractional part of the argument is truncated.
The result is the same number that would result from CAST(string-expression AS NUMERIC(p,s)). Digits are truncated from the end if the number of digits to the right of the decimal-character is greater than the scale s. An error is returned if the number of significant digits to the left of the decimal-character (the whole part of the number) in string-expression is greater than p-s. The default decimal separator character is not valid in the substring if the decimal-character argument is specified.
Syntax alternatives: When the precision is specified, the CAST specification should be used for maximal portability. For more information, see CAST specification.
SELECT ZONED(:Z1,15,14) FROM SYSIBM.SYSDUMMY1Returns the value 1.12300000000000.
SELECT ZONED(:Z1,11,2) FROM SYSIBM.SYSDUMMY1Returns the value 1123.00.
SELECT ZONED(:Z1,4) FROM SYSIBM.SYSDUMMY1Returns the value 1123.