How to Read Log File in SQL Server using TSQL

By:   |   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:

  1. Value of error log file you want to read: 0 = current, 1 = Archive #1, 2 = Archive #2, etc...
  2. Log file type: 1 or NULL = error log, 2 = SQL Agent log
  3. Search string 1: String one you want to search for
  4. 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.

error log output
sp rea2

Example 2

EXEC sp_readerrorlog 6, 1, '2005' 

This returns only the rows from the log where the value 2005 appears.

error log output

Example 3

EXEC sp_readerrorlog 6, 1, '2005', 'exec' 

This returns only rows where the value '2005' and 'exec' exist.

error log output

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:

  1. Value of error log file you want to read: 0 = current, 1 = Archive #1, 2 = Archive #2, etc...
  2. Log file type: 1 or NULL = error log, 2 = SQL Agent log
  3. Search string 1: String one you want to search for
  4. Search string 2: String two you want to search for to further refine the results
  5. Search from start time
  6. Search to end time
  7. 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 log output

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


sql server categories

sql server webinars

subscribe to mssqltips

sql server tutorials

sql server white papers

next tip



About the author
MSSQLTips author Greg Robidoux Greg Robidoux is the President and founder of Edgewood Solutions, a technology services company delivering services and solutions for Microsoft SQL Server. He is also one of the co-founders of MSSQLTips.com. Greg has been working with SQL Server since 1999, has authored numerous database-related articles, and delivered several presentations related to SQL Server. Before SQL Server, he worked on many data platforms such as DB2, Oracle, Sybase, and Informix.

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

Comments For This Article




Tuesday, December 21, 2021 - 11:56:25 AM - Greg Robidoux Back To Top (89609)
Hi Mehwish,

check out this article: https://www.mssqltips.com/sqlservertip/3090/how-to-find-user-who-ran-drop-or-delete-statements-on-your-sql-server-objects/

-Greg

Tuesday, December 21, 2021 - 11:32:41 AM - Mehwish Mushtaq Inamdar Back To Top (89608)
Sir, thanks for sharing Info.

Sir I want to Know Deleted record from specific Table with specific date period

How I can get this Result In SQL 2008 R2, SQL 20014, SQL 2016


Sunday, June 20, 2021 - 8:21:09 AM - Greg Robidoux Back To Top (88878)
Thanks Gregory. I agree. This allows you to query the data much easier.

Thanks for sharing.

-Greg

Saturday, June 19, 2021 - 7:09:37 AM - Gregory Liénard Back To Top (88877)
Hi Greg,

It's more flexible if you put everything in a temp table. We had a recovery of one of our biggest databases (> 100 TB) and logs were filled with logon issues due to thousands of connections not being able to connect. This script will show all but logon issues:

DROP TABLE IF EXISTS #SQLErrorLog; --assuming SQL Server 2016+...otherwise use the typical if object exists drop

CREATE TABLE #SQLErrorLog
(
LogDate DATETIME
,ProcessInfo NVARCHAR(12)
,LogText NVARCHAR(3999)
)

INSERT INTO #SQLErrorLog
(
LogDate
,ProcessInfo
,LogText
)
EXEC sp_readerrorlog;

SELECT * FROM #SQLErrorLog
where processinfo <>'logon'
order by logdate desc

Gregory Liénard
Microsoft Data Engineer
https://seopageoptimizer.com/ : analyses billions of webpages
https://keyboost.com/ : analyses trillions of links

If the statistics are boring, you’ve got the wrong numbers.

Wednesday, June 26, 2019 - 1:06:05 PM - Greg Robidoux Back To Top (81598)

Clifton, the only way to do that would be to load the data to a temp table and then pull the data you need.

CREATE TABLE #temp ( LogDate datetime, ProcessInfo varchar(100), TextData varchar(max) )

INSERT INTO #temp(LogDate, ProcessInfo, TextData)
EXEC sp_readerrorlog 0, 1, N'Manufacturer'

SELECT TextData FROM #temp

DROP TABLE #temp

-Greg


Wednesday, June 26, 2019 - 12:45:48 PM - Clifton S Dunaway Back To Top (81597)

How can I retrieve teh TEXT field alone from this? I need to get the Server Manaufacturer from thsi query:

EXEC sys.xp_readerrorlog 0, 1, N'Manufacturer'


Friday, January 4, 2019 - 10:55:48 AM - Greg Robidoux Back To Top (78628)

Thanks Danette.  Glad this was of use.  Hope all is well.

-Greg


Friday, January 4, 2019 - 10:39:12 AM - Danette Riviello Back To Top (78626)

Yesterday I stumbled upon an example in article that used a search string in xp_readerrorlog.   I never knew you could  - so I searched for more information and found this article.  Thanks for presenting the all the options - and providing examples.  I always say - "you don't know what you don't know. "  I have written my own code to do a lot of these functions because I didn't know they were built in.   Thanks, Greg!  


Tuesday, September 20, 2016 - 4:04:49 AM - BetterFiltering Back To Top (43364)

I already capture this information.  I'm hoping to store and notify any time a genuine error occurs and ignore 'informative' messages.  The data is placed in a temp table and then filtered using this code:

 

Can anyone suggest something better?

 

[Text] NOT LIKE 'Log was backed up%'

AND [Text] NOT LIKE 'SQL Trace stopped%'

AND [Text] NOT LIKE 'Database backed up. Database:%'

AND [Text] NOT LIKE '%found 0 errors and repaired 0 errors%'

AND [Text] NOT LIKE 'SQL Trace ID _ was started by login%'

/*Ignore I/O freezing if it's out of hours*/

AND (DATEPART(HOUR,[LogDate]) NOT IN (0,22,23)

AND [Text] NOT LIKE 'I/O was resumed on%')

AND (DATEPART(HOUR,[LogDate]) NOT IN (0,22,23)

AND [Text] NOT LIKE 'I/O is frozen on database%')

AND [Text] NOT LIKE '%This is an informational message only. no user action is required.'

AND [Text] NOT LIKE '%This is an informational message only.  No user action is required.'

AND [Text] NOT LIKE '%This is an informational message; no user action is required%'

AND [Text] NOT LIKE '%This is an informational message. No user action is required.'

AND [Text] NOT LIKE '%This is an informational message only; no user action is required.'

AND [Text] NOT LIKE '%Intel X86%'

AND [Text] NOT LIKE '%Copyright%'

AND [Text] NOT LIKE '%All rights reserved.%'

AND [Text] NOT LIKE '%Server Process ID is %'

AND [Text] NOT LIKE '%Logging SQL Server messages in file %'

AND [Text] NOT LIKE '%Errorlog has been reinitialized%'

AND [Text] NOT LIKE '%This instance of SQL Server has been using a process ID %'

AND [Text] NOT LIKE '%Starting up database %'

AND [Text] NOT LIKE '%SQL Server Listening %'

AND [Text] NOT LIKE '%SQL Server is ready %'

AND [Text] NOT LIKE '%Clearing tempdb %'

AND [Text] NOT LIKE '%to execute extended stored procedure %'

AND [Text] NOT LIKE '%Analysis of database %'

AND [Text] NOT LIKE '%Login fail%'

AND [Text] NOT LIKE 'Error: 18456%'

 

Can anyone suggest something better?

 

Many Thanks,

BetterFiltering


Tuesday, January 20, 2015 - 12:33:36 PM - Greg Robidoux Back To Top (36001)

Hi Peter,

you can use xp_readerrorlog and use the 5th parameter Start Time.

-Greg


Monday, January 19, 2015 - 9:31:45 PM - Peter Back To Top (35990)

Hi,

How to display only the entries from current logs, for today's date only? Thanks.


Tuesday, August 19, 2014 - 1:01:16 PM - Sean P. Tomas Back To Top (34194)

Hola David

 

No debes tener el Management Studio pero necesitas una manera que puede corer el SQL que nos enseno.  Perdo, pero no entiendo su pregunta sobre errors.  Que esta buscando in ese caso?

 

-- Sean


Saturday, July 26, 2014 - 1:03:33 AM - David Alfonso Back To Top (32893)

Hi,  I would known if I can execute those commads when i dont have Management Studio, and what does mean this errors.

No hablo muy bien el ingles espero puedan responder en español


Monday, March 3, 2014 - 7:23:44 AM - MSSQL DBA Back To Top (29626)

How to check SSRS error log using Query ?


Friday, June 21, 2013 - 7:23:24 AM - Jim Curry Back To Top (25513)

Great article. Is there a method to search the windows event logs?


Wednesday, February 27, 2013 - 11:57:46 AM - Hillsman Back To Top (22447)

Many thanks for this Greg - very useful.

I used your code it to loop through the SQL Server Logs to return information about database restores. I found that this is the only way I could retrieve database restore finish-times from SQL Server (since msdb.dbo.restorehistory only stores the restore start time).

 


Thursday, January 31, 2013 - 7:04:49 AM - Greg Robidoux Back To Top (21830)

@Deepu - you could use sp_readerrorlog to get the errors and then use sp_send_dbmail to send the messages.  You would need to setup a job to periodically check the error log.  Stay tuned for a future tip to do what you are requesting.

Here is a tip that show you how to send emails: http://www.mssqltips.com/sqlservertip/2347/send-email-in-a-tabular-format-using-sql-server-database-mail/

Greg


Thursday, January 31, 2013 - 12:40:28 AM - Deepu Back To Top (21817)

Can any one help me to reading errorlogs, and send alert mails if any errors found


Wednesday, June 25, 2008 - 12:33:05 PM - Pardo Back To Top (1249)

Great tip,

Parameters 6 and 7 are between dates!!!

exec xp_readerrorlog 0, 1,'succeeded','pardo','2008-06-23 10:06:59.250','2008-06-24 16:40:56.790','asc'

It is only for  SQL Server 2005

 Pardo


Tuesday, June 17, 2008 - 5:30:26 AM - hexiaomail Back To Top (1182)

This procedure takes 7 parameters:
1.        Value of error log file you want to read: 0 = current, 1 = Archive #1, 2 = Archive #2, etc...
2.        Log file type: 1 or NULL = error log, 2 = SQL Agent log
3.        Search string 1: String one you want to search for
4.        Search string 2: String two you want to search for to further refine the results
5.        Search from  start time
6.        Search to end time
7.        Sort order for results: N'asc' = ascending, N'desc' = descending

--the 5 and 6 paramenters use VARCHAR type,desc
declare @Time_Start varchar(30);
declare @Time_End varchar(30);
set @Time_Start=convert(varchar(30),getdate()-5,25);
set @Time_End=convert(varchar(30),getdate(),25);
EXEC master.dbo.xp_readerrorlog 0, 1, 'Failed', 'login', @Time_Start, @Time_End, N'desc';

--the 5 and 6 paramenters use DATETIME type
declare @Time_Start datetime;
declare @Time_End datetime;
set @time_start=getdate()-5;
set @Time_End=getdate();
EXEC master.dbo.xp_readerrorlog 0, 1, 'Failed', 'login', @Time_Start, @Time_End, N'desc';


Tuesday, April 15, 2008 - 8:14:08 AM - apostolp Back To Top (871)

Many thanks Greg.


Tuesday, April 15, 2008 - 8:01:19 AM - grobido Back To Top (870)

I think the format for SQL Server 2000 is different than SQL Server 2005.

Take a look at this article:

http://vyaskn.tripod.com/sp_readerrorlog_undocumented.htm

Regards,
Greg


Tuesday, April 15, 2008 - 7:18:24 AM - apostolp Back To Top (869)
I was not aware of this functionality but I cannot seem to get the search facility to work in SQLServer 2000. It works fine in SQLServer 2005 but when I run EXEC sp_readerrorlog 1, null, 'master' (EXEC sp_readerrorlog 1, null, 'master'  actually returns an error in SQLServer 2000) 

in SQLServer 2000 it does not narrow the result set and just returns everything. Something similar happens with xp_readerrorlog.

Any ideas ?

Many thanks,

Peter A.















get free sql tips
agree to terms