× 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.



1. Move business logic into database, i.e. create views for each problem to solve and add the appropriate indexes. So complexity is NOT in the source code but in the view.
2. Variable WHERE conditions and ORDER BY clauses can easily be implemented with case clauses. In 98% of all SELECT statements it is enough.
Declare CsrC01 Cursor For
Select SalesYear, CustNo, CustName1, Amount
From SalesCustY
Where SalesYear = Case When :ParYear > 2000
Then :ParYear
Else SalesYear End
and CustNo = Case When Trim(:ParCustNo) <> ''
Then :ParCustNo
Else CustNo End
Order By Case When :ParSort in (1, 2)
Then SalesYear Else NULL End,
Case When :ParSort = 1
Then CustNo Else NULL End,
Case When :ParSort = 2
Then Amount Else NULL End Desc,
Case When :ParSort = 2
Then CustNo Else NULL End,
Case When :ParSort = 3
Then CustNo else NULL End,
Case When :ParSort = 3
Then SalesYear else NULL End
For Fetch Only;

I agree if the programmer / user can insert SELECT-Statements or filter criteria on the fly, there is no way than using embedded SQL.
But again I only use it if no other way, the risk of SQL injection may be huge.


Mit freundlichen Grüßen / Best regards

Birgitta Hauser

"Shoot for the moon, even if you miss, you'll land among the stars." (Les Brown)
"If you think education is expensive, try ignorance." (Derek Bok)
"What is worse than training your staff and losing them? Not training them and keeping them!"


-----Ursprüngliche Nachricht-----
Von: RPG400-L [mailto:rpg400-l-bounces@xxxxxxxxxxxx] Im Auftrag von Bradley Stone
Gesendet: Thursday, 26.2 2015 06:06
An: RPG programming on the IBM i (AS/400 and iSeries)
Betreff: Re: Using host variable in embedded sql

I use dynamic SQL whenever needed vs avoiding it. I'll take nanoseconds of run time vs logical complexity for embedded SQL.

When creating applications where the user input is used to create the SQL, dynamic SQL makes much more sense in cases where there are multiple selections, sorting options, etc.

Unless the options you present your users are simple enough to allow embedded SQL. Or you're using the SQL to verify data (ie, is a customer active... is an item number valid... etc).

But when you have a web/green screen that allows sorting and selecting using multiple criteria and sorting options, you'll be hard pressed to do that without dynamic SQL statments.

Case in point.. go here:
http://www.bvstools.com:5250/cgi-bin/cstlst

Selected "Detailed Search". Now, show me the code to do something like that without dynamic SQL.

There are cases for both, and the use for them should be obvious. I would think trying to use a host variable to house a variable CASE would be one of the perfect cases for dynamic SQL.

Brad
www,bvstools.com

On Wed, Feb 25, 2015 at 7:36 AM, Gary Thompson <gthompson@xxxxxxxxxxx>
wrote:

Birgitta,

Thank you for your detailed explanation.
To check my understanding of dynamic SQL; is it true that changing the
library of all tables is one case where an SQL PREPARE is appropriate ?

-----Original Message-----
From: RPG400-L [mailto:rpg400-l-bounces@xxxxxxxxxxxx] On Behalf Of
Birgitta Hauser
Sent: Tuesday, February 24, 2015 11:12 PM
To: 'RPG programming on the IBM i (AS/400 and iSeries)'
Subject: AW: Using host variable in embedded sql

I second the use of dynamic SQL...

I avoid dynamic SQL whenever possible.
... and in around 95% of all cases the request can be done with static SQL.
The only situation where dynamic SQL is really needed is, if the
tables, views or schemas cannot be determined before runtime.

Even though we talk about nanoseconds, dynamic SQL requires more work
at runtime (Syntax Check, building the access path).
And if you won't work with parameter markers, i.e. prepare once and
execute multiple times, each time the prepare statement is run a FULL
OPEN (which includes the most time consuming part of the query
execution, opening the data path) must be performed. That means the
cursor is not reusable.

When using static SQL the chance that the ODP (Open Data Path) is
reused is much higher, at least if you do not use compile Option/Set
Option CLOSQLCSR=*ENDMOD and do not run your SQL Statement in a
program compiled with activation group *NEW.

Mit freundlichen Grüßen / Best regards

Birgitta Hauser

"Shoot for the moon, even if you miss, you'll land among the stars."
(Les
Brown)
"If you think education is expensive, try ignorance." (Derek Bok)
"What is worse than training your staff and losing them? Not training
them and keeping them!"


-----Ursprüngliche Nachricht-----
Von: RPG400-L [mailto:rpg400-l-bounces@xxxxxxxxxxxx] Im Auftrag von
Bradley Stone
Gesendet: Tuesday, 24.2 2015 23:50
An: RPG programming on the IBM i (AS/400 and iSeries)
Betreff: Re: Using host variable in embedded sql

I second the use of dynamic SQL...

I use them all the time when the selection, sorting and/or anything
else isn't obvious and driven by user input.

Brad
www.bvstools.com

On Tue, Feb 24, 2015 at 4:36 PM, D*B <dieter.bender@xxxxxxxxxxxx> wrote:

... SQL is a striongly typed language => you can't put a fieldname
into a host variable, or into a parameter marker!!!
What would work is, to prepare a dynamic assembled string - with the
risc.
that it would blow up at preparetime - but mostly there are better
alternatives.

D*B
--
This is the RPG programming on the IBM i (AS/400 and iSeries)
(RPG400-L) mailing list To post a message email:
RPG400-L@xxxxxxxxxxxx To subscribe, unsubscribe, or change list
options,
visit: http://lists.midrange.com/mailman/listinfo/rpg400-l
or email: RPG400-L-request@xxxxxxxxxxxx Before posting, please take
a moment to review the archives at http://archive.midrange.com/rpg400-l.


--
This is the RPG programming on the IBM i (AS/400 and iSeries)
(RPG400-L) mailing list To post a message email: RPG400-L@xxxxxxxxxxxx
To subscribe, unsubscribe, or change list options,
visit: http://lists.midrange.com/mailman/listinfo/rpg400-l
or email: RPG400-L-request@xxxxxxxxxxxx Before posting, please take a
moment to review the archives at http://archive.midrange.com/rpg400-l.


--
This is the RPG programming on the IBM i (AS/400 and iSeries)
(RPG400-L) mailing list To post a message email: RPG400-L@xxxxxxxxxxxx
To subscribe, unsubscribe, or change list options,
visit: http://lists.midrange.com/mailman/listinfo/rpg400-l
or email: RPG400-L-request@xxxxxxxxxxxx Before posting, please take a
moment to review the archives at http://archive.midrange.com/rpg400-l.

--
This is the RPG programming on the IBM i (AS/400 and iSeries)
(RPG400-L) mailing list To post a message email: RPG400-L@xxxxxxxxxxxx
To subscribe, unsubscribe, or change list options,
visit: http://lists.midrange.com/mailman/listinfo/rpg400-l
or email: RPG400-L-request@xxxxxxxxxxxx Before posting, please take a
moment to review the archives at http://archive.midrange.com/rpg400-l.


--
This is the RPG programming on the IBM i (AS/400 and iSeries) (RPG400-L) mailing list To post a message email: RPG400-L@xxxxxxxxxxxx To subscribe, unsubscribe, or change list options,
visit: http://lists.midrange.com/mailman/listinfo/rpg400-l
or email: RPG400-L-request@xxxxxxxxxxxx
Before posting, please take a moment to review the archives at http://archive.midrange.com/rpg400-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.