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...

more ▼

asked Feb 29, 2012 at 03:33 PM in Default

avatar image

1.1k 56 60 66

(comments are locked)
10|1200 characters needed characters left

2 answers: sort voted first

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

 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
 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
more ▼

answered Feb 29, 2012 at 03:59 PM

avatar image

Kev Riley ♦♦
64.1k 48 61 81

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?

Feb 29, 2012 at 04:07 PM jhowe

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?

Feb 29, 2012 at 04:11 PM Kev Riley ♦♦

Yea I'll give it a shot! Thanks for your help.

Feb 29, 2012 at 04:19 PM jhowe

Hi Kev can you explain what the second part is doing, datetime functions always confuse the hell out of me...

Mar 01, 2012 at 04:38 PM jhowe
(comments are locked)
10|1200 characters needed characters left

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 
more ▼

answered Mar 01, 2012 at 06:07 AM

avatar image

Usman Butt
13.9k 6 13 21

You would need to do the same for the end date too

Mar 01, 2012 at 08:11 AM Kev Riley ♦♦

@Kev Riley Absolutely right :) if the current date has to be included then EndDate should be handled the same way.

Mar 01, 2012 at 09:04 AM Usman Butt
(comments are locked)
10|1200 characters needed characters left
Your answer
toggle preview:

Up to 2 attachments (including images) can be used with a maximum of 524.3 kB each and 1.0 MB total.

Follow this question

By Email:

Once you sign in you will be able to subscribe for any updates here



Answers and Comments

SQL Server Central

Need long-form SQL discussion? SQLserverCentral.com is the place.



asked: Feb 29, 2012 at 03:33 PM

Seen: 2070 times

Last Updated: Mar 01, 2012 at 04:38 PM

Copyright 2016 Redgate Software. Privacy Policy