Tuesday, August 3, 2010

Moving the System databases for SQL 2005 on a cluster

Background

Best practices for SQL configuration recommend moving system databases, particularly the TempDB, to a separate drive.  On a cluster, this drive must be a shared cluster resource that is, like all drives supporting the SQL instance, a dependent cluster resource.  While there is no need to separate out the data and log files for system databases, the following instructions will assist in moving system files together to a separate clustered drive.  In the examples below, assume E:\ is a clustered drive resource which can be replaced with whatever specific drive is designed for each particular instance.

1.0 Moving Model Database Files



  1. In Cluster Admin, shut down SQL Server and SQL component cluster resources.

  2. Navigate to a command prompt on the active node and start the SQL server using startup parameters:


"C:\Program Files\Microsoft SQL Server\MSSQL.1\MSSQL\Binn\sqlservr.exe" –s<instance name> –c –m –T3608

NOTE:  Cluster resources for drives, virtual server, and IP address must be online. Also, for more information on the startup parameters, see http://technet.microsoft.com/en-us/library/ms190737.aspx and http://technet.microsoft.com/en-us/library/ms188396.aspx

  1. Ensure the SQL Browser has been restarted.

  2. Open SQL Server Management Studio but cancel the login dialog

  3. Close the Object Explorer window.

  4. Click on New Query and log in as Admin (i.e., ADMIN:ServerName\InstanceName) using sa account (assuming the sa account is system administrator account).

  5. Use the following query:


use master
go
sp_detach_db 'model'
go


  1. Move the Model.mdf and Modellog.ldf files from the current location to the desired location.

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


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

(NOTE:  Replace the filepath above with the new location of the files.)

10.  Close SQL Server Management Studio

11.  Shut down SQL by typing Ctrl + C at the command prompt where you started SQL.

12.  Bring SQL Resource online in Cluster Administrator.

13.  Open SQL Server Management Studio (you should be able to log in normally as you are no longer in single-user mode).

14.  Verify the location of the model files by running the following query:
use model
go
sp_helpfile
go

2.0 Moving MSDB Database Files



  1. In Cluster Admin, shut down SQL Server and SQL component cluster resources.

  2. Navigate to a command prompt on the active node and start the SQL server using startup parameters:


"C:\Program Files\Microsoft SQL Server\MSSQL.1\MSSQL\Binn\sqlservr.exe" –s<instance name> –c –m –T3608

NOTE: Cluster resources for drives, virtual server, and IP address must be online.

  1. Ensure the SQL Browser has been restarted.

  2. Open SQL Server Management Studio but cancel the login dialog

  3. Close the Object Explorer window.

  4. Click on New Query and log in as Admin (i.e., ADMIN:ServerName\InstanceName) using sa account (assuming the sa account is system administrator).

  5. Use the following query:


use master
go
sp_detach_db 'msdb'
go


  1. Move the Model.mdf and Modellog.ldf files from the current location to the desired location.

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


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

(NOTE:  Replace the filepath above with the new location of the files.)

10.  Close SQL Server Management Studio

11.  Shut down SQL by typing Ctrl + C at the command prompt where you started SQL.

12.  Bring SQL Resource online in Cluster Administrator.

13.  Open SQL Server Management Studio (you should be able to log in normally as you are no longer in single-user mode).

14.  Verify the location of the model files by running the following query:
use msdb
go
sp_helpfile
go

3.0 Moving Master Database Files



  1. From the Start menu, point to All Programs, point to Microsoft SQL Server, point to Configuration Tools, and then click SQL Server Configuration Manager

  2. In the SQL Server Services node, right-click the instance of SQL Server (for example, SQL Server [MSSQLSERVER]) and select Properties

  3. In the SQL Server (instance_name) Properties dialog box, click the Advanced tab.

  4. Edit the Startup Parameters values to point to the planned location for the master database data and log files, and click OK.  Moving the error log file is optional.

  5. The parameter value for the data file must follow the -d parameter and the value for the log file must follow the -l parameter.  The following example shows the parameter values for the default location of the master data and log files.


-dC:\Program Files\Microsoft SQL Server\MSSQL10.MSSQLSERVER\MSSQL\DATA\master.mdf;-eC:\Program Files\Microsoft SQL Server\MSSQL10.MSSQLSERVER\MSSQL\LOG\ERRORLOG;-lC:\Program Files\Microsoft SQL Server\MSSQL10.MSSQLSERVER\MSSQL\DATA\mastlog.ldf


  1. If the planned relocation for the master data and log files is E:\SQLData, the parameter values would be changed as follows:


-dE:\SQLData\master.mdf;-eC:\Program Files\Microsoft SQL Server\MSSQL10.MSSQLSERVER\MSSQL\LOG\ERRORLOG;-lE:\SQLData\mastlog.ldf


  1. Stop the instance of SQL Server by right-clicking the instance name and selecting Stop

  2. Move the master.mdf and mastlog.ldf files to the new location.

  3. Restart the instance of SQL Server


10.  Verify the file change for the master database by running the following query:
SELECT name, physical_name AS CurrentLocation, state_desc
FROM sys.master_files
WHERE database_id = DB_ID('master');
GO

4.0  Moving TempDB Database Files



  1. Determine the logical file names of the tempdb database and their current location on the disk:


SELECT name, physical_name AS CurrentLocation
FROM sys.master_files
WHERE database_id = DB_ID(N'tempdb');
GO


  1. Change the location of each file by using ALTER DATABASE


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:\SQLLog\templog.ldf');
GO


  1. Stop and restart the instance of SQL Server

  2. Verify the file change:


SELECT name, physical_name AS CurrentLocation, state_desc
FROM sys.master_files
WHERE database_id = DB_ID(N'tempdb');


  1. Delete the tempdb.mdf and templog.ldf files from the original location.

  2. Add additional tempDB files:


ALTER DATABASE tempdb
ADD FILE (NAME = tempdev2, FILENAME = 'X:\tempdb2.mdf', SIZE = 256);
ALTER DATABASE tempdb
ADD FILE (NAME = tempdev3, FILENAME = 'X:\tempdb3.mdf', SIZE = 256);
ALTER DATABASE tempdb
ADD FILE (NAME = tempdev4, FILENAME = 'X:\tempdb4.mdf', SIZE = 256);
GO

NOTE: Replace the path and filename with appropriate target names.

Add as many files as there are processors per MS Best Practices.  The final number is discretionary based on the demand model for the system.

Restart the server and verify the functionality and location of tempDB:
use tempdb
go
sp_helpfile
go

Note: don't forget to delete the old tempdb MDF and LDF files. SQL won't do it...

No comments:

Post a Comment