IF statements
If the test expression of an IF statement resolves to NULL, the THEN clause is skipped and the ELSE clause — if present — executed.In other words, NULL and false have the same effect in this context.So in situations where you would logically expect false but NULL is returned, no harm will be done.However, we’ve already seen examples of NULL being returned where you would expect true, and that does affect the flow of the code!
Below are some examples of the seemingly paradoxical (but perfectly correct) results you can get if NULLs creep into your IF statements.
|
Tip
|
If you use Firebird 2 or higher, you can avoid all the pitfalls discussed here, simply by using |
-
Equals (‘
=’)if (a = b) then MyVariable = 'Equal'; else MyVariable = 'Not equal';If
aandbare bothNULL,MyVariablewill yet be “Not equal” after executing this code.The reason is that the expression “a = b” yieldsNULLif at least one of them isNULL.With aNULLtest expression, theTHENblock is skipped and theELSEblock executed. -
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.
So how should you set up equality tests that do give the logical result under all circumstances, even with NULL operands?In Firebird 2 you can use DISTINCT, as already shown (see Testing DISTINCTness). With earlier versions, you’ll have to write some more code.This is discussed in the section [nullguide-testing-equality], later on in this guide.For now, just remember that you have to be very careful with IF conditions that may resolve to NULL.
Another aspect you shouldn’t forget is the following: a NULL test expression may behave like false in an IF condition, but it doesn’t have the value false.It’s still NULL, and that means that its inverse will also be NULL — not “true”.As a consequence, inverting the test expression and swapping the THEN and ELSE blocks may change the behaviour of the IF statement.In binary logic, where only true and false can occur, such a thing could never happen.
To illustrate this, let’s refactor the last example:
-
Not not equals (“
not (.. <> ..)”)if (not (a <> b)) then MyVariable = 'Equal'; else MyVariable = 'Not equal';In the original version, if one operand was
NULLand the other wasn’t (so they were intuitively unequal), the result was “Equal”.Here, it’s “Not equal”.The explanation: one operand isNULL, therefore “a <> b” isNULL, therefore “not(a <> b)” isNULL, thereforeELSEis executed.While this result is correct where the original had it wrong, there’s no reason to rejoice: in the refactored version, the result is also “Not equal” if both operands areNULL— something that the original version “got right”.
Of course, as long as no operand in the test expression can ever be NULL, you can happily formulate your IF statements like above.Also, refactoring by inverting the test expression and swapping the THEN and ELSE blocks will always preserve the functionality, regardless of the complexity of the expressions — as long as they aren’t NULL.What’s especially treacherous is when the operands are almost always non-NULL, so in the vast majority of cases the results will be correct.In such a situation those rare NULL cases may go unnoticed for a long time, silently corrupting your data.