Re: select ..... not in ..... - Mailing list pgsql-sql

From Tom Lane
Subject Re: select ..... not in .....
Date
Msg-id 12152.1179157057@sss.pgh.pa.us
Whole thread Raw
In response to select ..... not in .....  (Gary Stainburn <gary.stainburn@ringways.co.uk>)
List pgsql-sql
Gary Stainburn <gary.stainburn@ringways.co.uk> writes:
> So, who does this select not return the row?

> select v_d_code, v_o_number,  v_vin, v_status from vista_details where v_vin 
> not in (
> goole(#   select substring(w_vin from '(.{11}$)') from walon);

NOT IN with a sub-select that returns any NULL values cannot succeed;
the result is either FALSE (definite match) or NULL (because of the
NULL comparison results).

You could work around that with a COALESCE, but I think a less klugy
and better-performing answer would be to write it as a left join:

select v_d_code, v_o_number,  v_vin, v_status from vista_details
left join walon on (v_vin = substring(w_vin from '(.{11}$)'))
where walon.some-never-null-column IS NULL;

The where-clause rejects any actual join matches...
        regards, tom lane


pgsql-sql by date:

Previous
From: Gary Stainburn
Date:
Subject: select ..... not in .....
Next
From: Michael Glaesemann
Date:
Subject: Re: Temporal Table Relations and Referential Integrity