This chapter describes SQL operators, general expressions, and conditional expressions.
Each expression is explained using a syntax diagram.
Various expressions are included in SQL statements. An expression consists of operators, operands, functions, etc. If values are assigned to all operands in an expression, the expression returns the result of the operation.
Two types of expressions exist:
General expression
Includes all operators except for logical and comparison operators.
Returns an arithmetic value, string, list, etc.
Conditional expression
Includes logical and comparison operators.
Returns TRUE, FALSE, or UNKNOWN.
The following figure shows an example of a syntax diagram for an expression:
The following table illustrates how to analyze a diagram:
Diagram | Description |
---|---|
The title that represents the entire syntax. It is located on the top left. In [Figure 3.1], the title is "example". | |
Characters in a square represent a syntax element and should be replaced by another appropriate string. In [Figure 3.1], "option", "value", "choice1", and "choice2" are the examples. | |
Characters in a circle are a keyword or a symbol used in expressions. They must be included in a statement as is. In [Figure 3.1], the parentheses ((, )) and comma (,) are examples. | |
The order of organizing a statement. A curved left arrow means that a pointed component may be included zero or more times. A split arrow means that one of the pointed components may be selected. In [Figure 3.1], "option" must be included in the statement, and the comma "," may not be included or be included one or more times. The parentheses "(" and ")" must be included. "value" must be included one or more times. "value" may be included one more time if the comma is included. One of either "choice1" or "choice2" is included in the statement. |
The following are possible examples of the above diagram in [Figure 3.1].
option1 (value1) choice1 option1 (value1, value2) choice1 option1 (value1, value2) choice2 option1 (value1) choice2
This section describes operators used in SQL statements. Expressions that include each operator will be described in “3.3. Expressions” and “3.4. Conditional Expressions”.
The operators used in SQL statements are arithmetic operators, string operators, and set operators.
Arithmetic operators
Arithmetic operators are used to perform four arithmetic operations. Arithmetic operators have four binary operators for addition, subtraction, multiplication, and division and two unary operators for expressing positive and negative numbers.
String operators
The only string operator is the concatenation operator (||) for concatenating two strings
The following example shows the concatenation of two strings, 'ABC' and 'DEF':
'ABC' || 'DEF' = 'ABCDEF'
Set operator
Set operators are related to the results of two queries and are not performed directly on a table. These operators always receive the result of a SELECT statement as an operand and return one result table that consists of zero or more rows.
The following table describes the set operators provided by Tibero.
When using arithmetic and string operators, verify that the result is within the expected range. For example, if an operation that results in the value 1234.0 is stored in a column declared as the NUMBER(3,0) type, or the string 'ABCDEF' is stored in a column declared as the VARCHAR(5) type, an error will occur.
Complex operations for arithmetic and string data can be performed using built-in functions. The built-in functions provided in Tibero are described in “Chapter 4. Functions”.
Logical and comparison operators are used in conditional expressions.
Logical operators always receive a conditional expression as an operand. The logical operators provided in Tibero are the NOT, the AND, and the OR operators. The NOT operator is a unary operator, and the AND and OR operators are binary operators.
Logical operators provided by Tibero differ from general logic operators. These logical operators can return UNKNOWN as well as TRUE and FALSE as a result.
The followings are the truth tables for the NOT, AND, and OR operators when the operands have a value of TRUE, FALSE, or UNKNOWN. The commutative rule is valid for the AND and OR operations.
Comparison operators receive arithmetic values, strings, lists, etc as operands. Comparison operations are divided into two types: operators for comparing two simple values and operators for comparing a simple value with a list. The next table displays arithmetic comparison operators used between simple values, provided in Tibero.
Operator | Description |
---|---|
= | Binary operator that determines whether or not two values are equal to each other |
!=, ^=, ~=, <> | Binary operator that determines whether or not two values are different from each other |
>, < | Binary operator that determines whether one value is greater or lesser than another value |
>=, <= | Binary operator that determines whether one value is greater than or equal to another value, or lesser than or equal to another value |
It is possible to compare a single value with a list using arithmetic operations combined with the operator ANY, SOME, or ALL (> ALL, = SOME, etc.), IN, etc. The meaning and syntax of conditional expressions that include comparison operators are described in “3.4. Conditional Expressions”.
Operator precedence
Several operators can be used in one expression. For this, there is a fixed order for deciding which operator will be evaluated first. This order is called operator precedence.
The following table shows the precedence of operators provided by Tibero. An operator with a lower precedence rating is evaluated earlier than an operator with a higher precedence rating.
Precedence | Operator | Description |
---|---|---|
1 | +, - | Unary operators expressing the sign of a number |
2 | *, / | Arithmetic operators |
3 | +, - | Arithmetic operators |
4 | =, !=, ^=, ~=, <>, <, >, <=, >= | Comparison operators |
5 | LIKE, BETWEEN, IN, EXISTS, IS NULL | Comparison operators |
6 | NOT | Logical operator (unary operator) |
7 | AND | Logical operator |
8 | OR | Logical operator |
Arithmetic operators (+, -, *, and /) and logical operators (AND and OR) can be used multiple times in a single expression. If multiple operators have the same precedence, they are evaluated in left-to-right order. Comparison operators and unary operators cannot be used more than once in one expression. Operators in parentheses are evaluated before those outside of parentheses. If nested parentheses are used, the most deeply nested operator is calculated first. To specify the operation order clearly, using parentheses is recommended.
An expression consists of operators, operands, functions, etc. Expressions are used in several SQL statements.
The following SQL statements include expressions:
SELECT clause (list) in a SELECT statement
WHERE clause (conditional expression) in SELECT, UPDATE, and DELETE statements
HAVING clause (conditional expression) in a SELECT statement
ORDER BY clause (list) in a SELECT statement
VALUES clause (list) in a INSERT statement
SET clause (assignment expression) in a UPDATE statement
If an expression is a list type, the expression does not need to be enclosed in parentheses when it is included in SELECT or ORDER BY clauses, but the expression must be enclosed in parentheses when it is included in the VALUES clause of an INSERT statement. Assignment expressions included in the SET clause of an UPDATE statement have the same syntax as those of comparison expressions that use an equal sign (=), but the left side of an equal sign must be a column name in an assignment expression.
Expressions that can be used in Tibero are simple expressions, compound expressions, functions, subquery expressions, lists, etc.
A detailed description of an expression follows:
Syntax
Component
Component | Description |
---|---|
simple_expr | A simple expression. For more information, refer to “3.3.2. Simple Expressions”. |
compound_expr | A compound expression. For more information, refer to “3.3.3. Compound Expressions”. |
case_expr | A CASE expression. For more information, refer to “3.3.4. CASE Expressions”. |
function | A function. For more information, refer to “3.3.5. Functions”. |
subquery | A subquery expression. It is always enclosed in parentheses (( )). For more information, refer to “3.3.6. Subquery Expressions”. |
variable_expr | A variable. For more information, refer to “3.3.7. Variables”. |
If the data type of an operand in an expression is not the type that an operator requests, Tibero attempts to convert the data type of the operand.
The following example illustrates the conversion of data types:
'30' + 50 = 80 'YEAR' || 2004 = 'YEAR2004'
In the first example, the operands of the addition operator (+) should be NUMBER type values. However, because one of the operands is a string type value ('30'), the operand is converted to the NUMBER type value. In the second example, the operands of the concatenation operator (||) should be string type values. However, because one of the operands is a NUMBER type value (2004), the operand is converted to a string type value.
Not all data types can be converted to every other data type. If data type conversion is not available when evaluating an expression, an error will occur. Even if a certain data type can be converted, an error may occur depending on the actual value. For example, the string '1234' can be converted to the NUMBER type value, but the string 'ABC' cannot be converted to the NUMBER type value. The BLOB type cannot be converted to any other data type except for the RAW and LONG RAW types.
The following table shows available combinations for data type conversion. The types written on the left hand size are the pre-conversion types, and the types written on the top are the post-conversion types.
Data Type | NUM BER | CHAR | VAR CHAR | RAW | DATE | TIME | TIME STAMP | INTE RVAL | LONG | LONG RAW | BLOB | CLOB | ROW ID | BINARY_ FLO AT | BINARY_ DOU BLE |
---|---|---|---|---|---|---|---|---|---|---|---|---|---|---|---|
NUMBER | - | O | O | - | - | - | - | - | O | - | - | O | - | O | O |
CHAR | O | - | O | O | O | O | O | O | O | O | O | O | O | O | O |
VARCHAR | O | O | - | O | O | O | O | O | O | O | O | O | O | O | O |
RAW | - | O | O | - | - | - | - | - | O | O | O | O | - | - | - |
DATE | - | O | O | - | - | - | O | - | O | - | - | - | - | - | - |
TIME | - | O | O | - | - | - | - | - | O | - | - | - | - | - | - |
TIMESTAMP | - | O | O | - | O | - | - | - | O | - | - | - | - | - | - |
INTERVAL | - | O | O | - | - | - | - | - | O | - | - | - | - | - | - |
LONG | - | O | O | O | - | - | - | - | - | O | - | O | - | - | - |
LONG RAW | - | O | O | O | - | - | - | - | O | - | O | - | - | - | - |
BLOB | - | - | - | O | - | - | - | - | - | O | - | - | - | - | - |
CLOB | - | O | O | - | - | - | - | - | O | - | - | - | - | - | - |
ROWID | - | O | O | - | - | - | - | - | O | - | - | - | - | - | - |
BINARY_ FLOAT | O | O | O | - | - | - | - | - | - | - | - | - | - | - | O |
BINARY_ DOUBLE | O | O | O | - | - | - | - | - | - | - | - | - | - | O | - |
A simple expression consists of one operand and does not include an operator or a function. As shown in the following diagram, a simple expression can be a table column, ROWID type, string, numeric value, NULL, etc.
A detailed description of a simple expression follows:
Syntax
Component
Component | Description |
---|---|
schema | Schema name. |
table | Table name. |
view | View name. |
column | Column name. |
text | String. |
number | Numeric data. |
sequence | Sequence name. |
Simple expressions are not case-sensitive for a schema, table, view, column name, or NULL, but they are case-sensitive for a string enclosed in single quotation marks (' ').
A compound expression includes one or more expressions.
A detailed description of a compound expression follows:
Syntax
Component
Component | Description |
---|---|
expr | A general expression. For more information, refer to “3.3. Expressions”. |
+, - | Unary operators(+, -) express the sign of a number. |
PRIOR | Operator to express a hierarchy between rows. For more information, refer to “5.5. Hierarchical Queries”. |
*, /, +, -, || | Arithmetic operators (*, /, +, -) and a string concatenation operator (||). |
A CASE expression expresses "IF... THEN ... ELSE" logic in a SQL statement. When using simple_when_clause, up to 65535 arguments can be used in a CASE expression including expr, comparision_expr, return_expr, and else_clause. When using searched_when_clause, up to 65535 arguments can be used in a else_clause.
A detailed description of a CASE expression follows:
Syntax
Component
Component | Description |
---|---|
simple_when_clause | comparison_expr and expr are compared in the specified order. If they are the same, return_expr from the THEN clause is returned. If every comparison with comparison_expr fails, else_expr from the else_clause is returned. It there is no else_clause, NULL is returned. |
searched_when_clause | The condition is evaluated in the specified order for WHEN... THEN pairs. If the result is TRUE, return_expr from the THEN clause is returned. It there is no TRUE condition, else_expr specified in else_clause is returned. If there is no else_clause, NULL is returned. |
comparison_expr | Comparison expression. expr and all comparison_expr should be the same type. For more information, refer to “3.2.2. Operators Used in Conditional Expressions”. |
condition | Conditional expression. For more information, refer to “3.4. Conditional Expressions”. |
return_expr | If the comparison result of simple_when_clause meets the conditional expression of searched_when_clause, return_expr is returned. All return_exprs and else_expr should be the same type. |
else_clause | If the comparison result of simple_when_clause does not meet the conditional expression of searched_when_clause, else_expr from the else_clause is returned. |
Example
The following example illustrates the use of the CASE expression:
SELECT CASE WHEN age > 19 THEN 'adult' ELSE 'minor' END FROM people;
A function expression consists of a function name and zero or more parameters. The parameters are separated by a comma (,) and enclosed in parentheses. If there are no parameters, the parentheses can be omitted. Tibero provides various single row functions and aggregate functions.
The following example illustrates the use of functions:
ROUND(123.456, 2) LENGTH(ADDR) SYSDATE AVG(EMP.SALARY)
A subquery expression is a SELECT statement included in an expression. The SELECT statement must return one row that has one column whereas generally a SELECT statement returns zero or more rows that have one or more columns. If the condition is not satisfied, an error will occur when the expression is calculated.
The following example illustrates the use of a subquery expression:
(SELECT MAX(SALARY) FROM EMP WHERE DEPTNO = 5) * 1.05
A subquery expression must be enclosed in parentheses. The SELECT clause in the SELECT statement has only one column and returns the maximum value from the result of the query. Therefore, there will not be an error during the calculation. Subquery expressions can be located in most locations where general expressions can be located. However, subquery expressions cannot be located in the following locations:
In a GROUP BY clause of a SELECT statement
As the default value of a column
In a conditional expression of a CHECK constraint
Variable are either a host variable, an indicator, or an indicator variable. Variables are used for tbESQL statements as well as for data input and output in a program.
A detailed description of a variable follows:
Syntax
Component
Component | Description |
---|---|
host_variable | A host variable. It is used with a colon (:). This variable is used to save a processing result in database. It can also be used as a variable in an application program. |
INDICATOR | An indicator. |
indicator_variable | An indicator variable. It is related to a host variable and is used to check whether the host variable is NULL or an error. It is used with a colon (:) like a host variable. |
For more information about variables, refer to Tibero tbESQL/C Guide".
A list contains one or more expressions, separating them with commas (,). A list can be enclosed in parentheses depending on its location in an SQL statement. Lists included in the WHERE clause of SELECT, UPDATE, and DELETE statements and the VALUES clause of a WHERE statement can be enclosed in parentheses.
A detailed description of a list follows:
Syntax
Component
Component | Description |
---|---|
expr | A general expression. For more information, refer to “3.3. Expressions”. |
Example
The following illustrates the use of lists:
EMPNO, ENAME, ADDR (35, 'John', 'Houston') (20, 30, 50)
A conditional expression is included in the WHERE clause of SELECT, UPDATE, and DELETE statements and the HAVING clause of a SELECT statement. Simple, group, compound, and comparison conditions can be used in Tibero. The conditional expressions are BETWEEN, EXISTS, IN, IS NULL, and LIKE.
A detailed description of a conditional expression follows:
Syntax
Component
Component | Description |
---|---|
simple_comparison_condition | Simple condition. For more information, refer to “3.4.1. Simple Conditions”. |
group_comparison_condition | Group condition. For more information, refer to “3.4.2. Group Conditions”. |
compound_condition | Compound condition. For more information, refer to “3.4.3. Compound Conditions”. |
between_condition | BETWEEN condition. For more information, refer to “3.4.4. BETWEEN Condition”. |
exists_condition | EXISTS condition. For more information, refer to “3.4.5. EXISTS Condition”. |
in_condition | IN condition. For more information, refer to “3.4.6. IN Condition”. |
is_null_condition | IS NULL condition. For more information, refer to “3.4.7. IS NULL Condition”. |
like_condition | LIKE condition. For more information, refer to “3.4.8. LIKE Condition”. |
regexp_like_condition | REGEXP_LIKE condition. For more information, refer to “3.4.9. REGEXP_LIKE Condition”. |
A simple condition compares two pieces of data. The operand can be a general expression as in the following diagram. If an operand in a simple condition is NULL, the condition will return UNKNOWN.
A detailed description of a simple condition follows:
Syntax
Component
Component | Description |
---|---|
expr | General expression. For more information, refer to “3.3. Expressions”. |
subquery | Subquery. For more information, refer to “3.3.6. Subquery Expressions”. |
=, !=, ^=, ~=, <>, <, >, >=, <= | Comparison operators. For more information, refer to “3.2. Operators”. |
A group condition compares one data value with values in a list.
A detailed description of a group condition follows:
Syntax
Component
Component | Description |
---|---|
expr | General expression. For more information, refer to “3.3. Expressions”. |
expr_list | List. For more information, refer to “3.3.8. List”. |
subquery | Subquery. For more information, refer to “3.3.6. Subquery Expressions”. |
ANY | If the left-side value satisfies a comparison operator for at least one right-side value in a list, the condition ANY returns TRUE. |
SOME | Like ANY, if the left-side value satisfies a comparison operator for at least one right-side value in a list, the condition SOME returns TRUE. |
ALL | If the left-side value satisfies a comparison operator for all right-side values in a list, the condition ALL returns TRUE. |
Example
The following example illustrates the use of group conditions:
EMPNO = ANY (35, 54, 27, 69) SALARY * 1.05 >= ALL (SELECT SALARY FROM EMP WHERE DEPTNO = 5)
On the first line, if the value of EMPNO is the same as least one value in the list, the expression will return true and will otherwise return false. On the second line, if the value of SALARY multiplied by 1.05 is greater than or equal to every value in the result of the subquery, the expression will return true and will otherwise return false.
If NULL is included in a right-side list, any group condition that includes the ANY operator will always return TRUE or UNKNOWN, and any group condition that includes the ALL operator will always return FALSE or UNKNOWN.
For example, the following two lines return the same result:
DEPTNO != ALL (4, 5, NULL) (DEPTNO != 4) AND (DEPTNO != 5) AND (DEPTNO != NULL)
On the second line, if the value of column DEPTNO is 4 or 5, the result of the last simple condition that compares the value with NULL will be UNKNOWN, and since the entire condition is connected by AND operators, the result will also be UNKNOWN.
A compound condition contains one or more conditions. Compound conditions can be enclosed in parentheses, have the NOT operator attached, be connected with logical operators (AND and OR), etc.
A detailed description of a compound condition follows:
Syntax
Component
Component | Description |
---|---|
condition | A condition. A detailed description was described in the beginning of “3.4. Conditional Expressions”. |
NOT, AND, OR | Logical operators; NOT, AND, and OR. For more information, refer to “3.2.2. Operators Used in Conditional Expressions”. |
The BETWEEN operator checks whether the left-side value exists in the range between two right-side values.
A detailed description of a BETWEEN condition follows:
Syntax
Component
Component | Description |
---|---|
expr1, expr2, expr3 | Expressions that return numeric values. If any expression among expr1, expr2, and expr3 contains NULL, the result of a BETWEEN condition will always be FALSE or UNKNOWN. |
BETWEEN ... AND | The BETWEEN operator is always used with AND and checks whether the left-side value exists in the range between two right-side values. |
NOT | If NOT is located before BETWEEN, the NOT operator is applied to the result of the BETWEEN operation. |
Example
A BETWEEN condition is equivalent to two arithmetic conditions connected with the AND operator.
For example, the following two lines return the same result:
SALARY BETWEEN 30000 AND 50000 (SALARY >= 30000) AND (SALARY <= 50000)
The EXISTS operator returns TRUE if the right-side subquery returns at least one row and otherwise returns FALSE.
A detailed description of an EXISTS condition follows:
Syntax
Component
Component | Description |
---|---|
EXISTS | Returns TRUE if the right-side subquery returns at least one row and otherwise returns FALSE. |
subquery | Subquery. For more information, refer to “3.3.6. Subquery Expressions”. |
The IN operator checks whether the left-side data is included in the right-side list. expr, expr_list, and subquery are defined in “3.3. Expressions”.
A detailed description of an IN condition follows:
Syntax
Component
Component | Description |
---|---|
expr | General expression. For more information, refer to “3.3. Expressions”. |
NOT | Logical operator; NOT. For more information, refer to “3.2.2. Operators Used in Conditional Expressions”. If NOT is located before IN, the NOT operator is applied to the result of the IN operation. |
IN | Checks whether the left-side value is present in the right-side list. |
expr_list | expr list. For more information, refer to “3.3.8. List”. expr_list itself should not be enclosed in parentheses. |
subquery | Subquery. For more information, refer to “3.3.6. Subquery Expressions”. |
Example
An IN condition can be changed to a group condition using the operators '= ANY' or '= SOME'.
For example, the following two lines return the same result:
EMPNO IN (35, 54, 27, 69) EMPNO = ANY (35, 54, 27, 69)
As an IN condition can be changed to a group condition using '= ANY', if the right-side list includes NULL, the IN condition always returns TRUE or UNKNOWN. Likewise, the NOT IN condition always returns FALSE or UNKNOWN.
The IS NULL operator returns TRUE if the result of the left-side expression is NULL and otherwise returns FALSE.
A detailed description of an IS NULL condition follows:
Syntax
Component
Component | Description |
---|---|
expr | General expression. For more information, refer to “3.3. Expressions”. |
IS NULL | Returns TRUE if the result of the left-side expression is NULL, and otherwise returns FALSE. |
IS NOT NULL | Returns the result of the NOT operation for the result of IS NULL operation. |
The LIKE operator compares patterns of string data. The LIKE operator is case-sensitive.
For example, 'ABCDE' and 'abcde' are different strings. The string 'ABCDE' matches the pattern 'A%', but 'abcde' does not.
A detailed description of a LIKE condition follows:
Syntax
Component
Component | Description |
---|---|
str_expr1, str_expr2 | Expressions that return a string with length greater than or equal to zero. |
esc_char | A single character that represents an escape character. |
LIKE | An operator that compares patterns of string data. Returns TRUE if the left-side string matches the right-side pattern. Returns UNKNOWN if either str_expr1 or str_expr2 is NULL. |
ESCAPE | An escape character is used to compare a character used as a wildcard character. |
While the equality (=) operator is used to determine if two strings are exactly the same, the LIKE operator can be used to determine if a string contains an arbitrary character and string and wildcard characters corresponding to the string.
Wildcard characters have the following characteristics:
A string pattern can have one or more wildcard characters.
To compare strings that contain the wildcard characters themselves, use an escape character.
For example, to find out all strings that start with 'A_', use the string pattern 'A\_%'. In this pattern, the backslash (\) is used as an escape character.
To match strings that contain the escape character itself, use the escape character twice. For example, to find all strings that start with 'C:\', use the string pattern 'C:\\%'.
An escape character is not fixed and can be chosen whenever a LIKE operator is used. The escape character must be a single character.
The REGEXP_LIKE operator is similar to LIKE. The REGEXP_LIKE operator compares patterns of strings using regular expressions.
A detailed description of a REGEXP_LIKE condition follows:
Syntax
Component
Component | Description |
---|---|
source_str | An expression that returns a string. The CHAR, VARCHAR2, NCHAR, or NVARCHAR2 type can be used. |
pattern | An expression that returns strings written in a regular expression. The CHAR, VARCHAR2, NCHAR, or NVARCHAR2 type can be used. If the type of pattern is different from source_str, the type is converted to the type in source_str. |
match_param | An expression that returns a string. It specifies how to check patterns. One or more of the following values can be specified:
If contradictory values like 'ic' are specified together, the last value is used. For example, if 'ic' is specified, case-sensitive matching will occur. |
Example
The following illustrates the use of the REGEXP_LIKE condition:
SQL> SELECT 1 FROM DUAL WHERE REGEXP_LIKE('12345', '3.?4'); 1 ---------- 1 1 row selected.