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


Updaing using ROW_NUMBER()


Updaing using ROW_NUMBER()

Author
Message
SALIM ALI
SALIM ALI
Old Hand
Old Hand (394 reputation)Old Hand (394 reputation)Old Hand (394 reputation)Old Hand (394 reputation)Old Hand (394 reputation)Old Hand (394 reputation)Old Hand (394 reputation)Old Hand (394 reputation)

Group: General Forum Members
Points: 394 Visits: 248
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)



Eugene Elutin
Eugene Elutin
SSCarpal Tunnel
SSCarpal Tunnel (5K reputation)SSCarpal Tunnel (5K reputation)SSCarpal Tunnel (5K reputation)SSCarpal Tunnel (5K reputation)SSCarpal Tunnel (5K reputation)SSCarpal Tunnel (5K reputation)SSCarpal Tunnel (5K reputation)SSCarpal Tunnel (5K reputation)

Group: General Forum Members
Points: 4964 Visits: 5478
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!":-D
(So many miracle inventions provided by MS to us...)

How to post your question to get the best and quick help
SALIM ALI
SALIM ALI
Old Hand
Old Hand (394 reputation)Old Hand (394 reputation)Old Hand (394 reputation)Old Hand (394 reputation)Old Hand (394 reputation)Old Hand (394 reputation)Old Hand (394 reputation)Old Hand (394 reputation)

Group: General Forum Members
Points: 394 Visits: 248
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.



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