Re: Weird NOT IN effect with NULL values - Mailing list pgsql-sql

From Peter Eisentraut
Subject Re: Weird NOT IN effect with NULL values
Date
Msg-id Pine.LNX.4.30.0103011955040.760-100000@peter.localdomain
Whole thread Raw
In response to Weird NOT IN effect with NULL values  (Frank Joerdens <frank@joerdens.de>)
List pgsql-sql
Frank Joerdens writes:

> When doing a subselect with NOT IN, as in
>
> SELECT name
> >FROM customer
> WHERE customer_id NOT IN (
> SELECT customer_id
> >FROM salesorder
> );
>
> (from Bruce Momjian's book)
>
> I get no rows if the result column returned by the subselect
> contains NULL values. It works as expected if I remove the NULL values
> >from the result set. Is this behaviour correct and if so, why?

It is correct.

customer_id NOT IN (value1, value2, value3, ...)

(which is what the subselect would essentially resolve to) is equivalent
to

NOT (customer_id = value1 OR customer_id = value2 OR customer_id = value3 ...)

Say value2 is NULL.  Then we have

NOT (customer_id = value1 OR customer_id = NULL OR customer_id = value3 ...)
NOT (customer_id = value1 OR NULL OR customer_id = value3 ...)
NOT (NULL)
NULL

which means FALSE in a WHERE condition, so no rows are returned.  Note
that 'xxx = NULL' is different from 'xxx IS NULL'.  Also note that NULL is
not the same as FALSE in general.

-- 
Peter Eisentraut      peter_e@gmx.net       http://yi.org/peter-e/



pgsql-sql by date:

Previous
From: Bruce Momjian
Date:
Subject: Re: Weird NOT IN effect with NULL values
Next
From: Stephan Szabo
Date:
Subject: Re: Weird NOT IN effect with NULL values