February 9, 2018 at 1:06 am
I have a table where there is a column called nationality having possible values "US" and "Non -US'.
I need to delete the "Non -US' records from my table which amounts to more than 5 lac records, in the best possible way considering the database performance.
Kindly suggest the ways to do that.
February 9, 2018 at 1:31 am
-- Subsititute x for the number of rows you're happy to
-- delete at a time in order to limit transaction log growth
DELETE TOP(x)
FROM MyTable
WHERE MyColumn = 'Non -US'
-- Rinse and repeat
John
February 9, 2018 at 4:14 am
Agree with the DELETE statement, would suggest to use BEGIN TRAN to be on a safe side and then COMMIT
February 9, 2018 at 4:26 am
Conficker - Friday, February 9, 2018 4:14 AMAgree with the DELETE statement, would suggest to use BEGIN TRAN to be on a safe side and then COMMIT
Doesn't make much difference for a single statement. If you're doing this in a lot of batches then you don't want to be doing an explicit COMMIT after each one.
John
February 9, 2018 at 4:35 am
Hi there,
in terms of performance, one thing you'll need - in order to prevent issues with other processes, even when they will not be touching the records in question is lock escalation.
Very briefly:
Initially, your SQL Server engine will look at either taking out row or page locks on the table concerned.
However, locks have a cost in terms of management and resource allocation - they're, to a degree, expensive.
Therefore, after a certain threshold, where the Engine considers locking the individual records / pages in question too expensive, it will escalate the lock to a table lock. This prevents other processes accessing those records, due to an inability to take out their own locks.
The approximate threshold per operation is c. 5000 locks (3000 pre 2005).
So, something based around this;
DECLARE @Rows INT = 1
WHILE @Rows > 0
BEGIN
DELETE TOP <number>
FROM <table>
WHERE <your filter>
SELECT @Rows = @@ROWCOUNT
END
PRINT 'Done'
I'm a DBA.
I'm not paid to solve problems. I'm paid to prevent them.
February 9, 2018 at 5:29 am
If there aren't too many foreign keys and the amount you're deleting is more than the amount of rows you want to keep, it may well be faster to insert the rows you want to keep into a new table, drop the old table and then rename the new one (and put all the keys and indexes back afterwards)
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
February 24, 2018 at 10:57 pm
GilaMonster - Friday, February 9, 2018 5:29 AMIf there aren't too many foreign keys and the amount you're deleting is more than the amount of rows you want to keep, it may well be faster to insert the rows you want to keep into a new table, drop the old table and then rename the new one (and put all the keys and indexes back afterwards)
That's a good idea. But should I include it in a transaction? If you can post a sample code, it will be ideal. Thanks
February 27, 2018 at 8:10 pm
VSSGeorge - Saturday, February 24, 2018 10:57 PMGilaMonster - Friday, February 9, 2018 5:29 AMIf there aren't too many foreign keys and the amount you're deleting is more than the amount of rows you want to keep, it may well be faster to insert the rows you want to keep into a new table, drop the old table and then rename the new one (and put all the keys and indexes back afterwards)That's a good idea. But should I include it in a transaction? If you can post a sample code, it will be ideal. Thanks
Can you describe the table a bit more? For example, what are the total number of rows that it has? How many foreign keys does it have pointing at other tables and how many foreign keys point at the table being deleted from? How much total disk space does the table occupy?
All these questions will help tell me if you can do the ol' trick of creating a temporary file group to isolate the good rows on, truncate the original table, and copy the rows back in a minimally logged fashion (for performance and to keep from blowing the log file out), and then dropping the temporary file group to keep from unnecessarily increasing the size of the MDF file. It's nearly the same as what Gail mentioned but has the advantage of not expanding the MDF file any further.
--Jeff Moden
Change is inevitable... Change for the better is not.
Viewing 8 posts - 1 through 7 (of 7 total)
You must be logged in to reply to this topic. Login to reply