July 11, 2009 at 12:45 pm
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
July 11, 2009 at 1:14 pm
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
July 11, 2009 at 1:16 pm
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.
July 11, 2009 at 8:38 pm
Thanks Lowell and Steve for your reply..
I will try putting ORDER BY clause and check the behaviour..
Regards,
Leela
July 12, 2009 at 3:56 am
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
July 12, 2009 at 11:12 am
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 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
“We are all faced with a series of great opportunities brilliantly disguised as impossible situations.”
― Charles R. Swindoll
How to post questions to get better answers faster
Managing Transaction Logs
July 12, 2009 at 11:22 am
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
July 14, 2009 at 2:52 am
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
Viewing 8 posts - 1 through 7 (of 7 total)
You must be logged in to reply to this topic. Login to reply