By: Greg Robidoux | Updated: 2022-02-24 | Comments (23) | Related: 1 | 2 | 3 | > Monitoring
Problem
One of the issues I have is that the SQL Server Error Log is quite large and it is not always easy to view the contents with the Log File Viewer. In a previous tip "Simple way to find errors in SQL Server error log" you discussed a method of searching the error log. Are there any other ways to search and find errors in the error log files?
Solution
SQL Server offers an undocumented system stored procedure sp_readerrorlog. This SP allows you to read the contents of the SQL Server error log files directly from a query window and also allows you to search for certain keywords when reading the error file.
This is a sample of the stored procedure that already exists in the master database. You will see that when this gets called it calls an extended stored procedure xp_readerrorlog.
CREATE PROC [sys].[sp_readerrorlog]( @p1 INT = 0, @p2 INT = NULL, @p3 VARCHAR(255) = NULL, @p4 VARCHAR(255) = NULL) AS BEGIN IF (NOT IS_SRVROLEMEMBER(N'securityadmin') = 1) BEGIN RAISERROR(15003,-1,-1, N'securityadmin') RETURN (1) END IF (@p2 IS NULL) EXEC sys.xp_readerrorlog @p1 ELSE EXEC sys.xp_readerrorlog @p1,@p2,@p3,@p4 END
This procedure takes four parameters:
- Value of error log file you want to read: 0 = current, 1 = Archive #1, 2 = Archive #2, etc...
- Log file type: 1 or NULL = error log, 2 = SQL Agent log
- Search string 1: String one you want to search for
- Search string 2: String two you want to search for to further refine the results
If you do not pass any parameters this will return the contents of the current error log.
Here are a few examples:
Example 1
EXEC sp_readerrorlog 6
This statement returns all of the rows from the 6th archived error log.
Example 2
EXEC sp_readerrorlog 6, 1, '2005'
This returns only the rows from the log where the value 2005 appears.
Example 3
EXEC sp_readerrorlog 6, 1, '2005', 'exec'
This returns only rows where the value '2005' and 'exec' exist.
xp_readerrrorlog
Even though sp_readerrolog accepts only 4 parameters, the extended stored procedure accepts at least 7 parameters.
If this extended stored procedure is called directly the parameters are as follows:
- Value of error log file you want to read: 0 = current, 1 = Archive #1, 2 = Archive #2, etc...
- Log file type: 1 or NULL = error log, 2 = SQL Agent log
- Search string 1: String one you want to search for
- Search string 2: String two you want to search for to further refine the results
- Search from start time
- Search to end time
- Sort order for results: N'asc' = ascending, N'desc' = descending
Here is are some examples.
EXEC master.dbo.xp_readerrorlog 0, 1, '2005', 'exec', NULL, NULL, N'desc' EXEC master.dbo.xp_readerrorlog 0, 1, '2005', 'exec', NULL, NULL, N'asc'
Error When Using xp_readerrrorlog
The above example shows the values in single quotes, but for later versions of SQL Server you may need to use double quotes or you might get this error.
Msg 22004, Level 12, State 1, Line 0
Error executing extended stored procedure: Invalid Parameter Type
Try this instead.
EXEC master.dbo.xp_readerrorlog 0, 1, "backup", "failed", "2017-01-02", "2017-02-02", "desc" EXEC master.dbo.xp_readerrorlog 0, 1, "2005", "exec", NULL, NULL, "asc"
Or try this, putting N before each parameter.
EXEC master.dbo.xp_readerrorlog 0, 1, N'backup', NULL, N'2017-01-02', N'2017-02-02', N'desc' EXEC master.dbo.xp_readerrorlog 0, 1, N'backup', N'failed', NULL, NULL, N'asc'
Next Steps
- As you can see this is a much easier way to read the error logs and to also look for a specific error message without having to use the Log File Viewer.
- Add this to your monitoring routine where this is run daily to search for errors or issues.
- Read this related artile Simple way to find errors in SQL Server error log
About the author
This author pledges the content of this article is based on professional experience and not AI generated.
View all my tips
Article Last Updated: 2022-02-24