question

jhowe avatar image
jhowe asked

Run query 1st month for previous month else current month

Hi All, What is the best way in sql using datetime format 2012-02-01 00:00:00.000 to select data where on the 1st of the month it returns all data from the previous month i.e. 2012-01-01 00:00:00.000 to 2012-02-01 00:00:00.000, otherwise return data from the 1st of the month to the current date? Thanks for your help! it's a where clause for a report that will be running daily...
sql-server-2008sql-server-2008-r2tsql
10 |1200

Up to 2 attachments (including images) can be used with a maximum of 512.0 KiB each and 1.0 MiB total.

Kev Riley avatar image
Kev Riley answered
First of all you need to realise that date data is not stored in a particular format. It is simply stored as datetime data (actually 8 bytes), and it is only when we read it out of the database does a format get applied. Given that it should be easy to follow that you need a where clause like where ( datepart(dd, getdate()) = 1 --1st of month and yourdatefield >= dateadd(mm, -1, cast(getdate() as date)) --1st of prev month and yourdatefield < cast(getdate() as date) --1st of this month ) or ( datepart(dd, getdate()) 1 -- not 1st of month and yourdatefield >= dateadd(dd, -datepart(dd, getdate())+1, cast(getdate() as date)) --1st of this month and yourdatefield < getdate() --now )
4 comments
10 |1200

Up to 2 attachments (including images) can be used with a maximum of 512.0 KiB each and 1.0 MiB total.

jhowe avatar image jhowe commented ·
Hi kev! are you going to sql bits? Can I use an else statement within a where clause so if 1st of month then do first part else do second part?
0 Likes 0 ·
Kev Riley avatar image Kev Riley ♦♦ commented ·
Probably not going to make it :(! You can't use an else statement, but only one of these will be true for a given date. The logic captures both cases (1st or not 1st) and then filters the data dependant on that. Make sense?
0 Likes 0 ·
jhowe avatar image jhowe commented ·
Yea I'll give it a shot! Thanks for your help.
0 Likes 0 ·
jhowe avatar image jhowe commented ·
Hi Kev can you explain what the second part is doing, datetime functions always confuse the hell out of me...
0 Likes 0 ·
Usman Butt avatar image
Usman Butt answered

I would have approached it a bit different. I would have applied the logic to the dates in variables before moving to the actual statement i.e.

DECLARE @StartDate DATE,   @EndDate DATE

IF DATEPART(dd, GETDATE()) = 1 --1st of month
BEGIN    
    SET @StartDate = DATEADD(mm, -1, GETDATE()) --1st of prev month
    SET @EndDate = GETDATE()
END
ELSE
BEGIN
    SET @StartDate = DATEADD(MONTH, DATEDIFF(MONTH, 0, GETDATE()) , 0) --1st of this month
    SET @EndDate = DATEADD(dd, 1, GETDATE())
END

Then an easy WHERE clause would have been

datefield >= StartDate AND datefield < EndDate 
2 comments
10 |1200

Up to 2 attachments (including images) can be used with a maximum of 512.0 KiB each and 1.0 MiB total.

Kev Riley avatar image Kev Riley ♦♦ commented ·
You would need to do the same for the end date too
0 Likes 0 ·
Usman Butt avatar image Usman Butt commented ·
@Kev Riley Absolutely right :) if the current date has to be included then EndDate should be handled the same way.
0 Likes 0 ·

Write an Answer

Hint: Notify or tag a user in this post by typing @username.

Up to 2 attachments (including images) can be used with a maximum of 512.0 KiB each and 1.0 MiB total.