June 17, 2013 at 1:15 am
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?
June 17, 2013 at 1:36 am
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/
June 17, 2013 at 2:39 am
thanks
June 17, 2013 at 3:41 am
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:
~ Lokesh Vij
Link to my Blog Post --> www.SQLPathy.com[/url]
Follow me @Twitter
June 17, 2013 at 3:44 am
thanks lokesh.its very help to us...
June 17, 2013 at 4:19 am
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
June 17, 2013 at 4:22 am
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
June 17, 2013 at 4:28 am
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:
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
Change is inevitable... Change for the better is not.
June 17, 2013 at 4:45 am
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
June 17, 2013 at 4:52 am
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
Link to my Blog Post --> www.SQLPathy.com[/url]
Follow me @Twitter
June 17, 2013 at 5:01 am
GilaMonster (6/17/2013)
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.
Agreed. I probably shouldn't have used the words "minimally logged" here but the effect is nearly the same.
--Jeff Moden
Change is inevitable... Change for the better is not.
June 17, 2013 at 5:09 am
Wouldn't "generate less logging" be more accurate since the logging to re-apply the truncate will also be logged?
June 17, 2013 at 6:25 am
Dird (6/17/2013)
Wouldn't "generate less logging" be more accurate since the logging to re-apply the truncate will also be logged?
???
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
Viewing 13 posts - 1 through 12 (of 12 total)
You must be logged in to reply to this topic. Login to reply