Scalar functions

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.

Example

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'

ABS

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-ABS--(--expression--)---------------------------------------><
 

The ABS function returns the absolute value of a number.

expression
The argument must be an expression that returns a value of any built-in numeric, character-string, or graphic-string data type. A string argument is cast to double-precision floating point before evaluating the function. For more information on converting strings to double-precision floating point, see DOUBLE_PRECISION or DOUBLE.

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.

Note

Syntax alternatives: ABSVAL is a synonym for ABS. It is supported only for compatibility with previous DB2® releases.

Example

ACOS

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-ACOS--(--expression--)--------------------------------------><
 

The ACOS function returns the arc cosine of the argument as an angle expressed in radians. The ACOS and COS functions are inverse operations.

expression
The argument must be an expression that returns a value of any built-in numeric, character-string, or graphic-string data type. A string argument is cast to double-precision floating point before evaluating the function. For more information on converting strings to double-precision floating point, see DOUBLE_PRECISION or DOUBLE. The value must be greater than or equal to -1 and less than or equal to 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.

The result is greater than or equal to 0 and less than or equal to π.

Example

ADD_MONTHS

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-ADD_MONTHS--(--expression--,--numeric-expression--)---------><
 

The ADD_MONTHS function returns a date that represents expression plus numeric-expression months.

expression
The argument must be an expression that returns a value of one of the following built-in data types: a date, a timestamp, a character string, or a graphic 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 date or timestamp. For the valid formats of string representations of dates and timestamps, see String representations of datetime values.

numeric-expression
The argument must be an expression that returns a value of a built-in numeric data type with zero scale. A negative numeric value is allowed.

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.

Example

ANTILOG

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-ANTILOG--(--expression--)-----------------------------------><
 

The ANTILOG function returns the anti-logarithm (base 10) of a number. The ANTILOG and LOG functions are inverse operations.

expression
The argument must be an expression that returns a value of any built-in numeric, character-string, or graphic-string data type. A string argument is cast to double-precision floating point before evaluating the function. For more information on converting strings to double-precision floating point, see DOUBLE_PRECISION or DOUBLE.

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.

Example

ASIN

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-ASIN--(--expression--)--------------------------------------><
 

The ASIN function returns the arc sine of the argument as an angle expressed in radians. The ASIN and SIN functions are inverse operations.

expression
The argument must be an expression that returns a value of any built-in numeric, character-string, or graphic-string data type. A string argument is cast to double-precision floating point before evaluating the function. For more information on converting strings to double-precision floating point, see DOUBLE_PRECISION or DOUBLE. The value must be greater than or equal to -1 and less than or equal to 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.

The result is greater than or equal to -π /2 and less than or equal to π /2.

Example

ATAN

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-ATAN--(--expression--)--------------------------------------><
 

The ATAN function returns the arc tangent of the argument as an angle expressed in radians. The ATAN and TAN functions are inverse operations.

expression
The argument must be an expression that returns a value of any built-in numeric, character-string, or graphic-string data type. A string argument is cast to double-precision floating point before evaluating the function. For more information on converting strings to double-precision floating point, see DOUBLE_PRECISION or DOUBLE.

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.

Example

ATANH

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-ATANH--(--expression--)-------------------------------------><
 

The ATANH function returns the hyperbolic arc tangent of a number, in radians. The ATANH and TANH functions are inverse operations.

expression
The argument must be an expression that returns a value of any built-in numeric, character-string, or graphic-string data type. A string argument is cast to double-precision floating point before evaluating the function. For more information on converting strings to double-precision floating point, see DOUBLE_PRECISION or DOUBLE. The value must be greater than -1 and less than 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.

Example

ATAN2

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-ATAN2--(--expression--,--expression--)----------------------><
 

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.

expression
The argument must be an expression that returns a value of any built-in numeric, character-string, or graphic-string data type. A string argument is cast to double-precision floating point before evaluating the function. For more information on converting strings to double-precision floating point, see DOUBLE_PRECISION or DOUBLE. If one argument is 0, the other argument must not be 0.

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.

Example

BIGINT

Click to skip syntax diagram

Numeric to Big Integer

Read syntax diagramSkip visual syntax diagram>>---BIGINT----(--numeric-expression--)------------------------><
 

String to Big Integer

Read syntax diagramSkip visual syntax diagram>>---BIGINT----(--string-expression--)-------------------------><
 

The BIGINT function returns a big integer representation of:

Numeric to Big Integer

numeric-expression
An expression that returns a numeric value of any built-in numeric data type.

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

string-expression
An expression that returns a value that is a character-string or graphic-string representation of a number.

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.

Note

Syntax alternatives: The CAST specification should be used for maximal portability. For more information, see CAST specification.

Example

BINARY

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-BINARY--(--string-expression--+------------+--)-------------><
                                 '-,--integer-'
 

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.

string-expression
A string-expression whose value must be a built-in character string, graphic string, binary string, or row ID data type.
integer
An integer constant that specifies the length attribute for the resulting binary string. The value must be between 1 and 32766.

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.

Note

Syntax alternatives: When the length is specified, the CAST specification should be used for maximal portability. For more information, see CAST specification.

Example

BIT_LENGTH

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>---BIT_LENGTH----(--expression--)----------------------------><
 

The BIT_LENGTH function returns the length of a string expression in bits. See LENGTH , CHARACTER_LENGTH , and OCTET_LENGTH for similar functions.

expression
The argument must be an expression that returns a value of 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.

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.

Example

BLOB

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-BLOB--(--string-expression--+------------+--)---------------><
                               '-,--integer-'
 

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.

string-expression
A string-expression whose value can be a character string, graphic string, binary string, or row ID.
integer
An integer constant that specifies the length attribute for the resulting binary string. The value must be between 1 and 2 147 483 647.

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.

Note

Syntax alternatives: When the length is specified, the CAST specification should be used for maximal portability. For more information, see CAST specification.

Example

CEILING

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-+-CEILING-+--(--expression--)-------------------------------><
   '-CEIL----'
 

The CEIL or CEILING function returns the smallest integer value that is greater than or equal to expression.

expression
The argument must be an expression that returns a value of any built-in numeric, character-string, or graphic-string data type. A string argument is cast to double-precision floating point before evaluating the function. For more information on converting strings to double-precision floating point, see DOUBLE_PRECISION or DOUBLE.

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.

Examples

CHAR

Click to skip syntax diagram

Datetime to Character

Read syntax diagramSkip visual syntax diagram>>-CHAR--(--datetime-expression--+--------------+--)-----------><
                                 '-,--+-ISO---+-'
                                      +-USA---+
                                      +-EUR---+
                                      +-JIS---+
                                      '-LOCAL-'
 

Graphic to Character

Read syntax diagramSkip visual syntax diagram>>-CHAR--(--graphic-expression--+------------+--)--------------><
                                '-,--integer-'
 

Character to Character

Read syntax diagramSkip visual syntax diagram>>-CHAR--(--character-expression--+------------+--)------------><
                                  '-,--integer-'
 

Integer to Character

Read syntax diagramSkip visual syntax diagram>>-CHAR--(--integer-expression--)------------------------------><
 

Decimal to Character

Read syntax diagramSkip visual syntax diagram>>-CHAR--(--decimal-expression--+----------------------+--)----><
                                '-,--decimal-character-'
 

Floating-point to Character

Read syntax diagramSkip visual syntax diagram>>-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

datetime-expression
An expression that is one of the following three built-in data types
date
The result is the character-string representation of the date in the format specified by the second argument. If the second argument is not specified, the format used is the default date format. If the format is ISO, USA, EUR, or JIS, the length of the result is 10. Otherwise the length of the result is the length of the default date format. For more information see String representations of datetime values.
time
The result is the character-string representation of the time in the format specified by the second argument. If the second argument is not specified, the format used is the default time format. The length of the result is 8. For more information see String representations of datetime values.
timestamp
The second argument is not applicable and must not be specified.

The result is the character-string representation of the timestamp. The length of the result is 26.

The CCSID of the string is the default SBCS CCSID at the current server.
ISO, EUR, USA, or JIS
Specifies the date or time format of the resulting character string. For more information, see String representations of datetime values.
LOCAL
Specifies that the date or time format of the resulting character string should come from the DATFMT, DATSEP, TIMFMT, and TIMSEP attributes of the job at the current server.

Graphic to Character

graphic-expression
An expression that returns a value that is a built-in graphic-string data type.
integer
An integer constant that specifies the length attribute for the resulting fixed length character string. The value must be between 1 and 32766 (32765 if nullable).

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

character-expression
An expression that returns a value that is a built-in character-string data type.
integer
An integer constant that specifies the length attribute for the resulting fixed length character string. The value must be between 1 and 32766 (32765 if nullable). If the first argument is mixed data, the second argument cannot be less than 4.

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

integer-expression
An expression that returns a value that is a built-in integer data type (either SMALLINT, INTEGER, or BIGINT).

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 CCSID of the string is the default SBCS CCSID at the current server.

Decimal to Character

decimal-expression
An expression that returns a value that is a built-in decimal data type (either DECIMAL or NUMERIC). If a different precision and scale is desired, the DECIMAL scalar function can be used to make the change.
decimal-character
Specifies the single-byte character constant that is used to delimit the decimal digits in the result character string. The character must be a period or comma. If the second argument is not specified, the decimal point is the default decimal point. For more information, see Decimal point.

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

floating-point expression
An expression that returns a value that is a built-in floating-point data type (DOUBLE or REAL).
decimal-character
Specifies the single-byte character constant that is used to delimit the decimal digits in the result character string. The character must be a period or comma. If the second argument is not specified, the decimal point is the default decimal point. For more information, see Decimal point.

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.

Note

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.

Examples

CHARACTER_LENGTH

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-+-CHARACTER_LENGTH-+--(--expression--)----------------------><
   '-CHAR_LENGTH------'
 

The CHARACTER_LENGTH or CHAR_LENGTH function returns the length of a string expression. See LENGTH for a similar function.

expression
The argument must be an expression that returns a value of 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 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.

Example

CLOB

Character to CLOB

Read syntax diagramSkip visual syntax diagram>>-CLOB (--character-expression--------------------------------->
 
>--+--------------------------------+--)-----------------------><
   '-,--+-length--+--+------------+-'
        '-DEFAULT-'  '-,--integer-'
 

Graphic to CLOB

Read syntax diagramSkip visual syntax diagram>>-CLOB (--graphic-expression----------------------------------->
 
>--+--------------------------------+--)-----------------------><
   '-,--+-length--+--+------------+-'
        '-DEFAULT-'  '-,--integer-'
 

Integer to CLOB

Read syntax diagramSkip visual syntax diagram>>-CLOB--(--integer-expression--)------------------------------><
 

Decimal to CLOB

Read syntax diagramSkip visual syntax diagram>>-CLOB--(--decimal-expression--+----------------------+--)----><
                                '-,--decimal-character-'
 

Floating-point to CLOB

Read syntax diagramSkip visual syntax diagram>>-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

character-expression
An expression that returns a value that is a built-in character-string data type.
length
An integer constant that specifies the length attribute for the resulting varying length character string. The value must be between 1 and 2 147 483 647. If the first argument is mixed data, the second argument cannot be less than 4.

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.

integer
An integer constant that specifies the CCSID of the result. It must be a valid SBCS CCSID or mixed data CCSID. 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 a SBCS CCSID, then the first argument cannot be a DBCS-either or DBCS-only string. The third argument cannot be 65535.

If the third argument is not specified, the first argument must not have a CCSID of 65535:

Graphic to CLOB

graphic-expression
An expression that returns a value that is a built-in graphic-string data type. It must not be DBCS-graphic data.
length
An integer constant that specifies the length attribute for the resulting varying length character string. The value must be between 1 and 2 147 483 647. If the result is mixed data, the second argument cannot be less than 4.

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.

integer
An integer constant that specifies the CCSID of the result. It must be a valid SBCS CCSID or mixed data CCSID. 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. The third argument cannot be 65535.

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

integer-expression
An expression that returns a value that is a built-in integer data type (either SMALLINT, INTEGER, or BIGINT).

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

decimal-expression
An expression that returns a value that is a built-in decimal data type (either DECIMAL or NUMERIC). If a different precision and scale is desired, the DECIMAL scalar function can be used to make the change.
decimal-character
Specifies the single-byte character constant that is used to delimit the decimal digits in the result character string. The character must be a period or comma. If the second argument is not specified, the decimal point is the default decimal point. For more information, see Decimal point.

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

floating-point expression
An expression that returns a value that is a built-in floating-point data type (DOUBLE or REAL).
decimal-character
Specifies the single-byte character constant that is used to delimit the decimal digits in the result character string. The character must be a period or comma. If the second argument is not specified, the decimal point is the default decimal point. For more information, see Decimal point.

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.

Note

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.

Example

COALESCE

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram                            .---------------.
                            V               |
>>-COALESCE--(--expression----,--expression-+--)---------------><
 

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.

expression
The arguments can be of either a built-in data type or a distinct type.41

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.

Examples

CONCAT

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-CONCAT--(--expression--,--expression--)---------------------><
 

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.

expression
The argument must be an expression that returns a value of 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.

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.

Note

Syntax alternatives: The CONCAT function is identical to the CONCAT operator. For more information, see With the concatenation operator.

Example

COS

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-COS--(--expression--)---------------------------------------><
 

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.

expression
The argument must be an expression that returns a value of any built-in numeric, character-string, or graphic-string data type. A string argument is cast to double-precision floating point before evaluating the function. For more information on converting strings to double-precision floating point, see DOUBLE_PRECISION or DOUBLE.

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.

Example

COSH

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-COSH--(--expression--)--------------------------------------><
 

The COSH function returns the hyperbolic cosine of the argument, where the argument is an angle expressed in radians.

expression
The argument must be an expression that returns a value of any built-in numeric, character-string, or graphic-string data type. A string argument is cast to double-precision floating point before evaluating the function. For more information on converting strings to double-precision floating point, see DOUBLE_PRECISION or DOUBLE.

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.

Example

COT

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-COT--(--expression--)---------------------------------------><
 

The COT function returns the cotangent of the argument, where the argument is an angle expressed in radians.

expression
The argument must be an expression that returns a value of any built-in numeric, character-string, or graphic-string data type. A string argument is cast to double-precision floating point before evaluating the function. For more information on converting strings to double-precision floating point, see DOUBLE_PRECISION or DOUBLE.

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.

Example

CURDATE

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-CURDATE--(--)-----------------------------------------------><
 

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.

Note

Syntax alternatives: The CURRENT_DATE special register should be used for maximal portability. For more information, see Special registers.

Example

CURTIME

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-CURTIME--(--)-----------------------------------------------><
 

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.

Note

Syntax alternatives: The CURRENT_TIME special register should be used for maximal portability. For more information, see Special registers.

Example

DATABASE

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-DATABASE--(--)----------------------------------------------><
 

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.

Note

Syntax alternatives: The DATABASE function returns the same result as the CURRENT SERVER special register.

Examples

DATAPARTITIONNAME

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-DATAPARTITIONNAME--(--table-designator--)-------------------><
 

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.

table-designator
The argument must be a table designator of the subselect. For more information about table designators, see Table designators.

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.

Example

DATAPARTITIONNUM

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-DATAPARTITIONNUM--(--table-designator--)--------------------><
 

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.

table-designator
The argument must be a table designator of the subselect. For more information about table designators, see Table designators.

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.

Example

DATE

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-DATE--(--expression--)--------------------------------------><
 

The DATE function returns a date from a value.

expression
The argument must be an expression that returns a value of one of the following built-in data types: a date, a timestamp, a character string, a graphic string, or any numeric data type.

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:

Note

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.

Examples

DAY

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-DAY--(--expression--)---------------------------------------><
 

The DAY function returns the day part of a value.

expression
The argument must be an expression that returns a value of one of the following built-in data types: a date, a timestamp, a character string, a graphic string, or a numeric data type.

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:

Examples

DAYNAME

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-DAYNAME--(--expression--)-----------------------------------><
 

Returns a mixed case character string containing the name of the day (e.g. Friday) for the day portion of the argument.

expression
The argument must be an expression that returns a value of one of the following built-in data types: a date, a timestamp, a character string, or a graphic 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 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.

Note

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.

Examples

DAYOFMONTH

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-DAYOFMONTH--(--expression--)--------------------------------><
 

The DAYOFMONTH function returns an integer between 1 and 31 that represents the day of the month.

expression
The argument must be an expression that returns a value of one of the following built-in data types: a date, a timestamp, a character string, or a graphic 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 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.

Examples

DAYOFWEEK

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-DAYOFWEEK--(--expression--)---------------------------------><
 

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.

expression
The argument must be an expression that returns a value of one of the following built-in data types: a date, a timestamp, a character string, or a graphic 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 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.

Example

DAYOFWEEK_ISO

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-DAYOFWEEK_ISO--(--expression--)-----------------------------><
 

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.

expression
The argument must be an expression that returns a value of one of the following built-in data types: a date, a timestamp, a character string, or a graphic 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 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.

Examples

DAYOFYEAR

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-DAYOFYEAR--(--expression--)---------------------------------><
 

The DAYOFYEAR function returns an integer between 1 and 366 that represents the day of the year where 1 is January 1.

expression
The argument must be an expression that returns a value of one of the following built-in data types: a date, a timestamp, a character string, or a graphic 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 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.

Example

DAYS

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-DAYS--(--expression--)--------------------------------------><
 

The DAYS function returns an integer representation of a date.

expression
The argument must be an expression that returns a value of one of the following built-in data types: a date, a timestamp, a character string, or a graphic 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 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.

Examples

DBCLOB

Click to skip syntax diagram

Character to DBCLOB

Read syntax diagramSkip visual syntax diagram>>-DBCLOB (--character-expression------------------------------->
 
>--+--------------------------------+--)-----------------------><
   '-,--+-length--+--+------------+-'
        '-DEFAULT-'  '-,--integer-'
 

Graphic to DBCLOB

Read syntax diagramSkip visual syntax diagram>>-DBCLOB (--graphic-expression--------------------------------->
 
>--+--------------------------------+--)-----------------------><
   '-,--+-length--+--+------------+-'
        '-DEFAULT-'  '-,--integer-'
 

Integer to DBCLOB

Read syntax diagramSkip visual syntax diagram>>-DBCLOB--(--integer-expression--)----------------------------><
 

Decimal to DBCLOB

Read syntax diagramSkip visual syntax diagram>>-DBCLOB--(--decimal-expression--+----------------------+--)--><
                                  '-,--decimal-character-'
 

Floating-point to DBCLOB

Read syntax diagramSkip visual syntax diagram>>-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

character-expression
An expression that returns a value that is a built-in character-string data type. It cannot be CHAR or VARCHAR bit data. If the expression is an empty string or the EBCDIC string X'0E0F', the result is an empty string.
length
An integer constant that specifies the length attribute for the resulting varying length character string. The value must be between 1 and 1 073 741 823.

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.

integer
An integer constant that specifies the CCSID for the resulting varying-length graphic string. It must be a DBCS, UTF-16, or UCS-2 CCSID. The CCSID cannot be 65535.

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

graphic-expression
An expression that returns a value that is a built-in graphic-string data type.
length
An integer constant that specifies the length attribute for the resulting varying length character string. The value must be between 1 and 1 073 741 823.

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.

integer
An integer constant that specifies the CCSID for the resulting varying-length graphic string. It must be a DBCS, UTF-16, or UCS-2 CCSID. The CCSID cannot be 65535.

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

integer-expression
An expression that returns a value that is a built-in integer data type (either SMALLINT, INTEGER, or BIGINT).

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

decimal-expression
An expression that returns a value that is a built-in decimal data type (either DECIMAL or NUMERIC). If a different precision and scale is desired, the DECIMAL scalar function can be used to make the change.
decimal-character
Specifies the single-byte character constant that is used to delimit the decimal digits in the result character string. The character must be a period or comma. If the second argument is not specified, the decimal point is the default decimal point. For more information, see Decimal point.

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

floating-point expression
An expression that returns a value that is a built-in floating-point data type (DOUBLE or REAL).
decimal-character
Specifies the single-byte character constant that is used to delimit the decimal digits in the result character string. The character must be a period or comma. If the second argument is not specified, the decimal point is the default decimal point. For more information, see Decimal point.

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).

Note

Syntax alternatives: When the length attribute is specified, the CAST specification should be used for maximal portability. For more information, see CAST specification.

Example

DBPARTITIONNAME

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-DBPARTITIONNAME--(--table-designator--)---------------------><
 

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.

table-designator
The argument must be a table designator of the subselect. For more information about table designators, see Table designators.

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.

Note

Syntax alternatives: NODENAME is a synonym for DBPARTITIONNAME.

Example

DBPARTITIONNUM

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-DBPARTITIONNUM--(--table-designator--)----------------------><
 

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.

table-designator
The argument must be a table designator of the subselect. For more information about table designators, see Table designators.

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.

Note

Syntax alternatives: NODENUMBER is a synonym for DBPARTITIONNUM.

Example

DECIMAL or DEC

Click to skip syntax diagram

Numeric to Decimal

Read syntax diagramSkip visual syntax diagram>>-+-DECIMAL-+-------------------------------------------------->
   '-DEC-----'
 
>--(--numeric-expression--+----------------------------+--)----><
                          '-,--precision--+----------+-'
                                          '-,--scale-'
 

String to Decimal

Read syntax diagramSkip visual syntax diagram>>-+-DECIMAL-+-------------------------------------------------->
   '-DEC-----'
 
>--(--string-expression--+------------------------------------------------------+--)-><
                         '-,--precision--+------------------------------------+-'
                                         '-,--scale--+----------------------+-'
                                                     '-,--decimal-character-'
 

The DECIMAL function returns a decimal representation of:

Numeric to Decimal

numeric-expression
An expression that returns a value of any built-in numeric data type.
precision
An integer constant with a value greater than or equal to 1 and less than or equal to 63.

The default for precision depends on the data type of the numeric-expression:

scale
An integer constant that is greater than or equal to 0 and less than or equal to precision. If not specified, the default is 0.

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

string-expression
An expression that returns a character-string or graphic-string representation of a number. Leading and trailing blanks are eliminated and the resulting string must conform to the rules for forming a floating-point, integer, or decimal constant.
precision
An integer constant that is greater than or equal to 1 and less than or equal to 63. If not specified, the default is 15.
scale
An integer constant that is greater than or equal to 0 and less than or equal to precision. If not specified, the default is 0.
decimal-character
Specifies the single-byte character constant that is used to delimit the decimal digits in string-expression from the whole part of the number. The character must be a period or comma. If decimal-character is not specified, the decimal point is the default decimal separator character. For more information, see Decimal point.

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.

Note

Syntax alternatives: When the precision is specified, the CAST specification should be used for maximal portability. For more information, see CAST specification.

Examples

DECRYPT_BIT, DECRYPT_BINARY, DECRYPT_CHAR and DECRYPT_DB

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-+-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.

encrypted-data
An expression that must be a string expression that returns a complete, encrypted data value of a CHAR FOR BIT DATA, VARCHAR FOR BIT DATA, BINARY, VARBINARY, or BLOB built-in data type. The data string must have been encrypted using the ENCRYPT_RC2 or ENCRYPT_TDES function.
password-string
An expression that returns a character string value with at least 6 bytes and no more than 127 bytes. The expression must not be a CLOB. This expression must be the same password used to encrypt the data or an error is returned. If the value of the password argument is null or not provided, the data will be decrypted using the ENCRYPTION PASSWORD value, which must have been set using the SET ENCRYPTION PASSWORD statement.
DEFAULT
The data will be decrypted using the ENCRYPTION PASSWORD value, which must have been set using the SET ENCRYPTION PASSWORD statement.
integer
An integer constant that specifies the CCSID of the result. If DECRYPT_BIT or DECRYPT_BINARY is specified, the third argument must not be specified.

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.

Notes

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.

Examples

DEGREES

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-DEGREES--(--expression--)-----------------------------------><
 

The DEGREES function returns the number of degrees of the argument which is an angle expressed in radians.

expression
The argument must be an expression that returns a value of any built-in numeric, character-string, or graphic-string data type. A string argument is cast to double-precision floating point before evaluating the function. For more information on converting strings to double-precision floating point, see DOUBLE_PRECISION or DOUBLE.

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.

Example

DIFFERENCE

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-DIFFERENCE--(--expression-1--,--expression-2--)-------------><
 

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.

expression-1 or expression-2
The arguments must be a built-in numeric, character-string, or graphic-string data types, but not CLOBs or DBCLOBs. The arguments cannot be binary-strings. 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.

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.

Examples

DIGITS

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-DIGITS--(--expression--)------------------------------------><
 

The DIGITS function returns a character-string representation of the absolute value of a number.

expression
The argument must be an expression that returns a value of a built-in small integer, integer, big integer, decimal, character-string, or graphic-string data type. A string argument is cast to DECIMAL(63,31) before evaluating the function. For more information on converting strings to decimal, see DECIMAL or DEC.

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.

Examples

DLCOMMENT

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-DLCOMMENT--(--DataLink-expression--)------------------------><
 

The DLCOMMENT function returns the comment value, if it exists, from a DataLink value.

DataLink-expression
The argument must be an expression that results in a value with a built-in DataLink data type.

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.

Examples

DLLINKTYPE

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-DLLINKTYPE--(--DataLink-expression--)-----------------------><
 

The DLLINKTYPE function returns the link type value from a DataLink value.

DataLink-expression
The argument must be an expression that results in a value with a built-in DataLink data type.

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.

Examples

DLURLCOMPLETE

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-DLURLCOMPLETE--(--DataLink-expression--)--------------------><
 

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.

DataLink-expression
The argument must be an expression that results in a value with a built-in DataLink data type.

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.

Examples

DLURLPATH

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-DLURLPATH--(--DataLink-expression--)------------------------><
 

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.

DataLink-expression
The argument must be an expression that results in a value with a built-in DataLink data type.

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.

Examples

DLURLPATHONLY

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-DLURLPATHONLY--(--DataLink-expression--)--------------------><
 

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.

DataLink-expression
The argument must be an expression that results in a value with a built-in DataLink data type.

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.

Examples

DLURLSCHEME

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-DLURLSCHEME--(--DataLink-expression--)----------------------><
 

The DLURLSCHEME function returns the scheme from a DataLink value with a linktype of URL. The value will always be in upper case.

DataLink-expression
The argument must be an expression that results in a value with a built-in DataLink data type.

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.

Examples

DLURLSERVER

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-DLURLSERVER--(--DataLink-expression--)----------------------><
 

The DLURLSERVER function returns the file server from a DataLink value with a linktype of URL. The value will always be in upper case.

DataLink-expression
The argument must be an expression that results in a value with a built-in DataLink data type.

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.

Examples

DLVALUE

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-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.

data-location
If the link type is URL, then this is a character string expression that contains a complete URL value. If the expression is not an empty string, it must include the URL scheme and URL server. The actual length of the character string expression must be less than or equal to 32718 characters.
linktype-string
An optional character string expression that specifies the link type of the DataLink value. The only valid value is 'URL'.
comment-string
An optional character string expression that provides a comment or additional location information. The actual length of the character string expression must be less than or equal to 254 characters.

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:

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.

Examples

DOUBLE_PRECISION or DOUBLE

Click to skip syntax diagram

Numeric to Double

Read syntax diagramSkip visual syntax diagram>>-+-DOUBLE_PRECISION-+--(--numeric-expression--)--------------><
   '-DOUBLE-----------'
 

String to Double

Read syntax diagramSkip visual syntax diagram>>-+-DOUBLE_PRECISION-+--(--string-expression--)---------------><
   '-DOUBLE-----------'
 

The DOUBLE_PRECISION and DOUBLE functions return a floating-point representation of:

Numeric to Double

numeric-expression
An expression that returns a value of any built-in numeric data type.

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

string-expression
An expression that returns a value that is a character-string or graphic-string representation of a number.

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.

Note

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.

Example

ENCRYPT_RC2

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-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).

data-string
An expression that returns the string value to be encrypted. The string expression must be a built-in string data type.

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.

password-string
An expression that returns a character string value with at least 6 bytes and no more than 127 bytes. The expression must not be a CLOB. The value represents the password used to encrypt the data-string. If the value of the password argument is null or not provided, the data will be encrypted using the ENCRYPTION PASSWORD value, which must have been set using the SET ENCRYPTION PASSWORD statement.
hint-string
An expression that returns a character string value with up to 32 bytes that will help data owners remember passwords (For example, 'Ocean' is a hint to remember 'Pacific'). The expression must not be a CLOB. If a hint value is specified, the hint is embedded into the result and can be retrieved using the GETHINT function. If the password-string is specified and this argument is the null value or not provided, no hint will be embedded in the result. If the password-string is not specified, the hint may be specified using the SET ENCRYPTION PASSWORD statement.

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.

Notes

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.

Example

ENCRYPT_TDES

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-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).

data-string
An expression that returns the string value to be encrypted. The string expression must be a built-in string data type.

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.

password-string
An expression that returns a character string value with at least 6 bytes and no more than 127 bytes. The expression must not be a CLOB and the CCSID of the expression must not be 65535. The value represents the password used to encrypt the data-string. If the value of the password argument is null or not provided, the data will be encrypted using the ENCRYPTION PASSWORD value, which must have been set using the SET ENCRYPTION PASSWORD statement.
hint-string
An expression that returns a character string value with up to 32 bytes that will help data owners remember passwords (For example, 'Ocean' is a hint to remember 'Pacific'). The expression must not be a CLOB and the CCSID of the expression must not be 65535. If a hint value is specified, the hint is embedded into the result and can be retrieved using the GETHINT function. If the password-string is specified and this argument is the null value or not provided, no hint will be embedded in the result. If the password-string is not specified, the hint may be specified using the SET ENCRYPTION PASSWORD statement.

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.

Notes

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.

Example

EXP

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-EXP--(--expression--)---------------------------------------><
 

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.

expression
The argument must be an expression that returns a value of any built-in numeric, character-string, or graphic-string data type. A string argument is cast to double-precision floating point before evaluating the function. For more information on converting strings to double-precision floating point, see DOUBLE_PRECISION or DOUBLE.

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.

Example

EXTRACT

Click to skip syntax diagram

Extract Date Values

Read syntax diagramSkip visual syntax diagram>>-EXTRACT--(--+-YEAR--+--FROM--+-date-expression------+--)----><
               +-MONTH-+        '-timestamp-expression-'
               '-DAY---'
 

Extract Time Values

Read syntax diagramSkip visual syntax diagram>>-EXTRACT--(--+-HOUR---+--FROM--+-time-expression------+--)---><
               +-MINUTE-+        '-timestamp-expression-'
               '-SECOND-'
 

The EXTRACT function returns a specified portion of a datetime value.

Extract Date Values

YEAR
Specifies that the year portion of the date or timestamp expression is returned. The result is identical to the YEAR scalar function. For more information, see YEAR.
MONTH
Specifies that the month portion of the date or timestamp expression is returned. The result is identical to the MONTH scalar function. For more information, see MONTH.
DAY
Specifies that the day portion of the date or timestamp expression is returned. The result is identical to the DAY scalar function. For more information, see DAY.
date-expression
An expression that returns the value of either a built-in date or built-in character string data type.

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.

timestamp-expression
An expression that returns the value of either a built-in timestamp or built-in character string data type.

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

HOUR
Specifies that the hour portion of the time or timestamp expression is returned. The result is identical to the HOUR scalar function. For more information, see HOUR.
MINUTE
Specifies that the minute portion of the time or timestamp expression is returned. The result is identical to the MINUTE scalar function. For more information, see MINUTE.
SECOND
Specifies that the second portion of the date or timestamp expression is returned. The result is identical to the following:
DECIMAL((DAY(expression) + DECIMAL(MICROSECOND(expression),12,6)/1000000), 8,6)
For more information, see SECOND and MICROSECOND.
time-expression
An expression that returns the value of either a built-in time or built-in character string data type.

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.

timestamp-expression
An expression that returns the value of either a built-in timestamp or built-in character string data type.

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.

Examples

FLOAT

Click to skip syntax diagram

Numeric to Float

Read syntax diagramSkip visual syntax diagram>>-FLOAT--(--numeric-expression--)-----------------------------><
 

String to Float

Read syntax diagramSkip visual syntax diagram>>-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.

FLOOR

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-FLOOR--(--expression--)-------------------------------------><
 

The FLOOR function returns the largest integer value less than or equal to expression.

expression
The argument must be an expression that returns a value of any built-in numeric, character-string, or graphic-string data type. A string argument is cast to double-precision floating point before evaluating the function. For more information on converting strings to double-precision floating point, see DOUBLE_PRECISION or DOUBLE.

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.

Example

GENERATE_UNIQUE

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-GENERATE_UNIQUE--(--)---------------------------------------><
 

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.

Examples

GETHINT

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-GETHINT--(--encrypted-data--)-------------------------------><
 

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').

encrypted-data
An expression that must be a string expression that returns a complete, encrypted data value of a CHAR FOR BIT DATA, VARCHAR FOR BIT DATA, BINARY, VARBINARY, or BLOB built-in data type. The data string must have been encrypted using the ENCRYPT_RC2 or ENCRYPT_TDES function.

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.

Example

GRAPHIC

Click to skip syntax diagram

Character to Graphic

Read syntax diagramSkip visual syntax diagram>>-GRAPHIC--(--character-expression----------------------------->
 
>--+--------------------------------+--)-----------------------><
   '-,--+-length--+--+------------+-'
        '-DEFAULT-'  '-,--integer-'
 

Graphic to Graphic

Read syntax diagramSkip visual syntax diagram>>-GRAPHIC--(--graphic-expression------------------------------->
 
>--+--------------------------------+--)-----------------------><
   '-,--+-length--+--+------------+-'
        '-DEFAULT-'  '-,--integer-'
 

Integer to Graphic

Read syntax diagramSkip visual syntax diagram>>-GRAPHIC--(--integer-expression--)---------------------------><
 

Decimal to GRAPHIC

Read syntax diagramSkip visual syntax diagram>>-GRAPHIC------------------------------------------------------>
 
>--(--decimal-expression--+----------------------+--)----------><
                          '-,--decimal-character-'
 

Floating-point to GRAPHIC

Read syntax diagramSkip visual syntax diagram>>-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

character-expression
Specifies a character string expression. It cannot be a CHAR or VARCHAR bit data. If the expression is an empty string or the EBCDIC string X'0E0F', the result is an empty string.
length
An integer constant that specifies the length attribute of the result and must be an integer constant between 1 and 16383 if the first argument is not nullable or between 1 and 16382 if the first argument is nullable. If the length of character-expression is less than the length specified, the result is padded with double-byte blanks to the length of the result.

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.

integer
An integer constant that specifies the CCSID of the result. It must be a DBCS, UTF-16, or UCS-2 CCSID. The CCSID cannot be 65535. If the CCSID represents 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.

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

graphic-expression
Specifies a graphic string expression.
length
An integer constant that specifies the length attribute of the result and must be an integer constant between 1 and 16383 if the first argument is not nullable or between 1 and 16382 if the first argument is nullable. If the length of graphic-expression is less than the length specified, the result is padded with double-byte blanks to the length of the result.

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.

integer
An integer constant that specifies the CCSID of the result. It must be a DBCS, UTF-16, or UCS-2 CCSID. The CCSID cannot be 65535.

If integer is not specified then the CCSID of the result is the CCSID of the first argument.

Integer to Graphic

integer-expression
An expression that returns a value that is an integer data type (either SMALLINT, INTEGER, or BIGINT).

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

decimal-expression
An expression that returns a value that is a packed or zoned decimal data type (either DECIMAL or NUMERIC). If a different precision and scale is desired, the DECIMAL scalar function can be used to make the change.
decimal-character
Specifies the single-byte character constant that is used to delimit the decimal digits in the result character string. The character must be a period or comma. If the second argument is not specified, the decimal point is the default decimal point. For more information, see Decimal point.

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

floating-point expression
An expression that returns a value that is a floating-point data type (DOUBLE or REAL).
decimal-character
Specifies the single-byte character constant that is used to delimit the decimal digits in the result character string. The character must be a period or comma. If the second argument is not specified, the decimal point is the default decimal point. For more information, see Decimal point.

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).

Note

Syntax alternatives: If the length attribute is specified, the CAST specification should be used for maximal portability. For more information, see CAST specification.

Example

HASH

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram            .-,----------.
            V            |
>>-HASH--(----expression-+--)----------------------------------><
 

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.

expression
The arguments can be any built-in data type except date, time, timestamp, floating-point, or DataLink values.

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.

Example

HASHED_VALUE

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-HASHED_VALUE--(--table-designator--)------------------------><
 

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.

table-designator
The argument must be a table designator of the subselect. For more information about table designators, see Table designators.

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.

Note

Syntax alternatives: PARTITION is a synonym for HASHED_VALUE.

Example

HEX

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-HEX--(--expression--)---------------------------------------><
 

The HEX function returns a hexadecimal representation of a value.

expression
The argument can be of any built-in data type.

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.

Example

HOUR

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-HOUR--(--expression--)--------------------------------------><
 

The HOUR function returns the hour part of a value.

expression
The argument must be an expression that returns a value of one of the following built-in data types: a time, a timestamp, a character string, a graphic string, or a numeric data type.

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:

Example

IDENTITY_VAL_LOCAL

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-IDENTITY_VAL_LOCAL--(--)------------------------------------><
 

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:

Notes

The following notes explain the behavior of the function when it is invoked in various situations:

Invoking the function within the VALUES clause of an INSERT statement
Expressions in an INSERT statement are evaluated before values are assigned to the target columns of the INSERT statement. Thus, when you invoke IDENTITY_VAL_LOCAL in an INSERT statement, the value that is used is the most recently assigned value for an identity column from a previous INSERT statement. The function returns the null value if no such INSERT statement had been executed within the same level as the invocation of the IDENTITY_VAL_LOCAL function.
Invoking the function following a failed INSERT statement
The function returns an unpredictable result when it is invoked after the unsuccessful execution of an INSERT statement for a table with an identity column. The value might be the value that would have been returned from the function had it been invoked before the failed INSERT or the value that would have been assigned had the INSERT succeeded. The actual value returned depends on the point of failure and is therefore unpredictable.
Invoking the function within the SELECT statement of a cursor
Because the results of the IDENTITY_VAL_LOCAL function are not deterministic, the result of an invocation of the IDENTITY_VAL_LOCAL function from within the SELECT statement of a cursor can vary for each FETCH statement.
Invoking the function within the trigger condition of an insert trigger
The result of invoking the IDENTITY_VAL_LOCAL function from within the condition of an insert trigger is the null value.
Invoking the function within a triggered action of an insert trigger
Multiple before or after insert triggers can exist for a table. In such cases, each trigger is processed separately, and identity values generated by SQL statements issued within a triggered action are not available to other triggered actions using the IDENTITY_VAL_LOCAL function. This is the case even though the multiple triggered actions are conceptually defined at the same level.

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.

Invoking the function following an INSERT with triggered actions
The result of invoking the function after an INSERT that activates triggers is the value actually assigned to the identity column (that is, the value that would be returned on a subsequent SELECT statement). This value is not necessarily the value provided in the INSERT statement or a value generated by the database manager. The assigned value could be a value that was specified in a SET transition variable statement within the triggered action of a before insert trigger for a trigger transition variable associated with the identity column.

Examples

IFNULL

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-IFNULL--(--expression--,--expression--)---------------------><
 

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.

Example

INSERT

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-INSERT--(--source-string--,--start--,--length--,--insert-string--)-><
 

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.

source-string
An expression that specifies the source string. The source-string may be any built-in numeric or string expression. It must be compatible with the insert-string. For more information about data type compatibility, see Assignments and comparisons. 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. The actual length of the string must be greater than zero.
start
An expression that returns a built-in BIGINT, INTEGER, or SMALLINT data type. The integer specifies the starting point within source-string where the deletion of characters and the insertion of another string is to begin. The value of the integer must be in the range of 1 to the length of source-string plus one.
length
An expression that returns a built-in BIGINT, INTEGER, or SMALLINT data type. The integer specifies the number of characters that are to be deleted from source-string, starting at the position identified by start. The value of the integer must be in the range of 0 to the length of source-string.
insert-string
An expression that specifies the string to be inserted into source-string, starting at the position identified by start. The insert-string may be any built-in numeric or string expression. It must be compatible with the source-string. For more information about data type compatibility, see Assignments and comparisons. 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. The actual length of the string must be greater than zero.

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:

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.

Examples

INTEGER or INT

Click to skip syntax diagram

Numeric to Integer

Read syntax diagramSkip visual syntax diagram>>-+-INTEGER-+--(--numeric-expression--)-----------------------><
   '-INT-----'
 

String to Integer

Read syntax diagramSkip visual syntax diagram>>-+-INTEGER-+--(--string-expression--)------------------------><
   '-INT-----'
 

The INTEGER function returns an integer representation of:

Numeric to Integer

numeric-expression
An expression that returns a numeric value of any built-in numeric data type.

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

string-expression
An expression that returns a value that is a character-string or graphic-string representation of a number.

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.

Note

Syntax alternatives: The CAST specification should be used for maximal portability. For more information, see CAST specification.

Example

JULIAN_DAY

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-JULIAN_DAY--(--expression--)--------------------------------><
 

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.

expression
The argument must be an expression that returns a value of one of the following built-in data types: a date, a timestamp, a character string, a graphic string, or a numeric data type. 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.

Examples

LAND

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram                        .---------------.
                        V               |
>>-LAND--(--expression----,--expression-+--)-------------------><
 

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.

expression
The arguments must be expressions that return a value of any built-in numeric or string data type, but cannot be LOBs. The arguments cannot be mixed data character strings, UTF-8 character strings, or graphic strings. 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.

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.

Example

LAST_DAY

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-LAST_DAY--(--expression--)----------------------------------><
 

The LAST_DAY scalar function returns a date that represents the last day of the month indicated by expression.

expression
The argument must be an expression that returns a value of one of the following built-in data types: a date, a timestamp, a character string, or a graphic 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 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.

Example

LCASE

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-LCASE--(--expression--)-------------------------------------><
 

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.

LEFT

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-LEFT--(--expression--,--integer--)--------------------------><
 

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.

expression
An expression that specifies the string from which the result is derived. The arguments must be expressions that return a value of any built-in numeric, character string, graphic string, or a binary 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.

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

integer
An expression that returns a built-in integer data type. The integer specifies the length of the result. The value of integer must be greater than or equal to 0 and less than or equal to n, where n is the length attribute of expression.

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.

Example

LENGTH

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-LENGTH--(--expression--)------------------------------------><
 

The LENGTH function returns the length of a value. See CHARACTER_LENGTH, OCTET_LENGTH, and BIT_LENGTH for similar functions.

expression
The argument must be an expression that returns a value of any built-in data type.

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:

Examples

LN

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-LN--(--expression--)----------------------------------------><
 

The LN function returns the natural logarithm of a number. The LN and EXP functions are inverse operations.

expression
The argument must be an expression that returns a value of any built-in numeric, character-string, or graphic-string data type. A string argument is cast to double-precision floating point before evaluating the function. For more information on converting strings to double-precision floating point, see DOUBLE_PRECISION or DOUBLE. The value of the argument must be greater than zero.

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.

Example

LNOT

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-LNOT--(--expression--)--------------------------------------><
 

The LNOT function returns a string that is the logical NOT of the argument string.

expression
The arguments must be expressions that return a value of any built-in numeric or string data type, but cannot be LOBs. The arguments cannot be mixed data character strings, UTF-8 character strings, or graphic strings. 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.

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.

Example

LOCATE

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-LOCATE--(--search-string--,--source-string--+----------+--)-><
                                               '-,--start-'
 

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.

search-string
An expression that specifies the string that is to be searched for. Search-string may be any built-in numeric or string expression. It must be compatible with the source-string. 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.
source-string
An expression that specifies the source string in which the search is to take place. Source-string may be any built-in numeric or string expression. 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.
start
An expression that specifies the position within source-string at which the search is to start. It must be an integer that is greater than or equal to zero.

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.

Example

LOG10

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-LOG10--(--expression--)-------------------------------------><
 

The LOG10 function returns the common logarithm (base 10) of a number. The LOG10 and ANTILOG functions are inverse operations.

expression
The argument must be an expression that returns a value of any built-in numeric, character-string, or graphic-string data type. A string argument is cast to double-precision floating point before evaluating the function. For more information on converting strings to double-precision floating point, see DOUBLE_PRECISION or DOUBLE.

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.

Note

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.

Example

LOR

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram                       .---------------.
                       V               |
>>-LOR--(--expression----,--expression-+--)--------------------><
 

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.

expression
The arguments must be expressions that return a value of any built-in numeric or string data type, but cannot be LOBs. The arguments cannot be mixed data character strings, UTF-8 character strings, or graphic strings. 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.

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.

Example

LOWER

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-LOWER--(--expression--)-------------------------------------><
 

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.

expression
An expression that specifies the string to be converted. expression must be any built-in numeric, character, UTF–16, or UCS-2 graphic string. 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.

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:

Note

Syntax alternatives: LCASE is a synonym for LOWER.

Examples

LTRIM

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-LTRIM--(--expression--)-------------------------------------><
 

The LTRIM function removes blanks or hexadecimal zeros from the beginning of an expression. 46

expression
The arguments must be expressions that return a value of 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.

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.

Example

MAX

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram                       .---------------.
                       V               |
>>-MAX--(--expression----,--expression-+--)--------------------><
 

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.

expression
The arguments must be any built-in numeric or string data types. If one of the arguments is numeric, then character and graphic string arguments are cast to numeric before evaluating the function.

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.

Examples

MICROSECOND

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-MICROSECOND--(--expression--)-------------------------------><
 

The MICROSECOND function returns the microsecond part of a value.

expression
The argument must be an expression that returns a value of one of the following built-in data types: a timestamp, a character string, a graphic string, or a numeric data type.

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:

Example

MIDNIGHT_SECONDS

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-MIDNIGHT_SECONDS--(--expression--)--------------------------><
 

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.

expression
The argument must be an expression that returns a value of one of the following built-in data types: a time, a timestamp, a character string, or a 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 large integer. If the argument can be null, the result can be null; if the argument is null, the result is the null value.

Examples

MIN

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram                       .---------------.
                       V               |
>>-MIN--(--expression----,--expression-+--)--------------------><
 

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.

expression
The arguments must be any built-in numeric or string data types. If one of the arguments is numeric, then character and graphic string arguments are cast to numeric before evaluating the function.

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.

Examples

MINUTE

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-MINUTE--(--expression--)------------------------------------><
 

The MINUTE function returns the minute part of a value.

expression
The argument must be an expression that returns a value of one of the following built-in data types: a time, a timestamp, a character string, a graphic string, or a numeric data type.

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:

Example

MOD

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-MOD--(--expression-1--,--expression-2--)--------------------><
 

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.

expression-1
The argument must be an expression that returns a value of any built-in numeric, character-string, or graphic-string data type. A string argument is cast to double-precision floating point before evaluating the function. For more information on converting strings to double-precision floating point, see DOUBLE_PRECISION or DOUBLE.
expression-2
The argument must be an expression that returns a value of any built-in numeric, character-string, or graphic-string data type. A string argument is cast to double-precision floating point before evaluating the function. For more information on converting strings to double-precision floating point, see DOUBLE_PRECISION or DOUBLE. expression-2 cannot be zero.

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:

Examples

MONTH

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-MONTH--(--expression--)-------------------------------------><
 

The MONTH function returns the month part of a value.

expression
The argument must be an expression that returns a value of one of the following built-in data types: a date, a timestamp, a character string, a graphic string, or a numeric data type.

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:

Example

MONTHNAME

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-MONTHNAME--(--expression--)---------------------------------><
 

Returns a mixed case character string containing the name of the month (e.g. January) for the month portion of the argument.

expression
The argument must be an expression that returns a value of one of the following built-in data types: a date, a timestamp, a character string, or a graphic 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 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.

Note

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.

Examples

MULTIPLY_ALT

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-MULTIPLY_ALT--(--expression-1--,--expression-2--)-----------><
 

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.

expression-1
The argument must be an expression that returns a value of any built-in numeric, character-string, or graphic-string data type. A string argument is cast to double-precision floating point before evaluating the function. For more information on converting strings to double-precision floating point, see DOUBLE_PRECISION or DOUBLE.
expression-2
The argument must be an expression that returns a value of any built-in numeric, character-string, or graphic-string data type. A string argument is cast to double-precision floating point before evaluating the function. For more information on converting strings to double-precision floating point, see DOUBLE_PRECISION or DOUBLE. expression-2 cannot be zero.

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)

Examples

NEXT_DAY

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-NEXT_DAY--(--expression--,--string-expression--)------------><
 

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.

expression
The argument must be an expression that returns a value of one of the following built-in data types: a date, a timestamp, a character string, or a graphic 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 date or timestamp. For the valid formats of string representations of dates and timestamps, see String representations of datetime values.

string-expression
An expression that returns a built-in character string data type or graphic string data type. The value must compare equal to the full name of a day of the week or compare equal to the abbreviation of a day of the week. For example, in the English language:
Day of Week Abbreviation
MONDAY MON
TUESDAY TUE
WEDNESDAY WED
THURSDAY THU
FRIDAY FRI
SATURDAY SAT
SUNDAY SUN
The minimum length of the input value is the length of the abbreviation. Leading and trailing blanks are trimmed from string-expression. The resulting value is then folded to uppercase, so the characters in the value may be in any case.

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.

Note

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.

Example

NOW

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-NOW--(--)---------------------------------------------------><
 

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.

Note

Syntax alternatives: The CURRENT_TIMESTAMP special register should be used for maximal portability. For more information, see Special registers.

Example

NULLIF

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-NULLIF--(--expression--,--expression--)---------------------><
 

The NULLIF function returns a null value if the arguments compare equal, otherwise it returns the value of the first argument.

expression
The arguments must be compatible and comparable data types. Character-string arguments are compatible with datetime values. If one operand is a distinct type, the other operand must be the same distinct type. The arguments cannot be DataLink values.

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.

Example

OCTET_LENGTH

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>---OCTET_LENGTH----(--expression--)--------------------------><
 

The OCTET_LENGTH function returns the length of a string expression in octets (bytes). See LENGTH and CHARACTER_LENGTH for similar functions.

expression
The argument must be an expression that returns a value of 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.

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.

Example

PI

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-PI--(--)----------------------------------------------------><
 

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.

Example

POSITION or POSSTR

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-+-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.

source-string
An expression that specifies the source string in which the search is to take place. Source-string may be any built-in numeric or string expression. 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.
search-string
An expression that specifies the string that is to be searched for. Search-string may be any built-in numeric or string expression. It must be compatible with the source-string. 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 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:

Example

POWER

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-POWER--(--expression-1--,--expression-2--)------------------><
 

The POWER function returns the result of raising the first argument to the power of the second argument. 48

expression-1
The argument must be an expression that returns a value of any built-in numeric, character-string, or graphic-string data type. A string argument is cast to double-precision floating point before evaluating the function. For more information on converting strings to double-precision floating point, see DOUBLE_PRECISION or DOUBLE.
expression-2
The argument must be an expression that returns a value of any built-in numeric data type. If the value of expression-1 is equal to zero, then expression-2 must be greater than or equal to zero. If the value of expression-1 is less than zero, then expression-2 must be an integer value.

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.

Example

QUARTER

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-QUARTER--(--expression--)-----------------------------------><
 

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.

expression
The argument must be an expression that returns a value of one of the following built-in data types: a date, a timestamp, a character string, or a graphic 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 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.

Example

RADIANS

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-RADIANS--(--expression--)-----------------------------------><
 

The RADIANS function returns the number of radians for an argument that is expressed in degrees.

expression
The argument must be an expression that returns a value of any built-in numeric, character-string, or graphic-string data type. A string argument is cast to double-precision floating point before evaluating the function. For more information on converting strings to double-precision floating point, see DOUBLE_PRECISION or DOUBLE.

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.

Example

RAISE_ERROR

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-RAISE_ERROR--(--sqlstate--,--diagnostic-string--)-----------><
 

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.

sqlstate
An expression that returns a character or UCS-2 or UTF-16 graphic string constant with exactly 5 characters that follow the rules for SQLSTATEs:

If the SQLSTATE does not conform to these rules, an error is returned.

diagnostic-string
Specifies a string that describes the error or warning.

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.

Example

RAND

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-RAND--(--+------------+--)----------------------------------><
            '-expression-'
 

The RAND function returns a floating point value between 0 and 1.

expression
If an expression is specified, it is used as the seed value. The argument must be an expression that returns a value of a built-in small integer, large integer, character-string, or graphic-string data type. A string argument is cast to integer before evaluating the function. For more information on converting strings to integer, see INTEGER or INT.

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.

Example

REAL

Click to skip syntax diagram

Numeric to Real

Read syntax diagramSkip visual syntax diagram>>-REAL--(--numeric-expression--)------------------------------><
 

String to Real

Read syntax diagramSkip visual syntax diagram>>-REAL--(--string-expression--)-------------------------------><
 

The REAL function returns a single-precision floating-point representation of:

Numeric to Real

numeric-expression
The argument is an expression that returns a value of any built-in numeric data type.

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

string-expression
An expression that returns a value that is a character-string or graphic-string representation of a number.

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.

Note

Syntax alternatives: The CAST specification should be used for maximal portability. For more information, see CAST specification.

Example

REPEAT

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-REPEAT--(--expression--,--integer--)------------------------><
 

The REPEAT function returns a string composed of expression repeated integer times.

expression
An expression that specifies the string to be repeated. The string must be a built-in numeric or string expression. 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.
integer
An expression that returns a built-in BIGINT, INTEGER, or SMALLINT data type whose value is a positive integer or zero. The integer specifies the number of times to repeat the string.

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

Examples

REPLACE

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-REPLACE--(--source-string--,--search-string--,--replace-string--)-><
 

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
An expression that specifies the source string. The source-string must be a built-in numeric or string expression. 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.
search-string
An expression that specifies the string to be removed from the source string. The search-string must be a built-in numeric or string expression. 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.
replace-string
An expression that specifies the replacement string. The replace-string must be a built-in numeric or string expression. 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.

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:

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.

Examples

RIGHT

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-RIGHT--(--expression--,--integer--)-------------------------><
 

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.

expression
An expression that specifies the string from which the result is derived. The string must be a built-in numeric or string expression. 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 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

integer
An expression that returns a built-in integer data type. The integer specifies the length of the result. integer must be greater than or equal to 0 and less than or equal to n, where n is the length attribute of expression.

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.

Example

ROUND

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-ROUND--(--expression-1--,--expression-2--)------------------><
 

The ROUND function returns expression–1 rounded to some number of places to the right or left of the decimal point.

expression–1
An expression that returns a value of any built-in numeric, character-string, or graphic-string data type. A string argument is converted to double-precision floating point before evaluating the function. For more information on converting strings to double-precision floating point, see DOUBLE_PRECISION or DOUBLE.
expression–2
The argument must be an expression that returns a value of a built-in BIGINT, INTEGER, or SMALLINT data type.

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.

Examples

ROWID

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-ROWID--(--string-expression--)------------------------------><
 

The ROWID function casts a character string to a row ID.

string-expression
An expression that returns a character string value. Although the string can contain any value, it is recommended that it contain a ROWID value that was previously generated by DB2 UDB for z/OS or DB2 UDB for iSeries to ensure a valid ROWID value is returned. For example, the function can be used to convert a ROWID value that was cast to a CHAR value back to a ROWID value.

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.

Note

Syntax alternatives: The CAST specification should be used for maximal portability. For more information, see CAST specification.

Example

RRN

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-RRN--(--table-designator--)---------------------------------><
 

The RRN function returns the relative record number of a row.

table-designator
The argument must be a table designator of the subselect. For more information about table designators, see Table designators.

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.

Example

RTRIM

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-RTRIM--(--expression--)-------------------------------------><
 

The RTRIM function removes blanks or hexadecimal zeroes from the end of a string expression. 51

expression
The arguments must be expressions that return a value of 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.

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.

Example

SECOND

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-SECOND--(--expression--)------------------------------------><
 

The SECOND function returns the seconds part of a value.

expression
The argument must be an expression that returns a value of one of the following built-in data types: a time, a timestamp, a character string, a graphic string, or a numeric data type.

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:

Examples

SIGN

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-SIGN--(--expression--)--------------------------------------><
 

The SIGN function returns an indicator of the sign of expression. The returned value is:

–1
if the argument is less than zero
0
if the argument is zero
1
if the argument is greater than zero
expression
An expression that returns a value of any built-in numeric, character-string, or graphic-string data type. A string argument is converted to double-precision floating point before evaluating the function. For more information on converting strings to double-precision floating point, see DOUBLE_PRECISION or DOUBLE.

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.

Example

SIN

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-SIN--(--expression--)---------------------------------------><
 

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.

expression
An expression that returns a value of any built-in numeric, character-string, or graphic-string data type. A string argument is converted to double-precision floating point before evaluating the function. For more information on converting strings to double-precision floating point, see DOUBLE_PRECISION or DOUBLE.

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.

Example

SINH

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-SINH--(--expression--)--------------------------------------><
 

The SINH function returns the hyperbolic sine of the argument, where the argument is an angle expressed in radians.

expression
An expression that returns a value of any built-in numeric, character-string, or graphic-string data type. A string argument is converted to double-precision floating point before evaluating the function. For more information on converting strings to double-precision floating point, see DOUBLE_PRECISION or DOUBLE.

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.

Example

SMALLINT

Click to skip syntax diagram

Numeric to Smallint

Read syntax diagramSkip visual syntax diagram>>-SMALLINT--(--numeric-expression--)--------------------------><
 

String to Smallint

Read syntax diagramSkip visual syntax diagram>>-SMALLINT--(--string-expression--)---------------------------><
 

The SMALLINT function returns a small integer representation of

Numeric to Smallint

numeric-expression
An expression that returns a numeric value of any built-in numeric data type.

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

string-expression
An expression that returns a value that is a character-string or graphic-string representation of a number.

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.

Note

Syntax alternatives: The CAST specification should be used for maximal portability. For more information, see CAST specification.

Example

SOUNDEX

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-SOUNDEX--(--expression--)-----------------------------------><
 

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.

expression
The argument must be an expression that returns a value of any built-in numeric or string data type, other than a CLOB or DBCLOB. The argument cannot be a binary-string. 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.

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.

Example

SPACE

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-SPACE--(--expression--)-------------------------------------><
 

The SPACE function returns a character string that consists of the number of SBCS blanks that the argument specifies.

expression
An expression that returns a value of any built-in numeric, character-string, or graphic-string data type. A string argument is converted to integer before evaluating the function. For more information on converting strings to integer, see INTEGER or INT.

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.

Example

SQRT

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-SQRT--(--expression--)--------------------------------------><
 

The SQRT function returns the square root of a number.

expression
An expression that returns a value of any built-in numeric, character-string, or graphic-string data type. A string argument is converted to double-precision floating point before evaluating the function. For more information on converting strings to double-precision floating point, see DOUBLE_PRECISION or DOUBLE. The value of expression must be greater than or equal to zero.

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.

Example

STRIP

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-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.

SUBSTRING or SUBSTR

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-+-+-SUBSTR----+--(--expression--,--start--+-----------+--)---+-><
   | '-SUBSTRING-'                           '-,--length-'      |
   '-SUBSTRING--(--expression--FROM--start--+--------------+--)-'
                                            '- FOR--length-'
 

The SUBSTR and SUBSTRING functions return a substring of a string.

expression
An expression that specifies the string from which the result is derived.

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:

start
An expression that specifies the position within expression of the first character (or byte) of the result. The expression must return a value that is a built-in BIGINT, INTEGER, or SMALLINT data type. start may be negative or zero. It may also be greater than the length attribute of expression. (The length attribute of a varying-length string is its maximum length.)
length
An expression that specifies the length of the result. If specified, length must be an expression that returns a value that is a built-in BIGINT, INTEGER, or SMALLINT data type. The value must be greater than or equal to 0 and less than or equal to n, where n is the length attribute of expression - start + 1.

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:
  • length is explicitly specified by an integer constant.
  • length is not explicitly specified, but expression is a fixed-length string and start is an integer constant.
VARCHAR, in all other cases
CLOB CLOB CLOB
GRAPHIC or VARGRAPHIC VARGRAPHIC GRAPHIC, if:
  • length is explicitly specified by an integer constant that is greater than zero.
  • length is not explicitly specified, but expression is a fixed-length string and start is an integer constant that is greater than zero.
VARGRAPHIC, in all other cases.
DBCLOB DBCLOB DBCLOB
BINARY or VARBINARY VARBINARY BINARY, if:
  • length is explicitly specified by an integer constant that is greater than zero.
  • length is not explicitly specified, but expression is a fixed-length string and start is an integer constant that is greater than zero.
VARBINARY, in all other cases.
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.

Examples

TAN

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-TAN--(--expression--)---------------------------------------><
 

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.

expression
An expression that returns a value of any built-in numeric, character-string, or graphic-string data type. A string argument is converted to double-precision floating point before evaluating the function. For more information on converting strings to double-precision floating point, see DOUBLE_PRECISION or DOUBLE.

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.

Example

TANH

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-TANH--(--expression--)--------------------------------------><
 

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.

expression
An expression that returns a value of any built-in numeric, character-string, or graphic-string data type. A string argument is converted to double-precision floating point before evaluating the function. For more information on converting strings to double-precision floating point, see DOUBLE_PRECISION or DOUBLE.

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.

Example

TIME

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-TIME--(--expression--)--------------------------------------><
 

The TIME function returns a time from a value.

expression
The argument must be an expression that returns a value of one of the following built-in data types: a time, a timestamp, a character string, or a graphic 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 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:

Note

Syntax alternatives: The CAST specification should be used for maximal portability. For more information, see CAST specification.

Example

TIMESTAMP

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-TIMESTAMP--(--expression-1--+-----------------+--)----------><
                               '-,--expression-2-'
 

The TIMESTAMP function returns a timestamp from its argument or arguments.

expression-1
If only one argument is specified, the argument must be an expression that returns a value of one of the following built-in data types: a timestamp, 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 one of the following:

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.

expression-2
The second argument must be an expression that returns a value of one of the following built-in data types: a time, a character string, or a graphic string.

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:

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.

Note

Syntax alternatives: If only one argument is specified, the CAST specification should be used for maximal portability. For more information, see CAST specification.

Example

TIMESTAMP_ISO

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-TIMESTAMP_ISO--(--expression--)-----------------------------><
 

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.

expression
The argument must be an expression that returns a value of one of the following built-in data types: a timestamp, a date, a time, a character string, or a graphic 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 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.

Note

Syntax alternatives: The CAST specification should be used for maximal portability. For more information, see CAST specification.

Example

TIMESTAMPDIFF

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-TIMESTAMPDIFF--(--numeric-expression--,--string-expression--)-><
 

The TIMESTAMPDIFF function returns an estimated number of intervals of the type defined by the first argument, based on the difference between two timestamps.

numeric-expression
The first argument must be a built-in data type of either INTEGER or SMALLINT. Valid values of interval (the first argument) are:
1 Fractions of a second
2 Seconds
4 Minutes
8 Hours
16 Days
32 Weeks
64 Months
128 Quarters
256 Years
string-expression
string-expression is the result of subtracting two timestamps and converting the result to a string of length 22. The argument must be an expression that returns a value of a built-in character string or a graphic string.

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.

Example

TRANSLATE

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-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.

expression
An expression that specifies the string to be converted 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.
to-string
A string that specifies the characters to which certain characters in expression are to be converted. This string is sometimes called the output translation table. 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 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.

from-string
A string that specifies the characters that if found in expression are to be converted. This string is sometimes called the input translation table. When a character in from-string is found, the character in expression is converted to the character in to-string that is in the corresponding position of the character in from-string.

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).

pad
A string that specifies the character with which to pad to-string if its length is less than from-string. The string must be a character string constant with a length of 1. The default is an SBCS blank.

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:

Examples

TRIM

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-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.

strip-character
The second argument, if specified, is a single-character constant that indicates the binary, SBCS, or DBCS character that is to be removed. If expression is a binary string, the second argument must be a binary string constant. If expression is a DBCS graphic or DBCS-only string, the second argument must be a graphic constant consisting of a single DBCS character. If the second argument is not specified then:
expression
The argument must be an expression that returns a value of 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.

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.

Examples

TRUNCATE or TRUNC

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-+-TRUNCATE-+--(--expression-1--,--expression-2--)-----------><
   '-TRUNC----'
 

The TRUNCATE function returns expression–1 truncated to some number of places to the right or left of the decimal point.

expression–1
An expression that returns a value of any built-in numeric, character-string, or graphic-string data type. A string argument is converted to double-precision floating point before evaluating the function. For more information on converting strings to double-precision floating point, see DOUBLE_PRECISION or DOUBLE.
expression–2
The argument must be an expression that returns a value of a built-in small integer, large integer, or big integer data type. The absolute value of integer specifies the number of places to the right of the decimal point for the result if expression–2 is not negative, or to left of the decimal point if expression–2 is negative.

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.

Examples

UCASE

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-UCASE--(--expression--)-------------------------------------><
 

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.

UPPER

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-UPPER--(--expression--)-------------------------------------><
 

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.

expression
An expression that specifies the string to be converted. expression must be any built-in numeric, character, UTF–16, or UCS-2 graphic string. 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.

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:

Note

Syntax alternatives: UCASE is a synonym for UPPER.

Examples

VALUE

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram                         .---------------.
                         V               |
>>-VALUE--(--expression----,--expression-+--)------------------><
 

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.

Note

Syntax alternatives: COALESCE should be used for conformance to the SQL 1999 standard.

VARBINARY

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-VARBINARY--(--string-expression--+------------+--)----------><
                                    '-,--integer-'
 

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.

string-expression
A string-expression whose value can be a character string, graphic string, binary string, or row ID.
integer
An integer constant that specifies the length attribute for the resulting binary string. The value must be between 1 and 32740 (32739 if nullable).

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.

Note

Syntax alternatives: When the length is specified, the CAST specification should be used for maximal portability. For more information, see CAST specification.

Example

VARCHAR

Click to skip syntax diagram

Datetime to Varchar

Read syntax diagramSkip visual syntax diagram>>-VARCHAR--(--datetime-expression--+--------------+--)--------><
                                    '-,--+-ISO---+-'
                                         +-USA---+
                                         +-EUR---+
                                         +-JIS---+
                                         '-LOCAL-'
 

Character to Varchar

Read syntax diagramSkip visual syntax diagram>>-VARCHAR (--character-expression------------------------------>
 
>--+--------------------------------+--)-----------------------><
   '-,--+-length--+--+------------+-'
        '-DEFAULT-'  '-,--integer-'
 

Graphic to Varchar

Read syntax diagramSkip visual syntax diagram>>-VARCHAR (--graphic-expression-------------------------------->
 
>--+--------------------------------+--)-----------------------><
   '-,--+-length--+--+------------+-'
        '-DEFAULT-'  '-,--integer-'
 

Integer to Varchar

Read syntax diagramSkip visual syntax diagram>>-VARCHAR--(--integer-expression--)---------------------------><
 

Decimal to Varchar

Read syntax diagramSkip visual syntax diagram>>-VARCHAR------------------------------------------------------>
 
>--(--decimal-expression--+----------------------+--)----------><
                          '-,--decimal-character-'
 

Floating-point to Varchar

Read syntax diagramSkip visual syntax diagram>>-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

datetime-expression
An expression that is one of the following three built-in data types
date
The result is the character-string representation of the date in the format specified by the second argument. If the second argument is not specified, the format used is the default date format. If the format is ISO, USA, EUR, or JIS, the length attribute and actual length of the result is 10. Otherwise the length attribute and actual length of the result is the length of the default date format. For more information see String representations of datetime values.
time
The result is the character-string representation of the time in the format specified by the second argument. If the second argument is not specified, the format used is the default time format. The length attribute and actual length of the result is 8. For more information see String representations of datetime values.
timestamp
The second argument is not applicable and must not be specified.

The result is the character-string representation of the timestamp. The length attribute and actual length of the result is 26.

The CCSID of the string is the default SBCS CCSID at the current server.
ISO, EUR, USA, or JIS
Specifies the date or time format of the resulting character string. For more information, see String representations of datetime values.
LOCAL
Specifies that the date or time format of the resulting character string should come from the DATFMT, DATSEP, TIMFMT, and TIMSEP attributes of the job at the current server.

Character to Varchar

character-expression
An expression that returns a value that is a built-in CHAR, VARCHAR, or CLOB data type.
length
An integer constant that specifies the length attribute for the resulting varying length character string. The value must be between 1 and 32740 (32739 if nullable). If the first argument is mixed data, the second argument cannot be less than 4.

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.

integer
An integer constant that specifies the CCSID of the result. It must be a valid SBCS CCSID, mixed data CCSID, or 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 65535, then the result is bit data. If the third argument is a SBCS CCSID, then the first argument cannot be a DBCS-either or DBCS-only string.

If the third argument is not specified then:

Graphic to Varchar

graphic-expression
An expression that returns a value that is a GRAPHIC, VARGRAPHIC, and DBCLOB data type. It must not be DBCS-graphic data.
length
An integer constant that specifies the length attribute for the resulting varying length character string. The value must be between 1 and 32740 (32739 if nullable). If the first argument contains DBCS data, the second argument cannot be less than 4.

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.

integer
An integer constant that specifies the CCSID of the result. It must be a valid SBCS CCSID or mixed data CCSID. 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. The third argument cannot be 65535.

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

integer-expression
An expression that returns a value that is an integer data type (either SMALLINT, INTEGER, or BIGINT).

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

decimal-expression
An expression that returns a value that is a packed or zoned decimal data type (either DECIMAL or NUMERIC). If a different precision and scale is desired, the DECIMAL scalar function can be used to make the change.
decimal-character
Specifies the single-byte character constant that is used to delimit the decimal digits in the result character string. The character must be a period or comma. If the second argument is not specified, the decimal point is the default decimal point. For more information, see Decimal point.

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

floating-point expression
An expression that returns a value that is a floating-point data type (DOUBLE or REAL).
decimal-character
Specifies the single-byte character constant that is used to delimit the decimal digits in the result character string. The character must be a period or comma. If the second argument is not specified, the decimal point is the default decimal point. For more information, see Decimal point.

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.

Note

Syntax alternatives: If the length attribute is specified, the CAST specification should be used for maximal portability. For more information, see CAST specification.

Example

VARCHAR_FORMAT

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-VARCHAR_FORMAT--(--expression--,--format-string--)----------><
 

The VARCHAR_FORMAT function returns a character representation of a timestamp in the format indicated by format-string.

expression
The argument must be an expression that returns a value of one of the following built-in data types: a timestamp, a character string, or a graphic 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.

format-string
An expression that returns a built-in character string data type or graphic string data type. format-string contains a template of how expression is to be formatted. Leading and trailing blanks are trimmed from format-string. The resulting value is then folded to uppercase, so the characters in the value may be in any case. The only valid format that can be specified for the function is:

'YYYY-MM-DD HH24:MI:SS'

where:

YYYY
4-digit year
MM
Month (01-12, January = 01)
DD
Day of month (01-31)
HH24
Hour of day (00–24, when the value is 24, the minutes and seconds must be 0).
MM
Minutes (00–59)
SS
Seconds (00–59)

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.

Note

Syntax alternatives: TO_CHAR is a synonym for VARCHAR_FORMAT.

Example

VARGRAPHIC

Click to skip syntax diagram

Character to Vargraphic

Read syntax diagramSkip visual syntax diagram>>-VARGRAPHIC--(--character-expression-------------------------->
 
>--+--------------------------------+--)-----------------------><
   '-,--+-length--+--+------------+-'
        '-DEFAULT-'  '-,--integer-'
 

Graphic to Vargraphic

Read syntax diagramSkip visual syntax diagram>>-VARGRAPHIC--(--graphic-expression---------------------------->
 
>--+--------------------------------+--)-----------------------><
   '-,--+-length--+--+------------+-'
        '-DEFAULT-'  '-,--integer-'
 

Integer to Vargraphic

Read syntax diagramSkip visual syntax diagram>>-VARGRAPHIC--(--integer-expression--)------------------------><
 

Decimal to Vargraphic

Read syntax diagramSkip visual syntax diagram>>-VARGRAPHIC--------------------------------------------------->
 
>--(--decimal-expression--+----------------------+--)----------><
                          '-,--decimal-character-'
 

Floating-point to Vargraphic

Read syntax diagramSkip visual syntax diagram>>-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

character-expression
Specifies a character string expression. It cannot be a CHAR or VARCHAR bit data.
length
An integer constant that specifies the length attribute of the result and must be an integer constant between 1 and 16370 if the first argument is not nullable or between 1 and 16369 if the first argument is nullable.

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.

integer
An integer constant that specifies the CCSID of the result. It must be a DBCS, UTF-16, or UCS-2 CCSID. The CCSID cannot be 65535. If the CCSID represents 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.

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

graphic-expression
An expression that returns a value that is a graphic string.
length
An integer constant that specifies the length attribute of the result and must be an integer constant between 1 and 16370 if the first argument is not nullable or between 1 and 16369 if the first argument is nullable.

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.

integer
An integer constant that specifies the CCSID of the result. It must be a DBCS, UTF-16, or UCS-2 CCSID. The CCSID cannot be 65535.

If integer is not specified then the CCSID of the result is the CCSID of the first argument.

Integer to Vargraphic

integer-expression
An expression that returns a value that is an integer data type (either SMALLINT, INTEGER, or BIGINT).

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

decimal-expression
An expression that returns a value that is a packed or zoned decimal data type (either DECIMAL or NUMERIC). If a different precision and scale is desired, the DECIMAL scalar function can be used to make the change.
decimal-character
Specifies the single-byte character constant that is used to delimit the decimal digits in the result character string. The character must be a period or comma. If the second argument is not specified, the decimal point is the default decimal point. For more information, see Decimal point.

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

floating-point expression
An expression that returns a value that is a floating-point data type (DOUBLE or REAL).
decimal-character
Specifies the single-byte character constant that is used to delimit the decimal digits in the result character string. The character must be a period or comma. If the second argument is not specified, the decimal point is the default decimal point. For more information, see Decimal point.

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).

Note

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.

Example

WEEK

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-WEEK--(--expression--)--------------------------------------><
 

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.

expression
The argument must be an expression that returns a value of one of the following built-in data types: a date, a timestamp, a character string, or a graphic 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 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.

Example

WEEK_ISO

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-WEEK_ISO--(--expression--)----------------------------------><
 

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.

expression
The argument must be an expression that returns a value of one of the following built-in data types: a date, a timestamp, a character string, or a graphic 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 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.

Examples

XOR

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram                       .---------------.
                       V               |
>>-XOR--(--expression----,--expression-+--)--------------------><
 

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.

expression
The arguments must be expressions that return a value of any built-in numeric or string data type, but cannot be LOBs. The arguments cannot be mixed data character strings, UTF-8 character strings, or graphic strings. 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.

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.

Example

YEAR

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-YEAR--(--expression--)--------------------------------------><
 

The YEAR function returns the year part of a value.

expression
The argument must be an expression that returns a value of one of the following built-in data types: a date, a timestamp, a character string, a graphic string, or a numeric data type.

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:

Examples

ZONED

Click to skip syntax diagram

Numeric to Zoned Decimal

Read syntax diagramSkip visual syntax diagram>>-ZONED-------------------------------------------------------->
 
>--(--numeric-expression--+--------------------------------------------+--)-><
                          '-,--precision-integer--+------------------+-'
                                                  '-,--scale-integer-'
 

String to Zoned Decimal

Read syntax diagramSkip visual syntax diagram>>-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

numeric-expression
An expression that returns a value of any built-in numeric data type.
precision
An integer constant with a value greater than or equal to 1 and less than or equal to 63.

The default for precision depends on the data type of the numeric-expression:

scale
An integer constant that is greater than or equal to 0 and less than or equal to precision. If not specified, the default is 0.

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

string-expression
An expression that returns a value that is a character-string or graphic-string representation of a number.

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.

precision
An integer constant that is greater than or equal to 1 and less than or equal to 63. If not specified, the default is 15.
scale
An integer constant that is greater than or equal to 0 and less than or equal to precision. If not specified, the default is 0.
decimal-character
Specifies the single-byte character constant that was used to delimit the decimal digits in string-expression from the whole part of the number. The character must be a period or comma. If the second argument is not specified, the decimal point is the default decimal separator character. For more information, see Decimal point.

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.

Note

Syntax alternatives: When the precision is specified, the CAST specification should be used for maximal portability. For more information, see CAST specification.

Examples


41.
This function cannot be used as a source function when creating a user-defined function. Because it accepts any compatible data types as arguments, it is not necessary to create additional signatures to support distinct types.
42.
If the argument identifies a DDS created logical file that is based on more than one physical file member, DBPARTITIONNUM will not return 0, but instead will return the underlying physical file member number.
43.
If the CCSID of comment string is 5026 or 930, the CCSID of the results will be 939.
44.
This hexadecimal representation for DATE, TIMESTAMP, and NUMERIC data types is different from other database products because the internal form for these data types is different.
45.
The LEFT function accepts mixed data strings. However, because LEFT operates on a strict byte-count basis, the result will not necessarily be a properly formed mixed data string.
46.
The LTRIM function returns the same results as: STRIP(expression,LEADING)
47.
This includes the case where the search-string is longer than the source-string.
48.
The result of the POWER function is exactly the same as the result of exponentiation: expression-1 ** expression-2.
49.
If the value of string-expression is mixed data that is not a properly formed mixed data string, the result will not be a properly formed mixed data string.
50.
The RIGHT function accepts mixed data strings. However, because RIGHT operates on a strict byte-count basis, the result will not necessarily be a properly formed mixed data string.
51.
The RTRIM function returns the same results as: STRIP(expression,TRAILING)
52.
The SUBSTR function accepts mixed data strings. However, because SUBSTR operates on a strict byte-count basis, the result will not necessarily be a properly formed mixed data string.



[ Top of Page | Previous Page | Next Page | Contents | Index ]