Showing posts with label SQL Agent. Show all posts
Showing posts with label SQL Agent. Show all posts

Tuesday, March 24, 2015

SQL Server Agent Job Last Run Time and Result

I've seen situations in which we have some SQL Server Agent jobs that are scheduled to run very rarely  (like once every year or once every half year). Either because of audit or troubleshooting, we need to find out those SQL Server Agent jobs last run time and their outcome. However, the SQL Server Agent history is being purged every few months (Notes: purging SQL Server Agent history periodically is not a bad thing, it is actually a good practice to keep the msdb database size manageable, esp. if your environment has lots of SQL Server Agent jobs, in which many of them have lots of job steps, and some of the jobs are scheduled to run frequently - every few minutes or even seconds).

Are we out of luck? Well not necessarily.

Demo

First create a SQL Agent job with the following script:

USE [msdb]
GO

BEGIN TRANSACTION
DECLARE @ReturnCode INT
SELECT @ReturnCode = 0

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'SQL Job Test',
@enabled=1,
@notify_level_eventlog=0,
@notify_level_email=0,
@notify_level_netsend=0,
@notify_level_page=0,
@delete_level=0,
@description=N'No description available.',
@category_name=N'[Uncategorized (Local)]',
@owner_login_name=N'sa', @job_id = @jobId OUTPUT
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback

EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'Job Step 1',
@step_id=1,
@cmdexec_success_code=0,
@on_success_action=3,
@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'select 1',
@database_name=N'master',
@flags=0
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback

EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'Job Step 2',
@step_id=2,
@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'select 2',
@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:


GO

Then we run the job using the following script:

USE [msdb];
GO

EXEC sp_start_job @job_name=N'SQL Job Test';
GO

Once that has been completed, there should be a job history for the SQL Server agent job:

image

Now purge the job history by running the following:

USE [msdb];
GO

EXEC dbo.sp_purge_jobhistory @job_name=N'SQL Job Test';
GO

After purging the job history, we will no longer have the entries for “SQL Job Test” job on dbo.sysjobhistory table in the msdb database.

image

If we try to query the sysjobhistory, using the following query, we would get 0 row:

USE [msdb];
GO

SELECT *
FROM dbo.sysjobhistory
WHERE job_id IN (
SELECT job_id
FROM dbo.sysjobs
WHERE [name] = N'SQL Job Test');

Or this query:

USE [msdb];
GO

EXEC sp_help_jobhistory @job_name = N'SQL Job Test';
GO

Gulp! No more history for SQL job “SQL Job Test”. But wait, if we look at the job properties, we can see when the job was last executed.

image

So the information must still be in the database. If we try to run the following query:

USE [msdb];
GO

EXEC sp_help_job @job_name = N'SQL Job Test';

We can see the job’s last run date, time and even outcome (For the definition of last_run_outcome column, you can check the following MSDN article). There’s more. When you run the sp_help_job stored procedure, you can also see each of the job step’s last run date, time and outcome.

If we investigate it further, the last run date, time and outcome are stored on sysjobservers and sysjobsteps within the msdb database. We can query them using the following:

USE [msdb];
GO

SELECT j.job_id,
j.Name,
js.last_run_outcome,
last_run_outcome_desc = CASE
WHEN js.last_run_outcome = 0
THEN 'Failed'
WHEN js.last_run_outcome = 1
THEN 'Succeeded'
WHEN js.last_run_outcome = 3
THEN 'Canceled'
ELSE 'Unknown'
END,
js.last_outcome_message,
last_run_datetime = dbo.agent_datetime(
CASE WHEN js.last_run_date = 0 THEN NULL ELSE js.last_run_date END,
CASE WHEN js.last_run_time = 0 THEN NULL ELSE js.last_run_time END),
js.last_run_duration
FROM dbo.sysjobs j
INNER JOIN dbo.sysjobservers js
ON j.job_id = js.job_id

Or if you want to see it for each of the job’s steps:

USE [msdb];
GO

SELECT j.job_id,
j.Name,
js.last_run_outcome,
last_run_outcome_desc = CASE
WHEN js.last_run_outcome = 0
THEN 'Failed'
WHEN js.last_run_outcome = 1
THEN 'Succeeded'
WHEN js.last_run_outcome = 3
THEN 'Canceled'
ELSE 'Unknown'
END,
js.last_outcome_message,
last_run_datetime = dbo.agent_datetime(
CASE WHEN js.last_run_date = 0 THEN NULL ELSE js.last_run_date END,
CASE WHEN js.last_run_time = 0 THEN NULL ELSE js.last_run_time END),
js.last_run_duration,
jst.step_id,
jst.step_name,
step_last_run_outcome = jst.last_run_outcome,
step_last_run_outcome_desc = CASE
WHEN jst.last_run_outcome = 0
THEN 'Failed'
WHEN jst.last_run_outcome = 1
THEN 'Succeeded'
WHEN jst.last_run_outcome = 2
THEN 'Retries'
WHEN jst.last_run_outcome = 3
THEN 'Canceled'
ELSE 'Unknown'
END,
step_last_run_datetime = dbo.agent_datetime(
CASE WHEN jst.last_run_date = 0 THEN NULL ELSE jst.last_run_date END,
CASE WHEN jst.last_run_time = 0 THEN NULL ELSE jst.last_run_time END)
FROM dbo.sysjobs j
INNER JOIN dbo.sysjobservers js
ON j.job_id = js.job_id
INNER JOIN dbo.sysjobsteps jst
ON j.job_id = jst.job_id

WHERE j.name = N'SQL Job Test';

Clean-up

To clean up the demo, you can run the following script:

USE [msdb];
GO

EXEC sp_delete_job @job_name = N'SQL Job Test';

GO

Thursday, February 6, 2014

Utilizing smtp4dev with SQL Server Database Mail for Testing

SQL Server has database mail, a solution which would allow us to send e-mail from our database server. It allows us to send either e-mail in html or text format to users. It’s great because we can use it to send query results to users (or ourselves). We can also configure SQL Server Agent to use database mail to send alerts to operator.

Database mail utilizes SMTP server to send the e-mails. In some cases, we might not have a readily available SMTP server in our environment (like in my home lab environment) or we might be block from using the SMTP server from our development environment for security reason. In those situations, I’ve been using smtp4dev. It is a neat little utility that would allow you to have a dummy SMTP server on your local computer. It is lightweight and also no installation is needed. When we run the utility, it would sit on the system tray and listen to port 25 (default SMTP port). It will receive the e-mail that get send to its way, without sending the e-mail to its final destination (the e-mail recipients). It is pretty handy when we need to run some tests.

Setting up database mail to work with smtp4dev is pretty simple.

  • Download smtp4dev from http://smtp4dev.codeplex.com.
  • Extract the file and save it on your system (assuming that it is your development system and it has the SQL Server).
  • Run smtp4dev. Notes: If you have Windows Firewall turned on, you might get a “Windows Security Alert” that ask you if you want to allow smtp4dev to communicate with either the private network, public network or both. Since normally I run smtp4dev on my development system with also has SQL Server that I want to have database mail turn on, I would just hit the cancel button.
  • If database mail in SQL Server has not been enable, we can enable it by using the following SQL script:
exec sp_configure 'show advanced', 1;
go
reconfigure;
go
exec sp_configure 'Database Mail XPs', 1;
go
reconfigure;
go
  • We then need to set up database mail profile, account and then associate the profile with the account in SQL Server. To do that, we can use the following script (based on the “Database Mail Simple Configuration Template”):
DECLARE @profile_name sysname,
@account_name sysname,
@SMTP_servername sysname,
@email_address NVARCHAR(128),
@display_name NVARCHAR(128),
@error_display NVARCHAR(500);

-- Profile name. Replace with the name for your profile
SET @profile_name = 'SMTP4Dev';

-- Account information. Replace with the information for your account.

SET @account_name = 'SMTP4Dev Account';
SET @SMTP_servername = 'localhost'; --- Since the smtp4dev is on local system.
SET @email_address = 'john.doe@email.com';
SET @display_name = 'John Doe';

-- Verify the specified account and profile do not already exist.
IF EXISTS (SELECT * FROM msdb.dbo.sysmail_profile WHERE name = @profile_name)
BEGIN
SET @error_display = 'The specified Database Mail profile (' + @profile_name + ') already exists.';
RAISERROR(@error_display, 16, 1);
GOTO done;
END;

IF EXISTS (SELECT * FROM msdb.dbo.sysmail_account WHERE name = @account_name )
BEGIN
SET @error_display = 'The specified Database Mail account (' + @account_name + ') already exists.';
RAISERROR(@error_display, 16, 1) ;
GOTO done;
END;

-- Start a transaction before adding the account and the profile
BEGIN TRANSACTION ;

DECLARE @rv INT;

-- Add the account
EXECUTE @rv=msdb.dbo.sysmail_add_account_sp
@account_name = @account_name,
@email_address = @email_address,
@display_name = @display_name,
@mailserver_name = @SMTP_servername;

IF @rv<>0
BEGIN
SET @error_display = 'Failed to create the specified Database Mail account (' + @account_name + ').';
RAISERROR(@error_display, 16, 1) ;
GOTO done;
END

-- Add the profile
EXECUTE @rv=msdb.dbo.sysmail_add_profile_sp
@profile_name = @profile_name ;

IF @rv<>0
BEGIN
SET @error_display = 'Failed to create the specified Database Mail profile (' + @profile_name + ').';
RAISERROR(@error_display, 16, 1);
ROLLBACK TRANSACTION;
GOTO done;
END;

-- Associate the account with the profile.
EXECUTE @rv=msdb.dbo.sysmail_add_profileaccount_sp
@profile_name = @profile_name,
@account_name = @account_name,
@sequence_number = 1 ;

IF @rv<>0
BEGIN
SET @error_display = 'Failed to associate the speficied profile with the specified account (' + @account_name + ').';
RAISERROR(@error_display, 16, 1) ;
ROLLBACK TRANSACTION;
GOTO done;
END;

COMMIT TRANSACTION;

done:

GO
  • Now the moment of truth, we can test to see if it works by trying to send an e-mail using sp_send_dbmail
exec msdb..sp_send_dbmail @profile_name = 'SMTP4Dev',
@recipients = 'jane.doe@email.com',
@subject = 'Test E-mail',
@body = 'This is a test email.';

If everything works as plan hopefully on your tray notification, you would see the following message:

image

And if you open smtp4dev, you should see the following:

image

To view the e-mail, you can click on the “View” or “Inspect” button.

Some caveats that I’ve noticed:

  • I have Microsoft Office 2013 installed on my system, which includes Outlook 2013. For some reason, when I click the “View” button, I would get an error message “The attempted operation failed. An object could not be found.” and it just would not open the e-mail (if I try to open it using Outlook 2013). It is ok if I use Windows Live Mail 2012. I would normally use the “Inspect” button instead.
  • If you exit out smtp4dev, the e-mails that you have on the Messages tab will get deleted.

Cleaning Up

If you want to remove the database mail from your SQL Server, first you want to remove the profile association with account, the profile and the account. You can do that by using the following script:

DECLARE @profile_name sysname,
@account_name sysname,
@error_display nvarchar(500);

-- Profile name. Replace with the name for your profile
SET @profile_name = 'SMTP4Dev';

-- Account information. Replace with the information for your account.
SET @account_name = 'SMTP4Dev Account';

IF NOT EXISTS (SELECT * FROM msdb.dbo.sysmail_profile WHERE name = @profile_name)
BEGIN
SET @error_display = 'The specified Database Mail profile (' + @profile_name + ') does not exists.';
RAISERROR(@error_display, 16, 1);
GOTO done;
END

IF NOT EXISTS (SELECT * FROM msdb.dbo.sysmail_account WHERE name = @account_name)
BEGIN
SET @error_display = 'The specified Database Mail account (' + @account_name + ') does not exists.';
RAISERROR(@error_display, 16, 1);
GOTO done;
END

-- Start a transaction before deleting the profile account, profile and account.
BEGIN TRANSACTION ;

DECLARE @rv INT;

EXEC @rv=msdb.dbo.sysmail_delete_profileaccount_sp
@profile_name = @profile_name,
@account_name = @account_name;

IF @rv<>0
BEGIN
SET @error_display = 'Failed to delete the profile with the specified account (' + @account_name + ').';
RAISERROR(@error_display, 16, 1) ;
ROLLBACK TRANSACTION;
GOTO done;
END;

EXEC @rv=msdb.dbo.sysmail_delete_profile_sp
@profile_name = @profile_name;

IF @rv<>0
BEGIN
SET @error_display = 'Failed to delete the database mail profile (' + @profile_name + ').';
RAISERROR(@error_display, 16, 1) ;
ROLLBACK TRANSACTION;
GOTO done;
END;

EXEC @rv=msdb.dbo.sysmail_delete_account_sp
@account_name = @account_name;
IF @rv<>0
BEGIN
SET @error_display = 'Failed to delete the database mail account (' + @account_name + ').';
RAISERROR(@error_display, 16, 1) ;
ROLLBACK TRANSACTION;
GOTO done;
END;

COMMIT TRANSACTION;

done:

GO

Then after that, you can disabled the database mail by using the following script:

exec sp_configure 'Database Mail XPs', 0;
go
reconfigure;
go
exec sp_configure 'show advanced', 0
go
reconfigure;
go

Friday, March 22, 2013

SQL Server Agent Job Last Run Date and Time from Sysjobsteps Table

A couple of weeks ago, I wrote a blog entry in regards to finding out the last successful run date and time of SQL Server Agent job by querying the sysjobhistory table in the msdb database. That blog entry can be found here. The sysjobhistory table stores the execution history of each SQL Server agent job and job steps.

There is another way in which you can get the last run date and time of the SQL Server agent jobs (well, kind of). You can do this by querying the sysjobsteps table in the msdb database. The sysjobsteps stores information of each SQL Server job step, including the last_run_outcome (whether the job step execution failed, succeeded, retry, canceled or unknown), the last_run_date and the last_run_time. Similar to the run_date and run_time columns in the sysjobhistory table, the last_run_date and the last_run_time columns in sysjobsteps have integer data type. Thus, to convert it to date and time, we can use the agent_datetime system function in the msdb database. Unlike, the sysjobhistory, there is no step 0 in the sysjobsteps table, which would give the overall job outcome.

An sample query that we can use to retrieve the last run date and time for each SQL Server job steps:

select j.job_id,
j.name,
js.step_id,
js.step_name,
last_run_outcome = case when js.last_run_outcome = 0 then 'Failed'
when js.last_run_outcome = 1 then 'Succeeded'
when js.last_run_outcome = 2 then 'Retry'
when js.last_run_outcome = 3 then 'Canceled'
else 'Unknown'
end,
last_run_datetime = msdb.dbo.agent_datetime(
case when js.last_run_date = 0 then NULL else js.last_run_date end,
case when js.last_run_time = 0 then NULL else js.last_run_time end)
from msdb.dbo.sysjobs j
inner join msdb.dbo.sysjobsteps js
on j.job_id = js.job_id;

The last_run_outcome can be a bit misleading. If the job step has not been run, the last_run_outcome is 0, which indicates that the job step has failed on its last run.

Purging the SQL Server agent history (see my blog post) would not remove the last_run_date and last_run_time value from the sysjobsteps table.

Tuesday, March 19, 2013

Purge SQL Server Job History

The msdb database stores SQL Server job information, including the job and job steps history. The job history information can grow really fast, especially if you have a lot of SQL Server jobs which run frequently. In turn, this can cause the msdb database to grow in size rather quickly. It is a good idea to purge old SQL Server job history on regular basis. You might want to check with your company policy or legal team on how much of job history you need to keep.

How do you go about purging the SQL Server Job History? There are several ways in which you can do this.

sp_purge_jobhistory

The sp_purge_jobhistory stored procedure in msdb database can be used to delete the SQL Server agent job history. It accepts 3 input parameters:

  • (Optional) @job_id - the SQL Server job id of the job history that you want to delete

  • (Optional) @job_name - the SQL Server job name of the job history that you want to delete

  • (Optional) @oldest_date - delete SQL Server job history that is older than the @oldest_date

One thing to know is that when running the sp_purge_jobhistory, you can specify the job_id or job_name or neither of them. But you can not specify both the job_id and job_name. If you do, you will most likely get the following error message:

"Msg 14294, Level 16, State 1, Procedure sp_verify_job_identifiers, Line 25
Supply either @job_id or @job_name to identify the job."

Some sample usage:

To delete all job history:

exec msdb.dbo.sp_purge_jobhistory;

To delete all job history of SQL Server job named "Backup TestDB":

exec msdb.dbo.sp_purge_jobhistory @job_name = 'Backup TestDB';

Alternatively:

declare @job as uniqueidentifier;
set @job = (select job_id from dbo.sysjobs where [name] = 'Backup TestDB');
exec msdb.dbo.sp_purge_jobhistory @job_id = @job;

To delete job history that is older than 30 days:

declare @jobdate as datetime;
set @jobdate = dateadd(dd, -30, getdate());
exec msdb.dbo.sp_purge_jobhistory @oldest_date = @jobdate;

To delete job hisotry for SQL Server job named "Backup TestDB", which are older than 30 days:

declare @jobdate as datetime;
set @jobdate = dateadd(dd, -30, getdate());
exec msdb.dbo.sp_purge_jobhistory @job_name = 'Backup TestDB', @oldest_date = @jobdate;

It is pretty straight forward. To do this on regular basis, you can create a SQL Server agent job to run the sp_purge_jobhistory with the appropriate input parameter(s) on a scheduled time.

SQL Server Agent Properties

If you go to the SQL Server Agent Properties window, you have the option to "remove agent history". Here, you need to specify the cut-off time.

agent_property

If you try to script this out, you will see that it is generating the following script:

EXEC msdb.dbo.sp_purge_jobhistory @oldest_date='2013-02-12T22:54:55'

So basically it is executing the same sp_purge_jobhistory stored procedure on the background. One thing to remember about purging the job history this way is that it is just one time only. It will not actually create any SQL Server Agent that would automatically delete job history that are older than 4 weeks.

syspolicy_purge_history SQL Server Job

By default, if you are using SQL Server 2008, 2008 R2 or 2012, you might see the syspolicy_purge_history SQL Server agent job. The job is scheduled to run daily at 2 AM. This SQL Server job would look into the Policy Management "HistoryRetentionInDays" property (You can get to this window by going to Management on the Object Explorer and then right click Policy Management and select Properties).

policy_mgmt

By default, the HistoryRetentionInDays is set to 0, which means that it will not delete any SQL Server job history. If you set it 30, then on daily basis at 2 AM, it will delete SQL Server job history that are older than 30 days.

Tuesday, March 5, 2013

Last Successful SQL Server Agent Job Run Date and Time

SQL Server stores SQL Server Agent job history in sysjobhistory table within the msdb database. We can query the table to get the date and time of last successful SQL Server agent job(s) run. The table stores each job step history, where step_id 0 for each job actually give the overall job outcome.

The sysjobhistory table also stores each step's run date and time. However, they are being stored in separate columns, run_date and run_time. Also instead of having date and/or time data type, they have integer data type. But don't worry, there is a system function in msdb database, called agent_datetime, which can be used to convert those run_date and run_time into a datetime data type.

So, to get the date and time of the last successful SQL Server Agent job(s) run, we can use the following script:

WITH jobhistory as (   
   SELECT    job_id,
             run_status,
             last_run_time = max(dbo.agent_datetime(run_date, run_time))
   FROM      msdb.dbo.sysjobhistory
   WHERE     step_id = 0
             AND run_status = 1
   GROUP BY job_id, run_status)

SELECT    j.job_id,
          j.name,
          jh.run_status,
          jh.last_run_time
FROM      msdb.dbo.sysjobs j
          LEFT OUTER JOIN jobhistory jh
          ON j.job_id = jh.job_id
ORDER BY j.name ASC

The script should be pretty straight forward. Basically, first we build a CTE to get the last successful time of each job from the sysjobhistory table. We do this by filtering those SQL Server agent jobs that have run status equal to 1 (success) for job step with id 0. Once we do that, we then create a join of the sysjobs table (which contains information such as the job name), with the CTE.

Sunday, October 7, 2012

Querying SQL Server Error Log

SQL Server error log offers good way to obtain information when troubleshooting SQL Server related problem. A while back, I wrote a blog post about reading SQL Server error log using Microsoft Log Parser. That blog post can be found here. There are many ways in which you can query the SQL Server error log. One of them is using the sys.sp_readerrorlog stored procedure. This stored procedure can be located in the master database. It accepts 4 input parameters:
  1. @p1 – integer: This parameter is to specify which error log to read. SQL Server error log would rollover. By default, SQL Server error log would keep a file for the current log and maximum 6 of archived logs (this setting can be changed easily), ERRORLOG, ERRORLOG.1, ERRORLOG.2, ERRORLOG.3, ERRORLOG.4, ERRORLOG5 and ERRORLOG6. ERRORLOG is where SQL Server stores the current error log, ERRORLOG.1 is where SQL Server stores the most recent archived, etc. If we put 0 or null on this parameter, we are querying the current error log (ERRORLOG). 1 would refer to ERRORLOG.1. The same concept would apply to SQL Server Agent error log.
  2. @p2 – integer: This parameter is to specify if we want to query the SQL Server Error Log or the SQL Server Agent Error Log. If we enter 1 or null, we are querying the SQL Server Error Log. However, if we enter 2, then we are querying the SQL Server Agent Error Log.
  3. @p3 – varchar(255): We can specify word or phrase that we are looking within the text/message on the SQL Server error log or SQL Server Agent error log.
  4. @p4 – varchar(255): We can specify word or phrase that we are looking within the text/message on the SQL Server error log or SQL Server Agent error log. If we enter a word or phrase on @p3 parameter and enter another word or phrase on @p4 parameter, the stored procedure should return error log entries that contain both words/phrases (AND operator). If we leave @p3 blank but enter a word or phrase on @p4, the stored procedure would not filter the error log. It will ignore the @p4 parameter filter.

Some Usage Examples

The following would return all entries on the current SQL Server error log (ERRORLOG):
EXEC sp_readerrorlog
or:
EXEC sp_readerrorlog 0
or:
EXEC sp_readerrorlog NULL, NULL, NULL, NULL
The following would return all entries on the current SQL Server Agent error log (SQLAGENT.OUT):
EXEC sp_readerrorlog 0, 2
The following would return entry from SQL Server error log when the SQL Server was starting the msdb database (in this case it was part of the server start up):
EXEC sp_readerrorlog 0, 1, 'starting', 'msdb'
This would returns:
image

Wait, There’s more…

If we look at the sp_readerrorlog stored procedure code closely, it is actually calling the xp_readererrorlog extended stored procedure. The xp_readerrorlog actually accepts more input parameter than the 4 input parameters described above. The following blog article described the parameters that xp_readerrorlog would accept. Basically it would accept 3 additional parameters:

  1. Log date from range – Date time: this parameter would help to filter the log entries from a specific time period.
  2. Log date to range – Date time: this parameter would help to filter the log entries to a specific time period.
  3. Ascending or Descending – Varchar: this parameter can be use to specify the sorting order of the log entries based on the log date. Enter ‘asc’ for ascending order, and ‘desc’ for descending order.
So, for example, if we want to get the list of current SQL Server error log entries between 6:27 PM and 6:28 PM today (7th October 2012), and list the log entries in the descending log date order, I can use the following query:
EXEC xp_readerrorlog 0, 1, NULL, NULL, '2012-10-07 18:27', '2012-10-07 18:28', 'desc'

Related Notes:

Wednesday, June 16, 2010

Querying SQL Server Agent Error Log with Microsoft LogParser

Last week I wrote about using Microsoft LogParser to query entries in SQL Error Log. You can read more about it here.

Normally, we would read or query SQL Agent Error Log using SQL Log Viewer. But just as SQL Error Log, SQL Server Agent Error Log is also text-based log. Thus, we can also use Microsoft LogParser to query the log(s).

What is SQL Server Agent Error Log?

SQL Server Agent Error Log contains information, warning or error messages related specifically to SQL Server Agent, information such as when SQL Server Agent service is started or stopped. By default, SQL Server Agent Error Log can be found under the following directory: C:\Program Files\Microsoft SQL Server\MSSQL.x\MSSQL\LOG\. It has file name of SQLAGENT.OUT or SQLAGENT.x.

Using Microsoft LogParser to Read SQL Server Agent Error Log

To output all of the SQL Server Agent Error Logs into a datagrid format, you can use the following command with Microsoft LogParser:

LogParser "SELECT TO_TIMESTAMP(STRCAT(STRCAT(Date,' '), Time), 'yyyy-MM-dd hh:mm:ss') AS DateTime, Message INTO DATAGRID FROM 'C:\Program Files\Microsoft SQL Server\MSSQL.1\MSSQL\LOG\SQLAGENT*'" -i:TSV -iSeparator:spaces -headerRow:OFF -iHeaderFile:C:\SQLAgentLogHeader.txt

Some explanations on the option used:

-i:TSV This is to indicate that the input file used is a TSV (Tab Separated Values) file
-iSeparator:spaces This is to specify that we use spaces as the separator between values
-iHeaderFile:C:\SQLAgentLogHeader.txt The SQLAgentLogHeader.txt file can be downloaded from the following location. If you open one of the SQL Server Agent Error Log, you would notice that it does not have any column header. What this option does is that it tell LogParser to use SQLAgentLogHeader.txt as the header format file. We can use the header specify in the header format file in our SQL query.
-i:headerRow:OFF This just to tell LogParser that the first row of the input file is not header.
-o:DATAGRID This is to indicate that we want the output into datagrid format

Additional Examples

To query entries in SQL Server Agent Error Log that are older than 1st January 2010, you can use the following command:

LogParser "SELECT TO_TIMESTAMP(STRCAT(STRCAT(Date,' '), Time), 'yyyy-MM-dd hh:mm:ss') AS DateTime, Message INTO DATAGRID FROM 'C:\Program Files\Microsoft SQL Server\MSSQL.1\MSSQL\LOG\SQLAGENT*' WHERE DateTime < TO_TIMESTAMP('01/01/2010', 'MM/dd/yyyy')" -i:TSV -iSeparator:spaces -headerRow:OFF -iHeaderFile:C:\SQLAgentLogHeader.txt

To find out when SQL Server Agent has been stopped:

LogParser "SELECT TO_TIMESTAMP(STRCAT(STRCAT(Date,' '), Time), 'yyyy-MM-dd hh:mm:ss') AS DateTime, Message INTO DATAGRID FROM 'C:\Program Files\Microsoft SQL Server\MSSQL.1\MSSQL\LOG\SQLAGENT*' WHERE Message LIKE '%SQLSERVERAGENT stopping%'" -i:TSV -iSeparator:spaces -headerRow:OFF -iHeaderFile:C:\SQLAgentLogHeader.txt