Expressions involving NULL
In SQL, NULL is not a value.It is a condition, or state, of a data item, in which its value is unknown.Because it is unknown, NULL cannot behave like a value.When you try to perform arithmetic on NULL, or involve it with values in other expressions, the result of the operation will almost always be NULL.It is not zero or blank or an “empty string”, and it does not behave like any of these values.
Below are some examples of the types of surprises you will get if you try to perform calculations and comparisons with NULL.
The following expressions all return NULL:
-
1 + 2 + 3 + NULL -
not (NULL) -
'Home ' || 'sweet ' || NULL
You might have expected 6 from the first expression and “Home sweet” from the third, but as we just said, NULL is not like the number 0 or an empty string — it’s far more destructive!
The following expression:
FirstName || ' ' || LastName
will return NULL if either FirstName or LastName is NULL.Otherwise, it will nicely concatenate the two names with a space in between — even if any one of the variables is an empty string.
|
Tip
|
Think of |
Now let’s examine some PSQL (Procedural SQL) examples with if-constructs:
-
Equals (‘
=’)if (a = b) then MyVariable = 'Equal'; else MyVariable = 'Not equal';After executing this code,
MyVariablewill be'Not equal'if bothaandbareNULL.The reason is thata = byieldsNULLif at least one of them isNULL.If the test expression of an “if” statement isNULL, it behaves likefalse: the ‘then’ block is skipped, and the ‘else’ block executed.WarningAlthough the expression may behave like
falsein this case, it’s stillNULL.If you try to invert it usingnot(), what you get is anotherNULL— not “true”. -
Not equals (‘
<>’)if (a <> b) then MyVariable = 'Not equal'; else MyVariable = 'Equal';Here,
MyVariablewill be'Equal'ifaisNULLandbisn’t, or vice versa.The explanation is analogous to that of the previous example.