Mimer SQL Documentation TOC PREV NEXT INDEX

Mimer SQL Developer Site


Comparisons


Values to be compared must be of compatible data types. If values with incompatible data types are compared, an error occurs.

Character String Comparisons

Both fixed-length and variable-length character strings are compared character by character from left to right.

If the strings are of different length, the shorter string is conceptually padded to the right with blanks before the comparison is made, that is, character differences take precedence over length differences.

For example, the variable-length column with the value 'town ', one trailing blank, is equal to the variable-length column with the value 'town ', two trailing blanks.

When comparing a character string to a national character string, the character string is implicitly converted to a national character string, before the comparison is performed.

Collations

A collation determines whether a character string is less than, equal to, or greater than another when sorting or comparing data.

SQL only permits compatible character strings to be compared. That is, you can compare character strings only if the source and target strings belong to the same collation or are coerced into having the same collation.

A character string that is defined with a named collation can only be compared to a character string that is either defined with the same named collation or is defined without a collation.

In the case where one of the strings is not associated with a named collation then it will be implicitly coerced to the same collation as the other string.

A collation specified in the column-definition will take precedence over a domain collation.

For more information on character sets, see Character Sets.

For more information on collations, see Mimer SQL User's Manual, Collations.

Numerical Comparisons

Numerical values are always compared according to their algebraic values.

Integer values compared with decimal or floating point values are treated as decimal or floating respectively. When decimal values are compared with decimal, the lower precision value is conceptually padded with leading and trailing zeros as necessary. Decimal values compared with floating point values are treated as floating.

Thus all the following comparisons evaluate to true:

 1 = 1.0
 2 < 2.3E0
 35.3 = 035.300
 35.3 > 3.5E1

Datetime and Interval Comparisons

Two DATETIME values may be compared if they are assignment-compatible, as defined in Datetime Assignment Rules.

DATETIME comparisons are performed in accordance with chronological ordering.

When two TIME or two TIMESTAMP values are compared, the seconds precision of the value with the lowest seconds precision is extended by adding trailing zeros.

Two INTERVAL values may be compared if they are assignment-compatible, as defined in Interval Assignment Rules.

INTERVAL comparisons are performed in accordance with their sign and magnitude.

It is not possible to compare YEAR-MONTH intervals with DAY-TIME intervals.

Comparable INTERVAL types with different interval precisions are conceptually converted to the same interval precision, prior to any comparison, by adding fields as required.

Binary Comparisons

Binary values are compared bytewise. If the two binary values have different lengths they are not equal.

Boolean Comparisons

Boolean values are compared to TRUE or FALSE. When comparing truth values FALSE is less than TRUE.

When equals true is to be evaluated it is unnecessary to write the = TRUE part. I.e.

 WHERE boolcol = TRUE
 

is typically written as

 WHERE boolcol
 

Similarly, = FALSE is typically re-written using NOT. I.e.

 WHERE boolcol = FALSE
 

is usually expressed as

 WHERE NOT boolcol
 

Mimer SQL Experience
The BOOLEAN TEST syntax is supported for truth value tests, i.e.:
boolean-primary IS TRUE
boolean-primary IS FALSE
boolean-primary IS UNKNOWN
boolean-primary IS NOT TRUE
boolean-primary IS NOT FALSE
boolean-primary IS NOT UNKNOWN

NULL Comparisons

All comparisons involving NULL on either side of the comparison operator evaluate to unknown. NULL is never equal to, greater than or less than anything else. SQL provides a special NULL predicate to test for the presence or absence of NULL in a column, see The NULL Predicate.

Considerable care is required in writing search conditions involving columns which may contain NULL. It is often very easy to overlook the effect of NULL comparisons, with the result that rows which should be included in the result table are omitted or vice versa. See the Mimer SQL User's Manual, Handling NULL Values, for further discussion of this point.

Truth Tables

The following truth tables summarize the outcome of conditional expressions where comparisons are negated by NOT or joined by AND or OR.

A question mark (?) represents the truth value unknown, T represents the value TRUE and F represents the value FALSE.

NOT

NOT
T
F
F
T
?
?

AND

AND
T
F
?
T
T
F
?
F
F
F
F
?
?
F
?

OR

OR
T
F
?
T
T
T
T
F
T
F
?
?
T
?
?

IS

IS
T
F
?
T
T
F
F
F
F
T
F
?
F
F
T

Standard Compliance

This section summarizes standard compliance concerning comparisons.

Standard
Compliance
Comments
SQL-2011
Core
Fully compliant.
SQL-2011
Features outside core
Feature T031, "BOOLEAN data type"
Mimer SQL Experience:
Feature F571, "Truth value tests"


Mimer
Mimer Information Technology AB
Voice: +46 18 780 92 00
Fax: +46 18 780 92 40
info@mimer.se
Mimer SQL Documentation TOC PREV NEXT INDEX