Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

Updaing using ROW_NUMBER() Expand / Collapse
Author
Message
Posted Monday, March 11, 2013 9:18 AM


Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Tuesday, July 15, 2014 3:22 PM
Points: 352, Visits: 173
Let's just say I have a table with columns ID and Name that looks like:

ID Name
01
02
03 Bill
04
05
06
07
08
09 Ted
10
11
12


I want to update rows 1-2 & 4-6 with the Name Bill
and 7-8 & 10-12 with the Name Ted.

the update will always be an update to two prior and three subsequent rows where there is a non-null entry in column [Name]

This is easy enough to do in an RBAR fashion but not efficient but I'm not interested in that.
How could I achieve this using ROW_NUMBER()

Thank you in advance

Sal.

(Updaning??? must be a new command, meant updating, sorry)



Post #1429339
Posted Monday, March 11, 2013 9:48 AM
SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Today @ 9:42 AM
Points: 2,856, Visits: 5,125
You don't need ROW_NUMBER here:


declare @table table (ID int, Name varchar(100))
insert @table select 1,null
insert @table select 2,null
insert @table select 3,'Bill'
insert @table select 4,null
insert @table select 5,null
insert @table select 6,null
insert @table select 7,null
insert @table select 8,null
insert @table select 9,'Ted'
insert @table select 10,null
insert @table select 11,null
insert @table select 12,null


UPDATE u
SET u.Name = n.Name
FROM @table u
CROSS APPLY(SELECT TOP 1 t.Name FROM @table t
WHERE t.Name IS NOT NULL
AND ( t.ID - u.ID between 1 AND 2
OR u.ID - t.ID between 1 AND 3)) n
WHERE u.Name IS NULL

SELECT * FROM @table



Please refer to the link at the bottom of my signature. The article provides tips about how to post your question on this forum in order to get most relevant and prompt help.


_____________________________________________
"The only true wisdom is in knowing you know nothing"
"O skol'ko nam otkrytiy chudnyh prevnosit microsofta duh!"
(So many miracle inventions provided by MS to us...)

How to post your question to get the best and quick help
Post #1429356
Posted Monday, March 11, 2013 10:17 AM


Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Tuesday, July 15, 2014 3:22 PM
Points: 352, Visits: 173
Thank you for the quick response. The example you provided works great. So I've tweaked it to update my test table which has about 2.5million rows. It's been running for 10 minutes and counting. The estimated execution plan looked ok and it was making use of available indexes. I'll post up the results when it completes.




Post #1429374
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse