Please start any new threads on our new site at https://forums.sqlteam.com. We've got lots of great SQL Server experts to answer whatever question you can come up with.

 All Forums
 SQL Server 2008 Forums
 Transact-SQL (2008)
 Query to display Backup compression

Author  Topic 

ProgressBoy
Starting Member

14 Posts

Posted - 2012-07-07 : 19:14:48
I have a query from msdb..backupset that displays Database Name and Compression Ratio, but it displays multiple records for every database/backup. I just want one record for latest backup of the database.

If I specify Max(b.backup_finish_date) I have to group by Compression Ratio, that aggregates Compression Ratio number and is not what I want.



SELECT
b.database_name 'Database Name',

CONVERT (NUMERIC (20,2), (CONVERT (FLOAT, b.backup_size) /
CONVERT (FLOAT, b.compressed_backup_size))) 'Compression Ratio'

FROM
msdb.dbo.backupset b
WHERE
DATEDIFF (SECOND, b.backup_start_date, b.backup_finish_date) > 0
AND b.backup_size > 0
and b.type = 'd'
ORDER BY
b.database_name

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2012-07-07 : 20:32:28
may be this is what you want


;With CTE
AS
(
SELECT
b.database_name 'Database Name',

CONVERT (NUMERIC (20,2), (CONVERT (FLOAT, b.backup_size) /
CONVERT (FLOAT, b.compressed_backup_size))) 'Compression Ratio',
DATEDIFF (SECOND, b.backup_start_date, b.backup_finish_date) AS Duration,
ROW_NUMBER() OVER (PARTITION BY [Database Name] ORDER BY DATEDIFF (SECOND, b.backup_start_date, b.backup_finish_date) DESC) AS Seq
FROM
msdb.dbo.backupset b
WHERE
DATEDIFF (SECOND, b.backup_start_date, b.backup_finish_date) > 0
AND b.backup_size > 0
and b.type = 'd'
)

SELECT *
FROM CTE
WHERE Seq=1
ORDER BY
[Database Name]


------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/

Go to Top of Page

ProgressBoy
Starting Member

14 Posts

Posted - 2012-07-08 : 10:20:04
very nice, thank you. Great use of the Row_NUmber () with Partition By

Thanks!!
Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2012-07-08 : 16:07:07
welcome

------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/

Go to Top of Page
   

- Advertisement -