SQL Server Database Mail and SQL Agent Mail setup by using a script

By:   |   Comments (8)   |   Related: > Database Mail


Problem

I was in the middle of upgrading many servers to SQL Server 2005 and SQL Server 2008.  As I was setting up Database Mail and the SQL Server Agent Alert System I wanted to create a script that I could use to do this instead of having to do this manually through the GUI. In this tip I provide a script with a few parameters that need to be setup to configure and turn on both of these features.

Solution

SQL 2005 and later versions have this new option to use SMTP to send email from SQL Server and this can be setup using the GUI or by using scripts.  In this tip, I go through the steps to set this up by only using scripts.


The following breaks down the overall script into four sections, so I can explain what each section does.  The entire script can be download from here which I encourage you to use instead of having to piece the sections together.

 

Section 1 - Declare and Set Values

Before you run the script, you will need to fill out some information for your environment.  The four values that need to be set are:

  • @SMTPServer - You will need to get SMTP server that you want to use to send email out.
  • @AdminEmail  - After setup, the script will send test email to this email address
  • @DomainName - This will be part of SQL Server Email Name
  • @replyToEmail - this is how you will see for reply to email when you get the email.
use master
DECLARE @SMTPServer VARCHAR(100)
DECLARE @AdminEmail VARCHAR(100)
DECLARE @DomainName VARCHAR(100)
DECLARE @replyToEmail VARCHAR(100)
   
SET @SMTPServer = 'smtp.mydomain.com'
SET @AdminEmail = '[email protected]'
SET @DomainName = '@mydomain.com'
SET @replyToEmail = '[email protected]'

Section 2 - Change Global Configuration Settings

In order to setup Database Mail and SQL Agent mail, you will need to turn on two global configuration settings.

exec sp_configure 'show advanced options', 1
exec sp_configure 'Database Mail XPs', 1
exec sp_configure 'Agent XPs',1
RECONFIGURE WITH OVERRIDE

Section 3 - Database Mail Configuration

This will setup database mail. It does not require the SQL Server service to be restarted. At the end of the script, it will send a Test Mail.

The email address that will be configured for Database Mail is based on the server name.  So if your server name is "ProdServer1" and your domain is "MyDomain.com" the email address that this script creates is "[email protected]". If you want something different you will need to modify the script.

Also, this uses "anonymous authentication" for the mail server.  If you want to provide other parameters take a look at these system stored procedures; sysmail_add_account_sp, sysmail_add_profile_sp, sysmail_add_profileaccount_sp and sysmail_add_principalprofile_sp.

declare @servername varchar(100)
declare @email_address varchar(100)
declare @display_name varchar(100)
declare @testmsg varchar(100)
set @servername = replace(@@servername,'\','_')
set @email_address = @servername + @DomainName
set @display_name = 'MSSQL - ' + @servername
set @testmsg = 'Test from ' + @servername
IF EXISTS(SELECT * from msdb.dbo.sysmail_profile)
PRINT 'DB mail already configured'
ELSE
BEGIN
  --Create database mail account.
   exec msdb.dbo.sysmail_add_account_sp
   @Account_name = 'SQLMail Account'
   , @description = 'Mail account for use by all database users.'
   , @email_address = @email_address
   , @replyto_address = @replyToEmail
   , @display_name = @display_name
   , @mailserver_name = @SMTPServer
   --Create global mail profile.
   exec msdb.dbo.sysmail_add_profile_sp
   @profile_name = 'SQLMail Profile'
   , @description = 'Mail profile setup for email from this SQL Server'
   --Add the account to the profile.
   exec msdb.dbo.sysmail_add_profileaccount_sp
   @profile_name = 'SQLMail Profile'
   , @Account_name = 'SQLMail Account'
   , @sequence_number=1
   --grant access to the profile to all users in the msdb database
   use msdb
   exec msdb.dbo.sysmail_add_principalprofile_sp
   @profile_name = 'SQLMail Profile'
   , @principal_name = 'public'
  , @is_default = 1
END
--send a test message.
exec msdb..sp_send_dbmail
@profile_name = 'SQLMail Profile', 
@recipients = @AdminEmail,
@subject = @testmsg,
@body = @testmsg

EXEC msdb.dbo.sysmail_help_profile_sp

 


Section 4 - SQL Agent Mail Configuration

Once Database Mail is setup, you now can enable SQL Agent notifications. To take affect, this may require the SQL Agent Service to be restarted.

In order to send out email from SQL Agent you need to configure the Alert System.  The script below will do this.  In uses the extended stored procedure "xp_instance_regwrite" to write two values to the registry.  The first setting just tells the SQL Agent Alert System to use Database Mail as the email option and the second setting tells the SQL Agent Alert System which mail profile to set.  The value "SQLMail Profile" was the name that was given in Section 3.

-- Enabling SQL Agent notification
USE [msdb]
EXEC msdb.dbo.sp_set_sqlagent_properties 
 @email_save_in_sent_folder=1
 
EXEC master.dbo.xp_instance_regwrite 
 N'HKEY_LOCAL_MACHINE'
 , N'SOFTWARE\Microsoft\MSSQLServer\SQLServerAgent'
 , N'UseDatabaseMail'
 , N'REG_DWORD'
 , 1
 
EXEC master.dbo.xp_instance_regwrite 
 N'HKEY_LOCAL_MACHINE'
 , N'SOFTWARE\Microsoft\MSSQLServer\SQLServerAgent'
 , N'DatabaseMailProfile'
 , N'REG_SZ'
 , N'SQLMail Profile'

There are many things that you can automate by scripting when it comes to SQL Server related tasks. This saves a lot of time if you need to do this over and over again as well as to ensure things are kept consistent.

Next Steps


sql server categories

sql server webinars

subscribe to mssqltips

sql server tutorials

sql server white papers

next tip



About the author
MSSQLTips author Kun Lee Kun Lee is a database administrator and his areas of interest are database administration, architecture, data modeling and development.

This author pledges the content of this article is based on professional experience and not AI generated.

View all my tips



Comments For This Article




Friday, September 25, 2015 - 3:54:22 PM - kiran Back To Top (38756)

Dear Sir

 Actually when i was run script i got below error

DB mail already configured

Msg 14607, Level 16, State 1, Procedure sysmail_verify_profile_sp, Line 42

profile name is not valid

 

(0 row(s) affected)

 

(0 row(s) affected)


Tuesday, May 15, 2012 - 3:25:28 AM - sylvia moestl vasilik Back To Top (17459)

Very helpful script - thank you!


Thursday, June 3, 2010 - 4:14:04 PM - rsbutterfly16 Back To Top (5646)

yes, i did a failover over to another node in the mscs cluster, and when i moved back, i noticed that i was'nt getting any of my alerts, i checked sql agent and i noticed that the "enable mail profile" box was unchecked.   Is there a configuration i need to have, i know that i had this checked before.


Thursday, June 3, 2010 - 3:52:11 AM - --cranfield Back To Top (5643)

are you failing over in an MSCS cluster? Please explain.  I'm not aware of an issue like this.  tks


Wednesday, June 2, 2010 - 9:06:50 PM - rsbutterfly16 Back To Top (5639)

hi, if i set up the mail profile in SQL agent using your script and then i do a failover will the mail profile checkbox would remain checked? I did that as a test and once i did the failback the email mail profile checkbox was unchecked.  Is there something i need to change for this not to happen?


Thursday, January 14, 2010 - 11:06:02 AM - admin Back To Top (4713)

This script is related to SQL 2005 or 2008.

For SQL 2000 you have to setup a MAPI client usually Outlook to get this to work.

Take a look at this article http://support.microsoft.com/kb/312839 as a different approach.

 

 


Thursday, January 14, 2010 - 10:37:12 AM - yakaaithiri Back To Top (4712)

hi ,

 i have tried using this script but all in vain only.

In my environment i have SQL server 2000 , in MS server 2003.

My company uses LOtus notes for mails.

 Please help me to configure Database mail.

Regards,

Balabharathi Narayanan


Friday, April 24, 2009 - 1:26:08 AM - EdVassie Back To Top (3243)

A great script!

You may also want to try SQL Server FineBuild, available at Codeplex.  This gives 1-click installation and best-practice configuration of SQL Server 2005 and 2008.  DB Mail setup is just one part of what FineBuild does. 















get free sql tips
agree to terms