RESTORE Statements (Transact-SQL)

Restores SQL database backups taken using the BACKUP command.

Click one of the following tabs for the syntax, arguments, remarks, permissions, and examples for a particular SQL version with which you are working.

For more information about the syntax conventions, see Transact-SQL Syntax Conventions.

Click a product!

In the following row, click whichever product name you are interested in. The click displays different content here, appropriate for whichever product you click:

::: moniker range=“>=sql-server-2016||>=sql-server-linux-2017||=sqlallproducts-allversions”

[!div class=“mx-tdCol2BreakAll”] |||| |-|-|-| |* SQL Server *|SQL Database
Managed Instance
|Parallel
Data Warehouse

 

SQL Server

This command enables you to perform the following restore scenarios:

For more information about SQL Server restore scenarios, see Restore and Recovery Overview (SQL Server). For more information about descriptions of the arguments, see RESTORE Arguments (Transact-SQL). When restoring a database from another instance, consider the information from Manage Metadata When Making a Database Available on Another Server Instance (SQL Server).

[!NOTE] For more information about restoring from the Microsoft Azure Blob storage service, see SQL Server Backup and Restore with Microsoft Azure Blob Storage Service.

Syntax

--To Restore an Entire Database from a Full database backup (a Complete Restore):  
RESTORE DATABASE { database_name | @database_name_var }   
 [ FROM <backup_device> [ ,...n ] ]  
 [ WITH   
   {  
    [ RECOVERY | NORECOVERY | STANDBY =   
        {standby_file_name | @standby_file_name_var }   
       ]  
   | ,  <general_WITH_options> [ ,...n ]  
   | , <replication_WITH_option>  
   | , <change_data_capture_WITH_option>  
   | , <FILESTREAM_WITH_option>  
   | , <service_broker_WITH options>   
   | , \<point_in_time_WITH_options—RESTORE_DATABASE>   
   } [ ,...n ]  
 ]  
[;]  
  
--To perform the first step of the initial restore sequence of a piecemeal restore:  
RESTORE DATABASE { database_name | @database_name_var }   
   <files_or_filegroups> [ ,...n ]  
 [ FROM <backup_device> [ ,...n ] ]   
   WITH   
      PARTIAL, NORECOVERY   
      [  , <general_WITH_options> [ ,...n ]   
       | , \<point_in_time_WITH_options—RESTORE_DATABASE>   
      ] [ ,...n ]   
[;]  
  
--To Restore Specific Files or Filegroups:   
RESTORE DATABASE { database_name | @database_name_var }   
   <file_or_filegroup> [ ,...n ]  
 [ FROM <backup_device> [ ,...n ] ]   
   WITH   
   {  
      [ RECOVERY | NORECOVERY ]  
      [ , <general_WITH_options> [ ,...n ] ]  
   } [ ,...n ]   
[;]  
  
--To Restore Specific Pages:   
RESTORE DATABASE { database_name | @database_name_var }   
   PAGE = 'file:page [ ,...n ]'   
 [ , <file_or_filegroups> ] [ ,...n ]  
 [ FROM <backup_device> [ ,...n ] ]   
   WITH   
       NORECOVERY     
      [ , <general_WITH_options> [ ,...n ] ]  
[;]  
  
--To Restore a Transaction Log:  
RESTORE LOG { database_name | @database_name_var }   
 [ <file_or_filegroup_or_pages> [ ,...n ] ]  
 [ FROM <backup_device> [ ,...n ] ]   
 [ WITH   
   {  
     [ RECOVERY | NORECOVERY | STANDBY =   
        {standby_file_name | @standby_file_name_var }   
       ]  
    | ,  <general_WITH_options> [ ,...n ]  
    | , <replication_WITH_option>  
    | , \<point_in_time_WITH_options—RESTORE_LOG>   
   } [ ,...n ]  
 ]   
[;]  
  
--To Revert a Database to a Database Snapshot:     
RESTORE DATABASE { database_name | @database_name_var }   
FROM DATABASE_SNAPSHOT = database_snapshot_name   
  
<backup_device>::=  
{   
   { logical_backup_device_name |  
      @logical_backup_device_name_var }  
 | { DISK    
     | TAPE  
     | URL   
   } = { 'physical_backup_device_name' |  
      @physical_backup_device_name_var }   
}   
Note: URL is the format used to specify the location and the file name for the Microsoft Azure Blob. Although Microsoft Azure storage is a service, the implementation is similar to disk and tape to allow for a consistent and seemless restore experince for all the three devices.  
<files_or_filegroups>::=   
{   
   FILE = { logical_file_name_in_backup | @logical_file_name_in_backup_var }   
 | FILEGROUP = { logical_filegroup_name | @logical_filegroup_name_var }   
 | READ_WRITE_FILEGROUPS  
}   
  
<general_WITH_options> [ ,...n ]::=   
--Restore Operation Options  
   MOVE 'logical_file_name_in_backup' TO 'operating_system_file_name'   
          [ ,...n ]   
 | REPLACE   
 | RESTART   
 | RESTRICTED_USER  | CREDENTIAL  
  
--Backup Set Options  
 | FILE = { backup_set_file_number | @backup_set_file_number }   
 | PASSWORD = { password | @password_variable }   
  
--Media Set Options  
 | MEDIANAME = { media_name | @media_name_variable }   
 | MEDIAPASSWORD = { mediapassword | @mediapassword_variable }   
 | BLOCKSIZE = { blocksize | @blocksize_variable }   
  
--Data Transfer Options  
 | BUFFERCOUNT = { buffercount | @buffercount_variable }   
 | MAXTRANSFERSIZE = { maxtransfersize | @maxtransfersize_variable }  
  
--Error Management Options  
 | { CHECKSUM | NO_CHECKSUM }   
 | { STOP_ON_ERROR | CONTINUE_AFTER_ERROR }   
  
--Monitoring Options  
 | STATS [ = percentage ]   
  
--Tape Options. 
 | { REWIND | NOREWIND }   
 | { UNLOAD | NOUNLOAD }   
  
<replication_WITH_option>::=  
 | KEEP_REPLICATION   
  
<change_data_capture_WITH_option>::=  
 | KEEP_CDC  
  
<FILESTREAM_WITH_option>::=  
 | FILESTREAM ( DIRECTORY_NAME = directory_name )  
  
<service_broker_WITH_options>::=   
 | ENABLE_BROKER   
 | ERROR_BROKER_CONVERSATIONS   
 | NEW_BROKER  
  
\<point_in_time_WITH_options—RESTORE_DATABASE>::=   
 | {  
   STOPAT = { 'datetime'| @datetime_var }   
 | STOPATMARK = 'lsn:lsn_number'  
                 [ AFTER 'datetime']   
 | STOPBEFOREMARK = 'lsn:lsn_number'  
                 [ AFTER 'datetime']   
   }   
  
\<point_in_time_WITH_options—RESTORE_LOG>::=   
 | {  
   STOPAT = { 'datetime'| @datetime_var }   
 | STOPATMARK = { 'mark_name' | 'lsn:lsn_number' }  
                 [ AFTER 'datetime']   
 | STOPBEFOREMARK = { 'mark_name' | 'lsn:lsn_number' }  
                 [ AFTER 'datetime']   
   }  

Arguments

For descriptions of the arguments, see RESTORE Arguments (Transact-SQL).

About Restore Scenarios

SQL Server supports a variety of restore scenarios:

Additional Considerations About RESTORE Options

Discontinued RESTORE Keywords

The following keywords were discontinued in SQL Server 2008
|Discontinued keyword|Replaced by…|Example of replacement keyword|
|————————–|——————|————————————|
|LOAD|RESTORE|RESTORE DATABASE|
|TRANSACTION|LOG|RESTORE LOG|
|DBO_ONLY|RESTRICTED_USER|RESTORE DATABASE ... WITH RESTRICTED_USER|

RESTORE LOG

RESTORE LOG can include a file list to allow for creation of files during roll forward. This is used when the log backup contains log records written when a file was added to the database.

[!NOTE] For a database using the full or bulk-logged recovery model, in most cases you must back up the tail of the log before restoring the database. Restoring a database without first backing up the tail of the log results in an error, unless the RESTORE DATABASE statement contains either the WITH REPLACE or the WITH STOPAT clause, which must specify a time or transaction that occurred after the end of the data backup. For more information about tail-log backups, see Tail-Log Backups (SQL Server).

Comparison of RECOVERY and NORECOVERY

Roll back is controlled by the RESTORE statement through the [ RECOVERY | NORECOVERY ] options:

In this case, the restore sequence can restore other backups and roll them forward.

Recovering the database requires that the entire set of data being restored (the roll forward set) is consistent with the database. If the roll forward set has not been rolled forward far enough to be consistent with the database and RECOVERY is specified, the Database Engine issues an error.

Compatibility Support

Backups of master, model and msdb that were created by using an earlier version of SQL Server cannot be restored by SQL Server SQL Server 2017

[!NOTE] No SQL Server backup be restored to an earlier version of SQL Server SQL Server than the version on which the backup was created.

Each version of SQL Server uses a different default path than earlier versions. Therefore, to restore a database that was created in the default location for earlier version backups, you must use the MOVE option. For information about the new default path, see File Locations for Default and Named Instances of SQL Server.

After you restore an earlier version database to SQL Server 2017 the database is automatically upgraded. Typically, the database becomes available immediately. However, if a SQL Server 2017 SQL Server 2005 (9.x) database has full-text indexes, the upgrade process either imports, resets, or rebuilds them, depending on the setting of the upgrade_option server property. If the upgrade option is set to import (upgrade_option = 2) or rebuild (upgrade_option = 0), the full-text indexes will be unavailable during the upgrade. Depending the amount of data being indexed, importing can take several hours, and rebuilding can take up to ten times longer. Note also that when the upgrade option is set to import, the associated full-text indexes are rebuilt if a full-text catalog is not available. To change the setting of the upgrade_option server property, use sp_fulltext_service.

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.

General Remarks

During an offline restore, if the specified database is in use, RESTORE forces the users off after a short delay. For online restore of a non-primary filegroup, the database can stay in use except when the filegroup being restored is being taken offline. Any data in the specified database is replaced by the restored data.

For more information about database recovery, see Restore and Recovery Overview (SQL Server).

Cross-platform restore operations, even between different processor types, can be performed as long as the collation of the database is supported by the operating system.

RESTORE can be restarted after an error. In addition, you can instruct RESTORE to continue despite errors, and it restores as much data as possible (see the CONTINUE_AFTER_ERROR option).

RESTORE is not allowed in an explicit or implicit transaction.

Restoring a damaged master database is performed using a special procedure. For more information, see Back Up and Restore of System Databases (SQL Server).

Restoring a database clears the plan cache for the instance of SQL Server Clearing the plan cache causes a recompilation of all subsequent execution plans and can cause a sudden, temporary decrease in query performance. For each cleared cachestore in the plan cache, the SQL Server SQL Server error log contains the following informational message: “[!INCLUDEssNoVersion] has encountered %d occurrence(s) of cachestore flush for the ‘%s’ cachestore (part of plan cache) due to some database maintenance or reconfigure operations”. This message is logged every five minutes as long as the cache is flushed within that time interval.

To restore an availability database, first restore the database to the instance of SQL Server and then add the database to the availability group.

Interoperability

Database Settings and Restoring

During a restore, most of the database options that are settable using ALTER DATABASE are reset to the values in force at the time of the end of backup.

Using the WITH RESTRICTED_USER option, however, overrides this behavior for the user access option setting. This setting is always set following a RESTORE statement, which includes the WITH RESTRICTED_USER option.

Restoring an Encrypted Database

To restore a database that is encrypted, you must have access to the certificate or asymmetric key that was used to encrypt the database. Without the certificate or asymmetric key, the database cannot be restored. As a result, the certificate that is used to encrypt the database encryption key must be retained as long as the backup is needed. For more information, see SQL Server Certificates and Asymmetric Keys.

Restoring a Database Enabled for vardecimal Storage

Backup and restore work correctly with the vardecimal storage format. For more information about vardecimal storage format, see sp_db_vardecimal_storage_format (Transact-SQL).

Restore Full-Text Data

Full-text data is restored together with other database data during a complete restore. Using the regular RESTORE DATABASE database_name FROM backup_device syntax, the full-text files are restored as part of the database file restore.

The RESTORE statement also can be used to perform restores to alternate locations, differential restores, file and filegroup restores, and differential file and filegroup restores of full-text data. In addition, RESTORE can restore full-text files only, as well as with database data.

[!NOTE] Full-text catalogs imported from SQL Server 2005 (9.x) are still treated as database files. For these, the SQL Server 2005 (9.x) SQL Server 2005 (9.x) procedure for backing up full-text catalogs remains applicable, except that pausing and resuming during the backup operation are no longer necessary. For more information, see Backing Up and Restoring Full-Text Catalogs.

Metadata

SQL Server includes backup and restore history tables that track the backup and restore activity for each server instance. When a restore is performed, the backup history tables are also modified. For information on these tables, see Backup History and Header Information (SQL Server).

REPLACE Option Impact

REPLACE should be used rarely and only after careful consideration. Restore normally prevents accidentally overwriting a database with a different database. If the database specified in a RESTORE statement already exists on the current server and the specified database family GUID differs from the database family GUID recorded in the backup set, the database is not restored. This is an important safeguard.

The REPLACE option overrides several important safety checks that restore normally performs. The overridden checks are as follows:

Redoing a Restore

Undoing the effects of a restore is not possible; however, you can negate the effects of the data copy and roll forward by starting over on a per-file basis. To start over, restore the desired file and perform the roll forward again. For example, if you accidentally restored too many log backups and overshot your intended stopping point, you would have to restart the sequence.

A restore sequence can be aborted and restarted by restoring the entire contents of the affected files.

Reverting a Database to a Database Snapshot

A revert database operation (specified using the DATABASE_SNAPSHOT option) takes a full source database back in time by reverting it to the time of a database snapshot, that is, overwriting the source database with data from the point in time maintained in the specified database snapshot. Only the snapshot to which you are reverting can currently exist. The revert operation then rebuilds the log (therefore, you cannot later roll forward a reverted database to the point of user error).

Data loss is confined to updates to the database since the snapshot’s creation. The metadata of a reverted database is the same as the metadata at the time of snapshot creation. However, reverting to a snapshot drops all the full-text catalogs.

Reverting from a database snapshot is not intended for media recovery. Unlike a regular backup set, the database snapshot is an incomplete copy of the database files. If either the database or the database snapshot is corrupted, reverting from a snapshot is likely to be impossible. Furthermore, even when possible, reverting in the event of corruption is unlikely to correct the problem.

Restrictions on Reverting

Reverting is unsupported under the following conditions:

For more information, see Revert a Database to a Database Snapshot.

Security

A backup operation may optionally specify passwords for a media set, a backup set, or both. When a password has been defined on a media set or backup set, you must specify the correct password or passwords in the RESTORE statement. These passwords prevent unauthorized restore operations and unauthorized appends of backup sets to media using SQL Server tools. However, password-protected media can be overwritten by the BACKUP statement’s FORMAT option.

[!IMPORTANT]
The protection provided by this password is weak. It is intended to prevent an incorrect restore using SQL Server tools by authorized or unauthorized users. It does not prevent the reading of the backup data by other means or the replacement of the password. SQL Server This feature is in maintenance mode and may 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. best practice for protecting backups is to store backup tapes in a secure location or back up to disk files that are protected by adequate access control lists (ACLs). The ACLs should be set on the directory root under which backups are created.

[!NOTE] For information specific to SQL Server backup and restore with the Microsoft Azure Blob storage, see SQL Server Backup and Restore with Microsoft Azure Blob Storage Service.

Permissions

If the database being restored does not exist, the user must have CREATE DATABASE permissions to be able to execute RESTORE. If the database exists, RESTORE permissions default to members of the sysadmin and dbcreator fixed server roles and the owner (dbo) of the database (for the FROM DATABASE_SNAPSHOT option, the database always exists).

RESTORE permissions are given to roles in which membership information is always readily available to the server. Because fixed database role membership can be checked only when the database is accessible and undamaged, which is not always the case when RESTORE is executed, members of the db_owner fixed database role do not have RESTORE permissions.

Examples

All the examples assume that a full database backup has been performed.

The RESTORE examples include the following:

[!NOTE] For additional examples, see the restore how-to topics that are listed in Restore and Recovery Overview (SQL Server).

A. Restoring a full database

The following example restores a full database backup from the AdventureWorksBackups logical backup device. For an example of creating this device, see Backup Devices.

RESTORE DATABASE AdventureWorks2012   
   FROM AdventureWorks2012Backups;  

[!NOTE] For a database using the full or bulk-logged recovery model, SQL Server requires in most cases that you back up the tail of the log before restoring the database. For more information, see Tail-Log Backups (SQL Server).

[Top of examples]

B. Restoring full and differential database backups

The following example restores a full database backup followed by a differential backup from the Z:\SQLServerBackups\AdventureWorks2012.bak backup device, which contains both backups. The full database backup to be restored is the sixth backup set on the device (FILE = 6), and the differential database backup is the ninth backup set on the device (FILE = 9). As soon as the differential backup is recovered, the database is recovered.

RESTORE DATABASE AdventureWorks2012  
   FROM DISK = 'Z:\SQLServerBackups\AdventureWorks2012.bak'  
   WITH FILE = 6  
      NORECOVERY;  
RESTORE DATABASE AdventureWorks2012  
   FROM DISK = 'Z:\SQLServerBackups\AdventureWorks2012.bak'  
   WITH FILE = 9  
      RECOVERY;  

[Top of examples]

C. Restoring a database using RESTART syntax

The following example uses the RESTART option to restart a RESTORE operation interrupted by a server power failure.

-- This database RESTORE halted prematurely due to power failure.  
RESTORE DATABASE AdventureWorks2012  
   FROM AdventureWorksBackups;  
-- Here is the RESTORE RESTART operation.  
RESTORE DATABASE AdventureWorks2012   
   FROM AdventureWorksBackups WITH RESTART;  

[Top of examples]

D. Restoring a database and move files

The following example restores a full database and transaction log and moves the restored database into the C:\Program Files\Microsoft SQL Server\MSSQL13.MSSQLSERVER\MSSQL\Data directory.

RESTORE DATABASE AdventureWorks2012  
   FROM AdventureWorksBackups  
   WITH NORECOVERY,   
      MOVE 'AdventureWorks2012_Data' TO   
'C:\Program Files\Microsoft SQL Server\MSSQL13.MSSQLSERVER\MSSQL\Data\NewAdvWorks.mdf',   
      MOVE 'AdventureWorks2012_Log'   
TO 'C:\Program Files\Microsoft SQL Server\MSSQL13.MSSQLSERVER\MSSQL\Data\NewAdvWorks.ldf';  
RESTORE LOG AdventureWorks2012  
   FROM AdventureWorksBackups  
   WITH RECOVERY;  

[Top of examples]

E. Copying a database using BACKUP and RESTORE

The following example uses both the BACKUP and RESTORE statements to make a copy of the **AdventureWorks2012** database. The MOVE statement causes the data and log file to be restored to the specified locations. The RESTORE FILELISTONLY statement is used to determine the number and names of the files in the database being restored. The new copy of the database is named TestDB. For more information, see RESTORE FILELISTONLY (Transact-SQL).

BACKUP DATABASE AdventureWorks2012   
   TO AdventureWorksBackups ;  
  
RESTORE FILELISTONLY   
   FROM AdventureWorksBackups ;  
  
RESTORE DATABASE TestDB   
   FROM AdventureWorksBackups   
   WITH MOVE 'AdventureWorks2012_Data' TO 'C:\MySQLServer\testdb.mdf',  
   MOVE 'AdventureWorks2012_Log' TO 'C:\MySQLServer\testdb.ldf';  
GO  

[Top of examples]

F. Restoring to a point-in-time using STOPAT

The following example restores a database to its state as of 12:00 AM on April 15, 2020 and shows a restore operation that involves multiple log backups. On the backup device, AdventureWorksBackups, the full database backup to be restored is the third backup set on the device (FILE = 3), the first log backup is the fourth backup set (FILE = 4), and the second log backup is the fifth backup set (FILE = 5).

RESTORE DATABASE AdventureWorks2012  
   FROM AdventureWorksBackups  
   WITH FILE=3, NORECOVERY;  
  
RESTORE LOG AdventureWorks2012  
   FROM AdventureWorksBackups  
   WITH FILE=4, NORECOVERY, STOPAT = 'Apr 15, 2020 12:00 AM';  
  
RESTORE LOG AdventureWorks2012  
   FROM AdventureWorksBackups  
   WITH FILE=5, NORECOVERY, STOPAT = 'Apr 15, 2020 12:00 AM';  
RESTORE DATABASE AdventureWorks2012 WITH RECOVERY;  
  

[Top of examples]

G. Restoring the transaction log to a mark

The following example restores the transaction log to the mark in the marked transaction named ListPriceUpdate.

USE AdventureWorks2012  
GO  
BEGIN TRANSACTION ListPriceUpdate  
   WITH MARK 'UPDATE Product list prices';  
GO  
  
UPDATE Production.Product  
   SET ListPrice = ListPrice * 1.10  
   WHERE ProductNumber LIKE 'BK-%';  
GO  
  
COMMIT TRANSACTION ListPriceUpdate;  
GO  
  
-- Time passes. Regular database   
-- and log backups are taken.  
-- An error occurs in the database.  
USE master;  
GO  
  
RESTORE DATABASE AdventureWorks2012  
FROM AdventureWorksBackups  
WITH FILE = 3, NORECOVERY;  
GO  
  
RESTORE LOG AdventureWorks2012  
   FROM AdventureWorksBackups   
   WITH FILE = 4,  
   RECOVERY,   
   STOPATMARK = 'UPDATE Product list prices';  

[Top of examples]

H. Restoring using TAPE syntax

The following example restores a full database backup from a TAPE backup device.

RESTORE DATABASE AdventureWorks2012   
   FROM TAPE = '\\.\tape0';  

[Top of examples]

I. Restoring using FILE and FILEGROUP syntax

The following example restores a database named MyDatabase that has two files, one secondary filegroup, and one transaction log. The database uses the full recovery model.

The database backup is the ninth backup set in the media set on a logical backup device named MyDatabaseBackups. Next, three log backups, which are in the next three backup sets (10, 11, and 12) on the MyDatabaseBackups device, are restored by using WITH NORECOVERY. After restoring the last log backup, the database is recovered.

[!NOTE] Recovery is performed as a separate step to reduce the possibility of you recovering too early, before all of the log backups have been restored.

In the RESTORE DATABASE, notice that there are two types of FILE options. The FILE options preceding the backup device name specify the logical file names of the database files that are to be restored from the backup set; for example, FILE = 'MyDatabase_data_1'. This backup set is not the first database backup in the media set; therefore, its position in the media set is indicated by using the FILE option in the WITH clause, FILE=9.

RESTORE DATABASE MyDatabase  
   FILE = 'MyDatabase_data_1',  
   FILE = 'MyDatabase_data_2',  
   FILEGROUP = 'new_customers'  
   FROM MyDatabaseBackups  
   WITH   
      FILE = 9,  
      NORECOVERY;  
GO  
-- Restore the log backups.  
RESTORE LOG MyDatabase  
   FROM MyDatabaseBackups  
   WITH FILE = 10,   
      NORECOVERY;  
GO  
RESTORE LOG MyDatabase  
   FROM MyDatabaseBackups  
   WITH FILE = 11,   
      NORECOVERY;  
GO  
RESTORE LOG MyDatabase  
   FROM MyDatabaseBackups  
   WITH FILE = 12,   
      NORECOVERY;  
GO  
--Recover the database:  
RESTORE DATABASE MyDatabase WITH RECOVERY;  
GO  

[Top of examples]

J. Reverting from a database snapshot

The following example reverts a database to a database snapshot. The example assumes that only one snapshot currently exists on the database. For an example of how to create this database snapshot, see Create a Database Snapshot (Transact-SQL).

[!NOTE] Reverting to a snapshot drops all the full-text catalogs.

USE master;    
RESTORE DATABASE AdventureWorks2012 FROM DATABASE_SNAPSHOT = 'AdventureWorks_dbss1800';  
GO  

For more information, see Revert a Database to a Database Snapshot.

[Top of examples]

K. Restoring from the Microsoft Azure Blob storage service

The three examples below involve the use of the Microsoft Azure storage service. The storage Account name is mystorageaccount. The container for data files is called myfirstcontainer. The container for backup files is called mysecondcontainer. A stored access policy has been created with read, write, delete, and list, rights for each container. SQL Server credentials were created using Shared Access Signatures that are associated with the Stored Access Policies. For information specific to SQL Server backup and restore with the Microsoft Azure Blob storage, see SQL Server Backup and Restore with Microsoft Azure Blob Storage Service.

K1. Restore a full database backup from the Microsoft Azure storage service
A full database backup, located at mysecondcontainer, of Sales will be restored to myfirstcontainer. Sales does not currently exist on the server.

RESTORE DATABASE Sales
  FROM URL = 'https://mystorageaccount.blob.core.windows.net/mysecondcontainer/Sales.bak'   
  WITH  MOVE 'Sales_Data1' to 'https://mystorageaccount.blob.core.windows.net/myfirstcontainer/Sales_Data1.mdf', 
  MOVE 'Sales_log' to 'https://mystorageaccount.blob.core.windows.net/myfirstcontainer/Sales_log.ldf', 
  STATS = 10;

K2. Restore a full database backup from the Microsoft Azure storage service to local storage
A full database backup, located at mysecondcontainer, of Sales will be restored to local storage. Sales does not currently exist on the server.

RESTORE DATABASE Sales
  FROM URL = 'https://mystorageaccount.blob.core.windows.net/mysecondcontainer/Sales.bak'   
  WITH  MOVE 'Sales_Data1' to 'H:\DATA\Sales_Data1.mdf', 
  MOVE 'Sales_log' to 'O:\LOG\Sales_log.ldf', 
  STATS = 10;

K3. Restore a full database backup from local storage to the Microsoft Azure storage service

RESTORE DATABASE Sales
  FROM DISK = 'E:\BAK\Sales.bak'
  WITH  MOVE 'Sales_Data1' to 'https://mystorageaccount.blob.core.windows.net/myfirstcontainer/Sales_Data1.mdf', 
  MOVE 'Sales_log' to 'https://mystorageaccount.blob.core.windows.net/myfirstcontainer/Sales_log.ldf', 
  STATS = 10;

[Top of examples]

Much more information!!

::: moniker-end ::: moniker range=“=azuresqldb-mi-current||=sqlallproducts-allversions”

[!div class=“mx-tdCol2BreakAll”] |||| |-|-|-| |SQL Server|* SQL Database
Managed Instance *
|Parallel
Data Warehouse

 

Azure SQL Database Managed Instance

This command enables you to restore an entire database from a full database backup (a complete restore) from Azure Blob Storage account.

For other supported RESTORE commands, see: - RESTORE FILELISTONLY (Transact-SQL)
- RESTORE HEADERONLY (Transact-SQL) - RESTORE LABELONLY ONLY (Transact-SQL) - RESTORE VERIFYONLY (Transact-SQL)

[!IMPORTANT] To restore from Azure SQL Database Managed Instance automatic backups, see SQL Database Restore.

Syntax

--To Restore an Entire Database from a Full database backup (a Complete Restore):  
RESTORE DATABASE { database_name | @database_name_var }   
 FROM URL = { 'physical_device_name' | @physical_device_name_var } [ ,...n ]   
[;]  
  

Arguments

DATABASE

Specifies the target database.

FROM URL

Specifies one or more backup devices placed on URLs that will be used for the restore operation. The URL format is used for restoring backups from the Microsoft Azure storage service.

[!IMPORTANT]
In order to restore from multiple devices when restoring from URL, you must use Shared Access Signature (SAS) tokens. For examples creating a Shared Access Signature, see SQL Server Backup to URL and Simplifying creation of SQL Credentials with Shared Access Signature (SAS) tokens on Azure Storage with Powershell.

n
Is a placeholder that indicates that up to 64 backup devices may be specified in a comma-separated list.

General Remarks

As a prerequisite, you need to create a credential with the name that matches the blob storage account url, and Shared Access Signature placed as secret. RESTORE command will lookup credential using the blob storage url to find the information required to read the backup device.

RESTORE operation is asynchronous - the restore continues even if client connection breaks. If your connection is dropped, you can check sys.dm_operation_status view for the status of a restore operation (as well as for CREATE and DROP database).

The following database options are set/overridden and cannot be changed later:

Limitations - SQL Database Managed Instance

These limitations apply:

For more information, see Managed Instance

Restoring an Encrypted Database

To restore a database that is encrypted, you must have access to the certificate or asymmetric key that was used to encrypt the database. Without the certificate or asymmetric key, the database cannot be restored. As a result, the certificate that is used to encrypt the database encryption key must be retained as long as the backup is needed. For more information, see SQL Server Certificates and Asymmetric Keys.

Permissions

The user must have CREATE DATABASE permissions to be able to execute RESTORE.

CREATE LOGIN mylogin WITH PASSWORD = 'Very Strong Pwd123!';
GRANT CREATE ANY DATABASE TO [mylogin];

RESTORE permissions are given to roles in which membership information is always readily available to the server. Because fixed database role membership can be checked only when the database is accessible and undamaged, which is not always the case when RESTORE is executed, members of the db_owner fixed database role do not have RESTORE permissions.

Examples

The following examples restore a copy only database backup from URL, including the creation of a credential.

A. Restore database from four backup devices.


-- Create credential
CREATE CREDENTIAL [https://mybackups.blob.core.windows.net/wide-world-importers]
WITH IDENTITY = 'SHARED ACCESS SIGNATURE',
       SECRET = 'sv=2017-11-09&ss=bq&srt=sco&sp=rl&se=2022-06-19T22:41:07Z&st=2018-06-01T14:41:07Z&spr=https&sig=s7wddcf0w%3D';
GO
-- Restore database
RESTORE DATABASE WideWorldImportersStandard
FROM URL = N'https://mybackups.blob.core.windows.net/wide-world-importers/00-WideWorldImporters-Standard.bak',
URL = N'https://mybackups.blob.core.windows.net/wide-world-importers/01-WideWorldImporters-Standard.bak',
URL = N'https://mybackups.blob.core.windows.net/wide-world-importers/02-WideWorldImporters-Standard.bak',
URL = N'https://mybackups.blob.core.windows.net/wide-world-importers/03-WideWorldImporters-Standard.bak'

The following error is shown if the database already exists:

Msg 1801, Level 16, State 1, Line 9
Database 'WideWorldImportersStandard' already exists. Choose a different database name.

B. Restore database specified via variable.

DECLARE @db_name sysname = 'WideWorldImportersStandard';
DECLARE @url nvarchar(400) = N'https://mybackups.blob.core.windows.net/wide-world-importers/WideWorldImporters-Standard.bak';

RESTORE DATABASE @db_name 
FROM URL = @url

C. Track progress of restore statement.

SELECT  query = a.text, start_time, percent_complete,
        eta = dateadd(second,estimated_completion_time/1000, getdate()) 
FROM sys.dm_exec_requests r
    CROSS APPLY sys.dm_exec_sql_text(r.sql_handle) a 
WHERE r.command = 'RESTORE DATABASE'

[!Note] This view will probably show two restore requests. One is original RESTORE statement sent by the client, and the another one is background RESTORE statement that is executing even if the client connection fails.

::: moniker-end ::: moniker range=“>=aps-pdw-2016||=sqlallproducts-allversions”

[!div class=“mx-tdCol2BreakAll”] |||| |-|-|-| |SQL Server|SQL Database
Managed Instance
|* Parallel
Data Warehouse *

 

Parallel Data Warehouse

Restores a Parallel Data Warehouse user database from a database backup to a Parallel Data Warehouse Parallel Data Warehouse appliance. The database is restored from a backup that was previously created by the Parallel Data Warehouse Parallel Data Warehouse Parallel Data Warehouse DATABASE (Parallel Data Warehouse)](../../t-sql/statements/backup-transact-sql.md) command. Use the backup and restore operations to build a disaster recovery plan, or to move databases from one appliance to another.

[!NOTE]
Restoring master includes restoring appliance login information. To restore master, use the Restore the master Database (Transact-SQL) page in the Configuration Manager tool. An administrator with access to the Control node can perform this operation.
For more information about Parallel Data Warehouse database backups, see “Backup and Restore” in the Parallel Data Warehouse [Parallel Data Warehouse product documentation](https://www.microsoft.com/en-us/download/details.aspx?id=51610)

Syntax

  
-- Restore the master database  
-- Use the Configuration Manager tool.  
  
Restore a full user database backup.  
RESTORE DATABASE database_name   
    FROM DISK = '\\UNC_path\full_backup_directory'  
[;]  
  
--Restore a full user database backup and then a differential backup.  
RESTORE DATABASE database_name  
    FROM DISK = '\\UNC_path\differential_backup_directory'   
    WITH [ ( ] BASE = '\\UNC_path\full_backup_directory' [ ) ]   
[;]  
  
--Restore header information for a full or differential user database backup.  
RESTORE HEADERONLY   
    FROM DISK = '\\UNC_path\backup_directory'  
[;]  

Arguments

RESTORE DATABASE database_name
Specifies to restore a user database to a database called database_name. The restored database can have a different name than the source database that was backed up. database_name cannot already exist as a database on the destination appliance. For more details on permitted database names, see “Object Naming Rules” in the [Parallel Data Warehouse product documentation](https://www.microsoft.com/en-us/download/details.aspx?id=51610)

Restoring a user database restores a full database backup and then optionally restores a differential backup to the appliance. A restore of a user database includes restoring database users, and database roles.

FROM DISK = ‘\\UNC_path\backup_directory
The network path and directory from which Parallel Data Warehouse will restore the backup files. For example, FROM DISK = ‘\.xxx.xxx.xxx\2012\08.2012.Mybackup’.

backup_directory
Specifies the name of a directory that contains the full or differential backup. For example, you can perform a RESTORE HEADERONLY operation on a full or differential backup.

full_backup_directory
Specifies the name of a directory that contains the full backup.

differential_backup_directory
Specifies the name of the directory that contains the differential backup.

RESTORE HEADERONLY
Specifies to return only the header information for one user database backup. Among other fields, the header includes the text description of the backup, and the backup name. The backup name does not need to be the same as the name of the directory that stores the backup files.

RESTORE HEADERONLY results are patterned after the SQL Server RESTORE HEADERONLY results. The result has over 50 columns, which are not all used by SQL Server Parallel Data Warehouse For a description of the columns in the SQL Server Parallel Data Warehouse SQL Server RESTORE HEADERONLY results, see RESTORE HEADERONLY (Transact-SQL).

Permissions

Requires the CREATE ANY DATABASE permission.

Requires a Windows account that has permission to access and read from the backup directory. You must also store the Windows account name and password in Parallel Data Warehouse

Error Handling

The RESTORE DATABASE command results in errors under the following conditions:

General Remarks

Parallel Data Warehouse tracks the success of database restores. Before restoring a differential database backup, Parallel Data Warehouse Parallel Data Warehouse verifies the full database restore finished successfully.

After a restore, the user database will have database compatibility level 120. This is true for all databases regardless of their original compatibility level.

Restoring to an Appliance With a Larger Number of Compute Nodes
Run DBCC SHRINKLOG (Azure SQL Data Warehouse) after restoring a database from a smaller to larger appliance since redistribution will increase transaction log.

Restoring a backup to an appliance with a larger number of Compute nodes grows the allocated database size in proportion to the number of Compute nodes.

For example, when restoring a 60 GB database from a 2-node appliance (30 GB per node) to a 6-node appliance, Parallel Data Warehouse creates a 180 GB database (6 nodes with 30 GB per node) on the 6-node appliance. Parallel Data Warehouse Parallel Data Warehouse initially restores the database to 2 nodes to match the source configuration, and then redistributes the data to all 6 nodes.

After the redistribution each Compute node will contain less actual data and more free space than each Compute node on the smaller source appliance. Use the additional space to add more data to the database. If the restored database size is larger than you need, you can use ALTER DATABASE (Parallel Data Warehouse) to shrink the database file sizes.

Limitations and Restrictions

For these limitations and restrictions, the source appliance is the appliance from which the database backup was created, and the target appliance is the appliance to which the database will be restored.

Locking

Takes an exclusive lock on the DATABASE object.

Examples

A. Simple RESTORE examples

The following example restores a full backup to the SalesInvoices2013 database. The backup files are stored in the \.xxx.xxx.xxx2013Full directory. The SalesInvoices2013 database cannot already exist on the target appliance or this command will fail with an error.

RESTORE DATABASE SalesInvoices2013  
FROM DISK = '\\xxx.xxx.xxx.xxx\backups\yearly\Invoices2013Full';  

B. Restore a full and differential backup

The following example restores a full, and then a differential backup to the SalesInvoices2013 database

The full backup of the database is restored from the full backup which is stored in the ‘\.xxx.xxx.xxx2013Full’ directory. If the restore completes successfully, the differential backup is restored to the SalesInvoices2013 database. The differential backup is stored in the ‘\.xxx.xxx.xxx2013Diff’ directory.

RESTORE DATABASE SalesInvoices2013  
    FROM DISK = '\\xxx.xxx.xxx.xxx\backups\yearly\Invoices2013Diff'  
    WITH BASE = '\\xxx.xxx.xxx.xxx\backups\yearly\Invoices2013Full'  
[;]  
  

C. Restoring the backup header

This example restores the header information for database backup ‘\.xxx.xxx.xxx2013Full’ . The command results in one row of information for the Invoices2013Full backup.

RESTORE HEADERONLY  
    FROM DISK = '\\xxx.xxx.xxx.xxx\backups\yearly\Invoices2013Full'  
[;]  

You can use the header information to check the contents of a backup, or to make sure the target restoration appliance is compatible with the source backup appliance before attempting to restore the backup.

See Also

BACKUP DATABASE (Parallel Data Warehouse)

::: moniker-end