From: | Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us> |
---|---|
To: | Gary Stainburn <gary(dot)stainburn(at)ringways(dot)co(dot)uk> |
Cc: | pgsql-sql(at)postgresql(dot)org |
Subject: | Re: select ..... not in ..... |
Date: | 2007-05-14 15:37:37 |
Message-ID: | 12152.1179157057@sss.pgh.pa.us |
Views: | Raw Message | Whole Thread | Download mbox | Resend email |
Thread: | |
Lists: | pgsql-sql |
Gary Stainburn <gary(dot)stainburn(at)ringways(dot)co(dot)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
From | Date | Subject | |
---|---|---|---|
Next Message | Michael Glaesemann | 2007-05-14 16:10:02 | Re: Temporal Table Relations and Referential Integrity |
Previous Message | Gary Stainburn | 2007-05-14 15:07:24 | select ..... not in ..... |