× The internal search function is temporarily non-functional. The current search engine is no longer viable and we are researching alternatives.
As a stop gap measure, we are using Google's custom search engine service.
If you know of an easy to use, open source, search engine ... please contact support@midrange.com.



Pete,

1) Use Visual Explain to see exactly what the query is doing.

2) often the IN predicate is replaced by the query engine with a join.
This usually results in the same or better performance.

But you might try a CTE instead

with tbl as ( select pissnv from ppcs301 group by
pissnv having sum(pipctf)>100)
select picode,pissnv,emlnam,emfnam,emmnam, decimal(pipctf/100,5,2)
as tot from ppcs301,peis301 where pissnv=em# and
emstat='Y' and pissnv in(select pissnv from tbl)
order by emlnam,emfnam,emmnam

and maybe get rid of the IN explicitly
with tbl as ( select pissnv from ppcs301 group by
pissnv having sum(pipctf)>100)
select picode,pissnv,emlnam,emfnam,emmnam, decimal(pipctf/100,5,2)
as tot from ppcs301,peis301, tbl where pissnv=em# and
emstat='Y' and pissnv = tbl.pissnv
order by emlnam,emfnam,emmnam

Charles

On Wed, Jan 7, 2009 at 2:01 PM, Pete Helgren <Pete@xxxxxxxxxx> wrote:
I have run into a situation where two sub second queries, when combined,
became a 10 -20 minute monster and I am not sure why.

Here is the SQL statement being executed:

select picode,pissnv,emlnam,emfnam,emmnam, decimal(pipctf/100,5,2)
as tot from ppcs301,peis301 where pissnv=em# and
emstat='Y' and pissnv in(select pissnv from ppcs301 group by
pissnv having sum (pipctf)>100 ) order by emlnam,emfnam,emmnam

This query runs in less than a second and produces 5555 records:

select picode,pissnv,emlnam,emfnam,emmnam, decimal(pipctf/100,5,2)
as tot from ppcs301,peis301 where pissnv=em# and
emstat='Y'
order by emlnam,emfnam,emmnam

This query (the subselect) runs in less than a second and produces 4
records:

select pissnv from ppcs301 group by
pissnv having sum(pipctf)>100

When combined (as in the first statement) it will take 10 - 20 minutes
to run, process millions of records and produce 8 results (which is
correct).

Obviously, I am doing something wrong because I assumed the result of
these two queries would also be sub-second to run. What did I do wrong?

Thanks.

Pete Helgren


--
This is the Midrange Systems Technical Discussion (MIDRANGE-L) mailing list
To post a message email: MIDRANGE-L@xxxxxxxxxxxx
To subscribe, unsubscribe, or change list options,
visit: http://lists.midrange.com/mailman/listinfo/midrange-l
or email: MIDRANGE-L-request@xxxxxxxxxxxx
Before posting, please take a moment to review the archives
at http://archive.midrange.com/midrange-l.



As an Amazon Associate we earn from qualifying purchases.

This thread ...

Replies:

Follow On AppleNews
Return to Archive home page | Return to MIDRANGE.COM home page

This mailing list archive is Copyright 1997-2024 by midrange.com and David Gibbs as a compilation work. Use of the archive is restricted to research of a business or technical nature. Any other uses are prohibited. Full details are available on our policy page. If you have questions about this, please contact [javascript protected email address].

Operating expenses for this site are earned using the Amazon Associate program and Google Adsense.