Background
Recently,
one of our DBA restored a database on live server, but with old backup accidentally. Later on, we have found that it was hard to detect which backup was
actually restored. To check, which backups we have created for database we have
a perfect script, which you can find over here
and here.
But unfortunately no such script found anywhere to get restore history.
Here
is a script, we have used to create a job, which will fetch restore related log
entries from SQL Server Log and will archive it to a user created history table.
Using the code
USE master
GO
CREATE TABLE DatabaseRestoreLog
(DatabaseName VARCHAR(50), RestoreDate DATETIME, RestoredFrom VARCHAR(500))
GO
-- Table variable to hold intermediate data
DECLARE @ReportSQLErrorLogs TABLE
(
[log_date] [datetime] NULL,
[processinfo] [varchar](255) NULL,
[processtext] [text] NULL
)
DECLARE @NumErrorLogs INT,
@CurrentLogNum INT
SET @CurrentLogNum = 0
-- Get total number of log files from registry
EXEC master.dbo.xp_instance_regread N'HKEY_LOCAL_MACHINE',
N'Software\Microsoft\MSSQLServer\MSSQLServer', N'NumErrorLogs',
@NumErrorLogs OUTPUT
SELECT @NumErrorLogs = ISNULL(@NumErrorLogs, 6)
-- NULL in registry entry for Error Log files mean default of 6 value
WHILE @CurrentLogNum < @NumErrorLogs
BEGIN
insert into @ReportSQLErrorLogs
exec master..xp_readerrorlog @CurrentLogNum
PRINT @CurrentLogNum
SELECT @CurrentLogNum = @CurrentLogNum + 1
END
INSERT INTO DatabaseRestoreLog
SELECT SUBSTRING(processtext, CHARINDEX('base:', processtext, 1) + 5,
CHARINDEX(',', processtext, 0) - ( CHARINDEX('base:', processtext, 0) )
- 5), log_date,
SUBSTRING(processtext, CHARINDEX(': {''', processtext, 1) + 4,
CHARINDEX('''})', processtext, 0) - ( CHARINDEX(': {''', processtext, 0) )- 4)
FROM @ReportSQLErrorLogs
WHERE processtext LIKE 'Database was restored%'
--For last 24 hours
AND DATEDIFF(HH,log_date,GETDATE()) <=24
ORDER BY log_date DESC
Output of history table will be as following.