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


Delete records without logging


Delete records without logging

Author
Message
bala2013
bala2013
SSC-Enthusiastic
SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)

Group: General Forum Members
Points: 103 Visits: 167
Deal all,

we have a database AA in SQL Server,while inserting the records to table DB log file size are growing same scenario happening while deleting the records.we dont want log growing for deleting the records without affecting DB Mirror,how to handle this ONE?

Please help me on this?
Adi Cohn
Adi Cohn
SSCertifiable
SSCertifiable (7.7K reputation)SSCertifiable (7.7K reputation)SSCertifiable (7.7K reputation)SSCertifiable (7.7K reputation)SSCertifiable (7.7K reputation)SSCertifiable (7.7K reputation)SSCertifiable (7.7K reputation)SSCertifiable (7.7K reputation)

Group: General Forum Members
Points: 7741 Visits: 6594
You can't do any and modification in the database without logging. Logging is essential for the database. Without it the server won't be able to rollback any statement. If you don't want the log to grow so much you can do the fallowing things:
If you delete the whole table and there is no replication and other tables don't reference your table with a foreign key, then you can truncate the table instead of running the delete statement. This will still be logged, but it will log the modification in the table's pages allocation and not every record that was deleted.
If you delete many records, you should delete it in chunks and not all the records in one statement. If your database is in full recovery or bulk logged model you can do logs backup between the chunks (not between each one of them, but after each X chunks. You'll have to work out yourself when to do it). If the database is in simple recovery model, you don't have (and can't) do the log backup.

Adi

--------------------------------------------------------------
To know how to ask questions and increase the chances of getting asnwers:
http://www.sqlservercentral.com/articles/Best+Practices/61537/

For better answers on performance questions, click on the following...
http://www.sqlservercentral.com/articles/SQLServerCentral/66909/
bala2013
bala2013
SSC-Enthusiastic
SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)

Group: General Forum Members
Points: 103 Visits: 167
thanks
Lokesh Vij
Lokesh Vij
Hall of Fame
Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)

Group: General Forum Members
Points: 3240 Visits: 1599
There is nothing called "No Logging" in SQL Server...there is something called "Minimal Logging". This can be achieved by using table locking hints.

DELETE FROM TableName  with (TABLOCK) WHERE id > 100;



For more details, refer this link:
http://blogs.msdn.com/b/sqlserverstorageengine/archive/2008/03/06/minimal-logging-changes-in-sql-server-2008-part-1.aspx

~ Lokesh Vij

Guidelines for quicker answers on T-SQL question
Guidelines for answers on Performance questions

Link to my Blog Post --> www.SQLPathy.com

Follow me @Twitter


bala2013
bala2013
SSC-Enthusiastic
SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)SSC-Enthusiastic (103 reputation)

Group: General Forum Members
Points: 103 Visits: 167
thanks lokesh.its very help to us...
GilaMonster
GilaMonster
SSC Guru
SSC Guru (212K reputation)SSC Guru (212K reputation)SSC Guru (212K reputation)SSC Guru (212K reputation)SSC Guru (212K reputation)SSC Guru (212K reputation)SSC Guru (212K reputation)SSC Guru (212K reputation)

Group: General Forum Members
Points: 212727 Visits: 46259
Lokesh Vij (6/17/2013)
There is nothing called "No Logging" in SQL Server...there is something called "Minimal Logging". This can be achieved by using table locking hints.

DELETE FROM TableName  with (TABLOCK) WHERE id > 100;





Err, no.
Minimal logging is for inserts, not deletes. You can't minimally log deletes.

The blog describes how to use TABLOCK on an insert to get minimal logging in bulk-logged and simple recovery.

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


GilaMonster
GilaMonster
SSC Guru
SSC Guru (212K reputation)SSC Guru (212K reputation)SSC Guru (212K reputation)SSC Guru (212K reputation)SSC Guru (212K reputation)SSC Guru (212K reputation)SSC Guru (212K reputation)SSC Guru (212K reputation)

Group: General Forum Members
Points: 212727 Visits: 46259
balamurugan.devadas (6/17/2013)
we dont want log growing for deleting the records without affecting DB Mirror,how to handle this ONE?


Minimal logging is not a possibility, because deletes can't be minimally logged and even if they could mirroring requires full recovery model.

The usual method is to delete in chunks and do transaction log backups between each chunk. It'll still use the same amount of log but the log backups mark the log reusable between each delete chunk.

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


Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (204K reputation)SSC Guru (204K reputation)SSC Guru (204K reputation)SSC Guru (204K reputation)SSC Guru (204K reputation)SSC Guru (204K reputation)SSC Guru (204K reputation)SSC Guru (204K reputation)

Group: General Forum Members
Points: 204723 Visits: 41952
Lokesh Vij (6/17/2013)
There is nothing called "No Logging" in SQL Server...there is something called "Minimal Logging". This can be achieved by using table locking hints.

DELETE FROM TableName  with (TABLOCK) WHERE id > 100;



For more details, refer this link:
http://blogs.msdn.com/b/sqlserverstorageengine/archive/2008/03/06/minimal-logging-changes-in-sql-server-2008-part-1.aspx


I agree with Gail. You cannot achieve minimal logging for DELETEs. It also usually takes a whole lot more than just using WITH(TABLOCK) to achieve minimal logging on inserts, as well. There's a whole set of rules in Books Online for what is necessary to achieve minimal logging.

As Adi pointed out above, if you want to delete the entire contents of a table and it meets the rules he stated, then you could use TRUNCATE instead of DELETE and that will be minimally logged.

--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
GilaMonster
GilaMonster
SSC Guru
SSC Guru (212K reputation)SSC Guru (212K reputation)SSC Guru (212K reputation)SSC Guru (212K reputation)SSC Guru (212K reputation)SSC Guru (212K reputation)SSC Guru (212K reputation)SSC Guru (212K reputation)

Group: General Forum Members
Points: 212727 Visits: 46259
Jeff Moden (6/17/2013)
then you could use TRUNCATE instead of DELETE and that will be minimally logged.


Technically truncate is fully logged. It just logs the page deallocations like a drop table does rather than the rows as delete does.

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


Lokesh Vij
Lokesh Vij
Hall of Fame
Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)Hall of Fame (3.2K reputation)

Group: General Forum Members
Points: 3240 Visits: 1599
GilaMonster (6/17/2013)
Lokesh Vij (6/17/2013)
There is nothing called "No Logging" in SQL Server...there is something called "Minimal Logging". This can be achieved by using table locking hints.

DELETE FROM TableName  with (TABLOCK) WHERE id > 100;





Err, no.
Minimal logging is for inserts, not deletes. You can't minimally log deletes.

The blog describes how to use TABLOCK on an insert to get minimal logging in bulk-logged and simple recovery.


Thanks Gail for correcting me.

~ Lokesh Vij

Guidelines for quicker answers on T-SQL question
Guidelines for answers on Performance questions

Link to my Blog Post --> www.SQLPathy.com

Follow me @Twitter


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