Best-Practice Of Moving
Master and Resource Databse:
Notes:
-
1. The
procedures in this topic require the logical name of the database files. To
obtain the name, query the name column
in the sys.master_files
catalog view.
2. Before
moving the system databases, ensure to have full database backup of all system
databases (except Resource database).
3. Also,
ensure to have offline backup (mdf & ldf files) of all system databases
including Resource database.
4. Carry
out the activity successfully on the UAT server before proceeding with the same
on the Production servers.
Moving the master and
Resource Databases
The Resource database depends on the location of the master
database. The Resource data and log files must reside together and must
be in the same location as the master data file (master.mdf). Therefore,
if you move the master database, you must also move the Resource
database to the same location as the master data file. Do not put the Resource
database in either compressed or encrypted NTFS file system folders. Doing so
will hinder performance and prevent upgrades.
To move the master and Resource
databases, follow these steps.
- From
the Start menu, point to All Programs, point to Microsoft
SQL Server 2005, point to Configuration Tools, and then click SQL
Server Configuration Manager.
- In
the SQL Server 2005 Services node, right-click the instance of SQL
Server (for example, SQL Server (MSSQLSERVER)) and choose Properties.
- In
the SQL Server (instance_name)
Properties dialog box, click the Advanced tab.
- 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.
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\MSSQL.1\MSSQL\DATA\master.mdf;
-eC:\Program Files\Microsoft SQL Server\MSSQL.1\MSSQL\LOG\ERRORLOG;
-lC:\Program Files\Microsoft SQL Server\MSSQL.1\MSSQL\DATA\mastlog.ldf
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\MSSQL.1\MSSQL\LOG\ERRORLOG;
-lE:\SQLData\mastlog.ldf
- Stop
the instance of SQL Server by right-clicking the instance name and
choosing Stop.
- Move
the master.mdf and mastlog.ldf files to the new location.
- Start
the instance of SQL Server in master-only recovery mode by entering one of
the following commands at the command prompt. The parameters specified in
these commands are case sensitive. The commands fail when the parameters
are not specified as shown.
·
For the default
(MSSQLSERVER) instance, run the following command:
NET START MSSQLSERVER /f /T3608
·
For a named instance,
run the following command:
NET START MSSQL$instancename /f /T3608
- Using sqlcmd commands
or SQL Server Management Studio, run the following statements. Change the
FILENAME
path to match the new location of the master data file. Do not change the name of the database or the file names.
ALTER DATABASE mssqlsystemresource
MODIFY FILE (NAME=data, FILENAME= 'new_path_of_master\mssqlsystemresource.mdf');
GO
ALTER DATABASE mssqlsystemresource
MODIFY FILE (NAME=log, FILENAME= 'new_path_of_master\mssqlsystemresource.ldf');
GO
- Move the
mssqlsystemresource.mdf and mssqlsystemresource.ldf files to the new
location.
- Set the Resource
database to read-only by running the following statement:
ALTER DATABASE mssqlsystemresource SET READ_ONLY;
- Exit the sqlcmd
utility or SQL Server Management Studio.
- Stop the instance of
SQL Server.
- Restart the instance
of SQL Server.
- Verify the file change
for the master database by running the following query. The Resource
database metadata cannot be viewed by using the system catalog views or
system tables.
SELECT name, physical_name AS CurrentLocation, state_desc
FROM sys.master_files
WHERE database_id = DB_ID ('master');
GO
Moving model and msdb databases
Moving
of model and msdb databases also follow the similar procedure as moving the
tempdb database but with some additional steps.
Since these are also system databases, unfortunately we cannot move them just by detach and attach process, as we cannot attach or detach a system database.
Moving model database:
Since these are also system databases, unfortunately we cannot move them just by detach and attach process, as we cannot attach or detach a system database.
Moving model database:
1.
First get the list of model database
files by using this query
select name,physical_name from sys.master_files whereDB_NAME(database_id)='model'
2.
Then for each model database file that
you need to move, execute statements like below
Alter Database model modify
Alter Database model modify
file (NAME = 'modeldev' ,
FILENAME = 'Drive:\Path\model.mdf') -- Mention the new location
Alter Database model modify
file (NAME = 'modellog' ,
FILENAME = 'Drive:\Path\modellog.ldf') -- Mention the new location
3.
Stop SQL Services
4.
Move the files manually to the new
location
5.
Start SQL Services
6.
Verify the new Location
select name,physical_name from sys.master_files whereDB_NAME(database_id)='model'
select name,physical_name from sys.master_files whereDB_NAME(database_id)='model'
Moving msdb database:
1.
First get the list of msdb files by
using this query
select name,physical_name from sys.master_files whereDB_NAME(database_id)='msdb'
2.
Then for each msdb database file that
you need to move, execute statements like below
Alter Database msdb modify
Alter Database msdb modify
file (NAME = 'MSDBData' ,
FILENAME = 'Drive:\Path\MSDBData.mdf') -- Mention the new location
Alter Database msdb modify
file (NAME = 'MSDBLog' ,
FILENAME = 'Drive:\Path\MSDBLog.ldf') -- Mention the new location
3.
Stop SQL Services
4.
Move the files manually to the new
location
5.
Start SQL Services
6.
Verify the new Location
select name,physical_name from sys.master_files whereDB_NAME(database_id)='msdb'
If
the SQL Server Instance is configured with Database Mail option, then
after the msdb movement you will have to verify that the database mail is
working fine by sending a test email.
DEMO :-
sp_helpdb 'master'
ALTER DATABASE
mssqlsystemresource
MODIFY FILE (NAME=data, FILENAME= 'D:\prod\mssqlsystemresource.mdf');
GO
ALTER DATABASE
mssqlsystemresource
MODIFY FILE (NAME=log, FILENAME= 'D:\prod\mssqlsystemresource.ldf');
GO
--Move the mssqlsystemresource.mdf and
mssqlsystemresource.ldf files to the new location.
--Set the Resource database to read-only by running the
following statement:
ALTER DATABASE
mssqlsystemresource SET READ_ONLY;
sp_helpdb 'model'
Alter DATABASE MODEL MODIFY FILE
( NAME=modeldev,FILENAME='D:\prod\model.MDF')
GO
Alter DATABASE MODEL MODIFY FILE
( NAME=modellog,FILENAME='D:\prod\modellog.LDF')
GO
sp_helpdb 'MSDB'
Alter DATABASE MSDB MODIFY FILE
( NAME=MSDBData,FILENAME='D:\prod\MSDBData.MDF')
GO
Alter DATABASE MSDB MODIFY FILE
( NAME=MSDBLog,FILENAME='D:\prod\MSDBLog.LDF')
GO
sp_helpdb 'TEMPDB'
Alter DATABASE TEMPDB MODIFY FILE
( NAME=tempdev,FILENAME='D:\prod\tempdb.MDF')
GO
Alter DATABASE TEMPDB MODIFY FILE
( NAME=templog,FILENAME='D:\prod\templog.LDF')
GO
No comments:
Post a Comment