I second his recommendation.   The optimizer is very sophisticated and
takes  A LOT of things into account, therefore using EXPLAIN can be
crucial when solving these kinds of problems.

Another thing to keep in mind is the "access path" taken by different
programs.   In this case, I mean "access path" to be more like
"execution thread".  It is very possible that when you run your queries
in the native environment the DB2 optimizer "sees" that product very
differently than when you access via Java or some other non-native or
non-static access path product.   A similar case in point are the three
query products  DB2 Query Manager, NGS-IQ and Crystal Reports.

- Query Manager runs against DB2 very fast
- NGS-IQ is very fast, invokes in QSYSWRK, seems to be using static
access paths (the real DB2 meaning of access paths) and the CPU use is
minimal
- Crystal Reports uses ODBC and therefore used DYNAMIC access paths,
runs slower and uses HUGE amounts of CPU

As with any of the DB2s IBM makes, STATIC is your friend, DYNAMIC is
usually not.  There are times when DYNAMIC is the only way to go,
however.

FWIW,

Dave Odom
Old DB2 DBA (VM, MVS, i5/OS)


>>> albartell@xxxxxxxxx 4/19/2006 15:03:17 >>>
Use iSeries Navigator and run your SQL statement through the Visual
Explain
process.  I was completely surprised by the recommended indexes because
they
were way different from the ones I built and thought it should be.

Aaron Bartell 

-----Original Message-----
From: web400-bounces@xxxxxxxxxxxx [mailto:web400-bounces@xxxxxxxxxxxx]
On
Behalf Of Corissa Andrascik
Sent: Wednesday, April 19, 2006 4:20 PM
To: Web Enabling the AS400 / iSeries
Subject: Re: [WEB400] Slow Query Performance from the Web

I think we actually just found the problem - 

We rearranged the where clause - and created new indexes to match.  One
of
the fields is a reference number for customer accounts - which is much
more
likely to be unique that the ranges we were searching on first before.


 I still don't understand the reason why it made such a huge difference
when
running on the web compared to the 400  - but running it from the web
we
needed to have it ordered so that the criteria in the where clause
were
progressively LESS unique.  Does that make sense?  We put the reference
#
first (field3 and field4), then got everything field11 >
.01 and THEN searched for the ranges of group#'s (field6).  

This massively increased our performance to where it's running in
under
7 seconds from the web now. 


-----Original Message-----
From: web400-bounces@xxxxxxxxxxxx [mailto:web400-bounces@xxxxxxxxxxxx]

On Behalf Of Corissa Andrascik
Sent: Wednesday, April 19, 2006 1:17 PM
To: Web Enabling the AS400 / iSeries
Subject: Re: [WEB400] Slow Query Performance from the Web

The query is as follows

select field1, field2, field3, field4, field5, field6,  field7,
field8,
field9, field10, field11 from View1 where ((field6 >= 0000 and field6
<
0100) or
(field6 >= 8300 and field6 < 8400)) and
(field3=999999999 or field4=999999999)
and field11>=0.01 


I'm not worried so much about the result set per se. The view in our
test
database is over 4 physical files totaling about 3.7 million records. 
The
result set is very small.  Usually less than 5 records -
never more than 30.   From our web logs I can see where the query is
created and sent to the 400 - and when it returns results.  This is
where we
see the lag in time - about 1 minute 10 seconds. 

When we get to production the view will be over 22 million records but
will
still have approximately the same amount of results. 


Thanks for all of your help!

-----Original Message-----
From: web400-bounces@xxxxxxxxxxxx [mailto:web400-bounces@xxxxxxxxxxxx]

On Behalf Of Tom Huff
Sent: Wednesday, April 19, 2006 9:05 AM
To: 'Web Enabling the AS400 / iSeries'
Subject: Re: [WEB400] Slow Query Performance from the Web

Long Live Green Screen

-----Original Message-----
From: web400-bounces@xxxxxxxxxxxx [mailto:web400-bounces@xxxxxxxxxxxx]

On Behalf Of Walden H. Leverich
Sent: Wednesday, April 19, 2006 7:36 AM
To: Web Enabling the AS400 / iSeries
Subject: Re: [WEB400] Slow Query Performance from the Web

Can you post the SQL and the number of rows returned in the result
set?
Also, have you run SQL Performance Monitors on the job?

One mistake I've seen lots of people make in Java is not to pre-size a
collection when loading records into a collection. In one case simply
adding
an ensurecapacity(500) method call to an ArrayList changed response
time
from 20 seconds to sub-second.

The more memory constrained the app server the more a problem like this
will
be noticed.

-Walden

--
Walden H Leverich III
Tech Software
(516) 627-3800 x3051
WaldenL@xxxxxxxxxxxxxxx 
http://www.TechSoftInc.com 

Quiquid latine dictum sit altum viditur.
(Whatever is said in Latin seems profound.)


-----Original Message-----
From: web400-bounces+waldenl=techsoftinc.com@xxxxxxxxxxxx 
[mailto:web400-bounces+waldenl=techsoftinc.com@xxxxxxxxxxxx] On Behalf
Of
Corissa Andrascik
Sent: Tuesday, April 18, 2006 6:23 PM
To: web400@xxxxxxxxxxxx 
Subject: [WEB400] Slow Query Performance from the Web

Hi All, 
 
 I'm new to this list - and I'm not sure this is the proper place to
be
asking this question - but I'd appreciate any direction you can give. 
 
We have a query that runs over a view that joins together several
related
physical files. We created indexes for each physical based on the
Where
clause in the query and when I run it through STRSQL on the
400 - the performance is good - about 8-9 seconds.   When the same
query
is passed from the web - we're running websphere on Window 2003 boxes -
it
takes in the neighborhood of 1 minute 10 seconds.  
 
  We are trying to figure out what can be done to optimize it from the
web.
I realize I'm probably not giving enough information here - I just have
no
clue where to start!  If any of you have any ideas I'd be eternally
grateful.
 
Thanks
--
This is the Web Enabling the AS400 / iSeries (WEB400) mailing list To
post a
message email: WEB400@xxxxxxxxxxxx To subscribe, unsubscribe, or change
list
options,
visit: http://lists.midrange.com/mailman/listinfo/web400 
or email: WEB400-request@xxxxxxxxxxxx 
Before posting, please take a moment to review the archives at
http://archive.midrange.com/web400.


--
This is the Web Enabling the AS400 / iSeries (WEB400) mailing list To
post a
message email: WEB400@xxxxxxxxxxxx To subscribe, unsubscribe, or change
list
options,
visit: http://lists.midrange.com/mailman/listinfo/web400 
or email: WEB400-request@xxxxxxxxxxxx 
Before posting, please take a moment to review the archives at
http://archive.midrange.com/web400.

--
This is the Web Enabling the AS400 / iSeries (WEB400) mailing list To
post a
message email: WEB400@xxxxxxxxxxxx To subscribe, unsubscribe, or change
list
options,
visit: http://lists.midrange.com/mailman/listinfo/web400 
or email: WEB400-request@xxxxxxxxxxxx 
Before posting, please take a moment to review the archives at
http://archive.midrange.com/web400.



--
This is the Web Enabling the AS400 / iSeries (WEB400) mailing list To
post a
message email: WEB400@xxxxxxxxxxxx To subscribe, unsubscribe, or change
list
options,
visit: http://lists.midrange.com/mailman/listinfo/web400 
or email: WEB400-request@xxxxxxxxxxxx 
Before posting, please take a moment to review the archives at
http://archive.midrange.com/web400.



--
This is the Web Enabling the AS400 / iSeries (WEB400) mailing list To
post a
message email: WEB400@xxxxxxxxxxxx To subscribe, unsubscribe, or change
list
options,
visit: http://lists.midrange.com/mailman/listinfo/web400 
or email: WEB400-request@xxxxxxxxxxxx 
Before posting, please take a moment to review the archives at
http://archive.midrange.com/web400.


As an Amazon Associate we earn from qualifying purchases.

This thread ...


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.