Re: Problem with "NOT IN (subquery)

From: Stephan Szabo <sszabo(at)megazone(dot)bigpanda(dot)com>
To: Steve SAUTETNER <steve(at)sautetner(dot)com>
Cc: pgsql-sql(at)postgresql(dot)org
Subject: Re: Problem with "NOT IN (subquery)
Date: 2005-11-13 09:16:18
Message-ID: 20051113010417.D61269@megazone.bigpanda.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-sql


On Sun, 13 Nov 2005, Steve SAUTETNER wrote:

> Hi,
>
> I have a table named "famille" whose structure and content is :
>
> famille_code | famille_mere_famille_code | famille_libelle |
> famille_niveau
> --------------+---------------------------+-------------------+-------------
> ---
> 000000 | | Mhre |

Is that a NULL famille_mere_famille_code?

> The first col is the family id and the second is the mother family id.
> I would get a list of all families that are never in the col n2, so
> the families that aren't node but leaf.
>
> The query, i made was "SELECT * FROM famille WHERE famille_code NOT IN
> (SELECT DISTINCT famille_mere_famille_code FROM famille);"
>
> But the DB returns 0 records instead of 15. If i use a list instead of a
> subquery it works normaly but it's not easy to manage it like this.
>
> So if anyone can help me please ...

In the case where the subselect returns a NULL, the behavior of IN and NOT
IN is rather unfortunate. A NOT IN B is basically NOT(A IN B) and A IN B
is basically A =ANY B IIRC. However, A=ANY B only returns false if A = Bi
returns false for all Bi contained in B and A = NULL returns unknown, not
false, so NOT IN cannot return true if the subselect contains a NULL.

If that is a null above, probably the best solution is to exclude NULLs
from the subselect results.

In response to

Browse pgsql-sql by date

  From Date Subject
Next Message chester c young 2005-11-13 17:07:01 Re: Problem with "NOT IN (subquery) - use NOT EXISTS
Previous Message Steve SAUTETNER 2005-11-13 06:27:09 Problem with "NOT IN (subquery)