From: | Alfred Perlstein <bright(at)wintelcom(dot)net> |
---|---|
To: | Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us> |
Cc: | pgsql-hackers(at)postgresql(dot)org |
Subject: | Re: Unable to get acceptable performance from EXCEPT |
Date: | 2000-05-11 00:10:43 |
Message-ID: | 20000510171043.R28180@fw.wintelcom.net |
Views: | Raw Message | Whole Thread | Download mbox | Resend email |
Thread: | |
Lists: | pgsql-hackers |
* Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us> [000510 16:22] wrote:
> Alfred Perlstein <bright(at)wintelcom(dot)net> writes:
> > =# select ref_id from ref_old except select ref_id from ref_new;
> > Takes over 10 minutes, probably closer to half an hour.
> > I've also tried using 'NOT IN ( select ref_id from ref_new )'
>
> Yup. EXCEPT is effectively translated to a NOT IN, if I recall
> correctly, and neither IN ( sub-select ) nor NOT IN ( sub-select )
> are implemented very efficiently. Basically you get O(N^2) behavior
> because the inner select is rescanned for each outer tuple.
>
> We have a TODO list item to try to be smarter about this...
>
> > Is there a way to formulate my SQL to get Postgresql to follow
> > this algorithm [ kind of like a mergejoin ]
>
> No, but you could try
>
> select ref_id from ref_old where not exists
> (select ref_id from ref_new where ref_id = ref_old.ref_id);
>
> which would at least be smart enough to consider using an index
> on ref_new(ref_id) instead of a sequential scan.
Which cuts the query time down to less than a second!
thanks!
Ready for the evil magic?
select
distinct(o.ref_id)
from
ref_link o
where
o.stat_date < '2000-04-26 12:12:41-07'
AND not exists
(
select
n.ref_id
from
ref_link n
where
n.stat_date >= '2000-04-26 12:12:41-07'
AND n.ref_id = o.ref_id
)
;
Thanks a ton.
--
-Alfred Perlstein - [bright(at)wintelcom(dot)net|alfred(at)freebsd(dot)org]
"I have the heart of a child; I keep it in a jar on my desk."
From | Date | Subject | |
---|---|---|---|
Next Message | Bruce Momjian | 2000-05-11 00:12:12 | Re: setproctitle() no longer used? |
Previous Message | Vince Vielhaber | 2000-05-11 00:07:30 | Re: setproctitle() no longer used? |