Recover a database from a older full backup and a current .LDF file

Pinal Dave at SQLAuthority.com posted an interesting question that tested my knowledge. I was sure there was a way to complete his question, but I haven’t had much experience with databases in FULL recovery model in the past.

His question

Let us assume that you have corrupted (beyond repairable) or missing MDF. Along with that you have full backup of the database at TimeA. Additionally there has been no backup since TimeA. You have now recovered log file at TimeB. How to get the Database back online with the same state as TimeB?

My response is as follows.

On a test system, I created a database FullBackupTest with Full Recovery Model.
I created a table TableA.
I inserted a single record into TableA.
I took a full backup of FullBackupTest.
I stopped SQL Server Service and copied both the .mdf and .ldf files to different folder.
I started SQL Server Service
I inserted two more records into TableA.

I then stopped the SQL Server Service.
I then deleted the .mdf file in the Data directory.
I started SQL Server.
Database FullBackupTest failed to come online.
Just for tests, I stopped SQL Server Service again and copied the .mdf file back from the copy I made manually (I now have the .mdf file from an earlier copy out of sync with the .ldf file).
I started SQL Server and the database failed to come online.The Error in the log file was

2011-04-14 21:13:15.37 spid16s Error: 5173, Severity: 16, State: 1.
2011-04-14 21:13:15.37 spid16s One or more files do not match the primary file of the database. If you are attempting to attach a database, retry the operation with the correct files. If this is an existing database, the file may be corrupted and should be restored from a backup.

Looks good, can’t just do that, as I expected. For further testing, I did the following
I switched FullBackupTest to Emergency Mode
I switched FullBackupTest to Single User Mode
I ran dbcc checkdb (FullBackupTest).
No errors were reported.
Database would not switch from Emergency to Online mode with same error as above.
I then ran dbcc checkdb (FullBackupTest, repair_allow_data_loss)
Database would then switch to Online mode, however we were back to a single record in TableA, so it was just the same as a restore from the full backup at TimeA.

Then I stopped SQL Server Service one more time, and restored both the mdf and ldf from the manual copy.
Started SQL Server, verified FullBackupTest came online, and there were three rows in TableA.
Stopped SQL Server Service
Deleted the .mdf file
Started SQL Server Service.
FullBackupTest failed to come online again.
In Management Studio I executed
BACKUP LOG FullBackupTest TO DISK='FullBackupTest.trn' WITH NO_TRUNCATE"
Then
RESTORE DATABASE FullBackupTest FROM DISK='FullBackupTestTimeA.bak' WITH NORECOVERY

This set the database in RECOVERING Mode and allowed me to restore Log File Backups.
I then executed
RESTORE LOG FullBackupTest FROM DISK='FullBackupTest.trn' WITH RECOVERY

Once complete, I find three rows in TableA as I expected to.

The keys are
1) To make sure you backup the tail of the log on the lost database.
2) Restore the full backup using the WITH NORECOVERY
3) Restore the log file backup from Step 1 using WITH RECOVERY to switch back to Online mode.

Great question Pinal!

2 thoughts on “Recover a database from a older full backup and a current .LDF file

  1. Hi,

    I performed all your steps but encountered following error at the last command i.e. ‘RESTORE LOG FullBackupTest FROM DISK=’FullBackupTest.trn’ WITH RECOVERY’

    Msg 4305, Level 16, State 1, Line 1
    The log in this backup set begins at LSN 572172000000152400001, which is too recent to apply to the database. An earlier log backup that includes LSN 572077000002033600001 can be restored.
    Msg 3013, Level 16, State 1, Line 1
    RESTORE LOG is terminating abnormally.

    As a result, I don’t have test table which I created after taking full Database backup.

    • Hammad, just a quick glance at what you’ve written, I’d guess that you’re not using the most recent full backup of the database. What it’s saying is that according to the log chain, you’ve skipped a backup in the process and that’s why the Tail of the Log backup is showing as too recent.

Leave a Reply to Hammad Mansoor Cancel reply

Your email address will not be published.

*

This site uses Akismet to reduce spam. Learn how your comment data is processed.