On Sun, 26 Feb 2006, Dhanaraj wrote:
> I have two tables, let's say A and B.
>
> B is a child of a in one to many relationship. A contains records that are
> not referenced by B.
>
> I am running a query:
>
> select * from A t1 where t1.id not in (select t2.A_id from B t2);
>
> It returns 0 rows.
>
> Now I run
> (select t1.id from A t1) except (select t2.A_id from B t2);
>
> And now Postgres correctly returns records from A that are not referenced by
> B.
>
> Thanks a lot for your consideration of this bug.
This may not be a bug if t2.A_id contains NULLs because not in and except
handle them differently and return different results by spec.
Specifically, something like
1 NOT IN (values (NULL)) is unknown
while
select 1 except select NULL returns a row with 1.
The first is because IN is based on equality, and 1 = NULL is unknown.
The second is because it uses distinctness (or more precisely duplicate
which is itself defined in terms of distinctness), and 1 IS DISTINCT FROM
NULL is true.
If you're getting platform dependant results on the same (non-textual)
data, it would be helpful to make a complete script that others can run.