SINGULAR
SINGULAR
is an InterBase/Firebird extension to the SQL standard.It is often described as returning true
if exactly one row in the subquery meets the search condition.By analogy with EXISTS
this would make you expect that SINGULAR
too will only ever return true
or false
.After all, a result set has either exactly 1 row or a different number of rows.Unfortunately, all versions of Firebird up to and including 2.0 have a bug that causes NULL
results in a number of cases.The behaviour is pretty inconsistent, but at the same time fully reproducible.For instance, on a column A
containing (1, NULL
, 1), a SINGULAR
test with subselect “A=1
” returns NULL
, but the same test on a column with (1, 1, NULL
) returns false
.Notice that only the insertion order is different here!
To make matters worse, all versions prior to 2.0 sometimes return NULL
for NOT SINGULAR
where false
or true
is returned for SINGULAR
.In 2.0, this at least doesn’t happen anymore: it’s either false
vs. true
or twice NULL
.
The code has been fixed for Firebird 2.1; from that version onward SINGULAR
will return:
-
false
if the search condition is nevertrue
(this includes the empty-set case); -
true
if the search condition istrue
for exactly 1 row; -
false
if the search condition istrue
for more than 1 row.
Whether the other rows yield false
, NULL
or a combination thereof, is irrelevant.
NOT SINGULAR
will always return the opposite of SINGULAR
(as is already the case in 2.0).
In the meantime, if there’s any chance that the search condition may evolve to NULL
for one or more rows, you should always add an IS NOT NULL
condition to your [NOT] SINGULAR
clauses, e.g.like this:
... SINGULAR( SELECT * from MyTable
WHERE MyField > 38
AND MyField IS NOT NULL )