Re: negative queries puzzle

From: Stephan Szabo <sszabo(at)megazone23(dot)bigpanda(dot)com>
To: Jinn Koriech <lists(at)idealint(dot)co(dot)uk>
Cc: PostgreSQL Mailing List <pgsql-sql(at)postgresql(dot)org>
Subject: Re: negative queries puzzle
Date: 2002-07-31 20:08:43
Message-ID: 20020731130557.A19958-100000@megazone23.bigpanda.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-sql


On 31 Jul 2002, Jinn Koriech wrote:

> hi all,
>
> here's a query i've never been able to improve:
>
> i have an old data set and a new data set - in this case uk postcodes
> with eastings and northings. i want to extract the new and changed
> postcodes from the new set. to get the changed entries i use a join and
> it works okay:
>
> SELECT n.postcode, n.easting, n.northing FROM v_postcode_new n,
> v_postcode_old o WHERE n.postcode = o.postcode AND (n.easting <>
> o.lattitude OR n.northing <> o.longitude);
>
>
> but then to get the entirely new items out i use a sub query which takes
> for ever
>
> SELECT DISTINCT * FROM v_postcode_new WHERE postcode NOT IN ( SELECT
> postcode FROM v_postcode_old ) ORDER BY postcode ASC;
>
> does anyone know of a quicker way to accomplish this? i guess there
> must be some cleaver way around it, but it's beyond me.

Hmm, a couple of possible other queries:

-- Do you really need the distinct?
select distinct * from v_postcode_new where not exists (
select * from v_postcode_old where v_postcode_old.postcode=
v_postcode_new.postcode);

Or maybe (just thought of this, think it should work, but
am not entirely sure)
select distinct v_postcode_new.* from
v_postcode_new left outer join v_postcode_old using(postcode)
where v_postcode_old.postcode is null;

In response to

Browse pgsql-sql by date

  From Date Subject
Next Message Tom Haddon 2002-07-31 22:59:37 Case Statement
Previous Message Jinn Koriech 2002-07-31 19:15:36 negative queries puzzle