title | description | author | ms.author | ms.reviewer | ms.date | ms.service | ms.subservice | ms.topic | helpviewer_keywords | monikerRange | |||
---|---|---|---|---|---|---|---|---|---|---|---|---|---|
Copy-only backups |
A copy-only backup is a SQL Server backup that is independent of the sequence of SQL Server backups. It doesn't affect how later backups are restored. |
MashaMSFT |
mathoma |
randolphwest |
12/28/2023 |
sql |
backup-restore |
conceptual |
|
=azuresqldb-mi-current || >=sql-server-2016 || >=sql-server-linux-2017 |
[!INCLUDE SQL Server SQL MI]
A copy-only backup is a [!INCLUDE ssNoVersion] backup that is independent of the sequence of conventional [!INCLUDE ssNoVersion] backups. Usually, taking a backup changes the database and affects how later backups are restored. However, occasionally, it's useful to take a backup for a special purpose without affecting the overall backup and restore procedures for the database. Copy-only backups serve this purpose.
The types of copy-only backups are as follows:
-
Copy-only full backups (all recovery models)
-
A copy-only backup can't serve as a differential base or differential backup and doesn't affect the differential base.
-
Restoring a copy-only full backup is the same as restoring any other full backup.
-
-
Copy-only log backups (full recovery model and bulk-logged recovery model only)
-
A copy-only log backup preserves the existing log archive point and, therefore, doesn't affect the sequencing of regular log backups. Copy-only log backups are typically unnecessary. Instead, you can create a new routine log backup (using
WITH NORECOVERY
) and use that backup together with any previous log backups that are required for the restore sequence. However, a copy-only log backup can sometimes be useful for performing an online restore. For more information, follow the instructions in the article Example: Online restore of a read-write file (full recovery model), using the copy-only backup files instead. -
The transaction log is never truncated after a copy-only backup.
-
Copy-only backups are recorded in the is_copy_only
column of the backupset table.
Important
In [!INCLUDE ssazuremi-md], copy-only backups can't be created for a database encrypted with service-managed Transparent Data Encryption (TDE). Service-managed TDE uses internal key for encryption of data, and that key can't be exported, so you couldn't restore the backup anywhere else. Consider using customer-managed TDE instead to be able to create copy-only backups of encrypted databases, but make sure to have encryption key available for later restore.
You can create a copy-only backup with [!INCLUDE ssManStudioFull], [!INCLUDE azure-data-studio], [!INCLUDE tsql], or PowerShell.
In this example, a copy-only backup of the Sales
database is backed up to disk at the default backup location.
-
In Object Explorer, connect to an instance of the SQL Server Database Engine and then expand that instance.
-
Expand Databases, right-click
Sales
, point to Tasks, and then select Back Up.... -
On the General page in the Source section, check the Copy-only backup checkbox.
-
Select OK.
This example creates a copy-only backup for the Sales
database utilizing the COPY_ONLY
parameter. A copy-only backup of the transaction log is taken as well.
BACKUP DATABASE Sales
TO DISK = 'E:\BAK\Sales_Copy.bak'
WITH COPY_ONLY;
BACKUP LOG Sales
TO DISK = 'E:\BAK\Sales_LogCopy.trn'
WITH COPY_ONLY;
Note
COPY_ONLY
has no effect when specified with the DIFFERENTIAL
option.
Azure SQL Managed Instance supports taking COPY_ONLY full backups. The example performs a COPY_ONLY backup of MyDatabase
to the Microsoft Azure Blob Storage. The storage Account name is mystorageaccount
. The container is called myfirstcontainer
. A storage access policy has been created with read, write, delete, and list rights. The [!INCLUDEssNoVersion] credential, https://mystorageaccount.blob.core.windows.net/myfirstcontainer
, was created using a Shared Access Signature that is associated with the Storage Access Policy secret. For information on [!INCLUDEssNoVersion] backup to the Microsoft Azure Blob Storage, see SQL Server Backup and Restore with Microsoft Azure Blob Storage and SQL Server Backup to URL.
-- Prerequisite to have write permissions
CREATE CREDENTIAL [https://mystorageaccount.blob.core.windows.net/myfirstcontainer]
WITH IDENTITY = 'SHARED ACCESS SIGNATURE',
SECRET = 'sp=...' -- Enter your secret SAS token here.
BACKUP DATABASE MyDatabase
TO URL = 'https://mystorageaccount.blob.core.windows.net/myfirstcontainer/MyDatabaseBackup.bak'
WITH STATS = 5, COPY_ONLY;
To take a copy-only backup divided into multiple stripes, use this example:
BACKUP DATABASE MyDatabase
TO URL = 'https://mystorageaccount.blob.core.windows.net/myfirstcontainer/MyDatabase-01.bak',
URL = 'https://mystorageaccount.blob.core.windows.net/myfirstcontainer/MyDatabase-02.bak',
URL = 'https://mystorageaccount.blob.core.windows.net/myfirstcontainer/MyDatabase-03.bak',
URL = 'https://mystorageaccount.blob.core.windows.net/myfirstcontainer/MyDatabase-04.bak'
WITH COPY_ONLY;
This example creates a copy-only backup for the Sales
database utilizing the -CopyOnly
parameter.
Backup-SqlDatabase -ServerInstance 'SalesServer' -Database 'Sales' -BackupFile 'E:\BAK\Sales_Copy.bak' -CopyOnly