On Wed, 19 Oct 2005, [iso-8859-2] Havasv�lgyi Ott� wrote:
> Hi,
>
> I have just run this command on 8.0.4 :
>
> SELECT 'foo' WHERE 0 NOT IN (NULL, 1);
>
> And it resulted is zero rows.
> Without NULL it is OK.
> Is this a bug, or the standard has such a rule?
This is standard behavior.
Seeing if I can do this from memory...
a NOT IN b is equivalent in the spec to NOT(a IN b). a IN b is equivalent
to a =ANY b. a =ANY b returns true if a = x is true for any x in b. a =ANY
b returns false if a = x is false for all x in b. Otherwise it returns
unknown.
0 = NULL returns unknown
0 = 1 returns false
So, 0 IN (NULL,1) returns unknown.
NOT(unknown) is unknown.
WHERE clauses only return rows for which the search condition is true, so
a row is not returned.