SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Update for multiple conditions


Update for multiple conditions

Author
Message
Sangeeth878787
Sangeeth878787
SSCrazy
SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)SSCrazy (2.8K reputation)

Group: General Forum Members
Points: 2835 Visits: 395
Hi,

In order to remove duplicates, I am using Flag column to specify whether row is active or not in Dimension Table

Ex

StagingTable
TempKey SLNNumber
356 45657
123 45657

Dimension Table
Key SLNNumber Row_is_Active
356 45657 Yes
123 'Unknown' No


I have to update Dimension table by using temp keys from StagingTable and Keys from Dimension table.I have to update only row where SLNNumber is Unknown.

I could write update statement like

update dimensiontable set Row_is_Active = 'No'
from StagingTable ST
where dimensiontable.key = ST.key and dimensiontable.SLNNumber = 'Unknown'

The above update statement will update when there is SLNnumber is unknown, but I am looking to update [Row_is_Active = 'No'] even if the SLN Number <> 'Unknown' when I receive only one row from StagingTable.


StagingTable
TempKey SLNNumber
222 99221

Dimension Table
Key SLNNumber Row_is_Active
222 99221 No (Need to update this column to 'No' though SLNnumber is not Unknown because I have received only one row from stagingtable).

Summary
StagingTable 1Row StraightUpdate in Dimension table
StagingTable 1+Rows, update only one value which has 'Unknown' SLN Number.


I am sure the above update sql statement wont satisfy my condition, could any help me how to handle this scenario


Many Thanks
John Mitchell-245523
John Mitchell-245523
SSC Guru
SSC Guru (133K reputation)SSC Guru (133K reputation)SSC Guru (133K reputation)SSC Guru (133K reputation)SSC Guru (133K reputation)SSC Guru (133K reputation)SSC Guru (133K reputation)SSC Guru (133K reputation)

Group: General Forum Members
Points: 133354 Visits: 19370
No consumable DDL or sample data supplied, so I couldn't test, but this should work after any necessary tweaking.

WITH KeysandCounts AS (
SELECT
TempKey
, MAX(SLNNumber) AS SLNNumber
, COUNT(*) AS NoofRows
FROM StagingTable
GROUP BY TempKey
)
UPDATE d
SET Row_is_Active = 'No'
FROM DimensionTable d
JOIN KeysandCounts k
ON k.TempKey = d.Key
AND (k.NoofRows = 1 OR d.SLNNumber = 'Unknown')


John
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum








































































































































































SQLServerCentral


Search