Jaa


sysmail_delete_mailitems_sp (Transact-SQL)

Permanently deletes e-mail messages from the Database Mail internal tables.

Topic link iconTransact-SQL Syntax Conventions

Syntax

sysmail_delete_mailitems_sp  [ [ @sent_before = ] 'sent_before' ]
    [ , [ @sent_status = ] 'sent_status' ]

Arguments

  • [ @sent_before= ] 'sent_before'
    Deletes e-mails up to the date and time provided as the sent_before argument. sent_before is datetime with NULL as default. NULL indicates all dates.
  • [ @sent_status= ] 'sent_status'
    Deletes e-mails of the type specified by sent_status. sent_status is varchar(8) with no default. Valid entries are sent, unsent, retrying, and failed. NULL indicates all statuses.

Return Code Values

0 (success) or 1 (failure)

Remarks

Database Mail messages and their attachments are stored in the msdb database. Messages should be periodically deleted to prevent msdb from growing larger than expected and to comply with your organizations document retention program. Use the sysmail_delete_mailitems_sp stored procedure to permanently delete e-mail messages from the Database Mail tables. An optional argument allows you to delete only older e-mails by providing a date and time. E-mails older than that argument will be deleted. Another optional argument allows you to delete only e-mails of a certain type, specified as the sent_status argument. Beginning with SQL Server 2005 Service Pack 1, you must provide an argument either for @sent_before or @sent_status. Both arguments cannot be NULL.

Deleting e-mail also deletes attachments related to those messages. Deleting e-mail does not delete the corresponding entries in sysmail_event_log. Use sysmail_delete_log_sp to delete items from the log.

Permissions

By default, this stored procedure is granted for execution to members off the sysadmin fixed server role and DatabaseMailUserRole. Members of the sysadmin fixed server role can execute this procedure to delete e-mails sent by all users. Members of DatabaseMailUserRole can only delete e-mails sent by that user.

Examples

A. Deleting all e-mails

The following example deletes all e-mails in the Database Mail system.

DECLARE @GETDATE datetime
SET @GETDATE = GETDATE()
EXECUTE msdb.dbo.sysmail_delete_mailitems_sp  @sent_before = @GETDATE;
GO

B. Deleting the oldest e-mails

The following example deletes e-mails in the Database Mail log that are older than October 9, 2005.

EXECUTE msdb.dbo.sysmail_delete_mailitems_sp 
    @sent_before = 'October 9, 2005' ;
GO

C. Deleting all e-mails of a certain type

The following example deletes all failed e-mails in the Database Mail log.

EXECUTE msdb.dbo.sysmail_delete_mailitems_sp 
    @sent_status = 'failed' ;
GO

See Also

Reference

sysmail_allitems (Transact-SQL)
sysmail_event_log (Transact-SQL)
sysmail_mailattachments (Transact-SQL)

Other Resources

How to: Create a SQL Server Agent Job to Archive Database Mail Messages and Event Logs
Troubleshooting Database Mail

Help and Information

Getting SQL Server 2005 Assistance

Change History

Release History

14 April 2006

New content:
  • Added the Service Pack 1 requirement that one of the arguments must be provided.