Blog Post

What’s in my backup file?

,

Restoring a backup file is pretty easy right?

RESTORE DATABASE [Test] FROM DISK = 'C:\backups\backup.bak';

Ok, but what if more than one database backup is stored in that single backup file? Didn’t know you could do that?

Yep. You can.

BACKUP DATABASE [Test] TO DISK = 'C:\backups\backup.bak';
BACKUP DATABASE [AdventureWorks2014] TO DISK = 'C:\backups\backup.bak';

So if we are passed the file backup.bak, how do we know what’s in it? Well, we can use RESTORE HEADERONLY.

RESTORE HEADERONLY FROM DISK = 'C:\backups\backup.bak';

whatsinabackupfile1

Now that we have a list of what’s in the backup file it’s easy enough to restore the file we want. To restore AdventureWorks2014 we just reference it’s position in the file.

RESTORE DATABASE [AdventureWorks2014] FROM DISK = 'C:\backups\backup.bak'
WITH FILE = 2;

Now let’s say we are restoring the original AdventureWorks backup file. The one from Microsoft.

RESTORE DATABASE [AdventureWorks2014] 
FROM DISK = 'C:\backups\AdventureWorks2014.bak';

Msg 5133, Level 16, State 1, Line 8

Directory lookup for the file “C:\Program Files\Microsoft SQL Server\MSSQL12.SQL2014MULTI\MSSQL\DATA\AdventureWorks2014_Data.mdf” failed with the operating system error 3(The system cannot find the path specified.).

Msg 3156, Level 16, State 3, Line 8

File ‘AdventureWorks2014_Data’ cannot be restored to ‘C:\Program Files\Microsoft SQL Server\MSSQL12.SQL2014MULTI\MSSQL\DATA\AdventureWorks2014_Data.mdf’. Use WITH MOVE to identify a valid location for the file.

Msg 5133, Level 16, State 1, Line 8

Directory lookup for the file “C:\Program Files\Microsoft SQL Server\MSSQL12.SQL2014MULTI\MSSQL\DATA\AdventureWorks2014_Log.ldf” failed with the operating system error 3(The system cannot find the path specified.).

Msg 3156, Level 16, State 3, Line 8

File ‘AdventureWorks2014_Log’ cannot be restored to ‘C:\Program Files\Microsoft SQL Server\MSSQL12.SQL2014MULTI\MSSQL\DATA\AdventureWorks2014_Log.ldf’. Use WITH MOVE to identify a valid location for the file.

Msg 3119, Level 16, State 1, Line 8

Problems were identified while planning for the RESTORE statement. Previous messages provide details.

Msg 3013, Level 16, State 1, Line 8

RESTORE DATABASE is terminating abnormally.

Notice all of those WITH MOVE errors? The location of the database files from the original backup doesn’t match what’s available on my machine.

I do want to stop and point out that you won’t always get these errors. There are several possibilities here. If the database name that you are restoring to doesn’t exist yet then you will get this error if the directories listed in the backup file don’t already exist. If, however, the database exists then the files (based on file name, i.e. AdventureWorks2014_Log not C:\Program Files\Microsoft SQL Server\MSSQL12.SQL2014MULTI\MSSQL\DATA\AdventureWorks2014_Log.ldf) will be put in the same location as the existing files. If the backup file has more files in it, or they are named differently, then you are still going to get the above error.

All right. So how do we tell what files exist in the backup? RESTORE FILELISTONLY

RESTORE FILELISTONLY FROM DISK = 'C:\backups\backup.bak'
WITH FILE = 2;

whatsinabackupfile2

And now we have a list of files and file names we can add in the MOVE clause of the RESTORE command.

RESTORE DATABASE AdventureWorks2014 FROM DISK = 'C:\backups\backup.bak'
WITH FILE = 2,
MOVE 'AdventureWorks2014_Data' 
TO 'C:\Program Files\Microsoft SQL Server\MSSQL13.SQL2016CS\MSSQL\DATA\AdventureWorks2014_Data.mdf', 
MOVE 'AdventureWorks2014_Log' 
TO 'C:\Program Files\Microsoft SQL Server\MSSQL13.SQL2016CS\MSSQL\DATA\AdventureWorks2016_Log.ldf';

The basics of restoring a backup file is pretty easy. But it’s important to know what’s actually in that file before you start restoring it.

Filed under: Backups, Microsoft SQL Server, SQLServerPedia Syndication Tagged: backups, microsoft sql server, T-SQL

Rate

You rated this post out of 5. Change rating

Share

Share

Rate

You rated this post out of 5. Change rating