Logical Predicates
A logical predicate tests an operand against one or more other operands to evaluate to a logical (Boolean TRUE, FALSE, or UNKNOWN) result.
The tested operand can be one of the following:
Where Logical Predicates Are Used
Logical predicates are typically used in a WHERE, ON, or HAVING clause to qualify or disqualify rows as a table expression is evaluated in a SELECT statement.
Logical predicates can be used in a WHEN clause search condition in a searched CASE expression.
The type of test performed is a function of the predicate.
Conditional Expressions as a Collection of Logical Primitives
You can think of a conditional expression as a collection of logical predicate primitives where the order of evaluation is controlled by the use of the logical operators AND, OR, and NOT and by the placement of parentheses.
Superficially similar conditional expressions can produce radically different results depending on how you group their component primitives, so use caution in planning the logic of any conditional expressions.
SQL supports the logical predicate primitives listed in the following table. Note that Match and Unique conditions are not supported.
Logical Predicate Primitive Condition |
SQL Logical Predicate |
Function |
Comparison |
For a complete list of SQL comparison operators, see “Supported Comparison Operators” on page 495. |
Tests for equality, inequality, or magnitude difference between two data values. |
Range |
BETWEEN |
Tests whether a data value is included within (or excluded from) a specified range of column data values. |
Like |
LIKE |
Tests for a pattern match between a specified character string and a column data value. |
In |
IN |
Tests whether a data value is (or is not) a member of a specified set of column values. IN is equivalent to = ANY. NOT IN is equivalent to <> ALL. |
All |
ALL |
Tests whether a data value compares TRUE to all column values in a specified set. |
Any |
ANY |
Tests whether a data value compares TRUE to any column value in a specified set. |
Exists |
EXISTS |
Tests whether a specified table contains at least one row. |
Period predicates
|
For a complete list of period predicate operators, see Chapter 23: “Period Functions and Operators.”
|
Operates on: Evaluates to TRUE, FALSE, or UNKNOWN. |
OVERLAPS |
Tests whether two time periods, including derived periods, overlap |
|
IS UNTIL_CHANGED |
Tests whether the ending bound of a Period expression, including a derived period is (or is not) UNTIL_CHANGED. |
Restrictions on the Data Types Involved in Predicates
The restrictions in the following table apply to operations involving predicates and CLOB, BLOB, and UDT types.
Data Type |
Restrictions |
|||
BLOB |
Predicates do not support BLOB or CLOB data types. You can explicitly cast BLOBs to BYTE and VARBYTE types and CLOBs to CHARACTER and VARCHAR types, and use the results in a predicate. |
|||
CLOB |
||||
UDT
|
The LIKE and OVERLAPS logical predicates do not support UDTs. For EXISTS and NOT EXISTS: Multiple UDTs involved as predicate operands must be identical types because Teradata Database does not perform implicit type conversion on UDTs involved as predicate operands. A workaround for this restriction is to use CREATE CAST to define casts that cast between the UDTs and then explicitly invoke the CAST function within the operation involving predicates. For more information on CREATE CAST, see SQL Data Definition Language. For BETWEEN/ NOT BETWEEN and IN/NOT: A workaround for this restriction is to use CREATE CAST to define casts that cast between the UDTs and then explicitly invoke the CAST function within the operation involving predicates. Teradata Database generates ordering functionality for distinct UDTs where the source types are not LOBs. To create an ordering definition for structured UDTs or distinct UDTs where the source types are LOBs, or to replace system-generated ordering functionality, use CREATE ORDERING. For more information on CREATE CAST and CREATE ORDERING, see SQL Data Definition Language. |
Restrictions on the DEFAULT Function in a Predicate
The DEFAULT function returns the default value of a column. It has two forms: one that specifies a column name and one that omits the column name. Predicates support both forms of the DEFAULT function, but the following conditions must be true when the DEFAULT function omits the column name:
For example, the following statement uses DEFAULT to compare the values of the Dept_No column with the default value of the Dept_No column. Because the comparison operation involves a single column reference, Teradata Database can derive the column context of the DEFAULT function even though the column name is omitted.
SELECT * FROM Employee WHERE Dept_No < DEFAULT;
Note that if the DEFAULT function evaluates to null, the predicate is unknown and the WHERE condition is false.