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



Jeff,

You may be correct, but I thought your coalesce would take care of that.

To be honest, I always have to play around a little bit with these types
of statements to get what I want. <grin>

The one gotcha for these types of update statements is that you have to
account for no records being returned, ie. the subselect returns NULL.
If the field you are updating is not NULL capable, then you'll get an
error when you try and run the statement.

Again, from a quick look, I thought the way you had the coalesce would
take care of that.


Charles Wilt
--
iSeries Systems Administrator / Developer
Mitsubishi Electric Automotive America
ph: 513-573-4343
fax: 513-398-1121
  

-----Original Message-----
From: rpg400-l-bounces@xxxxxxxxxxxx 
[mailto:rpg400-l-bounces@xxxxxxxxxxxx] On Behalf Of Jeff Crosby
Sent: Monday, September 11, 2006 3:27 PM
To: 'RPG programming on the AS400 / iSeries'
Subject: RE: Embedded SQL update a field based on difference 
of totals in2otherfiles

Try this:

ActSQL = 'Update DMVDRMST z +
                 Set z.AMDUE = +
                 Coalesce((Select Sum(i.INVAM) - Sum(p.PAYAM) +
                           From DMVDRMST v +
                             Left Outer Join +
                           VAINVWK i On v.VNDNR = i.VNDNR +
                             Left Outer Join +
                           VAPAYWK p On v.VNDNR = p.VNDNR), +
                           Cast(0.00 as Decimal(7,2))) +
                           where z.vndnr = v.vndnr';

You have to tie a record from the updated file to the 
subselect.  I'm doing that here with the where z.vndnr = 
v.vndnr.  Note that I change to correlation name on the 
update file from v to z so not to confuse it with the 
DMVDRMST file in the subselect.

This would be a simpler form:
ActSQL = 'Update DMVDRMST v +
                 Set v.AMDUE = +
                 Coalesce((Select Sum(i.INVAM) - Sum(p.PAYAM) +
                           from VAINVWK i +
                             Left Outer Join +
                           VAPAYWK p On v.VNDNR = p.VNDNR), +
                           Cast(0.00 as Decimal(7,2)))
                           where v.VNDNR = i.VNDNR';

You shouldn't(?) need the DMVDRMST file in there twice.

Regarding the simpler one, what about the situation where there are no
transactions for a vendor?  AMDUE should be set to zero.  
Since there's no
"Left Outer Join" from DMVDRMST to anything, won't some records be
untouched?

-- 
Jeff Crosby
Dilgard Frozen Foods, Inc.
P.O. Box 13369
Ft. Wayne, IN 46868-3369
260-422-7531

The opinions expressed are my own and not necessarily the 
opinion of my
company.  Unless I say so.


-- 
This is the RPG programming on the AS400 / 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.