9.2. Comparison Functions and Operators
The usual comparison operators are available, as shown in Table 9.1 .
Table 9.1. Comparison Operators
| Operator | Description | 
|---|---|
| 
         datatype
        
        <
       
         datatype
        →
        boolean
        | Less than | 
| 
         datatype
        
        >
       
         datatype
        →
        boolean
        | Greater than | 
| 
         datatype
        
        <=
       
         datatype
        →
        boolean
        | Less than or equal to | 
| 
         datatype
        
        >=
       
         datatype
        →
        boolean
        | Greater than or equal to | 
| 
         datatype
        
        =
       
         datatype
        →
        boolean
        | Equal | 
| 
         datatype
        
        <>
       
         datatype
        →
        boolean
        | Not equal | 
| 
         datatype
        
        !=
       
         datatype
        →
        boolean
        | Not equal | 
Note
   
    <>
   
   is the standard SQL notation for
   
    "
    
     not
     equal
    
    "
   
   .
   
    !=
   
   is an alias, which is converted
     to
   
    <>
   
   at a very early stage of parsing.
     Hence, it is not possible to implement
   
    !=
   
   and
   
    <>
   
   operators that do different things.
  
These comparison operators are available for all built-in data types that have a natural ordering, including numeric, string, and date/time types. In addition, arrays, composite types, and ranges can be compared if their component data types are comparable.
  It is usually possible to compare values of related data
    types as well; for example
  
   integer
  
  
   >
  
  
   bigint
  
  will work.  Some cases of this sort are implemented
    directly by
  
   "
   
    cross-type
   
   "
  
  comparison operators, but if no
    such operator is available, the parser will coerce the less-general type
    to the more-general type and apply the latter's comparison operator.
 
  As shown above, all comparison operators are binary operators that
    return values of type
  
   boolean
  
  .  Thus, expressions like
  
   1 < 2 < 3
  
  are not valid (because there is
    no
  
   <
  
  operator to compare a Boolean value with
  
   3
  
  ).  Use the
  
   BETWEEN
  
  predicates
    shown below to perform range tests.
 
There are also some comparison predicates, as shown in Table 9.2 . These behave much like operators, but have special syntax mandated by the SQL standard.
Table 9.2. Comparison Predicates
| Predicate Description Example(s) | 
|---|
| 
        
          Between (inclusive of the range endpoints). 
         
         | 
| 
        
          
        Not between (the negation of
         
         | 
| 
        
          Between, after sorting the two endpoint values. 
         | 
| 
        
          Not between, after sorting the two endpoint values. 
         | 
| 
        
          Not equal, treating null as a comparable value. 
         
         | 
| 
        
          Equal, treating null as a comparable value. 
         
         | 
| 
        
          Test whether value is null. 
         | 
| 
        
          Test whether value is not null. 
         | 
| 
        
          Test whether value is null (nonstandard syntax). | 
| 
        
          Test whether value is not null (nonstandard syntax). | 
| 
         Test whether boolean expression yields true. 
         
         | 
| 
         Test whether boolean expression yields false or unknown. 
         
         | 
| 
         Test whether boolean expression yields false. 
         
         | 
| 
         Test whether boolean expression yields true or unknown. 
         
         | 
| 
         Test whether boolean expression yields unknown. 
         
         | 
| 
         Test whether boolean expression yields true or false. 
         
         | 
  
  
  
  
  The
  
   BETWEEN
  
  predicate simplifies range tests:
 
aBETWEENxANDy
is equivalent to
a>=xANDa<=y
  Notice that
  
   BETWEEN
  
  treats the endpoint values as included
    in the range.
  
   BETWEEN SYMMETRIC
  
  is like
  
   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.
 
  The various variants of
  
   BETWEEN
  
  are implemented in
    terms of the ordinary comparison operators, and therefore will work for
    any data type(s) that can be compared.
 
Note
   The use of
   
    AND
   
   in the
   
    BETWEEN
   
   syntax creates an ambiguity with the use of
   
    AND
   
   as a
     logical operator.  To resolve this, only a limited set of expression
     types are allowed as the second argument of a
   
    BETWEEN
   
   clause.  If you need to write a more complex sub-expression
     in
   
    BETWEEN
   
   , write parentheses around the
     sub-expression.
  
  
  
  
  
  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
  
  predicates:
 
aIS DISTINCT FROMbaIS 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 predicates 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 predicates:
expressionIS NULLexpressionIS NOT NULL
or the equivalent, but nonstandard, predicates:
expressionISNULLexpressionNOTNULL
  Do
  
   
    not
   
  
  write
  
   
    
  because
  
     expression
    
   
   = NULL
  
   NULL
  
  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
     
    
    = NULL
   
     expression
    
   
   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.  For example:
 
SELECT ROW(1,2.5,'this is a test') = ROW(1, 3, 'not the same'); SELECT ROW(table.*) IS NULL FROM table; -- detect all-null rows SELECT ROW(table.*) IS NOT NULL FROM table; -- detect all-non-null rows SELECT NOT(ROW(table.*) IS NOT NULL) FROM TABLE; -- detect at least one null in rows
  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 predicates
boolean_expressionIS TRUEboolean_expressionIS NOT TRUEboolean_expressionIS FALSEboolean_expressionIS NOT FALSEboolean_expressionIS UNKNOWNboolean_expressionIS 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.
 
Some comparison-related functions are also available, as shown in Table 9.3 .
Table 9.3. Comparison Functions