The following are the parameter available with the stored procedure:
Parameter
|
Name
|
Type
|
Description
|
1 | FileToRead | int | 0 = Current, 1 or 2, 3, … n Archive Number |
2 | Logtype | int | 1 = SQL Error Log and 2 = SQL Agent log |
3 | String1 | varchar(255) | the string to match the logs on |
4 | String2 | varchar(255) | a second string to match in combination with String1 (AND) |
5 | StartDate | datetime | beginning date to look from |
6 | EndDate | datetime | ending date to look up to |
7 | ResultsOrder | ASC or DESC sorting |
Note:
If the SQL Server Agent hasn’t been active, then there will be no Agent log and the call to the stored procedure will return an error.
Here are a few examples of using the stored procedure:
-- listing the content of the current SQL Server error log EXEC xp_readerrorlog 0, 1 -- listing the content of the second SQL Server error log EXEC xp_readerrorlog 1, 1 -- listing the content of the current SQL Server Agent log EXEC xp_readerrorlog 0, 2 -- searching for errors EXEC xp_readerrorlog 0, 1, N'error' -- searching for errors that have to do with consistency checks EXEC xp_readerrorlog 0, 1, N'error', N'CHECKDB' -- searching for errors that have to do with consistency checks EXEC xp_readerrorlog 0, 1, N'failed', N'backups' -- searching for warnings EXEC xp_readerrorlog 0, 1, N'warning' -- searching who killed a session EXEC xp_readerrorlog 0, 1, N'kill' -- searching for I/O information EXEC xp_readerrorlog 0, 1, N'I/O' -- searching for consistency checks EXEC xp_readerrorlog 0, 1, N'CHECKDB' -- searching for consistency checks performed via DBCC EXEC xp_readerrorlog 0, 1, N'DBCC CHECKDB' -- searching for failed logins EXEC xp_readerrorlog 0, 1, N'Login failed' -- searching for EXEC xp_readerrorlog 0, 1, N'[INFO]' -- searching for shutdowns EXEC xp_readerrorlog 0, 1, N'shutdown' -- searching for a database instant file initialization event EXEC xp_readerrorlog 0, 1, N'database instant file initialization'
If the error log is too big it’s important to narrow the search for a given time interval:
-- searching for errors starting with a given date DECLARE @StartDate as Date = DateAdd(d, -1, GetDate()) EXEC xp_readerrorlog 0, 1, N'error', N'', @StartDate -- searching for errors within a time interval DECLARE @StartDate as Date = DateAdd(d, -14, GetDate()) DECLARE @EndDate as Date = DateAdd(d, -7, GetDate()) EXEC xp_readerrorlog 0, 1, N'', N'', @StartDate, @EndDate, N'desc'
The output can be dumped into a table especially when is needed to perform a detailed analysis on the error log. It might be interesting to check how often an error message occurred, like in the below example. One can take thus advantage of more complex pattern searching.
-- creating the error log table CREATE TABLE dbo.ErrorLogMessages ( LogDate datetime2(0) , ProcessInfo nvarchar(255) , [Text] nvarchar(max)) -- loading the errors INSERT INTO dbo.ErrorLogMessages EXEC xp_readerrorlog 0, 1 -- checking the results SELECT * FROM dbo.ErrorLogMessages -- checking messages frequency SELECT [Text] , count(*) NoOccurrences , Min(LogDate) FirstOccurrence FROM dbo.ErrorLogMessages GROUP BY [Text] HAVING count(*)>1 ORDER BY NoOccurrences DESC -- getting the errors and their information SELECT * FROM ( SELECT * , Lead([Text], 1) OVER (PARTITION BY LogDate, ProcessInfo ORDER BY LogDate) PrevMessage FROM dbo.ErrorLogMessages ) DAT WHERE [Text] LIKE '%error:%[0-9]%' -- cleaning up --DROP TABLE IF EXISTS dbo.ErrorLogMessages
For those who don’t have admin permissions it is necessary to explicitly give execute permissions on the xp_readerrorlog stored procedure:
-- giving explicit permissions to account GRANT EXECUTE ON xp_readerrorlog TO [<account_name>]
Personally, I’ve been using the stored procedure mainly to check whether error messages were logged for a given time interval and whether the consistency checks run without problems. Occasionally, I used it to check for failed logins or sessions terminations (aka kills).
Notes:
Microsoft warns that undocumented objects might change in future releases. Fortunately, xp_readerrorlog made it since SQL Server 2005 to SQL Server 2017, so it might make it further…
The above code was tested also on SQL Server 2017.
Happy coding!