|
Jeff, 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. HTH, 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 2:59 PM To: 'RPG programming on the AS400 / iSeries' Subject: Embedded SQL update a field based on difference of totals in 2 otherfiles All, I hope I'm not overstaying my welcome with too many SQL questions, but I'm really learning a lot from it, and I can't seem to find any examples that fit this scenario. Or else I'm just not hitting on the right search terms. Or else you'll tell me I'm making it much harder than it needs to be. We want to print a trial balance report "as of" a date in time. To do this, I created QTEMP work files: the vendor master file and the 2 related transaction files (open invoices and unmatched payments). Then I programmatically determined, based on dates, which transactions were "open" at that time, and inserted them into the QTEMP transaction files. Now I want to set the QTEMP vendor master file field AMDUE (amount due) to be the net of those transactions, by vendor. Here's what I tried: ActSQL = 'Update DMVDRMST v + Set v.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)))'; Exec SQL Execute Immediate :ActSQL; Don't laugh if this is really bad SQL <g>. I dumped the program afterward. Variable ActSQL has what I expect in it, and SQLSTT is 01504 (UPDATE or DELETE does not contain a WHERE clause). But AMDUE in the master has 70,662.30 dollars in _every_ record of the master. This 70,662.30 figure is the net of _all_ transactions for _all_ vendors. Am I heading the right direction? Thanks. -- 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 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.