sp_attach_db (Transact-SQL)

Attaches a database to a server.

Important

This feature will be removed in a future version of Microsoft SQL Server. Avoid using this feature in new development work, and plan to modify applications that currently use this feature. We recommend that you use CREATE DATABASE database_name FOR ATTACH instead. For more information, see CREATE DATABASE (Transact-SQL).

Note

To rebuild multiple log files when one or more have a new location, use CREATE DATABASE database_name FOR ATTACH_REBUILD_LOG.

Security noteSecurity Note

We recommend that you do not attach or restore databases from unknown or untrusted sources. Such databases could contain malicious code that might execute unintended Transact-SQL code or cause errors by modifying the schema or the physical database structure. Before you use a database from an unknown or untrusted source, run DBCC CHECKDB on the database on a nonproduction server and also examine the code, such as stored procedures or other user-defined code, in the database.

Topic link icon Transact-SQL Syntax Conventions

Syntax

sp_attach_db [ @dbname= ] 'dbname'
    , [ @filename1= ] 'filename_n' [ ,...16 ] 

Arguments

  • [ @dbname= ] **'**dbnam '
    Is the name of the database to be attached to the server. The name must be unique. dbname is sysname, with a default of NULL.

  • [ @filename1= ] 'filename_n'
    Is the physical name, including path, of a database file. filename_n is nvarchar(260), with a default of NULL. Up to 16 file names can be specified. The parameter names start at @filename1 and increment to @filename16. The file name list must include at least the primary file. The primary file contains the system tables that point to other files in the database. The list must also include any files that were moved after the database was detached.

    Note

    This argument maps to the FILENAME parameter of the CREATE DATABASE statement. For more information, see CREATE DATABASE (Transact-SQL).

    When you attach a SQL Server 2005 database that contains full-text catalog files onto a SQL Server 2012 server instance, the catalog files are attached from their previous location along with the other database files, the same as in SQL Server 2005. For more information, see Upgrade Full-Text Search from SQL Server 2005.

Return Code Values

0 (success) or 1 (failure)

Result Sets

None

Remarks

The sp_attach_db stored procedure should only be executed on databases that were previously detached from the database server by using an explicit sp_detach_db operation or on copied databases. If you have to specify more than 16 files, use CREATE DATABASE database_name FOR ATTACH or CREATE DATABASE database_name FOR_ATTACH_REBUILD_LOG. For more information, see CREATE DATABASE (Transact-SQL).

Any unspecified file is assumed to be in its last known location. To use a file in a different location, you must specify the new location.

A database created by a more recent version of SQL Server cannot be attached in earlier versions.

Note

A database snapshot cannot be detached or attached.

When you attach a replicated database that was copied instead of being detached, consider the following:

  • If you attach the database to the same server instance and version as the original database, no additional steps are required.

  • If you attach the database to the same server instance but with an upgraded version, you must execute sp_vupgrade_replication to upgrade replication after the attach operation is complete.

  • If you attach the database to a different server instance, regardless of version, you must execute sp_removedbreplication to remove replication after the attach operation is complete.

Only SQL Server 2005 and later databases can be attached to SQL Server 2012. If the compatibility level of a database is less than 90, its compatibility level will be changed to level 90 when the database is attached to SQL Server 2012.

When a database is first attached or restored to a new instance of SQL Server, a copy of the database master key (encrypted by the service master key) is not yet stored in the server. You must use the OPEN MASTER KEY statement to decrypt the database master key (DMK). Once the DMK has been decrypted, you have the option of enabling automatic decryption in the future by using the ALTER MASTER KEY REGENERATE statement to provision the server with a copy of the DMK, encrypted with the service master key (SMK). When a database has been upgraded from an earlier version, the DMK should be regenerated to use the newer AES algorithm. For more information about regenerating the DMK, see ALTER MASTER KEY (Transact-SQL). The time required to regenerate the DMK key to upgrade to AES depends upon the number of objects protected by the DMK. Regenerating the DMK key to upgrade to AES is only necessary once, and has no impact on future regenerations as part of a key rotation strategy.

Permissions

For information about how permissions are handled when a database is attached, see CREATE DATABASE (Transact-SQL).

Examples

The following example attaches files from AdventureWorks2012 to the current server.

EXEC sp_attach_db @dbname = N'AdventureWorks2012', 
    @filename1 = 
N'C:\Program Files\Microsoft SQL Server\MSSQL11.MSSQLSERVER\MSSQL\Data\AdventureWorks2012_Data.mdf', 
    @filename2 = 
N'C:\Program Files\Microsoft SQL Server\MSSQL11.MSSQLSERVER\MSSQL\Data\AdventureWorks2012_log.ldf';

See Also

Reference

sp_detach_db (Transact-SQL)

sp_helpfile (Transact-SQL)

sp_removedbreplication (Transact-SQL)

System Stored Procedures (Transact-SQL)

Concepts

Database Detach and Attach (SQL Server)