Script to find latest backups for all databases
Overview
There are at times when different teams have control over a particular server but you have the responsibility of restoring the database in case of disater. This is a tricky situation. If you dont have a policy regarding backups? You should have a record of recent backups in the server for each databases. If you have knowledge on say when was latest full/differential/log backup taken on a particualr database, you will not be totally lost in time of a catastrophe. If you are new to the environement, this script will give you an idea of what backup plan goes on each database. Especially if you administer multiple servers, it will help you document your backup locations.
How to use the script
The procedure uses msdb to get the relevent backups you need to look at.
The Procedure can be executed in 3 ways.
- EXEC USP_DBA_RECENTBACKUPS: This will detail all recent backups of all types (Full, differential and log ) for each database. Eg. If you take only full backups you will find only one record for each server.
- EXEC USP_DBA_RECENTBACKUPS '<DBNAME>': The same result as above. But here you are ineterested in a single database. It will list all recent backups of all types for the given databse.
- EXEC USP_DBA_RECENTBACKUPS '<DBNAME>','R': If you are having a simple backup plan of Full, differential and log backups, you can use this syntax to see what you need to restore the database. It will list latest full backup, latest differntial backup, and all the log backups therafter.
Hope this script will be useful for you.
Note:
- There is no guarentee that the files listed in the backup history is available in the location. chances are someone might have moved/ deleted the records.
- The data is retrived from msdb database. It is recomented that you save the results for whole server in an excel fie.
USE MASTER
GO
IF OBJECT_ID('USP_DBA_RECENTBACKUPS') IS NOT NULL
DROP PROC USP_DBA_RECENTBACKUPS
GO
CREATE PROC USP_DBA_RECENTBACKUPS
@P_DBNAME VARCHAR(200)= NULL,
@PLAN CHAR(1)= NULL
AS
BEGIN
DECLARE @DB_NAME VARCHAR(200)
SET @DB_NAME=@P_DBNAME
IF @DB_NAME IS NULL
BEGIN
WITH
BACKUP_RECENT AS
(
SELECT MAX(BACKUP_DATE) BACKUP_DATE,MAX(ID) ID,[TYPE],SERVER_NAME,DATABASE_NAME
FROM
(
SELECT ROW_NUMBER() OVER (ORDER BY DATABASE_NAME,[TYPE],BACKUP_FINISH_DATE) ID,
BACKUP_FINISH_DATE BACKUP_DATE, PHYSICAL_DEVICE_NAME,A.MEDIA_SET_ID,
SERVER_NAME,DATABASE_NAME,[TYPE]
FROM MSDB.DBO.BACKUPSET A JOIN MSDB.DBO.BACKUPMEDIAFAMILY B
ON(A.MEDIA_SET_ID=B.MEDIA_SET_ID)
) BACKUPS
GROUP BY [TYPE],SERVER_NAME,DATABASE_NAME
),
BACKUP_ALL AS
(
SELECT ROW_NUMBER() OVER (ORDER BY DATABASE_NAME,[TYPE],BACKUP_FINISH_DATE) ID,
PHYSICAL_DEVICE_NAME
FROM MSDB.DBO.BACKUPSET A JOIN MSDB.DBO.BACKUPMEDIAFAMILY B
ON(A.MEDIA_SET_ID=B.MEDIA_SET_ID)
)
SELECT SERVER_NAME [SERVER],DATABASE_NAME [DATABASE],BAKUPTYPE=
CASE WHEN [TYPE]='D' THEN 'FULL'
WHEN [TYPE]='I' THEN 'DIFFERENTIAL'
WHEN [TYPE]='L' THEN 'LOG'
WHEN [TYPE]='F' THEN 'FILE / FILEGROUP'
WHEN [TYPE]='G' THEN 'DIFFERENTIAL FILE'
WHEN [TYPE]='P' THEN 'PARTIAL'
WHEN [TYPE]='Q' THEN 'DIFFERENTIAL PARTIAL'
END,BACKUP_DATE [RECENT BACKUP], PHYSICAL_DEVICE_NAME [LOCATION] FROM BACKUP_RECENT,BACKUP_ALL
WHERE BACKUP_RECENT.ID=BACKUP_ALL.ID
ORDER BY SERVER_NAME,DATABASE_NAME,BACKUP_DATE
END
ELSE
BEGIN
IF @PLAN = 'R'
BEGIN
WITH
BACKUP_RECENT AS
(
SELECT MAX(BACKUP_DATE) BACKUP_DATE,MAX(ID) ID,[TYPE],SERVER_NAME,DATABASE_NAME
FROM
(
SELECT ROW_NUMBER() OVER (ORDER BY DATABASE_NAME,[TYPE],BACKUP_FINISH_DATE) ID,
BACKUP_FINISH_DATE BACKUP_DATE, PHYSICAL_DEVICE_NAME,A.MEDIA_SET_ID,
SERVER_NAME,DATABASE_NAME,[TYPE]
FROM MSDB.DBO.BACKUPSET A JOIN MSDB.DBO.BACKUPMEDIAFAMILY B
ON(A.MEDIA_SET_ID=B.MEDIA_SET_ID)
) BACKUPS
GROUP BY [TYPE],SERVER_NAME,DATABASE_NAME
),
BACKUP_ALL AS
(
SELECT ROW_NUMBER() OVER (ORDER BY DATABASE_NAME,[TYPE],BACKUP_FINISH_DATE) ID,
PHYSICAL_DEVICE_NAME
FROM MSDB.DBO.BACKUPSET A JOIN MSDB.DBO.BACKUPMEDIAFAMILY B
ON(A.MEDIA_SET_ID=B.MEDIA_SET_ID)
)
SELECT * FROM(
SELECT SERVER_NAME [SERVER],DATABASE_NAME [DATABASE],BAKUPTYPE=
CASE WHEN [TYPE]='D' THEN 'FULL'
WHEN [TYPE]='I' THEN 'DIFFERENTIAL'
WHEN [TYPE]='L' THEN 'LOG'
WHEN [TYPE]='F' THEN 'FILE / FILEGROUP'
WHEN [TYPE]='G' THEN 'DIFFERENTIAL FILE'
WHEN [TYPE]='P' THEN 'PARTIAL'
WHEN [TYPE]='Q' THEN 'DIFFERENTIAL PARTIAL'
END,BACKUP_DATE [RECENT BACKUP], PHYSICAL_DEVICE_NAME [LOCATION] FROM BACKUP_RECENT,BACKUP_ALL
WHERE BACKUP_RECENT.ID=BACKUP_ALL.ID AND DATABASE_NAME=@P_DBNAME AND [TYPE] IN ('D','I')
UNION
SELECT
SERVER_NAME,DATABASE_NAME,BAKUPTYPE='LOG',
BACKUP_FINISH_DATE BACKUP_DATE,PHYSICAL_DEVICE_NAME [LOCATION]
FROM MSDB.DBO.BACKUPSET A JOIN MSDB.DBO.BACKUPMEDIAFAMILY B
ON(A.MEDIA_SET_ID=B.MEDIA_SET_ID)
WHERE [TYPE]='L'
AND BACKUP_FINISH_DATE>
(
SELECT TOP 1 BACKUP_FINISH_DATE FROM MSDB.DBO.BACKUPSET WHERE [TYPE] IN ('D','I')
AND DATABASE_NAME= @DB_NAME ORDER BY BACKUP_FINISH_DATE DESC
)
AND DATABASE_NAME= @DB_NAME ) AS RESTORE_PLAN
ORDER BY [RECENT BACKUP]
END
ELSE
BEGIN
WITH
BACKUP_RECENT AS
(
SELECT MAX(BACKUP_DATE) BACKUP_DATE,MAX(ID) ID,[TYPE],SERVER_NAME,DATABASE_NAME
FROM
(
SELECT ROW_NUMBER() OVER (ORDER BY DATABASE_NAME,[TYPE],BACKUP_FINISH_DATE) ID,
BACKUP_FINISH_DATE BACKUP_DATE, PHYSICAL_DEVICE_NAME,A.MEDIA_SET_ID,
SERVER_NAME,DATABASE_NAME,[TYPE]
FROM MSDB.DBO.BACKUPSET A JOIN MSDB.DBO.BACKUPMEDIAFAMILY B
ON(A.MEDIA_SET_ID=B.MEDIA_SET_ID)
) BACKUPS
GROUP BY [TYPE],SERVER_NAME,DATABASE_NAME
),
BACKUP_ALL AS
(
SELECT ROW_NUMBER() OVER (ORDER BY DATABASE_NAME,[TYPE],BACKUP_FINISH_DATE) ID,
PHYSICAL_DEVICE_NAME
FROM MSDB.DBO.BACKUPSET A JOIN MSDB.DBO.BACKUPMEDIAFAMILY B
ON(A.MEDIA_SET_ID=B.MEDIA_SET_ID)
)
SELECT SERVER_NAME [SERVER],DATABASE_NAME [DATABASE],BAKUPTYPE=
CASE WHEN [TYPE]='D' THEN 'FULL'
WHEN [TYPE]='I' THEN 'DIFFERENTIAL'
WHEN [TYPE]='L' THEN 'LOG'
WHEN [TYPE]='F' THEN 'FILE / FILEGROUP'
WHEN [TYPE]='G' THEN 'DIFFERENTIAL FILE'
WHEN [TYPE]='P' THEN 'PARTIAL'
WHEN [TYPE]='Q' THEN 'DIFFERENTIAL PARTIAL'
END,BACKUP_DATE [RECENT BACKUP], PHYSICAL_DEVICE_NAME [LOCATION] FROM BACKUP_RECENT,BACKUP_ALL
WHERE BACKUP_RECENT.ID=BACKUP_ALL.ID AND DATABASE_NAME=@P_DBNAME
ORDER BY BACKUP_DATE
END
END
END