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



Brigitta (or Chuck, Simon, ect. al),

Regarding the use of static SQL vs. dynamic, in particular when the
static SQL makes use of elements such as

Where Fld1 = Case When :EnterFld1 <> 0
then :EnterFld1 else Fld1
And Fld7 = Case When :EnterFld7 <> ' ' or :EnterFld7 is not
NULL Then :EnterFld7 Else Fld7 End,
And Fld8 = Case When :EnterFld8 between '0001-01-02' and
'9999-12-31' then :EnterFld8 else Fld8 End

I ran across an interesting article concerning the way MS SQL Server
handles such things...
http://www.sqlservercentral.com/articles/Dynamic+SQL/70109/

From the article:
"All columns on the table are defined to be NOT NULL and the passing
in of a parameter with a NULL value logically means that we don't care
what the value is. You might think that SQL Server would short-circuit
the query when it sees that the parameter is null and not bother to
look at the values on the table but it actually does a full table scan
instead."

"When SQL Server evaluates this query it does not work out in advance
that the parameter passed in is NULL and so ignore trying to match the
value to the column, instead it still tries to match the value to the
column, the query ends up doing a full table scan even if there is an
index on the column. If run on a table with many millions of rows will
run very slowly. A way to speed this up is to use Dynamic SQL, that is
generate the SQL statement within the stored procedure and then
execute it."

I believe DB2 on the i is smart enough to short circuit the query, but
haven't had a chance to test it out myself...

I'm wondering if anybody has or has enough knowledge of the internals
to say with authority that static SQL DB2 on the i is always better
than dynamic.

Charles Wilt

On Wed, May 26, 2010 at 1:01 AM, Birgitta Hauser <Hauser@xxxxxxxxxxxxxxx> wrote:
If you want to do an Select ... into dynamically, why not using something like this?

 /Free
  String = 'Values(Select count(*) from Item) into ?';
  //Or
  String = 'Values(' + MySelectStmt + ') into ?';

  /Exec SQL Prepare DynSQL from  :String;
  /Exec SQL Execute DynSQL using :MyResult;

 /End-Free

In either way I'd use static SQL whenever possible. With static SQL an access plan gets stored into the (service-)program object, that can be validated at runtime. With dynamic SQL the string must be converted into an executable SQL statement at runtime, an access plan must be created by scratch (if not stored in the SQL plan cache or already in the job's cache), additional steps at runtime that are not necessary for static SQL.

For multiple selections you may also use:

... Select Fld1, Fld2, .... FldN
     From MyTables ...
     Where     Fld1 = Case When :EnterFld1 <> 0                                  then :EnterFld1 else Fld1
           And Fld7 = Case When :EnterFld7 <> ' ' or :EnterFld7 is not NULL      Then :EnterFld7 Else Fld7 End,
           And Fld8 = Case When :EnterFld8 between '0001-01-02' and '9999-12-31' then :EnterFld8 else Fld8 End
           ...

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-bounces@xxxxxxxxxxxx [mailto:rpg400-l-bounces@xxxxxxxxxxxx] Im Auftrag von dmosley@xxxxxxxxxx
Gesendet: Tuesday, 25. May 2010 16:10
An: RPG programming on the IBM i / System i
Cc: RPG programming on the IBM i / System i; rpg400-l-bounces@xxxxxxxxxxxx
Betreff: Re: Quick SQL expression evaluation

That's an interesting trick.  I would have hoped that some like using
"SELECT COUNT(*) INTO ? FROM ITEM" would work the same.

 /Free
   String = 'SELECT COUNT(*) INTO ? FROM ITEM';
   /Exec SQL Prepare DynSQL From  :String;
   /Exec SQL Execute DynSQL using :MyResult;
  Dsply MyResult;
 /End-Free


David L. Mosley, Jr.
Technical Solutions Architect
Dancik International, Ltd.
2000 CentreGreen Way, Suite 250
Cary, NC 27513

www.dancik.com



Luis Rodriguez <luisro58@xxxxxxxxx>
Sent by: rpg400-l-bounces@xxxxxxxxxxxx
05/25/2010 05:04 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: Quick SQL expression evaluation






Wow!! Thanks Birgitta!! ..

One can always trust that you will find the solution to almost any SQL
problem, this one will go into the archives.


Best Regards,

Luis Rodriguez
IBM Certified Systems Expert — eServer i5 iSeries


On Tue, May 25, 2010 at 8:21 AM, Birgitta Hauser
<Hauser@xxxxxxxxxxxxxxx>wrote:

Try the following:

D MyResult     S           11P 2
D String       S          256A     Varying
D Expr         S          256A     Varying inz('2 + 2')
 /Free
   String = 'Values(' + Expr + ') into ?';
   /Exec SQL Prepare DynSQL From  :String;
   /Exec SQL Execute DynSQL using :MyResult;
  Dsply MyResult;
 /End-Free




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-bounces@xxxxxxxxxxxx
[mailto:rpg400-l-bounces@xxxxxxxxxxxx]
Im
Auftrag von Dennis Lovelady
Gesendet: Tuesday, 25. May 2010 14:30
An: 'RPG programming on the IBM i / System i'
Betreff: Quick SQL expression evaluation

I am trying to write a procedure I thought would be extremely simple: a
short SQL evaluation program that would simply take an expression and
return
the result of SQL operating on that expression.  For a silly example:

Exec sql set :myResult   = 2 + 2 ;



To minimize complexity, I am passing the '2 + 2' part as a string, so
that
the meat of this very short procedure is:

Exec sql setl :myResult = :myExpression ;



But (and, yes, I know I should have expected this) SQL is seeing it as
the
string "2 + 2" rather than a pair of values with an operator between
them.
Is there an SQL verb/clause that informs the SQL processor that the
following is an expression rather than a string (such as with unix'
"expr"
command)?  Or is this just a pipe dream, not worth the effort?



Dennis E. Lovelady
AIM/Skype: delovelady      MSN: fastcounter@xxxxxxxxxxxx
 <http://www.linkedin.com/in/dennislovelady>
www.linkedin.com/in/dennislovelady --
You can't have everything.  Where would you put it?



--
This is the RPG programming on the IBM i / System i (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 / System i (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 / System i (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 / System i (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 / System i (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.