×
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.
Paul,
Thanks for the explanation. I really don't think I like the 7 statements
bit, just because it doesn't scale well. If I had to add another
parameter it would be a nightmare to maintain. But I get the point. The
idea behind the OR statement seems sound, as long as we can verify that
SQL will execute in that order and stop upon the first True statement. If
someone has knowledge to verify that then I'd love to hear it. I don't
have time to test it at the moment, but maybe this afternoon I can.
Thanks
Bryce Martin
Programmer/Analyst I
570-546-4777
"Morgan, Paul" <Paul.Morgan@xxxxxxxxxxx>
Sent by: rpg400-l-bounces@xxxxxxxxxxxx
02/11/2011 09:23 AM
Please respond to
RPG programming on the IBM i / System i <rpg400-l@xxxxxxxxxxxx>
To
RPG programming on the IBM i / System i <rpg400-l@xxxxxxxxxxxx>
cc
Subject
RE: More efficient way to write this SQL Statement???
Martin,
With
cad3 = (case when :cszESTCity <> ''
then :cszESTCity else
cad3 End)
SQL could probably 'short circuit' it down to cad3 = :csZESTCITY
or cad3 = cad3 by only doing the case statement once. And if it's smart
it also wouldn't do the cad3 = cad3 test as that's always true.
But just to be sure I would have coded that as:
( :cszESTCITY = '' or cad3 = :cszESTCITY )
SQL could short circuit that down and never test against cad3 if
:CszESTCITY = ''. It can test the left side, find it's true then never
test the right side with the OR condition.
I was also thinking you could code seven different SQL statement
enumerating all possible combinations of City, State, and Zip being
provided (all three, three combinations of two each, three statements with
one each). Then you have an RPG case statement testing for empty strings
to run the right SQL statement. The SQL statements then just have:
cad3 = :cszESTCITY
and you never have to test for empty strings in the SQL as you've done
that test in RPG before running the SQL.
Paul Morgan
Principal Programmer Analyst
IT Supply Chain/Replenishment
-----Original Message-----
From: rpg400-l-bounces@xxxxxxxxxxxx [mailto:rpg400-l-bounces@xxxxxxxxxxxx]
On Behalf Of Bryce Martin
Sent: Friday, February 11, 2011 8:24 AM
To: RPG programming on the IBM i / System i
Subject: RE: More efficient way to write this SQL Statement???
Ok, so I don't quite get your 1) suggestion... I don't see how they are
equivalent. But #2 took that particular statement from 20 seconds down to
4. And that was on the first run of the morning. I'll keep working on
wrapping my head around your first suggestion. Thanks for the tip to use
EXISTS instead of IN.
Thanks
Bryce Martin
Programmer/Analyst I
570-546-4777
"Morgan, Paul" <Paul.Morgan@xxxxxxxxxxx>
Sent by: rpg400-l-bounces@xxxxxxxxxxxx
02/10/2011 05:21 PM
Please respond to
RPG programming on the IBM i / System i <rpg400-l@xxxxxxxxxxxx>
To
RPG programming on the IBM i / System i <rpg400-l@xxxxxxxxxxxx>
cc
Subject
RE: More efficient way to write this SQL Statement???
Martin,
1) Change all those case statements to OR conditions
( :CszESTCITY = '' or Cad3 = :cszESTCity ) etc.
2) use Exists instead of In
Where not Exists( Select *
from rcm
where ccust = tcust
and ....
Paul Morgan
Principal Programmer Analyst
IT Supply Chain/Replenishment
On Behalf Of Bryce Martin
Sent: Thursday, February 10, 2011 5:00 PM
To: RPG Midrange Discussion
Subject: More efficient way to write this SQL Statement???
I have a static sql statement I'm using in an SQLRPGLE program. It takes
about 20 seconds to execute and I need to make it faster if at all
possible...any suggestions will be greatly appreciated...
Here is the statement...
Exec SQL
Declare CSZEST1 Cursor For
Select Cast(tcust As Numeric(6,0)), tship, stadtp, tname,
tadr1,
tadr2, tadr3, tste, tpost, tphone
From est
Where tcust not in(Select ccust
From rcm
Where cad3 = (case when :cszESTCity <> ''
then :cszESTCity else
cad3 End)
and cste = (case when :cszESTState<>''
then :cszESTState else
cste End)
and czip = (case when :cszESTZip <> ''
then :cszESTZip else czip
End)
and cmid = 'CM')
and tadr3 = (case when :cszESTCity <> ''
then :cszESTCity else tadr3 End)
and tste = (case when :cszESTState <> ''
then :cszESTState else tste End)
and tpost = (case when :cszESTZip <> ''
then :cszESTZip else tpost End)
and tid = 'ST'
Order By tcust, tship, stadtp;
The data is structured as follows. There are 2 files, RCM and EST. RCM
is the customer master and EST is the address master for customers. So
the key from RCM to EST is CCUST = TCUST.
TSHIP and STADTP together with TCUST form a unique record. What happens
is the user can specify a City, State, and/or Zip. If they are not blank
I need to use them as inclusion criteria. What I want are any records in
EST that meet the City/State/Zip criteria where the master RCM record does
not.
I hope this is enough clear info.
Thanks
Bryce Martin
Programmer/Analyst I
570-546-4777
--- This message (including any attachments) is intended only for the use
of the individual or entity to which it is addressed and may contain
information that is non-public, proprietary, privileged, confidential, and
exempt from disclosure under applicable law. If you are not the intended
recipient, you are hereby notified that any use, dissemination,
distribution, or copying of this communication is strictly prohibited. If
you have received this communication in error, please notify us and
destroy this message immediately. ---
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.