Verify Latest Database Backups – T-SQL

A common challenge is to determine when database backups were taken from our databases. As soon as there are more than three user databases, this task is not that easy to accomplish by opening the database properties dialog in SSMS and checking the Last Full/Log Backup lines on the General tab. Scripting is your friend – as always :)

A very simplistic approach is to just get the time of the latest backups taken.

SELECT d.name as DBName, 
      ISNULL(CONVERT(varchar(16), MAX(bs.backup_finish_date), 120),'------ NEVER') as LastBackup
FROM sys.databases d
LEFT OUTER JOIN msdb.dbo.backupset bs ON bs.database_name = d.name
WHERE d.name != 'tempdb'
GROUP BY d.Name
ORDER BY d.Name;

Ok, that was easy – where’s the catch? Well, what kind of backup was taken of your database at that time? Was it a full, a copy-only or just a transaction log? Oops… So, let’s RTFM and find the magic column in the backupset table: type. Typically, we’re interested in the full, incremental and log backups, when applicable. Version 2:

SELECT d.name as DBName, 
      ISNULL(CONVERT(varchar(16), bs_D.LastBackup, 120),'------ NEVER') as LastFullBackup,
      ISNULL(CONVERT(varchar(16), bs_I.LastBackup, 120),'------ NEVER') as LastDiffBackup,
      CASE WHEN d.recovery_model_desc = 'SIMPLE' THEN 'N/A' ELSE ISNULL(CONVERT(varchar(16), bs_L.LastBackup, 120),'------ NEVER') END as LastTLogBackup
FROM sys.databases d
LEFT OUTER JOIN (select database_name, max(backup_finish_date) LastBackup FROM msdb.dbo.backupset WHERE type = 'D' group by database_name) bs_D ON bs_D.database_name = d.name
LEFT OUTER JOIN (select database_name, max(backup_finish_date) LastBackup FROM msdb.dbo.backupset WHERE type = 'I' group by database_name) bs_I ON bs_I.database_name = d.name
LEFT OUTER JOIN (select database_name, max(backup_finish_date) LastBackup FROM msdb.dbo.backupset WHERE type = 'L' group by database_name) bs_L ON bs_L.database_name = d.name
WHERE d.name != 'tempdb'
ORDER BY d.Name;

Looks a bit more fancy – and useful. If you’re really picky, you may want to check the full backups whether they were copy-only backups, by filtering on the is_copy_only column. Enjoy!

One Comment

  1. S.E.:

    Nice code.
    Good base to develop an enhenced version.

Leave a comment