Introduction –Â Mirrored Backup
This article is based on a real life experience of the author while working with database backup and restore during his consultancy work for various organizations. We will go over the following important concepts of database backup and restore.
- Conventional Backup and Restore
- Spilt File Backup and Restore
- Mirror File Backup
- Understanding FORMAT Clause
- Miscellaneous details about Backup and Restore
In our example, we will require the following folders:
- C:\Backup\SingleFile
- C:\Backup\MultiFile
- C:\Backup\MirrorFile
Conventional and Split File Backup and Restore
Just a day before working on one of the projects, I had to take a backup of one database of 14 GB. My hard drive lacked sufficient space at that moment. Fortunately, I had two 8 GB USB Drives with me. Now, the question was how to take a backup in two equal sizes, each of 7 GB, so I can fit them on each USB drive. Well, conventional backup takes one large backup in one file. However, SQL Server backup command can take backups in two or more split parts.
Let us see an example of a conventional one-file backup using the AdventureWorks database.
BACKUP DATABASE AdventureWorks TO DISK = 'C:\Backup\SingleFile\AdventureWorks.bak' GO
The result is displayed below. Here, the backup is taken in a single file.
Now, let us see how we can split one database into two different database files. This method is very similar to taking a single-file backup. By simply adding an additional DISK option we can split the files backup files.
BACKUP DATABASE AdventureWorks TO DISK = 'C:\Backup\MultiFile\AdventureWorks1.bak', DISK = 'C:\Backup\MultiFile\AdventureWorks2.bak', DISK = 'C:\Backup\MultiFile\AdventureWorks3.bak' GO
In the previous example, we can clearly see that backup is split into three equal parts of the original backup file size.
Restoring a backup from a single-file backup is quite easy. Let us go over an example where we restore the AdventureWorks database from a single backup file.
RESTORE DATABASE AdventureWorks FROM DISK = 'C:\Backup\SingleFile\AdventureWorks.bak' GO
Running the above script will give a successful message.
Now let us see an example where we restore a database from a split file. This method is very similar to restoring a database from a single file; just add an additional DISK option.
RESTORE DATABASE [AdventureWorks] FROM DISK = N'C:\Backup\MultiFile\AdventureWorks1.bak', DISK = N'C:\Backup\MultiFile\AdventureWorks2.bak', DISK = N'C:\Backup\MultiFile\AdventureWorks3.bak' GO
Running the above script will give a successful message as shown in the image below.
Make sure that while restoring database, the database is not in use, otherwise it will give an error of database in use. In the event of an error taking place, close all the connections and re-attempt to restore the database.
Mirror Backup of the file
It is quite a common practice to create an exact copy of the backup and store it to several places to deal with any catastrophes which might affect the place where the database is stored. Once a full backup is accomplished DBAs generally copy the database to another location in their network using a third party tools like robocopy or native DOS commands like xcopy.
In SQL Server 2005 and later versions, there is a Mirror command that makes a copy of the database backup to different locations while taking the original backup. The maximum limit of additional locations that can be specified with MIRROR clause is 3.
Mirrored backup can be taken in the local computer system as well as in a local network. Let us now see two examples of mirror backup.
Example 1. Single File Backup to Multiple Locations using Mirror
BACKUP DATABASE AdventureWorks TO DISK = 'C:\Backup\SingleFile\AdventureWorks.bak' MIRROR TO DISK = 'C:\Backup\MirrorFile\AdventureWorks.bak' WITH FORMAT GO
If this command is being run for the first time, it is mandatory to use the WITH FORMAT
clause; but for sub sequential runs it is not required. WITH FORMAT
reinitializes the backup.
When checked in both the folders ‘SingleFile’ and ‘MirrorFile’, backup files are exactly the same files. As mentioned earlier, four mirror backup can be specified in total.
Example 2. Split File Backup to Multiple Locations using Mirror
We have earlier seen an example where we can have multiple split files of large database backup files. SQL Server Mirror functionality also supports backup of the split files.
BACKUP DATABASE AdventureWorks TO DISK = 'C:\Backup\MultiFile\AdventureWorks1.bak', DISK = 'C:\Backup\MultiFile\AdventureWorks2.bak', DISK = 'C:\Backup\MultiFile\AdventureWorks3.bak' MIRROR TO DISK = 'C:\Backup\MirrorFile\AdventureWorks1.bak', DISK = 'C:\Backup\MirrorFile\AdventureWorks2.bak', DISK = 'C:\Backup\MirrorFile\AdventureWorks3.bak' WITH FORMAT GO
All the mirror sets will need the same number of DISK
clauses as the original backup media.
Mirrored database backup can be restored using the same method as the original backup. Mirrored backup is in fact an exact replica of the original backup.
Understanding the FORMAT Clause
The FORMAT
clause is used to reinitiate a backup media. Although it is a very useful clause it should be used with caution. When the clause is used it erases everything present in backup media. I have noticed that some DBAs are confused while taking a backup on a local disk where they have SQL Server installed. They have a misconception that if the format command is used, it will erase the complete disk including the SQL Server installation. However, the fact is that SQL Server format clause is quite different from OS format. The effect of SQL Server format clause is limited to a folder or path specified in the DISK
clause.
In our example, when the FORMAT
clause is specified, it will format only folders like C:\Backup\MultiFile\ or C:\Backup\SingleFile.
Related Errors
Error 3010
Invalid backup mirror specification. All mirrors must have the same number of members.
This error can show up while taking a mirrored database backup along with a regular backup; and DISK
and MIRROR TO DISK
do not match accurately.
The following image demonstrates how the error takes place.
To fix the error, match the members of DISK
and MIRROR TO DISK
to each other.
Error 3215
Use WITH FORMAT to create a new mirrored backup set
This error can spring up when a new backup is initiated and an existing media header needs to be reset for all headers on the backup media. If there is already a backup on the media, it will display this error and prevent backup from being overwritten. To fix this error, use WITH FORMAT
as shown in an earlier example.
Miscellaneous details about Backup and Restore
When no options are specified, BACKUP DATABASE
takes only full backups. Before taking the first log backup, full database backup is necessary to take one full backup. Backups created on later versions of SQL Server cannot be restored to earlier versions of SQL Server. The user needs permissions of sysadmin
or db_owner
or db_backupoperator
roles to perform backup operation.
Watch a 60 second video on this subject
Reference : Pinal Dave (https://blog.sqlauthority.com)
44 Comments. Leave new
excellent Pinal
HI Pinal,
i have dought in Backups,
how to find out current LSN number of a backup by using command prompt.
Thanks& Regards
Murali
@Murali,
USE MSDB
SELECT * FROM Backupset
From there you can filter what information you need via the WHERE clause.
We use that T-SQL above for our DRS site. Our admins there just click the batch file we made and it restores all differentials and translogs.
Commandline would be:
SQLCMD -S -E -d msdb -h-1 -W -Q “”
-E is for trusted connection
We use -h-1 so we don’t have to see header information. Makes it easier to parse the data returned.
-W removes any trailing spaces.
I know this was a little late, but I thought this might help anyone.
Really awesome explanation
The multiple restore throws up the following error
“Msg 3231, Level 16, State 1, Line 1 The media loaded on “D:\projects\SIMS\db\DIMS2Auditcopy.bak” is formatted to support 1 media families, but 2 media families are expected according to the backup device specification. Msg 3013, Level 16, State 1, Line 1 RESTORE DATABASE is terminating abnormally.”
for –
RESTORE DATABASE SIMDB
FROM DISK = N’D:\db\db1.bak’,
DISK = N’D:\db\db2.bak’
GO
executed from SQL Management Studio.
Can u please help me in understanding restoring of the Split backups with “With Move” option….
I have 10 databases. and I have n different different systems which has own SQL-SERVER . All systems may contain any no. of databases from 10 databases.
I want to write a cmmon query to take backup of those database only which lies in those 10 databases only.
Ex. databases is A,B, C, D, E, F, G, H
SYSTEM 1 HAS DATABASE A,B,C AND Z
SYSTEM 2 HAS DATABASE A, C, D, E, P, Y, Z
i want to write a query which can take backup only A,B,C or A,C,D,E not P,Y,Z.
pls help me
i want a script file for taking backup in sql server 2008
Backup database db_name to disk=’file path’
can restore different or multiple files *. bak from microsoft magnament studio, from a path example c: \ bakups \; containing different databases. many scrips in internet but none refers to this
Hi Dave,
Was experimenting on this, wanted to know the maximum number of splits that can be performed on a database during the backup.
As per books online https://docs.microsoft.com/en-us/sql/t-sql/statements/backup-transact-sql?view=sql-server-2017 it is 64
Thanks Dave for the information.
I implemented split backup in one of my DB’s which is 2 TB. I see significant improvement in backup time taken for the data bases.
However, restoration of the databases is taking longer than full backup. Any particular reason???
I have not tested but what is the wait you are seeing during restore? Have you enabled “Instant File Initialization”?
can we take split for log bakup in sql server?
Yes. Same method.
BACKUP LOG [EncryptTest] TO
DISK = N’E:InvalidPath1.trn’,
DISK = N’E:InvalidPath2.trn’ WITH NOFORMAT, NOINIT
GO
Hi Dave.
I have configured sql jobs to do daily backups but the backups are splitting into two files, and i dont want that. How do i fix that? I dont know where the setting to split the backup is or where it came from. I just want my SQL to do one backup file. I am using MS SQL 2000. Please help.
Thank you in advance.
Regards,
Tickey
SQL Server 2012: Restoring split backup of a Filestream enabled database from a different server
Hi Pinal Dave! I have a split backup of a FileStream enabled database ‘At’ spread across 4 drives L,M,O,X in the ‘prd’ server that I want to restore to the ‘crt’ server. Both the servers are of 2012 version. I am using the below T-SQL in the crt server to restore a split backup from the prd server:
RESTORE DATABASE [At] FROM
DISK = ‘\\prd\L\sql_bak\At_group1.bak’,
DISK = ‘\\prd\M\sql_bak\At_group2.bak’,
DISK = ‘\\prd\O\sql_bak\At_group3.bak’,
DISK = ‘\\prd\X\sql_bak\At_group4.bak’
WITH REPLACE, NORECOVERY, STATS=20,
MOVE N’\\prd\E\sql_dat\At’ TO N’\\crt\F:\sql_dat\At.mdf’,
MOVE N’\\prd\D\sql_log\At_log’ TO N’D:\sql_log\At_log.ldf’,
MOVE N’\\prd\F\sql_dat\At_FS’ TO N’I:\sql_dat\At_FS’,
MOVE N’\\prd\I\sql_dat\At_FS2′ TO N’J:\sql_dat\At_FS2′,
MOVE N’\\prd\J\sql_dat\At_FS3′ TO N’L:\sql_dat\At_FS3′,
MOVE N’\\prd\N\sql_dat\At_FS4′ TO N’O:\sql_dat\At_FS4′,
MOVE N’\\prd\K\sql_dat\At_FS5′ TO N’N:\sql_dat\At_FS5′,
MOVE N’\\prd\R\sql_dat\At_FS6′ TO N’K:\sql_dat\At_FS6′,
MOVE N’\\prd\P\sql_dat\At_FS7′ TO N’P:\sql_dat\At_FS7′,
MOVE N’\\prd\F\sql_dat\At_FS8′ TO N’I:\sql_dat\At_FS8′,
MOVE N’\\prd\P\sql_dat\At_FS9′ TO N’P:\sql_dat\At_FS9′,
MOVE N’\\prd\F\sql_dat\At_FS10′ TO N’I:\sql_dat\At_FS10′,
MOVE N’\\prd\P\sql_dat\At_FS11′ TO N’P:\sql_dat\At_FS11′,
MOVE N’\\prd\P\sql_dat\At_FS12′ TO N’P:\sql_dat\At_FS12′,
MOVE N’\\prd\P\sql_dat\At_FS13′ TO N’P:\sql_dat\At_FS13′,
MOVE N’\\prd\P\sql_dat\At_FS14′ TO N’P:\sql_dat\At_FS14′,
MOVE N’\\prd\F\sql_dat\At_FS15′ TO N’I:\sql_dat\At_FS15′,
MOVE N’\\prd\F\sql_dat\At_FS16′ TO N’I:\sql_dat\At_FS16′,
MOVE N’\\prd\F\sql_dat\At_FS17′ TO N’I:\sql_dat\At_FS17′,
MOVE N’\\prd\F\sql_dat\At_FS18′ TO N’I:\sql_dat\At_FS18′,
MOVE N’\\prd\F\sql_dat\At_FS19′ TO N’I:\sql_dat\At_FS19′,
MOVE N’\\prd\I\sql_dat\At_FS20′ TO N’J:\sql_dat\At_FS20′,
MOVE N’\\prd\I\sql_dat\At_FS21′ TO N’J:\sql_dat\At_FS21′,
MOVE N’\\prd\I\sql_dat\At_FS22′ TO N’J:\sql_dat\At_FS22′,
MOVE N’\\prd\I\sql_dat\At_FS23′ TO N’J:\sql_dat\At_FS23′,
MOVE N’\\prd\I\sql_dat\At_FS24′ TO N’J:\sql_dat\At_FS24′,
MOVE N’\\prd\I\sql_dat\At_FS25′ TO N’J:\sql_dat\At_FS25′,
MOVE N’\\prd\N\sql_dat\At_FS26′ TO N’O:\sql_dat\At_FS26′,
MOVE N’\\prd\N\sql_dat\At_FS27′ TO N’O:\sql_dat\At_FS27′,
MOVE N’\\prd\N\sql_dat\At_FS28′ TO N’O:\sql_dat\At_FS28′,
MOVE N’\\prd\R\sql_dat\At_FS29′ TO N’K:\sql_dat\At_FS29′,
MOVE N’\\prd\U\sql_dat\At_FS30′ TO N’K:\sql_dat\At_FS30′,
MOVE N’\\prd\J\sql_dat\At_FS31′ TO N’L:\sql_dat\At_FS31′,
MOVE N’\\prd\K\sql_dat\At_FS32′ TO N’N:\sql_dat\At_FS32′,
MOVE N’\\prd\T\sql_dat\At_FS33′ TO N’K:\sql_dat\At_FS33′,
MOVE N’\\prd\V\sql_dat\At_FS34′ TO N’K:\sql_dat\At_FS34′,
MOVE N’\\prd\W\sql_dat\At_FS35′ TO N’K:\sql_dat\At_FS35′;
I am receiving this error:
Msg 3231, Level 16, State 1, Line 1
The media loaded on “\\\prd\L\sql_bak\At_group1.bak” is formatted to
support 1 media families, but 4 media families are expected according
to the backup device specification.
Msg 3013, Level 16, State 1, Line 1 RESTORE DATABASE is terminating
abnormally.
Please suggest.
can we setup split backup with date time in it? i wants to create new files. without append or overrite.
—Thanks Pinal, Just to help anyone…we can use below it will create backup files with time stamp, so no overrite:
declare @backupfile1 nvarchar(2000)
declare @backupfile2 nvarchar(2000)
declare @backupfile3 nvarchar(2000)
declare @backupfile4 nvarchar(2000)
set @backupfile1 = ‘V:\DB_Backup\ECPFullBackup\msdb1′ + REPLACE(REPLACE(REPLACE(CONVERT(varchar,GETDATE(),
20),’-‘,”),’:’,”),’ ‘,”) +’.BAK’
set @backupfile2 = ‘V:\DB_Backup\ECPFullBackup\msdb2′ + REPLACE(REPLACE(REPLACE(CONVERT(varchar,GETDATE(),
20),’-‘,”),’:’,”),’ ‘,”) +’.BAK’
set @backupfile3 = ‘V:\DB_Backup\ECPFullBackup\msdb3′ + REPLACE(REPLACE(REPLACE(CONVERT(varchar,GETDATE(),
20),’-‘,”),’:’,”),’ ‘,”) +’.BAK’
set @backupfile4 = ‘V:\DB_Backup\ECPFullBackup\msdb4′ + REPLACE(REPLACE(REPLACE(CONVERT(varchar,GETDATE(),
20),’-‘,”),’:’,”),’ ‘,”) +’.BAK’
BACKUP DATABASE [msdb] TO DISK = @backupfile1,
disk = @backupfile2,
disk = @backupfile3,
disk = @backupfile4