Restoring a Microsoft SQL Server Database

This blog article is a scenario that I sent a coworker a while back about recovering a SQL Server database up to the point in time where a catastrophic hard disk drive failure occurs for the hard drive containing a SQL Server database. The transaction log for this database is on a separate physical disk and is still accessible.

I added the Northwind database to SQL Express on my machine, changed the recovery model to full, and then backed up the database and transaction log:

BACKUP DATABASE Northwind TO DISK = 'C:\Program Files\Microsoft SQL Server\MSSQL10.SQLEXPRESS\MSSQL\Backup\Northwind.bak'
WITH DESCRIPTION = 'Northwind Full Backup', NAME = 'Full Backup'
GO
BACKUP LOG Northwind TO DISK = 'C:\Program Files\Microsoft SQL Server\MSSQL10.SQLEXPRESS\MSSQL\Backup\Northwind1.trn'
WITH DESCRIPTION = 'Northwind Log Backup', NAME = 'Log Backup'
GO

Processed 392 pages for database ‘Northwind’, file ‘Northwind’ on file 1. Processed 2 pages for database ‘Northwind’, file ‘Northwind_log’ on file 1. BACKUP DATABASE successfully processed 394 pages in 0.922 seconds (3.331 MB/sec). Processed 2 pages for database ‘Northwind’, file ‘Northwind_log’ on file 1. BACKUP LOG successfully processed 2 pages in 0.074 seconds (0.171 MB/sec).

I modified a row of data:

UPDATE Categories
SET CategoryName = 'Drinks'
WHERE CategoryID = '1'

I stopped the SQL Server service and deleted the Northwind.mdf file and then restarted the SQL Server service, simulating a disk drive failure for the drive that contains the Northwind database. Keep in mind that the transaction log is on a separate physical disk.

db-restore1.jpg

I backed up the transaction log since it was still accessible:

BACKUP LOG Northwind TO DISK = 'C:\Program Files\Microsoft SQL Server\MSSQL10.SQLEXPRESS\MSSQL\Backup\Northwind2.trn'
WITH CONTINUE_AFTER_ERROR, DESCRIPTION = 'Northwind Log Backup - Tail', NAME = 'Log Backup'

Processed 9 pages for database ‘Northwind’, file ‘Northwind_log’ on file 1. BACKUP LOG successfully processed 9 pages in 0.045 seconds (1.562 MB/sec).

I restored the database and applied all of the transaction log backups:

RESTORE DATABASE Northwind
FROM DISK = 'C:\Program Files\Microsoft SQL Server\MSSQL10.SQLEXPRESS\MSSQL\Backup\Northwind.bak'
WITH NORECOVERY
GO
RESTORE LOG Northwind
FROM DISK = 'C:\Program Files\Microsoft SQL Server\MSSQL10.SQLEXPRESS\MSSQL\Backup\Northwind1.trn'
WITH NORECOVERY
GO
RESTORE LOG Northwind
FROM DISK = 'C:\Program Files\Microsoft SQL Server\MSSQL10.SQLEXPRESS\MSSQL\Backup\Northwind2.trn'
WITH NORECOVERY
GO
RESTORE DATABASE Northwind WITH RECOVERY
GO

Processed 392 pages for database ‘Northwind’, file ‘Northwind’ on file 1. Processed 2 pages for database ‘Northwind’, file ‘Northwind_log’ on file 1. RESTORE DATABASE successfully processed 394 pages in 0.335 seconds (9.168 MB/sec). Processed 0 pages for database ‘Northwind’, file ‘Northwind’ on file 1. Processed 2 pages for database ‘Northwind’, file ‘Northwind_log’ on file 1. RESTORE LOG successfully processed 2 pages in 0.012 seconds (1.057 MB/sec). Processed 0 pages for database ‘Northwind’, file ‘Northwind’ on file 1. Processed 9 pages for database ‘Northwind’, file ‘Northwind_log’ on file 1. RESTORE LOG successfully processed 9 pages in 0.020 seconds (3.515 MB/sec). RESTORE DATABASE successfully processed 0 pages in 0.512 seconds (0.000 MB/sec).

I validated my data changes which were only part of the transaction log backup that occurred after the simulated hard disk drive failure were restored to the database:

db-restore2.jpg

Pretty cool, huh?

ยต