Joel,
I don't see a reply to your "join update" question, so here is my input:
DB2 supports an update with "correlated subqueries"
Here are examples from some of my junk:
Example 1:
UPDATE BASDBW1/OM06 as t01
SET t01.CALTYP = '2 '
where t01.outnum not in ( select t02.outnum
from basdbw1/om06 as t02
where t02.outnum = t01.outnum and
t02.caltyp = '2 ' and
t02.calidf = t01.calidf ) and
t01.calrte = '10 ' and
t01.caltyp = '3 '
Example 2:
UPDATE basdbc5/om01 tgt
SET natoutnum = ( SELECT natoutnum
FROM usrgdt850/om01 src
WHERE tgt.outnum = src.outnum)
WHERE outnum = ( SELECT outnum
FROM usrgdt850/om01 src2
WHERE tgt.outnum = src2.outnum )
The subqueries are the query statements within ()
The main idea is that between the "update query" and
the subquery(s), the SET must operate on a single row
at a time.
It is ok to update one or more rows in
the target table, but only one row can be updated at
a time.
One guideline I use is to start with a select to see
if the record set looks like what I expect to update.
The next guideline is to specify all required keys in
the WHERE clause of the subquery.
If you have more than one subquery, make sure the WHERE
clauses are identical, or nearly identical.
Hope this makes helps.
-----Original Message-----
From: midrange-l-bounces@xxxxxxxxxxxx [mailto:midrange-l-bounces@xxxxxxxxxxxx] On Behalf Of Stone, Joel
Sent: Friday, September 07, 2012 9:22 AM
To: 'Midrange Systems Technical Discussion'
Subject: RE: SQL numeric field: edit to an alpha field
Thanks
What works for an SQL update to ONE file with a join to get values from another file?
The SQL Iseries books I have discuss separately JOINs and UPDATEs, but never both.
Does a join with update have to use the EXISTS predicate?
Or can the JOIN keyword be used with UPDATE?
For example is there a way to make this work for a join update:
UPDATE fileA set A.field1 = B.field1 join fileB on A.cust = b.cust where cust-active = 'Y'
-----Original Message-----
From: midrange-l-bounces@xxxxxxxxxxxx [mailto:midrange-l-bounces@xxxxxxxxxxxx] On Behalf Of Birgitta Hauser
Sent: Friday, September 07, 2012 9:36 AM
To: 'Midrange Systems Technical Discussion'
Subject: AW: SQL numeric field: edit to an alpha field
With the scalar functions CHAR or VARCHAR the numeric fields are converted into characters with decimal point and sign and left adjusted.
If you need the content to be right adjusted you may use something like
this:
Update MyTable
Set MyField = Right(Space(10), VarChar(NumFld), 10);
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: midrange-l-bounces@xxxxxxxxxxxx
[mailto:midrange-l-bounces@xxxxxxxxxxxx] Im Auftrag von Stone, Joel
Gesendet: Friday, 07.9 2012 16:26
An: 'Midrange Systems Technical Discussion'
Betreff: SQL numeric field: edit to an alpha field
Can I use UPDATE in SQL with a JOIN to populate an alpha field in fileA with a numeric field from fileB and have it edited to drop in a decimal point and sign?
Thanks
______________________________________________________________________
This outbound email has been scanned for all viruses by the MessageLabs Skyscan service.
For more information please visit
http://www.symanteccloud.com ______________________________________________________________________
--
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.
________________________________________________________________________
This inbound email has been scanned for all viruses by the MessageLabs SkyScan
service.
________________________________________________________________________
______________________________________________________________________
This outbound email has been scanned for all viruses by the MessageLabs Skyscan service.
For more information please visit
http://www.symanteccloud.com
______________________________________________________________________
As an Amazon Associate we earn from qualifying purchases.