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


SET ROWCOUNT usage with DELETE..


SET ROWCOUNT usage with DELETE..

Author
Message
LeelaKrishna
LeelaKrishna
Valued Member
Valued Member (58 reputation)Valued Member (58 reputation)Valued Member (58 reputation)Valued Member (58 reputation)Valued Member (58 reputation)Valued Member (58 reputation)Valued Member (58 reputation)Valued Member (58 reputation)

Group: General Forum Members
Points: 58 Visits: 12
Hi SQLers,
Iam Leela a fellow SQL user :-)

I am facing a typical problem in my STORED PROCEDURE..

In one of stored procedures written ages back which uses SET ROWCOUNT to limit rows effected by DELETE operation after that.. Rows from BOTTOM (Old rows) are getting deleted on one MS SQL 2005 Installation BUT on another MS SQL 2005 installation TOP (latest rows) are getting deleted.. I don't have any clue of what might be cause..

As per my understanding OLD ROWS would be deleted first..

Any clues on which might be going wrong.. how can i assure that OLD rows are deleted always..

Note: I checked that MS might drop support for SET ROWCOUNT in future release of MS SQL, but i am trying to figure out the problem with current scenario..

Thanks a lot for ur help..

Regards,
Leela
Lowell
Lowell
SSC Guru
SSC Guru (72K reputation)SSC Guru (72K reputation)SSC Guru (72K reputation)SSC Guru (72K reputation)SSC Guru (72K reputation)SSC Guru (72K reputation)SSC Guru (72K reputation)SSC Guru (72K reputation)

Group: General Forum Members
Points: 72268 Visits: 40942
the top and bottom rows are determined by their order....I'm betting your procedure does not have an ORDER BY clause.
with out that, SQL server does not guarantee the order or the data ; without an order by clause, the execution plan tries to return the data in the fastest way possible, based on the primary key of the table usually, but sometimes it has to do with how it was able to access the pages due to the WHERE clause or any joins.

in your case, it sounds like it is easiest for the execution plan to get the data in the order the data was created in descending order on one machine, and in ascending order on the other.

I think you need to explicitly add a ORDER BY clause to resolve.

Lowell
--help us help you! If you post a question, make sure you include a CREATE TABLE... statement and INSERT INTO... statement into that table to give the volunteers here representative data. with your description of the problem, we can provide a tested, verifiable solution to your question! asking the question the right way gets you a tested answer the fastest way possible!
Steve Jones
Steve Jones
SSC Guru
SSC Guru (147K reputation)SSC Guru (147K reputation)SSC Guru (147K reputation)SSC Guru (147K reputation)SSC Guru (147K reputation)SSC Guru (147K reputation)SSC Guru (147K reputation)SSC Guru (147K reputation)

Group: Administrators
Points: 147129 Visits: 19434
I think Lowell has the answer. Without an ORDER BY, you can NEVER be sure which rows will be returned or deleted (or updated), but a TOP or SET ROWCOUNT clause.

Follow me on Twitter: @way0utwest
Forum Etiquette: How to post data/code on a forum to get the best help
My Blog: www.voiceofthedba.com
LeelaKrishna
LeelaKrishna
Valued Member
Valued Member (58 reputation)Valued Member (58 reputation)Valued Member (58 reputation)Valued Member (58 reputation)Valued Member (58 reputation)Valued Member (58 reputation)Valued Member (58 reputation)Valued Member (58 reputation)

Group: General Forum Members
Points: 58 Visits: 12
Thanks Lowell and Steve for your reply..

I will try putting ORDER BY clause and check the behaviour..

Regards,
Leela
GilaMonster
GilaMonster
SSC Guru
SSC Guru (225K reputation)SSC Guru (225K reputation)SSC Guru (225K reputation)SSC Guru (225K reputation)SSC Guru (225K reputation)SSC Guru (225K reputation)SSC Guru (225K reputation)SSC Guru (225K reputation)

Group: General Forum Members
Points: 225805 Visits: 46321
LeelaKrishna (7/11/2009)
In one of stored procedures written ages back which uses SET ROWCOUNT to limit rows effected by DELETE operation after that.. Rows from BOTTOM (Old rows) are getting deleted on one MS SQL 2005 Installation BUT on another MS SQL 2005 installation TOP (latest rows) are getting deleted.. I don't have any clue of what might be cause..


Tables, by definition, have no order. So if you set RowCount to 200 and issue a delete statement, you're telling SQL to delete 200 rows that meet the conditions in the where clause. You've not saying anything about which 200 rows, that's completely up to SQL.

If you want to delete the oldest rows, then you need something like this (because order by is not permitted in a delete statement)

DELETE FROM SomeTable WHERE PrimaryKeyColumn IN (SELECT TOP (200) PrimaryKeycolumn FROM SomeTable ORDER BY SomeDate)



Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

We walk in the dark places no others will enter
We stand on the bridge and no one may pass


Jeffrey Williams 3188
Jeffrey Williams 3188
SSCoach
SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)SSCoach (19K reputation)

Group: General Forum Members
Points: 19299 Visits: 10042
GilaMonster (7/12/2009)
If you want to delete the oldest rows, then you need something like this (because order by is not permitted in a delete statement)

DELETE FROM SomeTable WHERE PrimaryKeyColumn IN (SELECT TOP (200) PrimaryKeycolumn FROM SomeTable ORDER BY SomeDate)



Or, you identify the oldest rows by your date column instead of order:


DELETE TOP (200)
FROM SomeTable
WHERE datecolumn <= {some date limiter};



I don't think anyone has mentioned this, but the reason you would use TOP or ROWCOUNT would be to limit the transaction. This is to prevent the log file from filling up and give SQL Server a chance to truncate the log or back it up. In most cases, you would see either a checkpoint or an explicit backup log after that statement - with the whole thing in a while loop.


WHILE @rowcount > 0
BEGIN
DELETE TOP (200)
FROM SomeTable
WHERE datecolumn <= {some date limiter};

SET @rowcount = @@rowcount;

-- CHECKPOINT --database is in simple recovery model
BACKUP LOG {database} TO DISK = '{backup location & file}';
END;



Jeffrey Williams
Problems are opportunities brilliantly disguised as insurmountable obstacles.

How to post questions to get better answers faster
Managing Transaction Logs

GilaMonster
GilaMonster
SSC Guru
SSC Guru (225K reputation)SSC Guru (225K reputation)SSC Guru (225K reputation)SSC Guru (225K reputation)SSC Guru (225K reputation)SSC Guru (225K reputation)SSC Guru (225K reputation)SSC Guru (225K reputation)

Group: General Forum Members
Points: 225805 Visits: 46321
Jeffrey Williams (7/12/2009)
GilaMonster (7/12/2009)
If you want to delete the oldest rows, then you need something like this (because order by is not permitted in a delete statement)

DELETE FROM SomeTable WHERE PrimaryKeyColumn IN (SELECT TOP (200) PrimaryKeycolumn FROM SomeTable ORDER BY SomeDate)



Or, you identify the oldest rows by your date column instead of order:


DELETE TOP (200)
FROM SomeTable
WHERE datecolumn <= {some date limiter};




True, but that will delete 200 rows older than a certain date, not necessarily the oldest 200 rows in the table. Depends which is needed.

Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

We walk in the dark places no others will enter
We stand on the bridge and no one may pass


Paul White
Paul White
SSC-Dedicated
SSC-Dedicated (35K reputation)SSC-Dedicated (35K reputation)SSC-Dedicated (35K reputation)SSC-Dedicated (35K reputation)SSC-Dedicated (35K reputation)SSC-Dedicated (35K reputation)SSC-Dedicated (35K reputation)SSC-Dedicated (35K reputation)

Group: General Forum Members
Points: 35784 Visits: 11361
Books Online 2008
Using SET ROWCOUNT will not affect DELETE, INSERT, and UPDATE statements in the next release of SQL Server. Avoid using SET ROWCOUNT with DELETE, INSERT, and UPDATE statements in new development work, and plan to modify applications that currently use it. We recommend that DELETE, INSERT, and UPDATE statements that currently are using SET ROWCOUNT be rewritten to use TOP.


It's amazing how many people haven't noticed that.

As far as the query is concerned, using TOP exactly as Gail posted is the recommended approach.

Paul



Paul White
SQLPerformance.com
SQLblog.com
@SQL_Kiwi
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