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



thanks Charles. I try to stay away from code with a lot of quoted strings.
What I ended up doing was creating a table in qtemp with a single row
containing all the selection variables.

// create a table containing the date range of the report.
exec sql
create table qtemp/FgDateRange (
key char(1),
fromDate date,
toDate date ) ;

exec sql
insert into qtemp/FgDateRange
values( '1', date(:FromDate), date(:ToDate)) ;

then, join to that selection row in the step where I extract from the large
file:

// build table containing number of shpnum per fg pallet id.
exec sql
create table qtemp/fgShpnum as (
with t1 as (
select distinct a.finpalid, a.shpnum
from dshpf05 a
join qtemp/fgDateRange b
on b.key = '1'
where date(a.assemts) between date(b.fromdate)
and date(b.todate)
and a.finpalid <> ' ' )
select a.finpalid, decimal(count(*),7,0) NbrShpnum
from t1 a
group by a.finpalid )
with data ;

-Steve






On Tue, Dec 11, 2012 at 10:12 PM, Charles Wilt <charles.wilt@xxxxxxxxx>wrote:

do it as a dynamic SQL

wSql = 'create table qtemp/fgShpnum as ('
+ ' with t1 as ('
+ ' select distinct a.finpalid, a.shpnum'
+ ' from dshpf05 a'
+ ' where date(a.assemts)'
+ ' between date(' + fromdate + ') and'
+ ' date(' + todate + '))'
+ ' select a.finpalid, decimal(count(*),7,0) NbrShpnum'
+ ' from t1 a'
+ ' group by a.finpalid )'
+ ' with data ';
exec sql
execute immediate :wSql;

Charles


On Tue, Dec 11, 2012 at 6:20 PM, Steve Richter <stephenrichter@xxxxxxxxx
wrote:

the following RPGSQL is not allowed at V5R4. Is it allowed in a newer
release?

Would like to use "create table as" to create an extract table, pulling a
few rows from a large table. Then later on in the code I do a bunch of
counts, sums and joins against the smaller extract file.

I do not follow why a host variable is not allowed in this situation.

exec sql
create table qtemp/fgShpnum as (
with t1 as (
select distinct a.finpalid, a.shpnum
from dshpf05 a
where date(a.assemts) between date(:fromdate) and
date(:todate))
select a.finpalid, decimal(count(*),7,0) NbrShpnum
from t1 a
group by a.finpalid )
with data ;
--
This is the Midrange Systems Technical Discussion (MIDRANGE-L) mailing
list
To post a message email: MIDRANGE-L@xxxxxxxxxxxx
To subscribe, unsubscribe, or change list options,
visit: http://lists.midrange.com/mailman/listinfo/midrange-l
or email: MIDRANGE-L-request@xxxxxxxxxxxx
Before posting, please take a moment to review the archives
at http://archive.midrange.com/midrange-l.


--
This is the Midrange Systems Technical Discussion (MIDRANGE-L) mailing list
To post a message email: MIDRANGE-L@xxxxxxxxxxxx
To subscribe, unsubscribe, or change list options,
visit: http://lists.midrange.com/mailman/listinfo/midrange-l
or email: MIDRANGE-L-request@xxxxxxxxxxxx
Before posting, please take a moment to review the archives
at http://archive.midrange.com/midrange-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.