|
Standard SQL Update Join syntax is really funky. Microsoft has some
non-standard but elegant and intuitive SQL syntax.
IBM sticks with standards so we have to as well :)
On the good note, following standards ensures your code is portable so I'm
not going to complain.
That particular subselect is doing your join between r1 & r2 and I'm using
EXISTS in the main WHERE clause to make sure only rows where there was a
match found for r1 are updated. You're not using any of the fields from r2
in the actual update (SET) part, so I chose to project a literal from the
inner join subselect.
Something HAS to be projected from the SELECT and literal 1 is as good as
anything else. I suppose you could use 'MATCH' or 'FOUND' literals to
illustrate this intention more clearly.
When there's no match found you'll get a NULL value projected out of
subselect and anything compared with NULL will evaluate to False (even NULL
against NULL evaluates to False).
Hope I didn't confuse the issue even further with this :)
Elvis
-----Original Message-----
Subject: [SPAM] RE: SQL - Updates with joins
Elvis, what does this 1 represent?
EXISTS (SELECT 1
-----Original Message-----
Subject: RE: SQL - Updates with joins
Joined file SQL view is likely to be read-only, hence it would not
updateable.
John needs to review UPDATE syntax a bit as there is no FROM in the base
UPDATE syntax (there is in subselects, which are often used in UPDATEs for
join purposes).
I'll give it a go for your UPDATE statement, but make sure you test it first
John:
UPDATE rugd80dat.asbacpp r1
SET bai1tx = 'N', bai2tx = 'N'
WHERE (r1.baartx = 'APV' or r1.baartx = 'MPV' or r1.baartx = 'SPV' or
r1.baartx = 'EPV')
AND r1.bai1tx = ' ' and r1.bai2tx = ' ' AND
EXISTS (SELECT 1 FROM rugd80dat.pmsp0200 r2
WHERE r1.baartx = r2.symbol and r1.baastx = r2.policy0num and r1.baadnb =
r2.module AND r2.trans0stat = 'V' and r2.renewal0cd = '1')
Elvis
-----Original Message-----
Subject: Re: SQL - Updates with joins
I've never seen an update statement with a FROM clause or a JOIN for that
matter. I suggest creating a view that combines the two files and then
run the update over the new view.
Michael Schutte
Work 614-492-7419
email michael_schutte@xxxxxxxxxxxx
"John Candidi"
<jacandidi@rutger
sinsurance.com> To
Sent by: <midrange-l@xxxxxxxxxxxx>
midrange-l-bounce cc
s@xxxxxxxxxxxx
Subject
SQL - Updates with joins
04/03/2006 02:18
PM
Please respond to
Midrange Systems
Technical
Discussion
<midrange-l@midra
nge.com>
I am having a problem generating the correct SQL script run in iSeries
Navigator.
This is what I have so far:
Update rugd80dat.asbacpp
set bai1tx = 'N', bai2tx = 'N'
from rugd80dat.asbacpp r1,rugd80dat.pmsp0200 r2
where (r1.baartx = r2.symbol and r1.baastx = r2.policy0num and r1.baadnb =
r2.module)
and (r1.baartx = 'APV' or r1.
baartx = 'MPV' or r1.baartx = 'SPV' or r1.baartx = 'EPV')
and (r1.bai1tx = ' ' and r1.bai2tx = ' ')
and (r2.trans0stat = 'V' and r2.renewal0cd = '1')
When run as a select statement, it returns the correct rows. When changed
to do the actual update, it reports an unexpected 'from'. Any
recommendations? I tried with a 'where exists' with a select subquery, but
it ended up hitting all the rows in the asbacpp table, not just the handful
in the query result.
John A Candidi
Rutgers Insurance Companies
IT Director - AS/400 Manager
856-779-2274
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.