|
After (IF?) you get past the outlying syntax problem (CTE and UPDATE
apparently remaining incompatible), you'll arrive at another syntax error.
UPDATE TABLE
SET COL1 = VAL1, COL2 = VAL2
WHERE...
Note that SET only appears in the statement once.
You could convert your CTE into a CREATE TABLE. Then your update steps
might look something like:
Create table qtemp/mydata as
(Select SUVNDA, SUMDL, Sum(SUTSLS) As MySls
,sum(suunit) as myunit
From SUMSLSP
Where SUDATE Between 20120601 and 20120901
and SUSTNO = 999 And SUTYPE = 'D'
group by suvnda, sumdl) with data
UPDATE WCSRTL/WCStmpP
SET tcsls =
(SELECT mysls
FROM QTEMP/MYDATA
WHERE SUVNDA = wcstmpp.TCVNDA
AND SUMDL = wcstmpp.TTCMDL)
, tcunit=
(SELECT myunit
FROM QTEMP/MYDATA
WHERE SUVNDA = wcstmpp.TCVNDA
AND SUMDL = wcstmpp.TTCMDL)
WHERE EXISTS
(SELECT 1
FROM QTEMP/MYDATA
WHERE SUVNDA = wcstmpp.TCVNDA
AND SUMDL = wcstmpp.TTCMDL)
The last WHERE clause is necessary in case there are rows of WCSTMPP that
are not represented in MYDATA. (Otherwise, for unmatched rows, you'll end
up setting MYSLS and MYUNIT to NULL --danger, Will Robinson!-- or, if those
columns are defined as NOT NULL, then you will get an exception for the
situation.)
This will not run as poorly as you might think, due to SQL optimization.
Dennis Lovelady
http://www.linkedin.com/in/dennislovelady
--
"Get your facts first, and then you can distort them as much as you please."
-- Mark Twain
That was probably a copy and paste error. I needed to add a group by
clause to the select statement, but I'm still getting the error on the
update:
with mydata as
(Select SUVNDA, SUMDL, Sum(SUTSLS) As MySls,sum(suunit) as myunit
From SUMSLSP Where SUDATE Between 20120601 and 20120901 and SUSTNO =999 And SUTYPE = 'D' group by suvnda, sumdl) update WCSRTL/WCStmpP set
tcsls=mysls,set tcunit=myunit where wcstmp p.TCVNDA = suvnda and
wcstmpp.TCMDL = sumdl
Keyword UPDATE not expected. Valid tokens: ( SELECT VALUES.
On Wed, Oct 3, 2012 at 1:44 PM, Gary Thompson <gthompson@xxxxxxxxxxx>
wrote:
Does the mydata select statement run in strsql?wrote:
what is the ">" character I see below "(Select SUVNDA"
-----Original Message-----
From: midrange-l-bounces@xxxxxxxxxxxx
[mailto:midrange-l-bounces@xxxxxxxxxxxx] On Behalf Of Michael Ryan
Sent: Wednesday, October 03, 2012 11:38 AM
To: Midrange Systems Technical Discussion
Subject: Re: Insert with Temp Table
So now it's barking at the UPDATE:
with mydata as
(Select SUVNDA, SUMDL, Sum(SUTSLS) As MySls,sum(suunit) as myunit
From SUMSLSP Where SUDATE Between 20120601 and 20120901 and SUSTNO =999 And SUTYPE = 'D')
update WCSRTL/WCStmpP set tcsls=mysls,set tcunit=myunit where wcstmp
p.TCVNDA = suvnda and wcstmpp.TCMDL = sumdl
Keyword UPDATE not expected. Valid tokens: ( SELECT VALUES.
Closer I think.
On Wed, Oct 3, 2012 at 1:30 PM, Gary Thompson <gthompson@xxxxxxxxxxx>
nice, I think.Luis, yes, seems to happen on this list with some regularity - kinda
advance.And Joe's comment about V5R4 indicates this is a fairly recent
ago!Thank you to the DB2 and i teams!
we happen to be V7R1.
-----Original Message-----
From: midrange-l-bounces@xxxxxxxxxxxx
[mailto:midrange-l-bounces@xxxxxxxxxxxx] On Behalf Of Luis Rodriguez
Sent: Wednesday, October 03, 2012 11:14 AM
To: Midrange Systems Technical Discussion
Subject: Re: Insert with Temp Table
Gary,
We (midrange.com) had a thread about this almost exactly two years
<gthompson@xxxxxxxxxxx>wrote:(Talk about coincidences!! :-) )
Check the following thread:
http://archive.midrange.com/midrange-l/201002/msg00593.html
Regards,
Luis Rodriguez
IBM Certified Systems Expert - eServer i5 iSeries
--
On Wed, Oct 3, 2012 at 12:34 PM, Gary Thompson
will
Michael,
I just noticed the "WITH", so, I >think< you can do and update with
a CTE, but Luis is always some steps ahead of me, >but< I think I
recently did this and will look for my code.
Meantime, rewrite to pace the WITH before the update and refer to
the mydata table in the update clause which, after the rewrite,
tcunit=myunit . . ."be
after< the WITH.
-----Original Message-----
From: midrange-l-bounces@xxxxxxxxxxxx [mailto:
midrange-l-bounces@xxxxxxxxxxxx] On Behalf Of Michael Ryan
Sent: Wednesday, October 03, 2012 10:59 AM
To: Midrange Systems Technical Discussion
Subject: Re: Insert with Temp Table
Thanks Gary...that didn't seem to work.
On Wed, Oct 3, 2012 at 12:53 PM, Gary Thompson
<gthompson@xxxxxxxxxxx>
wrote:
Michael, maybe you meant " set tcsls=mysls, SET
Ryan
-----Original Message-----
From: midrange-l-bounces@xxxxxxxxxxxx
[mailto:midrange-l-bounces@xxxxxxxxxxxx] On Behalf Of Michael
URSent: Wednesday, October 03, 2012 10:49 AMgetting this:
To: Midrange Systems Technical Discussion
Subject: Insert with Temp Table
Anyone see why this makes STRSQL spit up?
update WCSRTL/WCStmpP set tcsls=mysls, tcunit=myunit with mydata
as (Select SUVNDA, SUMDL, Sum(SUTSLS) As MySls,sum(suunit) as
myunit
From SUMSLSP Where SUDATE Between 20120601 and 20120901 SUSTNO =999 And SUTYPE = 'D') Select SUVNDA, SUMDL, MyCount From MyData
I'm doing the same type of thing with an Insert and it works fine.
I'm
Token MYDATA was not valid. Valid tokens: ALL CS CHG NONE RR RS
http://archive.midrange.com/midrange-l.Nmoment to review the archives at
with the cursor at the "with mydata as" area.
Thanks!
--
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
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.
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
take a moment to review the archives at--
--
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
http://archive.midrange.com/midrange-l.
take
--
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
mailinga moment to review the archives at--
http://archive.midrange.com/midrange-l.
This is the Midrange Systems Technical Discussion (MIDRANGE-L)
list To post a message email: MIDRANGE-L@xxxxxxxxxxxx To subscribe,a moment to review the archives at
unsubscribe, or change list options,
visit: http://lists.midrange.com/mailman/listinfo/midrange-l
or email: MIDRANGE-L-request@xxxxxxxxxxxx Before posting, please take
http://archive.midrange.com/midrange-l.
mailing
--
This is the Midrange Systems Technical Discussion (MIDRANGE-L)
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.
--
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 mailing list archive is Copyright 1997-2025 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.