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

SET ROWCOUNT usage with DELETE.. Expand / Collapse
Author
Message
Posted Saturday, July 11, 2009 12:45 PM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Monday, April 19, 2010 10:22 AM
Points: 4, 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
Post #751634
Posted Saturday, July 11, 2009 1:14 PM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Today @ 7:34 AM
Points: 12,744, Visits: 31,077
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

--There is no spoon, and there's no default ORDER BY in sql server either.
Actually, Common Sense is so rare, it should be considered a Superpower. --my son
Post #751638
Posted Saturday, July 11, 2009 1:16 PM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: Administrators
Last Login: Yesterday @ 11:24 AM
Points: 32,781, Visits: 14,942
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
Post #751639
Posted Saturday, July 11, 2009 8:38 PM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Monday, April 19, 2010 10:22 AM
Points: 4, Visits: 12
Thanks Lowell and Steve for your reply..

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

Regards,
Leela
Post #751660
Posted Sunday, July 12, 2009 3:56 AM


SSC-Forever

SSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-Forever

Group: General Forum Members
Last Login: Today @ 7:59 AM
Points: 41,530, Visits: 34,447
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 2008, MVP
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

Post #751682
Posted Sunday, July 12, 2009 11:12 AM
SSCarpal Tunnel

SSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal TunnelSSCarpal Tunnel

Group: General Forum Members
Last Login: Thursday, April 17, 2014 11:17 AM
Points: 4,379, Visits: 9,470
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 opportunites brilliantly disguised as insurmountable obstacles.

How to post questions to get better answers faster
Managing Transaction Logs
Post #751735
Posted Sunday, July 12, 2009 11:22 AM


SSC-Forever

SSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-Forever

Group: General Forum Members
Last Login: Today @ 7:59 AM
Points: 41,530, Visits: 34,447
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 2008, MVP
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

Post #751737
Posted Tuesday, July 14, 2009 2:52 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Yesterday @ 5:09 PM
Points: 11,168, Visits: 10,932
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
SQL Server MVP
SQLblog.com
@SQL_Kiwi
Post #752525
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse