Hi Dave,

I think this would likely have worked in one pass...

update SOOSH01T U
set SOWFSTSTID =
( select W.SOWFSTSTID
from SOWFSTST W
inner join SOOSH00V03 S
on S.SOOSH01TID = U.SOOSH01TID
where ( W.WRKFLWCDE = 'DELIVERED' and
S.SHPSTSCDE = 'Closed' )
or ( W.WRKFLWCDE = 'WAREHOUSEREADY' and S.SHPSTSCDE <>
'Closed' )
)
where exists( select 1 from SOOSH00V03 S where S.SOOSH01TID = U.SOOSH01TID )

Notes:
1) With an OR condition in the mix, it may not run faster though.
2) Notice how SOWFSTST is not being joined to SOOSH00V03. That may seem
odd. Remember though, JOINs really only look for a true / false
condition. You don't always have to join the tables you might expect. You
can have a join condition of ON 1 = 1 if you want (comes in handy on LEFT
JOINs). In this case, the table being updated SOOSH01T "U" is being joined
to SOOSH00V03, which is valid to do.
3) The outer WHERE clause is an EXISTS instead of using IN, because you may
see better performance from EXISTS vs. IN.

Mike


date: Mon, 29 Jan 2018 17:31:27 -0500
from: dlclark@xxxxxxxxxxxxxxxx
subject: Combining SQL Updates

I have a curiosity question that hopefully might also teach me
more about SQL set-based processing. We added a foreign key to an
existing table. To initialize the new column, we ran the following two
updated statements. My question is whether there is a way to do this as a
single update set -- rather than processing the table twice?


Update SOOSH01T
Set SOWFSTSTID = (Select SOWFSTSTID from SOWFSTST
Where WRKFLWCDE = 'DELIVERED')
Where SOOSH01TID in (Select SOOSH01TID from SOOSH00V03
Where SHPSTSCDE = 'Closed');

Update SOOSH01T
Set SOWFSTSTID = (Select SOWFSTSTID from SOWFSTST
Where WRKFLWCDE = 'WAREHOUSEREADY')
Where SOOSH01TID in (Select SOOSH01TID from SOOSH00V03
Where SHPSTSCDE <> 'Closed');


Sincerely,

Dave Clark
--
int.ext: 91078
direct: (937) 531-6378
home: (937) 751-3300

Winsupply Group Services
3110 Kettering Boulevard
Dayton, Ohio 45439 USA
(937) 294-5331


As an Amazon Associate we earn from qualifying purchases.

This thread ...


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.