Move System Databases
This topic describes how to move system databases in SQL Server. Moving system databases may be useful in the following situations:
Failure recovery. For example, the database is in suspect mode or has shut down because of a hardware failure.
Planned relocation.
Relocation for scheduled disk maintenance.
The following procedures apply to moving database files within the same instance of SQL Server. To move a database to another instance of SQL Server or to another server, use the backup and restore or detach and attach operations.
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.
Important
If you move a system database and later rebuild the master database, you must move the system database again because the rebuild operation installs all system databases to their default location.
In This Topic
Planned Relocation and Scheduled Disk Maintenance Procedure
Failure Recovery Procedure
Moving the master Database
Moving the Resource Database
Follow-up: After Moving All System Databases
Examples
Planned Relocation and Scheduled Disk Maintenance Procedure
To move a system database data or log file as part of a planned relocation or scheduled maintenance operation, follow these steps. This procedure applies to all system databases except the master and Resource databases.
For each file to be moved, run the following statement.
ALTER DATABASE database_name MODIFY FILE ( NAME = logical_name , FILENAME = 'new_path\os_file_name' )
Stop the instance of SQL Server or shut down the system to perform maintenance. For more information, see Start, Stop, Pause, Resume, Restart the Database Engine, SQL Server Agent, or SQL Server Browser Service.
Move the file or files to the new location.
Restart the instance of SQL Server or the server. For more information, see Start, Stop, Pause, Resume, Restart the Database Engine, SQL Server Agent, or SQL Server Browser Service.
Verify the file change by running the following query.
SELECT name, physical_name AS CurrentLocation, state_desc FROM sys.master_files WHERE database_id = DB_ID(N'<database_name>');
If the msdb database is moved and the instance of SQL Server is configured for Database Mail, complete these additional steps.
Verify that Service Broker is enabled for the msdb database by running the following query.
SELECT is_broker_enabled FROM sys.databases WHERE name = N'msdb';
For more information about enabling Service Broker, see ALTER DATABASE (Transact-SQL).
Verify that Database Mail is working by sending a test mail.
[Top]
Failure Recovery Procedure
If a file must be moved because of a hardware failure, follow these steps to relocate the file to a new location. This procedure applies to all system databases except the master and Resource databases.
Important
If the database cannot be started, that is it is in suspect mode or in an unrecovered state, only members of the sysadmin fixed role can move the file.
Stop the instance of SQL Server if it is started.
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
For more information, see Start, Stop, Pause, Resume, Restart the Database Engine, SQL Server Agent, or SQL Server Browser Service.
For each file to be moved, use sqlcmd commands or SQL Server Management Studio to run the following statement.
ALTER DATABASE database_name MODIFY FILE( NAME = logical_name , FILENAME = 'new_path\os_file_name' )
For more information about using the sqlcmd utility, see Use the sqlcmd Utility.
Exit the sqlcmd utility or SQL Server Management Studio.
Stop the instance of SQL Server. For example, run NET STOP MSSQLSERVER.
Move the file or files to the new location.
Restart the instance of SQL Server. For example, run NET START MSSQLSERVER.
Verify the file change by running the following query.
SELECT name, physical_name AS CurrentLocation, state_desc FROM sys.master_files WHERE database_id = DB_ID(N'<database_name>');
[Top]
Moving the master Database
To move the master database, follow these steps.
From the Start menu, point to All Programs, point to Microsoft SQL Server, point to Configuration Tools, and then click SQL Server Configuration Manager.
In the SQL Server 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 Startup Parameters tab.
In the Existing parameters box, select the –d parameter to move the master data file. Click Update to save the change.
In the Specify a startup parameter box, change the parameter to the new path of the master database.
In the Existing parameters box, select the –l parameter to move the master log file. Click Update to save the change.
In the Specify a startup parameter box, change the parameter to the new path of the master database.
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 file.
-dC:\Program Files\Microsoft SQL Server\MSSQL11.MSSQLSERVER\MSSQL\DATA\master.mdf
-lC:\Program Files\Microsoft SQL Server\MSSQL11.MSSQLSERVER\MSSQL\DATA\mastlog.ldf
If the planned relocation for the master data file is E:\SQLData, the parameter values would be changed as follows:
-dE:\SQLData\master.mdf
-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.
Restart the instance of SQL Server.
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
Moving the Resource Database
The location of the Resource database is <drive>:\Program Files\Microsoft SQL Server\MSSQL11.<instance_name>\MSSQL\Binn\. The database cannot be moved.
[Top]
Follow-up: After Moving All System Databases
If you have moved all of the system databases to a new drive or volume or to another server with a different drive letter, make the following updates.
Change the SQL Server Agent log path. If you do not update this path, SQL Server Agent will fail to start.
Change the database default location. Creating a new database may fail if the drive letter and path specified as the default location do not exist.
Change the SQL Server Agent Log Path
From SQL Server Management Studio, in Object Explorer, expand SQL Server Agent.
Right-click Error Logs and click Configure.
In the Configure SQL Server Agent Error Logs dialog box, specify the new location of the SQLAGENT.OUT file. The default location is C:\Program Files\Microsoft SQL Server\MSSQL11.<instance_name>\MSSQL\Log\.
Change the database default location
From SQL Server Management Studio, in Object Explorer, right-click the SQL Server server and click Properties.
In the Server Properties dialog box, select Database Settings.
Under Database Default Locations, browse to the new location for both the data and log files.
Stop and start the SQL Server service to complete the change.
[Top]
Examples
A. Moving the tempdb database
The following example moves the tempdb data and log files to a new location as part of a planned relocation.
Note
Because tempdb is re-created each time the instance of SQL Server is started, you do not have to physically move the data and log files. The files are created in the new location when the service is restarted in step 3. Until the service is restarted, tempdb continues to use the data and log files in existing location.
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
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 = 'F:\SQLLog\templog.ldf'); GO
Stop and restart the instance of SQL Server.
Verify the file change.
SELECT name, physical_name AS CurrentLocation, state_desc FROM sys.master_files WHERE database_id = DB_ID(N'tempdb');
Delete the tempdb.mdf and templog.ldf files from the original location.
[Top]