Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Find the first record for each month


Find the first record for each month

Author
Message
N.D
N.D
Old Hand
Old Hand (372 reputation)Old Hand (372 reputation)Old Hand (372 reputation)Old Hand (372 reputation)Old Hand (372 reputation)Old Hand (372 reputation)Old Hand (372 reputation)Old Hand (372 reputation)

Group: General Forum Members
Points: 372 Visits: 1074
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 Hehe )


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

ChrisM@Work
ChrisM@Work
SSCrazy Eights
SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)

Group: General Forum Members
Points: 8959 Visits: 19016
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
N.D
N.D
Old Hand
Old Hand (372 reputation)Old Hand (372 reputation)Old Hand (372 reputation)Old Hand (372 reputation)Old Hand (372 reputation)Old Hand (372 reputation)Old Hand (372 reputation)Old Hand (372 reputation)

Group: General Forum Members
Points: 372 Visits: 1074
I am not sure how the above worked, but it returned something !
ChrisM@Work
ChrisM@Work
SSCrazy Eights
SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)

Group: General Forum Members
Points: 8959 Visits: 19016
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
N.D
N.D
Old Hand
Old Hand (372 reputation)Old Hand (372 reputation)Old Hand (372 reputation)Old Hand (372 reputation)Old Hand (372 reputation)Old Hand (372 reputation)Old Hand (372 reputation)Old Hand (372 reputation)

Group: General Forum Members
Points: 372 Visits: 1074
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 Ermm
ChrisM@Work
ChrisM@Work
SSCrazy Eights
SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)

Group: General Forum Members
Points: 8959 Visits: 19016
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 Ermm



   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
N.D
N.D
Old Hand
Old Hand (372 reputation)Old Hand (372 reputation)Old Hand (372 reputation)Old Hand (372 reputation)Old Hand (372 reputation)Old Hand (372 reputation)Old Hand (372 reputation)Old Hand (372 reputation)

Group: General Forum Members
Points: 372 Visits: 1074
That's brilliant !

Thanks very much w00t
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search