Stop the Hollyweb! No DRM in HTML5.   

Thursday, October 1, 2009

Adding Leading Zeros in T-SQL

Today I ran into a situation where I had a character data type column that contained product ID numbers and these numbers were missing leading numbers. The column was a CHAR(11) as all product IDs should begin with leading zeros and be 11 characters long. To add leading zeros to a NVACHAR, VARCHAR, OR CHAR type column, use the RIGHT function.

SELECT RIGHT('00000000000' + LTRIM(RTRIM(PRODUCT_ID)),11) AS PRODUCT_ID

Or;

SELECT RIGHT(REPLICATE('0', 11) + LTRIM(RTRIM(PRODUCT_ID)),11) AS PRODUCT_ID

Monday, September 14, 2009

PASS SQL Summit 2009 Discount Code

With time running out for taking advantage of the pre-registration discounts to PASS 2009, here is a discount code for $100 off the registration fee. Get $100 off SQL Summit with code 24HR3D. See you at PASS 2009!

Friday, September 11, 2009

Microsoft Launches Non-Profit Open Source Foundation


I’m not sure what to think of this. I have always been a fan of the open source movement. I know, then why am I a Microsoft DBA? I can only say, at the time, my employers required me to support Microsoft products. And after working with SQL Server for many years, I became comfortable with it.

Anyway, Microsoft launched a new Non-Profit Open Source Foundation yesterday named, The CodePlex Foundation. And already, there are a lot of discussions about it. I think that Microsoft is trying to continue to build its community by having developers create open source software that will assist the community as a whole.

Also, I have no doubt that Microsoft has a business motivation in this as well, because after all, Microsoft is a profit driven company. It could be that Microsoft would like to see if there are ways for them sell their products to entities that run open source, or it could be something more. Either way, I don’t believe open source developers will embrace it as evident in this Slashdot post.

The CodePlex Foundation : http://codeplex.org/

Thursday, September 10, 2009

New SQL Server Background


I just picked up on Twitter that Buck Woody (MSFT) has published a blog post about SQL Server Desktop Screen Background. Use the link below to get it.

http://blogs.msdn.com/buckwoody/archive/2009/09/07/sql-server-desktop-screen-background.aspx


Friday, July 31, 2009

SQL Server Snapshot Sparse File Size

When you execute the CREATE AS SNAPSHOT sql statement, the snapshot creates a NTFS sparse file. In a sparse file only “nonzero” information is stored on the disk. The maximum size of a database snapshot is the size of the source database at snapshot creation. In Windows Explorer, the snapshot files are shown with a size matching that of the source database. However, when you go into the file properties you will see that the size on disk is 0KB or a multiple of 64KB (representing 1-8 data pages) if some data has been transferred.

At the beginning, there is no source/user data in the snapshot file. It’s only after changes are made in the source database that data pages get written to the snapshot file. When a data page in the source database is changed, the original data page is first copied to the snapshot file before updating in the source database (copy-on-write). The first time any page is written to the sparse file the entire 64K extent is allocated. All other pages in the extent are written as zero's.

When a sparse file is populated, Windows limits the amount of data that may reside in the file. Once the amount of data stored in the sparse file exceeds the limit further data storage in the file may be prevented.

• Windows 2003 - 64GB (Error 1450 returned)
• Windows 2008 and Vista - 16GB (Error 665 returned)


Windows 2003 Error: The operating system returned error 1450(Insufficient system resources exist to complete the requested service.) to SQL Server during a write at offset 0x000031abb4e000 in file with handle 0x00000F74. This is usually a temporary condition and the SQL Server will keep retrying the operation. If the condition persists then immediate action must be taken to correct it.

Windows 2008 Error: The operating system returned error 665(The requested operation could not be completed due to a file system limitation) to SQL Server during a write at offset 0x000005bd3dc000 in file 'Test.mdf:MSSQL_DBCC8'

Let’s take a look at what takes place when the snapshots are created.
  • A sparse file is created. This file will have the same file size as the database. Remember, the only data that may be contained in the snapshot file at this point are pointers to the source database data files. Only after something changes in the source database will copy-on-write insert data into the snapshot file.
  • The database is checkpointed (all dirty pages in the buffer cache are written to disk).
  • If uncommitted transactions are in progress in the database, the snapshot will reflect the state of the database before these transactions started in other words, in the context of the snapshot, these transactions will be rolled back – but transactions in the database itself are not.
  • The snapshot is brought online and is ready for use.
Quick Note:

From a Disaster Recovery standpoint, SQL Server snapshots are not very useful as they require an online database to function. In situations where there is a hardware failure, the database is no longer online and the snapshot becomes useless. Also, snapshots cannot be restored when users are accessing the database. So if there is a roll back in progress or some other process that does not allow the database’s state to be changed, snapshot restores can not be applied. However, in situations where an object was accidently deleted or altered, and needs to be restored, snapshots are ideal.

For a more detailed look inside how Copy-On-Write works, see: http://blogs.msdn.com/psssql/archive/2009/01/20/how-it-works-sql-server-sparse-files-dbcc-and-snapshot-databases-revisited.aspx

Wednesday, July 1, 2009

Can’t Delete Jobs (Microsoft SQL Server, Error: 547)

I was creating a new job to handle weekly database maintenance and when I attempted to delete the old job, I received the following error;

TITLE: Microsoft SQL Server Management Studio
------------------------------
Drop failed for Job 'Weekly_Maintenance'. (Microsoft.SqlServer.Smo)

For help, click: http://go.microsoft.com/fwlink?ProdName=Microsoft+SQL+Server&ProdVer=9.00.1399.00&EvtSrc=Microsoft.SqlServer.Management.Smo.ExceptionTemplates.FailedOperationExceptionText&EvtID=Drop+Job&LinkId=20476

------------------------------
ADDITIONAL INFORMATION:
An exception occurred while executing a Transact-SQL statement or batch. (Microsoft.SqlServer.ConnectionInfo)
------------------------------
The DELETE statement conflicted with the REFERENCE constraint "FK_subplan_job_id". The conflict occurred in database "msdb", table "dbo.sysmaintplan_subplans", column 'job_id'.

The statement has been terminated. (Microsoft SQL Server, Error: 547)
------------------------------


If you try deleting the job from the sysmaintplan_subplans table, you also get the following error:

Msg 547, Level 16, State 0, Line 41

The DELETE statement conflicted with the REFERENCE constraint "FK_sysmaintplan_log_subplan_id". The conflict occurred in database "msdb", table "dbo.sysmaintplan_log", column 'subplan_id'.


I wanted to create a stored procedure that I could just pass a job name to and it would check each of the tables and delete all references for me. Here is what I came up with.

CREATE PROC dbo.DropJob
@JobName AS VARCHAR(200) = NULL
AS

DECLARE @msg AS VARCHAR(500);

IF @JobName IS NULL
BEGIN
SET @msg = N'A job name must be supplied for parameter @JobName.';
RAISERROR(@msg,16,1);
RETURN;
END
IF EXISTS (
SELECT subplan_id FROM msdb.dbo.sysmaintplan_log WHERE subplan_id IN

( SELECT subplan_id FROM msdb.dbo.sysmaintplan_subplans WHERE job_id IN
(SELECT job_id FROM msdb.dbo.sysjobs_view WHERE name = @JobName)))
BEGIN
DELETE FROM msdb.dbo.sysmaintplan_log WHERE subplan_id IN

( SELECT subplan_id FROM msdb.dbo.sysmaintplan_subplans WHERE job_id IN
(SELECT job_id FROM msdb.dbo.sysjobs_view WHERE name = @JobName));

DELETE FROM msdb.dbo.sysmaintplan_subplans WHERE job_id IN
(SELECT job_id FROM msdb.dbo.sysjobs_view WHERE name = @JobName);

EXEC msdb.dbo.sp_delete_job @job_name=@JobName, @delete_unused_schedule=1;
END
ELSE IF EXISTS (
SELECT subplan_id FROM msdb.dbo.sysmaintplan_subplans WHERE job_id IN
(SELECT job_id FROM msdb.dbo.sysjobs_view WHERE name = @JobName))
BEGIN

DELETE FROM msdb.dbo.sysmaintplan_subplans WHERE job_id IN
(SELECT job_id FROM msdb.dbo.sysjobs_view WHERE name = @JobName);

EXEC msdb.dbo.sp_delete_job @job_name=@JobName, @delete_unused_schedule=1;
END
ELSE
BEGIN
EXEC msdb.dbo.sp_delete_job @job_name=@JobName, @delete_unused_schedule=1;

END
GO

Now you can call the SP with the following;

USE [msdb];
EXEC dbo.DropJob @JobName = N'Shrink_AWP_Databases.Subplan_1';

Wednesday, June 24, 2009

Convert Legacy 6 Character and 7 Character CC YY MM DD (ISO) Dates

The dates are stored as Century, Year, Month, and Day, where Century is 0 for 19 and 1 for 20, years are stored as two digits, and months and days always have leading zeros. In this example, somewhere along the way, the leading zeros for the Century were dropped.

Sample Data:


Let’s start solving this by creating our test data.

CREATE TABLE [dbo].[TestDates](
[Row_ID] [numeric](18, 0) IDENTITY(1,1) NOT NULL,
[Legacy_Date] [varchar](8),
[SQL_Date] [datetime])
GO


INSERT INTO [HI_Plaintiff].[dbo].[TestDates] ([Legacy_Date])
VALUES('1000118')
GO

INSERT INTO [HI_Plaintiff].[dbo].[TestDates] ([Legacy_Date])
VALUES('1000229')
GO

INSERT INTO [HI_Plaintiff].[dbo].[TestDates] ([Legacy_Date])
VALUES('1000509')
GO

INSERT INTO [HI_Plaintiff].[dbo].[TestDates] ([Legacy_Date])
VALUES('960426')
GO

INSERT INTO [HI_Plaintiff].[dbo].[TestDates] ([Legacy_Date])
VALUES('981003')
GO

INSERT INTO [HI_Plaintiff].[dbo].[TestDates] ([Legacy_Date])
VALUES('950899')
GO

Here is a simple query that will only update valid ISO dates to SQL Server’s datetime data type.

UPDATE dbo.TestDates
SET SQL_Date = CONVERT(VARCHAR(10), CONVERT(DATETIME, CONVERT(VARCHAR(8), Legacy_Date + 19000000)), 101)
WHERE ISDATE(CONVERT(VARCHAR(8), Legacy_Date + 19000000)) = 1

GO

Wednesday, June 10, 2009

Copy Several Tables to a Different Database Using Dynamic SQL

Here is a quick example of how to used dynamic SQL in a cursor to copy several tables from one database to another. I was given a list of 150 tables that one of my customers needed to be copied. I didn’t want to script all of them so I created this cursor. All you need to do is create a list of the tables to be copied.

In this example, I’m using Excel. In my list the SOURCE is the name of the table that we are copying from and the TARGET is where it’s being copied to.

In the SOURCE database, create the following table.

CREATE TABLE [dbo].[TRANSFER_TABLE_LIST](
[SOURCE_TABLE] [varchar](100),
[SOURCE_SCHEMA] [varchar](100),
[SOURCE_DATABASE] [varchar](100),
[TARGET_TABLE] [varchar](100),
[TARGET_SCHEMA] [varchar](100),
[TARGET_DATABASE] [varchar](100)
)
GO

Now, import your table list into the TRANSFER_TABLE_LIST table and create the following cursor.
DECLARE @SQL AS VARCHAR (2000), @SOURCE_TABLE AS VARCHAR (100),
@SOURCE_SCHEMA AS VARCHAR (100), @SOURCE_DATABASE AS VARCHAR (100),
@TARGET_TABLE AS VARCHAR (100), @TARGET_SCHEMA AS VARCHAR (100),
@TARGET_DATABASE AS VARCHAR (100)
DECLARE c1 CURSOR READ_ONLY
FOR
SELECT
[SOURCE_TABLE]
,[SOURCE_SCHEMA]
,[SOURCE_DATABASE]
,[TARGET_TABLE]
,[TARGET_SCHEMA]
,[TARGET_DATABASE]
FROM [dbo].[TRANSFER_TABLE_LIST]
OPEN c1
FETCH NEXT FROM c1
INTO @SOURCE_TABLE, @SOURCE_SCHEMA, @SOURCE_DATABASE, @TARGET_TABLE, @TARGET_SCHEMA, @TARGET_DATABASE
WHILE @@FETCH_STATUS = 0
BEGIN

SET @SQL = 'SELECT * INTO [' + @TARGET_DATABASE + '].[' + @TARGET_SCHEMA + '].['
SET @SQL = @SQL + @TARGET_TABLE + '] FROM [' + @SOURCE_DATABASE + '].['
SET @SQL = @SQL + @SOURCE_SCHEMA + '].[' + @SOURCE_TABLE + '];'
EXEC (@SQL)


FETCH NEXT FROM c1
INTO @SOURCE_TABLE, @SOURCE_SCHEMA, @SOURCE_DATABASE, @TARGET_TABLE, @TARGET_SCHEMA, @TARGET_DATABASE
END
CLOSE
c1
DEALLOCATE c1


If you receive the following error:

Msg 203, Level 16, State 2, Line 23
The name 'SELECT * INTO [TransCorpReporting].[dbo].[Products_cust_trans] FROM [TransCorp].[dbo].[Products_cust_trans];' is not a valid identifier.


This means that you forgot to add ( ) around the @SQL variable.

Monday, March 16, 2009

Visit Falafel King at PASS 2009



If you’ve been to the PASS Community Summit before, you’ll know that PASS does a great job at providing meals during the Summit. However, if you should miss meal time, don’t worry, just walk down Pike Street to 1st Street. There you’ll find Falafel King.

Falafel King in downtown Seattle is the best purveyor of Middle Eastern food I have ever had the privilege of patronizing. You can get an awesome meal for under $10.00. If you ever visit Seattle, you need to pay Falafel King a visit!

PASS: http://www.sqlpass.org/

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