- Denish Patel
- 6th December 2011
- mssql server
Transaction log file growth is dependent on one of the following Recovery method used for the instance:
1. Simple
2. Full
3. Bulk-Logged
If your database is in the Simple recovery mode, then the transaction log is truncated of inactive transaction after the checkpoint process occurs. The checkpoint process writes all modified data pages from memory to disk. When the checkpoint is performed, the inactive portion of the transaction log is marked as reusable.
SQL Server 2005 databases are set to the Full recovery model by default. With the Full or Bulk-Logged recovery mode, inactive transactions remain in the transaction log file until after a Checkpoint is processed and a transaction log backup is made. It’s important to note that a full backup does not remove inactive transactions from the transaction log. If database recovery model is set to Full or Bulk-Logged, then it is absolutely IMPORTANT that we make transaction log backups to go along with full backups because full backup does not remove inactive transactions from the transaction log. The transaction log backup performs a truncation of the inactive portion of the transaction log and allow them to used for future transactions. Note that truncation of log file does not shrink already bloated log file that’s the operation we have to do manually one time and if we set proper procedure in future, we could avoid unnecessary growth of log file. Other factors affecting transaction log to grow are:
- Replicated mirrored server falls behind master server
- Long running transactions
To solve #1:
Database mirroring is uses transaction logs for replication in that it requires that the transactions remain in the log until the record has been written to disk on the mirror server. If the mirror server falls behind the master server , the amount of active log space will grow. In this case, you might need to stop database mirroring, take a log backup that truncates the log, apply that log backup to the mirror database and restart mirroring.
To solve #2: ( it’s non-issue for most of the OLTP servers) :
If there are open transactions, DBCC OPENTRAN will provide a session_id or SPID of the connection that has the transaction open. You can pass this session_id to sp_who2 to determine which user has the connection open.
Following queries can be ued to detemine recovery model and transaction log truncation interval:
SELECT name, recovery_model_desc FROM sys.databases;
master SIMPLE
tempdb SIMPLE
model FULL
msdb SIMPLE
ReportServer SIMPLE
ReportServerTempDB SIMPLE
PRODUCTION_DB FULL
SELECT name, log_reuse_wait_desc FROM sys.databases;
master ACTIVE_TRANSACTION
tempdb ACTIVE_TRANSACTION
model NOTHING
msdb NOTHING
ReportServer NOTHING
ReportServerTempDB NOTHING
PRODUCTION_DB LOG_BACKUP
Results from above queries reveals that PRODUCTION_DB database is setup for FULL database backup and transaction log will not be truncated until LOG_BACKUP. Make sure that you take full backup followed by log backup that will make transactions log file’s inactive blocks to be available for re-write and prevent from growing further. Keep in mind that it will not shrink transaction log file . To shrink the transaction log file you can follow steps described in official docs OR following is the simple example of identifying and shrinking log file after taking log file backup:
SELECT name FROM sys.database_files WHERE type_desc = ‘LOG’
Once I have log file name, I can use the DBCC command to shrink the file. In the following command I try to shrink my log file down to 1GB.
DBCC SHRINKFILE (’PRODUCTION_DB_log.log’, 1000)
Run the shrink command couple of times during the off-peak hours. Also, please make sure that your databases are NOT set to auto-shrink. Auto-shrink database might encounter performance problems.
Hopefully, it will help you next time you come across transaction log file “too large” issue on MS SQL server installation.
Categories
Recent Blog
- Do you really need a DBA?
- Running VACUUM FULL in Non-blocking Mode
- Connection Scaling
- PSQL Helper: Managing Connections and Simplifying Queries
- Vacuum Those MVs!
- Working With Repmgr: Using Other 3rd Party Tools for Setting up a Standby
- Working with Amazon Aurora PostgreSQL: dag, standby rebooted again!
- Working with Amazon Aurora PostgreSQL: what happened to the stats?
- How to set application_name for psql command line utility?
- Is there a limit on number of partitions handled by Postgres?