Blog Post

Sending Mail using SQL Server Express Edition

,

In SQL server standard and enterprise edition,A DataBase mail functionality in built to sent mail.But in SQL Server express edition,You need either use CLR integration or configure SQL Mail using MSDB system database.
Here I am discussing sending mail using MSDB system database.By default the MSDB database installed when you install SQL Server.The below tables used to confiure sysmail account.

















To configure SQL mail we need to follow below steps.


  1. Create Sysmail Account
Use sysmail_add_account_sp stored procedure of MSDB database to configure sysmail   account.
EXECUTE msdb.dbo.sysmail_add_account_sp
@account_name = 'MailTest',
@description = 'Sent Mail using MSDB',
@email_address = 'umashankar@queryingsql.com',
@display_name = 'umashankar',
@username='umashankar@queryingsql.com',
@password='password',
@mailserver_name = 'mail.queryingsql.com'
      
  1. Creating Database Profile
Use sysmail_add_profile_sp stored procedure of MSDB database to configure Database Profile.
EXECUTE msdb.dbo.sysmail_add_profile_sp
@profile_name = 'MailTest',
@description = 'Profile used to send mail'


  1. Add database Mail account to profile
Use sysmail_add_profileaccount_sp stored procedure of MSDB database to map database mail account to Profile.


EXECUTE msdb.dbo.sysmail_add_profileaccount_sp
@profile_name = 'MailTest',
@account_name = 'MailTest',
@sequence_number = 1


  1. Grants permission for a database user or role to use a Database Mail profile.
To Grants permission for a database user or role to use a Database Mail profile use                     sysmail_add_principalprofile_sp.


EXECUTE msdb.dbo.sysmail_add_principalprofile_sp
@profile_name = 'MailTest',
@principal_name = 'public',
@is_default = 1 ;


--A principal_name of 'public' makes this profile a public profile, granting access to all principals in the database.


  1. You can query to test data
SELECT *FROM msdb.dbo.sysmail_account
SELECT *FROM msdb.dbo.sysmail_configuration
SELECT *FROM msdb.dbo.sysmail_principalprofile
SELECT *FROM msdb.dbo.sysmail_profile
SELECT *FROM msdb.dbo.sysmail_profileaccount
SELECT *FROM msdb.dbo.sysmail_profileaccount


  1. Send Mail using Created Profile


exec msdb.dbo.sp_send_dbmail @profile_name = 'MailTest', @recipients = 'receiver@queryingsql.com', @subject = 'Mail Test', @body = 'Mail Sent Successfully', @body_format = 'text'


If all things are going right,Mail sent successfully.But when I tried I found this error.
Msg 15281, Level 16, State 1, Procedure sp_send_dbmail, Line 0
SQL Server blocked access to procedure 'dbo.sp_send_dbmail' of component 'Database Mail XPs' because this component is turned off as part of the security configuration for this server. A system administrator can enable the use of 'Database Mail XPs' by using sp_configure. For more information about enabling 'Database Mail XPs', see "Surface Area Configuration" in SQL Server Books Online.



  1. This error occured due to 'Database Mail XPs' disabled.To enable this use this code
sp_configure 'show advanced options', 1;
GO
RECONFIGURE;
GO
sp_configure 'Database Mail XPs', 1;
GO
RECONFIGURE
GO

  1. Try to send mail again.I hope it works successfully.But If you tried this using Microsoft Exchange Server Mail ID,It will not work properly.Because maybe This is turned out to be an issue with a rule on the exchange server.

Rate

You rated this post out of 5. Change rating

Share

Share

Rate

You rated this post out of 5. Change rating