Stop the Hollyweb! No DRM in HTML5.   

Thursday, February 26, 2009

Send Database Mail from a Trigger

I was attempting to set up a trigger to send an email when a record was inserted into a table. I followed the instructions in Books Online, however, somewhere along the way, I ended up with the following error;

[SqlException (0x80131904): EXECUTE permission denied on object 'sp_send_dbmail', database 'msdb', schema 'dbo'.]

As I attempted to solve for this error, I ended up using EXECUTE AS in the trigger. When attempting to use this method, I received the following error;

[SqlException (0x80131904): Cannot execute as the server principal because the principal "SQLMail" does not exist, this type of principal cannot be impersonated, or you do not have permission.]

The I decieded to trun away from all the post that I was following on the internet and start from scratch in a test enviorment. Here’s what I did:

As dbo, create the database Principal that will use Test database to send the email.

USE [master]
GO
CREATE LOGIN [TestUser] WITH PASSWORD=N'password'
GO


Create the database Principal that will use msdb database to send the email.

USE [master]
GO
CREATE LOGIN [MailUser] WITH PASSWORD=
N'password'
GO
EXEC master..sp_addsrvrolemember @loginame = N'Mail_User', @rolename = N'
sysadmin'
GO


Now start setting up the mail. To send Database Mail using stored procedures, you must be a member of the DatabaseMailUserRole database role in the msdb database.

USE [msdb]
GO
CREATE USER [MailUser] FOR LOGIN [MailUser] WITH DEFAULT_SCHEMA=[dbo]
GO
USE [msdb]
GO
EXEC sp_addrolemember N'DatabaseMailUserRole', N'
MailUser'
GO


Execute permissions for sp_send_dbmail default to all members of the DatabaseMailUser database role in the msdb database.

To list all other members of the DatabaseMailUserRole execute the following statement:

EXEC msdb.sys.sp_helprolemember 'DatabaseMailUserRole';

Go to Surface Area configuration for features and expand Database engine option and select DatabaseMail option and checked Enable Database mail Stored procedure and click OK or Apply button.


Create a new Database Mail account.


EXECUTE msdb.dbo.sysmail_add_account_sp
@account_name = 'Test_Database_Mail',
@description = 'Mail account for testing sending email.',
@email_address = 'somebody@domain.com',
@replyto_address = 'somebody@domain.com',
@display_name = 'Clay McDonald',
@mailserver_name = 'mail.domian.com'



Create a Database Mail profile.


EXECUTE msdb.dbo.sysmail_add_profile_sp
@profile_name = 'Test_Email_Profile',
@description = 'Profile for testing sending email.'



Add the account to the profile.


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


Grant access to the profile to all users in the msdb database.

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


Check to see if Service Broker is enabled.

SELECT is_broker_enabled FROM sys.databases WHERE name = 'msdb';

is_broker_enabled will be 1 if Service Broker is enabled for the given database, otherwise it'll be 0.

To enable Service Broker run the following;

ALTER DATABASE msdb
SET ENABLE_BROKER;


Now test that Database Mail is working.

EXEC msdb.dbo.sp_send_dbmail
@profile_name = 'Test_Email_Profile',
@recipients='somebody@domain.com',
@body = 'This is a test for Database Mail.',
@body_format = 'TEXT',
@subject =
'Database Mail Test'
-- eMail sent!


Now I create my test database.

USE [master]
GO
CREATE DATABASE [Test] ON PRIMARY
( NAME = N'Test', FILENAME = N'D:\MSSQL\DATA\Test.mdf' , SIZE = 2048KB , MAXSIZE = UNLIMITED, FILEGROWTH = 1024KB )
LOG
ON
( NAME = N'Test_log', FILENAME = N'D:\MSSQL\LOG\Test_log.ldf' , SIZE = 1024KB , MAXSIZE = 2048GB , FILEGROWTH = 10%)
GO
EXEC dbo.sp_dbcmptlevel @dbname=N'Test', @new_cmptlevel=90
GO


Then create test table that will fire the trigger.

USE [Test]
GO
CREATE TABLE [dbo].[NewMail](
[ID] [int] IDENTITY(1,1) NOT NULL,
[Some_Text] [varchar](max) NULL
)
GO


Create the trigger.

USE Test
GO
CREATE TRIGGER TestMailTrigger
ON dbo.NewMail
AFTER INSERT
AS
BEGIN
EXEC msdb.dbo.sp_send_dbmail
@profile_name = 'Test_Email_Profile',
@recipients='somebody@domain.com',
@body = 'This is a test for Database Mail.',
@body_format = 'TEXT',
@subject =
'Database Mail Test'
END
GO


Test the trigger.

USE Test
GO
INSERT INTO dbo.NewMail (Some_Text)
VALUES('Fire the trigger to send mail')
GO
-- Mail sent!


Now we test logging in as TestUser. First, add TestUser to the Test database.

USE [Test]
GO
CREATE USER [TestUser] FOR LOGIN [TestUser] WITH DEFAULT_SCHEMA=[dbo]
GO
USE [Test]
GO
EXEC sp_addrolemember N'db_datareader',
N'TestUser'
GO
USE [Test]
GO
EXEC sp_addrolemember N'db_datawriter', N'TestUser'
GO


Now, disconnect and reconnect as Test_User.

USE Test
GO
INSERT INTO dbo.NewMail (Some_Text)
VALUES('Fire the trigger to send mail')
GO
-- It works!


NOTE: 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. You must provide an argument either for @sent_before or @sent_status. To delete all messages, use @sent_before = getdate().

If you have permission issues, you can start over by deleting Database Mail Accounts.
In SQL Mgt Studio, under Management -> Database Mail, you can select “Manage Database Mail accounts and profile”. Here you’ll find options for managing accounts and profiles.


Wednesday, February 25, 2009

Receiving Error: 18461 When Attempting to Move System Databases

I was attempting to move the master, tempdb, msdb, and model. After I added the –c option, -m option, and set trace flag 3608, and restarted, I got Error: 18461 when attempting to either connect via SSMS or sqlcmd in the consol. I had no idea what the problem was. Here is how it all played out;

I logged onto the Database Server remotely. In the SQL Server Configuration Manager, I added the –c option, the –m option, and set trace flag 3608 in Startup Parameters with (;-c;-m;-T3608).

I stopped all SQL Services (SSIS, FullText, Analysis Services, Reporting, SQL Server Browser, and SQL Agent) and restarted SQL Server (MSSQLSERVER).

When I attempted to connect via SSMS or sqlcmd in the consol, I receive the following error;

Login failed for user 'cmcdonald'. Reason: Server is in single user mode. Only one administrator can connect at this time. (Microsoft SQL Server, Error: 18461)

Then I attempted to login with Dedicated Administration Connection (DAC). I did this by opening SSMS window without connecting to a SQL Server. Then I clicked on the Database Engine Query button .
Next, I added ADMIN: and the name of my SQL Server Instance.


When I clicked Connect, I was connected to the instance. You can also connect with sqlcmd:


sqlcmd -A -d testDB -E -S \namedinstance


-A is for the DAC
-d is for the database
-E is for integrated security
-S is for the instance (in this example, a named instance)

Now I begin moving system databases starting with the model database.

1. Detach the model database by using the following commands:


use master
go
sp_detach_db 'model’
go


2. Move the Model.mdf and Modellog.ldf files from the D:\Mssql7\Data folder to the E:\Sqldata folder.


3. Reattach the model database by using the following commands:

use master
go
sp_attach_db
'model','E:\Sqldata\model.mdf','E:\Sqldata\modellog.ldf'
go


4. Remove -c -m -T3608 from the startup parameters in SQL Server Configuration Manager.


5. Stop and then restart SQL Server. You can verify the change in file locations by using the sp_helpfile stored procedure. For example, use the following command:

use model
go
sp_helpfile
go


Next, moved the msdb database.


1. Add -c -m -T3608(;-c;-m;-T3608) in the startup parameters in the SQL Server Configuration Manager and then restart SQL Server.


2. Make sure that the SQL Server Agent service is not currently running.


3. Log in with DAC and detach the msdb database as follows:


use master
go
sp_detach_db 'msdb'
go


Note: If your login fails, you may need to restart the windows server.


4. Move the Msdbdata.mdf and Msdblog.ldf files from the current location (D:\Mssql8\Data) to the new location (E:\Mssql8\Data).


5. Remove -c -m -T3608 from the startup parameters box in Enterprise Manager.


6. Then stop and restart SQL Server.


7. Reattach the msdb database as follows:


use master
go
sp_attach_db
'msdb','E:\Sqldata\msdbdata.mdf’,'E:\Sqldata\msdblog.ldf’
go


To moved the master database, do the following;

1. Change the path for the master data files and the master log files in SQL Server Enterprise Manager. Note: You may also change the location of the error log here.

2. Right-click the SQL Server in Enterprise Manager and then click Properties.

3. Click Startup Parameters to see the following entries:

-dD:\MSSQL7\data\master.mdf
-eD:\MSSQL7\log\ErrorLog
-lD:\MSSQL7\data\mastlog.ldf

-d is the fully qualified path for the master database data file.
-e is the fully qualified path for the error log file.
-l is the fully qualified path for the master database log file.

4. Change these values as follows:

a. Remove the current entries for the Master.mdf and Mastlog.ldf files.

b. Add new entries specifying the new location.

c.

-dE:\SQLDATA\master.mdf
-lE:\SQLDATA\mastlog.ldf

5. Stop SQL Server.
6. Copy the Master.mdf and Mastlog.ldf files to the new location (E:\Sqldata).
7. Restart SQL Server.

Move tempdb files by using the ALTER DATABASE statement.

1. Determine the logical file names for the tempdb database by using sp_helpfile as follows:

use tempdb
go
sp_helpfile
go


-- tempdev 1 G:\MSSQL\tempdb.mdf PRIMARY
-- templog 2 G:\MSSQL\templog.ldf NULL


The logical name for each file is contained in the name column. This example uses the default file names of tempdev and templog.

2. Use the ALTER DATABASE statement, specifying the logical file name as follows:

use master
go
Alter database tempdb modify file (name = tempdev, filename = ' E:\Sqldata\tempdb.mdf')
go
Alter database tempdb modify file (name = templog, filename = ' E:\Sqldata\templog.ldf')

go

You should receive the following messages that confirm the change:

Message 1

File 'tempdev' modified in sysaltfiles. Delete old file after restarting SQL Server.

Message 2

File 'templog' modified in sysaltfiles. Delete old file after restarting SQL Server.

3. Using sp_helpfile in tempdb will not confirm these changes until you restart SQL Server.

4. Stop and then restart SQL Server.


Here are some helpful links;

Moving System Databases: http://support.microsoft.com/kb/224071
Using DAC: http://msdn.microsoft.com/en-us/library/ms178068.aspx
SQL Server Startup Options: http://msdn.microsoft.com/en-us/library/ms190737.aspx