5.3.4.6 Working with NULL Values (original) (raw)
5.3.4.6 Working with NULL Values
The NULL
value can be surprising until you get used to it. Conceptually, NULL
means“a missing unknown value” and it is treated somewhat differently from other values.
To test for NULL
, use theIS NULL and IS NOT NULL operators, as shown here:
mysql> SELECT 1 IS NULL, 1 IS NOT NULL;
+-----------+---------------+
| 1 IS NULL | 1 IS NOT NULL |
+-----------+---------------+
| 0 | 1 |
+-----------+---------------+
You cannot use arithmetic comparison operators such as=,<, or<> to test for NULL
. To demonstrate this for yourself, try the following query:
mysql> SELECT 1 = NULL, 1 <> NULL, 1 < NULL, 1 > NULL;
+----------+-----------+----------+----------+
| 1 = NULL | 1 <> NULL | 1 < NULL | 1 > NULL |
+----------+-----------+----------+----------+
| NULL | NULL | NULL | NULL |
+----------+-----------+----------+----------+
Because the result of any arithmetic comparison withNULL
is also NULL
, you cannot obtain any meaningful results from such comparisons.
In MySQL, 0
or NULL
means false and anything else means true. The default truth value from a boolean operation is 1
.
This special treatment of NULL
is why, in the previous section, it was necessary to determine which animals are no longer alive using death IS NOT NULL
instead of death <> NULL
.
Two NULL
values are regarded as equal in aGROUP BY
.
When doing an ORDER BY
,NULL
values are presented first if you doORDER BY ... ASC
and last if you doORDER BY ... DESC
.
A common error when working with NULL
is to assume that it is not possible to insert a zero or an empty string into a column defined as NOT NULL
, but this is not the case. These are in fact values, whereasNULL
means “not having a value.” You can test this easily enough by usingIS [NOT] NULL
as shown:
mysql> SELECT 0 IS NULL, 0 IS NOT NULL, '' IS NULL, '' IS NOT NULL;
+-----------+---------------+------------+----------------+
| 0 IS NULL | 0 IS NOT NULL | '' IS NULL | '' IS NOT NULL |
+-----------+---------------+------------+----------------+
| 0 | 1 | 0 | 1 |
+-----------+---------------+------------+----------------+
Thus it is entirely possible to insert a zero or empty string into a NOT NULL
column, as these are in fact NOT NULL
. SeeSection B.3.4.3, “Problems with NULL Values”.