An expression specifies a value.
.-operator-------------------------. V | >>---+-----+--+-function------------+-+------------------------>< +- + -+ +-(expression)--------+ '- - -' +-constant------------+ +-column-name---------+ +-variable------------+ +-special-register----+ +-(scalar-fullselect)-+ +-labeled-duration----+ +-case-expression-----+ +-cast-specification--+ +-OLAP-specification--+ '-sequence-reference--'
operator:
>>-+-CONCAT-+-------------------------------------------------->< +- || ----+ +- / ----+ +- * ----+ +- ** ---+ +- + ----+ '- - ----'
labeled-duration:
>>-+-function-----+--+-YEAR---------+-------------------------->< +-(expression)-+ +-YEARS--------+ +-constant-----+ +-MONTH--------+ +-column-name--+ +-MONTHS-------+ '-variable-----' +-DAY----------+ +-DAYS---------+ +-HOUR---------+ +-HOURS--------+ +-MINUTE-------+ +-MINUTES------+ +-SECOND-------+ +-SECONDS------+ +-MICROSECOND--+ '-MICROSECONDS-'
If no operators are used, the result of the expression is the specified value.
SALARY :SALARY 'SALARY' MAX(SALARY)
If arithmetic operators are used, the result of the expression is a number derived from the application of the operators to the values of the operands.
If any operand can be null, the result can be null. If any operand has the null value, the result of the expression is the null value.
If one operand of an arithmetic operator is numeric, the other operand can be a string. The string is first converted to the data type of the numeric operand and must contain a valid string representation of a number.
The prefix operator + (unary plus) does not change its operand. The prefix operator - (unary minus) reverses the sign of a nonzero operand. If the data type of A is small integer, the data type of - A is large integer. The first character of the token following a prefix operator must not be a plus or minus sign.
The infix operators, +, -, *, /, and **, specify addition, subtraction, multiplication, division, and exponentiation, respectively. The value of the second operand of division must not be zero.
In COBOL, blanks must precede and follow a minus sign to avoid any ambiguity with COBOL host variable names (which allow use of a dash).
The result of an exponentiation (**) operator is a double-precision floating-point number. The result of the other operators depends on the type of the operand.
Operands with a NUMERIC data type are converted to DECIMAL operands prior to performing the arithmetic operation.
If both operands of an arithmetic operator are integers with zero scale, the operation is performed in binary, and the result is a large integer unless either (or both) operand is a big integer, in which case the result is a big integer. Any remainder of division is lost. The result of an integer arithmetic operation (including unary minus) must be within the range of large integers. If either integer operand has nonzero scale, it is converted to a decimal operand with the same precision and scale.
If one operand is an integer with zero scale and the other is decimal, the operation is performed in decimal using a temporary copy of the integer that has been converted to a decimal number with precision and scale 0 as defined in the following table:
Operand | Precision of Decimal Copy |
---|---|
Column or variable: big integer | 19 |
Column or variable: large integer | 11 |
Column or variable: small integer | 5 |
Constant (including leading zeros) | Same as the number of digits in the constant |
If one operand is an integer with nonzero scale, it is first converted to a decimal operand with the same precision and scale.
If both operands are decimal, the operation is performed in decimal. The result of any decimal arithmetic operation is a decimal number with a precision and scale that are dependent on the operation and the precision and scale of the operands. If the operation is addition or subtraction and the operands do not have the same scale, the operation is performed with a temporary copy of one of the operands. The copy of the shorter operand is extended with trailing zeros so that its fractional part has the same number of digits as the longer operand.
Unless specified otherwise, all functions and operations that accept decimal numbers allow a precision of up to 63 digits. The result of a decimal operation must not have a precision greater than 63.
The following formulas define the precision and scale of the result of decimal operations in SQL. The symbols p and s denote the precision and scale of the first operand and the symbols p' and s' denote the precision and scale of the second operand.
The symbol mp denotes the maximum precision. The value of mp is 63 if:
Otherwise, the value of mp is 31.
The symbol ms denotes the maximum scale. The default value of ms is 31. ms can be explicitly set to any number from 0 to the maximum precision.
The symbol mds denotes the minimum divide scale. The default value of mds is 0. mds can be explicitly set to any number from 0 to the maximum scale.
The maximum precision, maximum scale, and minimum divide scale can be explicitly specified on the DECRESULT parameter of the CRTSQLxxx command, RUNSQLSTM command, or SET OPTION statement. They can also be specified in ODBC data sources, JDBC properties, OLE DB properties, .NET properties.
The scale of the result of addition and subtraction is max (s,s'). The precision is min(mp,max(p-s,p'-s') +max(s,s')+1).
The precision of the result of multiplication is min (mp,p+p') and the scale is min(ms,s+s').
The precision of the result of division is (p-s+s') + max(mds, min(ms, mp - (p-s+s') ) ). The scale is max(mds, min(ms, mp - (p-s+s') ) ). The scale must not be negative.
If either operand of an arithmetic operator is floating point, the operation is performed in floating point. The operands are first converted to double-precision floating-point numbers, if necessary. Thus, if any element of an expression is a floating-point number, the result of the expression is a double-precision floating-point number.
An operation involving a floating-point number and an integer is performed with a temporary copy of the integer converted to double-precision floating point. An operation involving a floating-point number and a decimal number is performed with a temporary copy of the decimal number that has been converted to double-precision floating point. The result of a floating-point operation must be within the range of floating-point numbers.
The order in which floating-point operands (or arguments to functions) are processed can slightly affect results because floating-point operands are approximate representations of real numbers. Since the order in which operands are processed may be implicitly modified by the optimizer (for example, the optimizer may decide what degree of parallelism to use and what access plan to use), an application should not depend on the results being precisely the same each time an SQL statement is executed that uses floating-point operands.
A distinct type cannot be used with arithmetic operators even if its source data type is numeric. To perform an arithmetic operation, create a function with the arithmetic operator as its source. For example, if there were distinct types INCOME and EXPENSES, both of which had DECIMAL(8,2) data types, then the following user-defined function, REVENUE, could be used to subtract one from the other.
CREATE FUNCTION REVENUE ( INCOME, EXPENSES ) RETURNS DECIMAL(8,2) SOURCE "-" ( DECIMAL, DECIMAL)
Alternately, the - (minus) operator could be overloaded using a user-defined function to subtract the new data types.
CREATE FUNCTION "-" ( INCOME, EXPENSES ) RETURNS DECIMAL(8,2) SOURCE "-" ( DECIMAL, DECIMAL)
If the concatenation operator (CONCAT or ||) is used, the result of the expression is a string.
The operands of concatenation must be compatible strings or numeric data types. The operands must not be distinct types. If a numeric operand is specified, it is CAST to the equivalent character string prior to concatenation. Note that a binary string cannot be concatenated with a character string, including character strings defined as FOR BIT DATA.
The data type of the result is determined by the data types of the operands. The data type of the result is summarized in the following table:
If one operand column is ... | And the other operand is ... | The data type of the result column is ... |
---|---|---|
Unicode data | Unicode data or DBCS or mixed or SBCS data | Unicode data |
DBCS data | DBCS data | DBCS data |
bit data | mixed or SBCS or bit data | bit data |
mixed data | mixed or SBCS data | mixed data |
SBCS data | SBCS data | SBCS data |
If the sum of the lengths of the operands exceeds the maximum length attribute of the resulting data type:
If either operand can be null, the result can be null, and if either is null, the result is the null value. Otherwise, the result consists of the first operand string followed by the second.
With mixed data this result will not have redundant shift codes "at the seam". Thus, if the first operand is a string ending with a "shift-in" character (X'0F'), while the second operand is a character string beginning with a "shift-out" character (X'0E'), these two bytes are eliminated from the result.
The actual length of the result is the sum of the lengths of the operands unless redundant shifts are eliminated; in which case, the actual length is two less than the sum of the lengths of the operands.
The CCSID of the result is determined by the CCSID of the operands as explained under Conversion rules for operations that combine strings. Note that as a result of these rules:
Concatenate the column FIRSTNME with a blank and the column LASTNAME.
FIRSTNME CONCAT ' ' CONCAT LASTNAME
A scalar fullselect as supported in an expression is a fullselect, enclosed in parentheses, that returns a single row consisting of a single column value. If the fullselect does not return a row, the result of the expression is the null value. If the select list element is an expression that is simply a column name, the result column name is based on the name of the column. See fullselect for more information.
A scalar fullselect is not allowed if the query specifies:
A scalar subselect as supported in an expression is a subselect, enclosed in parentheses, that returns a single row consisting of a single column value. If the subselect does not return a row, the result of the expression is the null value. If the select list element is an expression that is simply a column name, the result column name is based on the name of the column. See fullselect for more information.
Datetime values can be incremented, decremented, and subtracted. These operations may involve decimal numbers called durations. A duration is a positive or negative number representing an interval of time. There are four types of durations:
A labeled duration can only be used as an operand of an arithmetic operator in which the other operand is a value of data type DATE, TIME, or TIMESTAMP. Thus, the expression HIREDATE + 2 MONTHS + 14 DAYS is valid whereas the expression HIREDATE + (2 MONTHS + 14 DAYS) is not. In both of these expressions, the labeled durations are 2 MONTHS and 14 DAYS.