Move User Databases
In SQL Server, you can move the data, log, and full-text catalog files of a user database to a new location by specifying the new file location in the FILENAME clause of the ALTER DATABASE statement. This method applies to moving database files within the same instance SQL Server. To move a database to another instance of SQL Server or to another server, use backup and restore or detach and attach operations.
Considerations
When you move a database onto another server instance, to provide a consistent experience to users and applications, you might have to re-create some or all the metadata for the database. For more information, see Manage Metadata When Making a Database Available on Another Server Instance (SQL Server).
Some features of the SQL Server Database Engine change the way that the Database Engine stores information in the database files. These features are restricted to specific editions of SQL Server. A database that contains these features cannot be moved to an edition of SQL Server that does not support them. Use the sys.dm_db_persisted_sku_features dynamic management view to list all edition-specific features that are enabled in the current database.
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.
Starting with SQL Server 2008 R2, full-text catalogs are integrated into the database rather than being stored in the file system. The full-text catalogs now move automatically when you move a database.
Planned Relocation Procedure
To move a data or log file as part of a planned relocation, follow these steps:
Run the following statement.
ALTER DATABASE database_name SET OFFLINE;
Move the file or files to the new location.
For each file moved, run the following statement.
ALTER DATABASE database_name MODIFY FILE ( NAME = logical_name, FILENAME = 'new_path\os_file_name' );
Run the following statement.
ALTER DATABASE database_name SET ONLINE;
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>');
Relocation for Scheduled Disk Maintenance
To relocate a file as part of a scheduled disk maintenance process, follow these steps:
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>');
Failure Recovery Procedure
If a file must be moved because of a hardware failure, use the following steps to relocate the file to a new location.
Ważne: |
---|
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.
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 how to use the sqlcmd utility, see Use the sqlcmd Utility.
Exit the sqlcmd utility or SQL Server Management Studio.
Stop the instance of SQL Server.
Move the file or files to the new location.
Start 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>');
Examples
The following example moves the AdventureWorks2012 log file to a new location as part of a planned relocation.
USE master;
GO
-- Return the logical file name.
SELECT name, physical_name AS CurrentLocation, state_desc
FROM sys.master_files
WHERE database_id = DB_ID(N'AdventureWorks2012')
AND type_desc = N'LOG';
GO
ALTER DATABASE AdventureWorks2012 SET OFFLINE;
GO
-- Physically move the file to a new location.
-- In the following statement, modify the path specified in FILENAME to
-- the new location of the file on your server.
ALTER DATABASE AdventureWorks2012
MODIFY FILE ( NAME = AdventureWorks2012_Log,
FILENAME = 'C:\NewLoc\AdventureWorks2012_Log.ldf');
GO
ALTER DATABASE AdventureWorks2012 SET ONLINE;
GO
--Verify the new location.
SELECT name, physical_name AS CurrentLocation, state_desc
FROM sys.master_files
WHERE database_id = DB_ID(N'AdventureWorks2012')
AND type_desc = N'LOG';
Zobacz także
Odwołanie
CREATE DATABASE (Transact-SQL)
Koncepcje
Database Detach and Attach (SQL Server)