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


Delete 5 lac records from table


Delete 5 lac records from table

Author
Message
VSSGeorge
VSSGeorge
SSCertifiable
SSCertifiable (5K reputation)SSCertifiable (5K reputation)SSCertifiable (5K reputation)SSCertifiable (5K reputation)SSCertifiable (5K reputation)SSCertifiable (5K reputation)SSCertifiable (5K reputation)SSCertifiable (5K reputation)

Group: General Forum Members
Points: 5019 Visits: 1590
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.
John Mitchell-245523
John Mitchell-245523
SSC Guru
SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)

Group: General Forum Members
Points: 85323 Visits: 18118
-- 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
Conficker
Conficker
Right there with Babe
Right there with Babe (749 reputation)Right there with Babe (749 reputation)Right there with Babe (749 reputation)Right there with Babe (749 reputation)Right there with Babe (749 reputation)Right there with Babe (749 reputation)Right there with Babe (749 reputation)Right there with Babe (749 reputation)

Group: General Forum Members
Points: 749 Visits: 413
Agree with the DELETE statement, would suggest to use BEGIN TRAN to be on a safe side and then COMMIT
John Mitchell-245523
John Mitchell-245523
SSC Guru
SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)

Group: General Forum Members
Points: 85323 Visits: 18118
Conficker - Friday, February 9, 2018 4:14 AM
Agree 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

andrew gothard
andrew gothard
SSCertifiable
SSCertifiable (6.5K reputation)SSCertifiable (6.5K reputation)SSCertifiable (6.5K reputation)SSCertifiable (6.5K reputation)SSCertifiable (6.5K reputation)SSCertifiable (6.5K reputation)SSCertifiable (6.5K reputation)SSCertifiable (6.5K reputation)

Group: General Forum Members
Points: 6543 Visits: 6261
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.
GilaMonster
GilaMonster
SSC Guru
SSC Guru (586K reputation)SSC Guru (586K reputation)SSC Guru (586K reputation)SSC Guru (586K reputation)SSC Guru (586K reputation)SSC Guru (586K reputation)SSC Guru (586K reputation)SSC Guru (586K reputation)

Group: General Forum Members
Points: 586723 Visits: 48004
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

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


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