Search This Blog

SQL Server 2005 Error Log Management

SQL Server Error Log
To limit the size of the SQL Server error log, the sp_cycle_errorlog system stored procedure can be issued to start a new error log.  Depending on the growth rate of the SQL Server error log dictates when sp_cycle_errorlog should be issued.  Reference the code below as an example.
EXEC master.sys.sp_cycle_errorlog;-- Expected successful output
-- DBCC execution completed. If DBCC printed error messages, contact your system administrator.
Next, the easiest means to address this need would be to schedule a SQL Server Job to support the need.  Reference the SQLServer2005_CycletheErrorLog_Job.txt as a point of reference.

SQLServer2005_CycletheErrorLog_Job.txt

USE [msdb]
GO
/****** Object:  Job [Sample - sp_cycle_errorlog]   ******/
BEGIN TRANSACTION
DECLARE @ReturnCode INT
SELECT @ReturnCode = 0
/****** Object:  JobCategory [[Uncategorized (Local)]]]    ******/
IF NOT EXISTS (SELECT name FROM msdb.dbo.syscategories WHERE name=N'[Uncategorized (Local)]' AND category_class=1)
BEGIN
EXEC @ReturnCode = msdb.dbo.sp_add_category @class=N'JOB', @type=N'LOCAL', @name=N'[Uncategorized (Local)]'
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback

END

DECLARE @jobId BINARY(16)
EXEC @ReturnCode =  msdb.dbo.sp_add_job @job_name=N'Sample - sp_cycle_errorlog', 
  @enabled=0, 
  @notify_level_eventlog=0, 
  @notify_level_email=0, 
  @notify_level_netsend=0, 
  @notify_level_page=0, 
  @delete_level=0, 
  @description=N'Sample job to recycle the SQL Server Error Log                                    *** NOTE *** - This job must be enabled and a schedule must be setup in order to execute this Job', 
  @category_name=N'[Uncategorized (Local)]', 
  @owner_login_name=N'sa', @job_id = @jobId OUTPUT
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
/****** Object:  Step [Recycle the SQL Server Error Log]    ******/
EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'Recycle the SQL Server Error Log', 
  @step_id=1, 
  @cmdexec_success_code=0, 
  @on_success_action=1, 
  @on_success_step_id=0, 
  @on_fail_action=2, 
  @on_fail_step_id=0, 
  @retry_attempts=0, 
  @retry_interval=0, 
  @os_run_priority=0, @subsystem=N'TSQL', 
  @command=N'EXEC master.sys.sp_cycle_errorlog;', 
  @database_name=N'master', 
  @flags=0
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
EXEC @ReturnCode = msdb.dbo.sp_update_job @job_id = @jobId, @start_step_id = 1
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
EXEC @ReturnCode = msdb.dbo.sp_add_jobserver @job_id = @jobId, @server_name = N'(local)'
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
COMMIT TRANSACTION
GOTO EndSave
QuitWithRollback:
 IF (@@TRANCOUNT > 0) ROLLBACK TRANSACTION
EndSave:


Finally, to address not loosing the historical SQL Server error log, the number of logs should be expanded beyond the default of 7.  The maximum number of logs is 99 for the SQL Server error log.  When it comes to expanding the number of SQL Server error logs, follow these steps:
  • Open Management Studio
  • Navigate to root | Management folder | SQL Server Logs folder
  • Right click on the SQL Server Logs folder and select the 'Configure' option
  • Select the 'Limit the number of error log files before they are recycled' check box
    • Reference the screen shot below as a point of reference
  • Enter the desired number of error logs in the 'Maximum number of error log files'
    • Reference the screen shot below as a point of reference   
  • Press the 'OK' button to save the configuration
Alternatively, the following code can be used to automate the process across multiple SQL Servers:
USE [master]
GO
EXEC xp_instance_regwrite N'HKEY_LOCAL_MACHINE', N'Software\Microsoft\MSSQLServer\MSSQLServer', N'NumErrorLogs', REG_DWORD, 50
GO
SQL Server Agent Error Log
The SQL Server Agent error log follows much of the same paradigm as the SQL Server error log.  The recycling process is completed by the sp_cycle_agent_errorlog in the MSDB database.
EXEC msdb.dbo.sp_cycle_agent_errorlog;
-- Expected successful output
-- Command(s) completed successfully.
In terms of configuring a specified number of SQL Server Agent error logs, this is not possible.  Only the current and 9 additional (a total of 10) SQL Server Agent error logs will be retained.  What can be configured are the type of messages (Errors, Warnings, Informational ) that are written to the SQL Server Agent error logs.  To access this interface, follow these steps:
  • Open Management Studio
  • Navigate to root | SQL Server Agent | Error Logs folder
  • Right click on the Error Logs folder and select the 'Configure' option, reference the screen shot below

To automate this process across servers, reference the sp_set_sqlagent_properties system stored procedure.  Below outlines a sample execution.
USE [msdb]
GO
EXEC msdb.dbo.sp_set_sqlagent_properties @errorlogging_level=7
GO
Alternative Error Log Access
The primary interface to access the SQL Server Error Logs is via the Log File Viewer.  This application provides insight into the SQL Server and Windows logs.  This application provides a means to review multiple logs as well as search and filter the logs.  If you do have a large error log that causes issues for this application, this should be copied and pasted and then the copied log can be reviewed via DOS's type command.  Although this is a less than ideal interface, it appears to provide immediate access and will not affect SQL Server writing new records to the original log.  Below is an example of reading a SQL Server Error log via DOS's type command.