9.2. Comparison Operators
The usual comparison operators are available, shown in Table 9.1.
Table 9.1. Comparison Operators
Operator | Description |
---|---|
< | less than |
> | greater than |
<= | less than or equal to |
>= | greater than or equal to |
= | equal |
<> or != | not equal |
Note
The !=
operator is converted to <>
in the parser stage. It is not possible to implement !=
and <>
operators that do different things.
Comparison operators are available for all relevant data types. All comparison operators are binary operators that return values of type boolean
; expressions like 1 < 2 < 3
are not valid (because there is no <
operator to compare a Boolean value with 3
).
In addition to the comparison operators, the special BETWEEN
construct is available:
a
BETWEENx
ANDy
is equivalent to
a
>=x
ANDa
<=y
Notice that BETWEEN
treats the endpoint values as included in the range. NOT BETWEEN
does the opposite comparison:
a
NOT BETWEENx
ANDy
is equivalent to
a
<x
ORa
>y
BETWEEN SYMMETRIC
is the same as BETWEEN
except there is no requirement that the argument to the left of AND
be less than or equal to the argument on the right. If it is not, those two arguments are automatically swapped, so that a nonempty range is always implied.
Ordinary comparison operators yield null (signifying “unknown”), not true or false, when either input is null. For example, 7 = NULL
yields null, as does 7 <> NULL
. When this behavior is not suitable, use the IS [ NOT ] DISTINCT FROM
constructs:
a
IS DISTINCT FROMb
a
IS NOT DISTINCT FROMb
For non-null inputs, IS DISTINCT FROM
is the same as the <>
operator. However, if both inputs are null it returns false, and if only one input is null it returns true. Similarly, IS NOT DISTINCT FROM
is identical to =
for non-null inputs, but it returns true when both inputs are null, and false when only one input is null. Thus, these constructs effectively act as though null were a normal data value, rather than “unknown”.
To check whether a value is or is not null, use the constructs:
expression
IS NULLexpression
IS NOT NULL
or the equivalent, but nonstandard, constructs:
expression
ISNULLexpression
NOTNULL
Do not write
because expression
= NULLNULL
is not “equal to” NULL
. (The null value represents an unknown value, and it is not known whether two unknown values are equal.)
Tip
Some applications might expect that
returns true if expression
= NULLexpression
evaluates to the null value. It is highly recommended that these applications be modified to comply with the SQL standard. However, if that cannot be done the transform_null_equals configuration variable is available. If it is enabled, PostgreSQL will convert x = NULL
clauses to x IS NULL
.
If the expression
is row-valued, then IS NULL
is true when the row expression itself is null or when all the row's fields are null, while IS NOT NULL
is true when the row expression itself is non-null and all the row's fields are non-null. Because of this behavior, IS NULL
and IS NOT NULL
do not always return inverse results for row-valued expressions; in particular, a row-valued expression that contains both null and non-null fields will return false for both tests. In some cases, it may be preferable to write row
IS DISTINCT FROM NULL
or row
IS NOT DISTINCT FROM NULL
, which will simply check whether the overall row value is null without any additional tests on the row fields.
Boolean values can also be tested using the constructs
expression
IS TRUEexpression
IS NOT TRUEexpression
IS FALSEexpression
IS NOT FALSEexpression
IS UNKNOWNexpression
IS NOT UNKNOWN
These will always return true or false, never a null value, even when the operand is null. A null input is treated as the logical value “unknown”. Notice that IS UNKNOWN
and IS NOT UNKNOWN
are effectively the same as IS NULL
and IS NOT NULL
, respectively, except that the input expression must be of Boolean type.