Re: Unable to get acceptable performance from EXCEPT
От | Alfred Perlstein |
---|---|
Тема | Re: Unable to get acceptable performance from EXCEPT |
Дата | |
Msg-id | 20000510171043.R28180@fw.wintelcom.net обсуждение исходный текст |
Ответ на | Re: Unable to get acceptable performance from EXCEPT (Tom Lane <tgl@sss.pgh.pa.us>) |
Список | pgsql-hackers |
* Tom Lane <tgl@sss.pgh.pa.us> [000510 16:22] wrote: > Alfred Perlstein <bright@wintelcom.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@wintelcom.net|alfred@freebsd.org] "I have the heart of a child; I keep it in a jar on my desk."
В списке pgsql-hackers по дате отправления: