Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

Find the first record for each month Expand / Collapse
Author
Message
Posted Monday, July 29, 2013 8:31 AM
Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Friday, December 12, 2014 3:21 AM
Points: 346, Visits: 956
I'm trying to pull out the file size and backup size for each database using the msdb backup history table. I want to get the 1st record for each month (due to the vagaries of the backup system, there may not always be a backup on the 1st - or there may be more than one !)

This is what I have so far (I think I want to use partition by, to get rank #1 of the 1st record and go from there, but am unsure how to express that I want to partition by month ??? )

Any suggestions appreciated !!! (especially if I'm on completely the wrong track )

select backup_start_date as [Date], ((backupfile.backup_size/1024)/1024) as [Database Size],
((backupfile.file_size/1024)/1024) as [File Size] ,
RANK() OVER
(PARTITION BY backup_start_date ORDER BY backup_start_date) AS Rank
from msdb..backupfile, msdb..backupset

where backupset.database_name = 'mydatabasename' and file_type = 'D'
and backupfile.backup_size > 0
and backupfile.backup_set_id = backupset.backup_set_id
order by backup_start_date
Post #1478616
Posted Monday, July 29, 2013 8:55 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Thursday, December 18, 2014 1:43 AM
Points: 6,890, Visits: 14,254
select 
backup_start_date as [Date],
((f.backup_size/1024)/1024) as [Database Size],
((f.file_size/1024)/1024) as [File Size] ,
RANK() OVER (PARTITION BY backup_start_date ORDER BY backup_start_date) AS Rank,
rn = ROW_NUMBER() OVER (PARTITION BY MONTH(backup_start_date) ORDER BY backup_start_date DESC)
from msdb..backupfile f
INNER JOIN msdb..backupset s
ON f.backup_set_id = s.backup_set_id
where s.database_name = 'mydatabasename'
and file_type = 'D'
and f.backup_size > 0
order by backup_start_date



“Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
Exploring Recursive CTEs by Example Dwain Camps
Post #1478632
Posted Monday, July 29, 2013 9:15 AM
Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Friday, December 12, 2014 3:21 AM
Points: 346, Visits: 956
I am not sure how the above worked, but it returned something !
Post #1478641
Posted Monday, July 29, 2013 9:38 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Thursday, December 18, 2014 1:43 AM
Points: 6,890, Visits: 14,254
There's an extra column in your output. You can filter on it, provided you set up the query as an inner query or CTE of an outer query wielding the filter.

“Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
Exploring Recursive CTEs by Example Dwain Camps
Post #1478650
Posted Monday, July 29, 2013 9:51 AM
Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Friday, December 12, 2014 3:21 AM
Points: 346, Visits: 956
Ok, I popped the results into a temporary table. It's only giving the results (rn = 1) for either the first or the last year (depending on whether I remove the desk or not) ie. a total of 12 results

This is a little like I got stuck before, I want something like month(date)&year(date) to partition on
Post #1478657
Posted Tuesday, July 30, 2013 12:52 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Thursday, December 18, 2014 1:43 AM
Points: 6,890, Visits: 14,254
N.D (7/29/2013)
Ok, I popped the results into a temporary table. It's only giving the results (rn = 1) for either the first or the last year (depending on whether I remove the desk or not) ie. a total of 12 results

This is a little like I got stuck before, I want something like month(date)&year(date) to partition on



	rn = ROW_NUMBER() OVER (PARTITION BY MONTH(backup_start_date), YEAR(backup_start_date) ORDER BY backup_start_date DESC)



“Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
Exploring Recursive CTEs by Example Dwain Camps
Post #1478842
Posted Tuesday, July 30, 2013 2:13 AM
Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Friday, December 12, 2014 3:21 AM
Points: 346, Visits: 956
That's brilliant !

Thanks very much
Post #1478873
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse