|
Hello, The optimizer likely will not pick a simple logical you build for this due to the scalar function in the statement (the substring function). The scalar causes the optimizer to have to build a temporary result table no matter what logicals you have - so, it is my guess from working on past performance issues that the optimizer is deciding that it is faster for it to build it's own temporary logical with the scalar results inside it at the same time, rather than use your logicals first and then calculate the scalar results later into a temporary file and combine the results together. Before starting to tune: 1. Ensure you have the latest SQL PTFs from IBM for your release (the latest Group PTF for database/SQL) before starting any of that, as the SQL optimizer is affected by PTFs in how it decides to choose to access your data. 2. Check the Info APAR for BPCS on your OS/400 release (II11801) to ensure you have all BPCS required PTFs. Rather than relying on PRTSQLINF, instead try to find out what the optimizer is building on the fly and see if you can help it out. For example, first try STRDBG program *NONE, UPDPROD *YES and see the SQL messages in your joblog by pressing F1 and then reading the 2nd level text to see what is in the logical file it builds. If the file has no name or keys listed, that is because it includes the scalar results. So, if that isn't revealing enough run a DBMON (the SSA Helpline can assist in analyzing this if you are working with a client who has OGS support, and if their final analysis involves requesting code changes, they can enter a BMR for you) and find out more about what happens when the statement runs. The PRTSQLINF is only an estimated run time, not the actual. DBMON shows how long the statement really takes to complete, and leaves lots of clues as to why the optimizer chooses to do what it does do. You can try to give it an index that has everything the query needs to complete (every field returned, with order by and selection keys first - the optimizer likes to remove as many records as possible, so put the most selective fields first ) except the SCALAR results of course. This would be an attempt to induce index-only access so that the optimizer has the choice of doing an index-from-index build. It may never choose to use anything you build in the end unless the statement is altered or program is altered. Changing the statement requires in depth application knowlege. If this is reducing performance significantly and you suspect a BMR is in order, you should ask the customer to open a call to the SSA Helpline AS/400 Technical team to investigate. They can involve the required application consultants to assist. Another option to try (if you have source and feel like playing) is to find out if the program fetches the cursor in a loop that involves lots of other activity in between reads of the next record in the cursor. In that case, you could alter the SQL statement to say at the end "OPTIMIZE for n ROWS" where n is a low number such as 10 or 20 - this way the first 10/20 records might be returned more quickly, and the loop can begin processing. This may make the program appear to process faster to an interactive user, but that is dependent again upon the program logic and what else the optimizer is doing behind the scenes. A DBMON would give you a lot more information to work with. Thanks Genyphyr Novak SSA -----Original Message----- From: ANTHONY_JACKSON@dcsgroup.co.uk <ANTHONY_JACKSON@dcsgroup.co.uk> To: BPCS-L@midrange.com <BPCS-L@midrange.com> Date: Tuesday, February 15, 2000 1:53 PM > >Hi folks.....anybody out there...ever compiled a logical on rar..which will be >used by >(see sqlinf below)...I have tried numerous qddssrc/LF specs/...and none got >picked up by >ACR500D2....bpcs ver=6.1 full client...on AS400...its the last piece of the >performance >improvements we have made on 'cash/memo posting' > File . . . . . : ACR500D2 Page/Line 2/42 > > Control . . . . . W6 Columns 6 - 83 > Find . . . . . . > ....1....+....2....+....3....+....4....+....5....+....6....+....7....+....8. .. > A1 > A1 > A1 > DECLARE C1 CURSOR FOR SELECT * FROM RAR WHERE RCOMP = : CRCMPY AND RCURR = : > > RCURR AND RCCUS = : CRCUST AND ARPTYP <> : W8PTP1 AND ARPTYP <> : W8PTP2 AND ( > RPTYP BETWEEN : W8FRTP AND : W8TOTP ) AND SUBSTR ( RRID , 1 , 1 ) IN ( 'R' , > T' ) AND ARWSID IN ( : W8WSID , : ZZSWS ) AND RSEQ = 0 AND RREM <> 0 ORDER BY > DDTE , RCUST , ARODPX , RINVC FOR FETCH ONLY > 4021 Access plan last saved on 18/05/99 at 08:15:58. > 4020 Estimated query run time is 12 seconds. > 4017 Host variables implemented as reusable ODP. > 4006 All access paths considered for file 1. > 4009 Access path created for file 1. > S1 V4R3M0 980729 Print SQL information Program *LIBL/ACR500D2 >*************************************************************************** ***** > >BPCS Support >DCS Industry Solutions >Caledonia House office 0113 2043300 >Lawnswood Business Park fax 0113 2043333 >Redvers Close >leeds LS16 6QY >The information contained in this electronic mail message is confidential. It is >intended solely for the use of the individual or entity to whom it is addressed >and others authorised to receive it. If the reader of this message is not the >intended recipient, you are hereby notified that any use, copying, dissemination >or disclosure of this information is strictly prohibited. > > > > > >+--- >| This is the BPCS Users Mailing List! >| To submit a new message, send your mail to BPCS-L@midrange.com. >| To subscribe to this list send email to BPCS-L-SUB@midrange.com. >| To unsubscribe from this list send email to BPCS-L-UNSUB@midrange.com. >| Questions should be directed to the list owner: dasmussen@aol.com >+--- > +--- | This is the BPCS Users Mailing List! | To submit a new message, send your mail to BPCS-L@midrange.com. | To subscribe to this list send email to BPCS-L-SUB@midrange.com. | To unsubscribe from this list send email to BPCS-L-UNSUB@midrange.com. | Questions should be directed to the list owner: dasmussen@aol.com +---
As an Amazon Associate we earn from qualifying purchases.
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.