May 23, 2012 at 9:59 pm
Comments posted to this topic are about the item Last Backup Taken, or Not
May 24, 2012 at 2:08 am
Nice one. Thanks for sharing
Thanks
May 24, 2012 at 6:38 am
Very nice "utility". Thanks!
May 24, 2012 at 7:16 am
We take image backups of the server partition for system restore purposes along with our SQL Server backups. Is there any way to have this script only consider SQL Server backups and not include the server Image backups?
May 24, 2012 at 7:29 am
I found a way to do this by adding
AND T2.NAME is not null
to the where clause of the top select. Still not sure if this is the best way to do this but it seems to be working.
May 24, 2012 at 9:59 am
Excellent Script, thanks for sharing.
May 29, 2012 at 8:13 am
Hi,
shortening it up a bit...
SELECT T1.Name AS DatabaseName,
DATABASEPROPERTYEX(T1.Name, 'recovery') AS database_recovery_model,
Isnull(Max(T2.recovery_model),'No Backup Taken') AS backup_recovery_model,
CASE type
WHEN 'D' THEN 'Full'
WHEN 'I' THEN 'Differential'
WHEN 'L' THEN 'Log'
ELSE COALESCE(type,'No Backup')
END AS BackupType,
Isnull(CONVERT(VARCHAR(17), CONVERT(DATETIME, Max(T2.backup_finish_date), 113)), 'Never') AS LastBackUpTaken
FROM sys.sysdatabases T1
LEFT OUTER JOIN msdb.dbo.backupset T2
ON T2.database_name = T1.name
GROUP BY T1.Name, type
ORDER BY T1.Name, type
Best regards
karl
December 9, 2012 at 2:07 am
That is a great script Karl Klingler, very compact compared to the original script, but I notice both the original script and your script does not report on the important situation for a database in full recovery mode, where there is a last database backup but never a transaction log backup.
Can you see if you can get your script to report on this situation?
Also you can exclude the tempdb database.
Regards,
DBA Pete
December 9, 2012 at 1:19 pm
That was actually the intent of the original script. You should try that one again.
GL,
Jon
December 10, 2012 at 5:40 pm
Hi Jon,
This is what I mean:
Create a new database called TEST in full recovery mode. It has never been backed up and shows as:
DatabaseName recovery_model BackupType LastBackUpTaken
TEST No Backup Taken No Backup
Backup the database and this now shows as:
DatabaseName recovery_model BackupType LastBackUpTaken
TEST FULL Full Dec 11 2012 10:53AM
But what I would find useful is to show that while the database had a full backup, it has never had a transaction log backup.
This is important as I have seen many cases of a database set up by vendors where the database is in full recovery mode.
It has regular full backups but never a transaction log backup.
This often results in the transaction log being larger than the main data file.
I think it would be useful to show something like the second row below:
DatabaseName recovery_model BackupType LastBackUpTaken
TEST FULL Full Dec 11 2012 10:53AM
TEST FULL Log Never
Regards,
DBA Pete.
December 11, 2012 at 10:04 am
I hear what you're saying, but I use this script on a regular basis to identify the issue. I do this by reviewing the output and if I see database name, full recovery, only a full backup and not another line indicating a transaction log backup, I know there's an issue. If you'd like to make an update to the script that inserts a line stating no t-log backup when the above is true, please feel free to contribute.
Thanks,
Jon
December 12, 2012 at 3:07 am
Hi,
this is not so short anymore, but should do the trick...
;WITH a AS (SELECT 'Full' AS type UNION ALL SELECT 'Log' UNION ALL SELECT 'Differential'), b AS
( SELECT Name, DATABASEPROPERTYEX(Name, 'recovery') AS rm
FROM sys.sysdatabases
), c AS
( SELECT * FROM a , b WHERE rm = 'FULL' OR (rm = 'SIMPLE' AND type IN ( 'FULL', 'Differential') )
), d AS
( SELECT database_name,
Isnull(Max(recovery_model),'No Backup Taken') AS backup_recovery_model,
CASE type
WHEN 'D' THEN 'Full'
WHEN 'I' THEN 'Differential'
WHEN 'L' THEN 'Log'
ELSE COALESCE(type,'No Backup')
END AS BackupType,
CONVERT(VARCHAR(17), CONVERT(DATETIME, Max(backup_finish_date), 113)) AS LastBackUpTaken
FROM msdb.dbo.backupset
GROUP BY database_name, type
)
SELECT c.Name AS DatabaseName,
c.rm AS database_recovery_model,
c.type AS BackupType,
Isnull(d.LastBackUpTaken, 'Never') AS LastBackUpTaken
FROM c LEFT OUTER JOIN d
ON d.database_name = c.name AND c.type = d.BackupType
WHERE NOT ( c.type = 'Differential' AND d.LastBackUpTaken IS NULL) AND c.name <> 'tempdb'
GROUP BY c.Name, d.BackupType, d.LastBackUpTaken, c.rm, c.type
ORDER BY 1, 3
All corrections are welcome... 🙂
Best regards
karl
December 16, 2012 at 9:12 pm
Hi Karl,
That works.
I also could not find a better way than to use an additional union to get this information.
If anyone does come up with a better way then let us know.
Thanks,
DBA Pete
December 18, 2012 at 6:21 am
Hi,
i had neglected bulk_logged databases... Here a better script
;WITH a AS
( SELECT type='D' UNION ALL SELECT 'L' UNION ALL SELECT 'I'
), c AS
( SELECT b.Name, DATABASEPROPERTYEX(b.Name, 'recovery') as rm, a.type
FROM a, sys.sysdatabases b
WHERE DATABASEPROPERTYEX(b.Name, 'recovery') IN ( 'FULL', 'BULK_LOGGED') OR a.type IN ( 'D', 'I')
), d AS
( SELECT database_name,
Isnull(Max(recovery_model),'No Backup Taken') AS backup_recovery_model,
type,
CONVERT(VARCHAR(17), CONVERT(DATETIME, Max(backup_finish_date), 113)) AS LastBackUpTaken
FROM msdb.dbo.backupset
GROUP BY database_name, type
)
SELECT c.Name AS DatabaseName,
c.rm AS database_recovery_model,
CASE c.type
WHEN 'D' THEN 'Full'
WHEN 'I' THEN 'Differential'
WHEN 'L' THEN 'Log'
ELSE COALESCE(d.type,'No Backup')
END AS BackupType,
Isnull(d.LastBackUpTaken, 'Never') AS LastBackUpTaken
FROM c LEFT OUTER JOIN d
ON d.database_name = c.name AND c.type = d.type
WHERE NOT ( c.type = 'I' AND d.LastBackUpTaken IS NULL) AND c.name <> 'tempdb'
GROUP BY c.Name, c.type, d.LastBackUpTaken, c.rm, d.type
ORDER BY c.Name, c.type
Best regards
karl
Viewing 15 posts - 1 through 15 (of 16 total)
You must be logged in to reply to this topic. Login to reply