Επεξεργασία

Κοινή χρήση μέσω


Move system databases

Applies to: SQL Server

This article describes how to move system databases in SQL Server. Moving system databases might 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 operation.

The procedures in this article 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.

Move the system databases

To move a system database data or log file as part of a planned relocation or scheduled maintenance operation, follow these steps. This includes the model, msdb, and tempdb system databases.

Important

This procedure applies to all system databases except the master and Resource databases. See later in this article for steps to move the master database. The Resource database can't be moved.

  1. Record the existing location of the database files you intend to move, by reviewing the sys.master_files catalog view.

  2. Verify that the service account for the SQL Server Database Engine has full permissions to the new location of the files. For more information, see Configure Windows service accounts and permissions. If the Database Engine service account can't control the files in their new location, the SQL Server instance doesn't start.

  3. For each database file to be moved, run the following statement.

    ALTER DATABASE database_name
        MODIFY FILE (NAME = logical_name, FILENAME = 'new_path\os_file_name');
    

    Until the service is restarted, the database continues to use the data and log files in the existing location.

  4. Stop the instance of SQL Server to perform maintenance. For more information, see Start, stop, pause, resume, and restart SQL Server services.

  5. Copy the database file or files to the new location. This step isn't necessary for the tempdb system database; those files are created in the new location automatically.

  6. Restart the instance of SQL Server or the server. For more information, see Start, stop, pause, resume, and restart SQL Server services.

  7. Verify the file change by running the following query. The system databases should report the new physical file locations.

    SELECT name,
           physical_name AS CurrentLocation,
           state_desc
    FROM sys.master_files
    WHERE database_id = DB_ID(N'<database_name>');
    
  8. Since in Step 5 you copied the database files instead of moving them, now you can safely delete the unused database files from their previous location.

Follow-up: After moving the msdb system database

If the msdb database is moved and Database Mail is configured, complete the following extra steps.

  1. 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';
    

    If the Service Broker isn't enabled for msdb, it must be re-enabled for Database Mail to function. For more information, see ALTER DATABASE ... SET ENABLE_BROKER.

    ALTER DATABASE msdb
        SET ENABLE_BROKER
        WITH ROLLBACK IMMEDIATE;
    

    Confirm that the value of is_broker_enabled is now 1.

  2. Verify that Database Mail is working by sending a test mail.

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. The following examples use the Windows command-line prompt and sqlcmd Utility.

Important

If the database can't be started, if it's in suspect mode or in an unrecovered state, only members of the sysadmin fixed role can move the file.

  1. Verify that the service account for the SQL Server Database Engine has full permissions to the new location of the files. For more information, see Configure Windows service accounts and permissions. If the Database Engine service account can't control the files in their new location, the SQL Server instance doesn't start.

  2. Stop the instance of SQL Server if it's started.

  3. Start the instance of SQL Server in master-only recovery mode by entering one of the following commands at the command prompt. Using startup parameter 3608 prevents SQL Server from automatically starting and recovering any database except the master database. For more information, see Startup Parameters and TF3608.

    The parameters specified in these commands are case sensitive. The commands fail when the parameters aren't 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, and restart SQL Server services.

  4. Promptly after service startup with trace flag 3608 and /f, start a sqlcmd connection to the server, to claim the single connection that is available. For example, when executing sqlcmd locally on the same server as the default (MSSQLSERVER) instance, and to connect with Active Directory integration authentication, run the following command:

    sqlcmd
    

    To connect to a named instance on the local server, with Active Directory integration authentication:

    sqlcmd -S localhost\instancename
    

    For more information on sqlcmd syntax, see sqlcmd utility.

    For each file to be moved, use sqlcmd commands or SQL Server Management Studio to run the following statement. For more information about using the sqlcmd utility, see sqlcmd - use the utility. Once the sqlcmd session is open, run the following statement once for each file to be moved:

    ALTER DATABASE database_name
        MODIFY FILE (NAME = logical_name, FILENAME = 'new_path\os_file_name');
    GO
    
  5. Exit the sqlcmd utility or SQL Server Management Studio.

  6. Stop the instance of SQL Server. For example, run NET STOP MSSQLSERVER in the command-line prompt.

  7. Copy the file or files to the new location.

  8. Restart the instance of SQL Server. For example, run NET START MSSQLSERVER in the command-line prompt.

  9. 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>');
    
  10. Since in Step 7 you copied the database files instead of moving them, now you can safely delete the unused database files from their previous location.

Move the master database

To move the master database, follow these steps.

  1. Verify that the service account for the SQL Server Database Engine has full permissions to the new location of the files. For more information, see Configure Windows service accounts and permissions. If the Database Engine service account can't control the files in their new location, the SQL Server instance doesn't start.

  2. From the Start menu, locate and launch SQL Server Configuration Manager. For more information on the expected location, see SQL Server Configuration Manager.

  3. In the SQL Server Services node, right-click the instance of SQL Server (for example, SQL Server (MSSQLSERVER)) and choose Properties.

  4. In the SQL Server (instance_name) Properties dialog box, select the Startup Parameters tab.

  5. In the Existing parameters box, select the -d parameter. In the Specify a startup parameter box, change the parameter to the new path of the master data file. Select Update to save the change.

  6. In the Existing parameters box, select the -l parameter. In the Specify a startup parameter box, change the parameter to the new path of the master log file. Select Update to save the change.

    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\MSSQL<version>.MSSQLSERVER\MSSQL\DATA\master.mdf
    -lC:\Program Files\Microsoft SQL Server\MSSQL<version>.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
    
  7. Select OK to save the changes permanently and close the SQL Server (instance_name) Properties dialog box.

  8. Stop the instance of SQL Server by right-clicking the instance name and choosing Stop.

  9. Copy the master.mdf and mastlog.ldf files to the new location.

  10. Restart the instance of SQL Server.

  11. 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');
    
  12. At this point SQL Server should run normally. However Microsoft recommends also adjusting the registry entry at HKEY_LOCAL_MACHINE\SOFTWARE\Microsoft\Microsoft SQL Server\instance_ID\Setup, where instance_ID is like MSSQL13.MSSQLSERVER. In that hive, change the SQLDataRoot value to the new path of the new location of the master database files. Failure to update the registry can cause patching and upgrading to fail.

  13. Since in Step 9 you copied the database files instead of moving them, now you can safely delete the unused database files from their previous location.

Move the resource database

The location of the Resource database is \<drive>:\Program Files\Microsoft SQL Server\MSSQL\<version>.<instance_name>\MSSQL\Binn\. The database can't be moved.

Follow-up: After moving all system databases

If you 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 don't update this path, SQL Server Agent fails to start.

  • Change the database default location. Creating a new database might fail if the drive letter and path specified as the default location don't exist.

Change the SQL Server Agent log path

If you have moved all of the system databases to a new volume or have migrated to another server with a different drive letter, and the path of the SQL Agent error log file SQLAGENT.OUT no longer exists, make the following updates.

  1. From SQL Server Management Studio, in Object Explorer, expand SQL Server Agent.

  2. Right-click Error Logs and select Configure.

  3. 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\MSSQL\<version>.<instance_name>\MSSQL\Log\.

Change the database default location

  1. From SQL Server Management Studio, in Object Explorer, connect to the desired SQL Server instance. Right-click the instance and select Properties.

  2. In the Server Properties dialog box, select Database Settings.

  3. Under Database Default Locations, browse to the new location for both the data and log files.

  4. Stop and start the SQL Server service to complete the change.

Examples

A. Move the tempdb database

The following example moves the tempdb data and log files to a new location as part of a planned relocation.

Tip

Take this opportunity to review your tempdb files for optimal size and placement. For more information, see Optimizing tempdb performance in SQL Server.

Because tempdb is recreated each time the instance of SQL Server is started, you don't have to physically move the data and log files. The files are created in the new location when the service is restarted in step 4. Until the service is restarted, tempdb continues to use the data and log files in the existing location.

  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
    
  2. Verify that the service account for the SQL Server Database Engine has full permissions to the new location of the files. For more information, see Configure Windows service accounts and permissions. If the Database Engine service account can't control the files in their new location, the SQL Server instance doesn't start.

  3. 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
    

    Until the service is restarted, tempdb continues to use the data and log files in the existing location.

  4. Stop and restart the instance of SQL Server.

  5. Verify the file change.

    SELECT name,
           physical_name AS CurrentLocation,
           state_desc
    FROM sys.master_files
    WHERE database_id = DB_ID(N'tempdb');
    
  6. Delete the unused tempdb files from their original location.