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


Select all months bewtween two dates


Select all months bewtween two dates

Author
Message
aneel.c
aneel.c
SSC-Enthusiastic
SSC-Enthusiastic (153 reputation)SSC-Enthusiastic (153 reputation)SSC-Enthusiastic (153 reputation)SSC-Enthusiastic (153 reputation)SSC-Enthusiastic (153 reputation)SSC-Enthusiastic (153 reputation)SSC-Enthusiastic (153 reputation)SSC-Enthusiastic (153 reputation)

Group: General Forum Members
Points: 153 Visits: 102
Please help me in finding a query to get all months the between two dates.
GSquared
GSquared
SSChampion
SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)

Group: General Forum Members
Points: 14363 Visits: 9729
The best way to do that is to build a calendar table.

The second best way is to use a numbers table.

After that, it's a numbers CTE.

After that, recursion.

Are you in a position where you can build a calendar table? It's just a table of dates, starting from whatever you need and ending whenever you need. For example, a table of dates between 1 Jan 2000 and 31 Dec 2050, is a default that I use quite often. You can then store in it things like which dates are holidays, weekends, etc.

If you have a numbers table, you can do a query where you use DateAdd(month) on the numbers table, with the first date being what you add to.

If you don't have either of those, and can't build either one, you might be able to build a numbers CTE, where you select row_number in a CTE, and then use that just like a numbers table.

If none of those are possible, build a While loop and insert into a temp table (or a table variable if it needs to be a UDF), or build a recursive CTE with a Union All operator.

- Gus "GSquared", RSVP, OODA, MAP, NMVP, FAQ, SAT, SQL, DNA, RNA, UOI, IOU, AM, PM, AD, BC, BCE, USA, UN, CF, ROFL, LOL, ETC
Property of The Thread

"Nobody knows the age of the human race, but everyone agrees it's old enough to know better." - Anon
Bijal Parekh
Bijal Parekh
Valued Member
Valued Member (71 reputation)Valued Member (71 reputation)Valued Member (71 reputation)Valued Member (71 reputation)Valued Member (71 reputation)Valued Member (71 reputation)Valued Member (71 reputation)Valued Member (71 reputation)

Group: General Forum Members
Points: 71 Visits: 352
declare @month table(months varchar(30))
declare @date1 datetime
declare @date2 datetime
set @date1='10/1/2011'
set @date2='9/1/2010'
declare @year1 int
declare @year2 int
set @year1= year(@date1)
set @year2= year(@date2)
declare @month1 int
declare @month2 int
set @month1=month(@date1)
set @month2=month(@date2)
declare @count int
declare @monthname datetime
if (@year1<>@year2)
begin
if @month1=@month2
set @count=12
else if @month1<>@month2
set @count=12-ABS(@month1-@month2)+1
if @date1<@date2
set @monthname=@date1
else if @date2<@date1
set @monthname=@date2
while @count>0
begin
insert @month(months)
select datename(month,@monthname)
set @monthname=dateadd(mm,1,@monthname)
set @count=@count-1
end
end
if @year1=@year2
begin
if @month1=@month2
set @count=1
else if @month1<>@month2
set @count=ABS(@month2-@month1)+1
if @date1<@date2
set @monthname=@date1
else if @date2<@date1
set @monthname=@date2
while @count>0
begin

insert @month(months)
select datename(month,@monthname)

set @monthname=dateadd(mm,1,@monthname)
set @count=@count-1
end
end
select * from @month
GSquared
GSquared
SSChampion
SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)

Group: General Forum Members
Points: 14363 Visits: 9729
Ouch! Yeah, that piece of code might work, but it hurts to look at!


;with Numbers (Number) as
   (select row_number() over (order by object_id)
   from sys.all_objects)
select dateadd(month, number, @StartDate)
from Numbers
where number <= datediff(month, @StartDate, @EndDate)



- Gus "GSquared", RSVP, OODA, MAP, NMVP, FAQ, SAT, SQL, DNA, RNA, UOI, IOU, AM, PM, AD, BC, BCE, USA, UN, CF, ROFL, LOL, ETC
Property of The Thread

"Nobody knows the age of the human race, but everyone agrees it's old enough to know better." - Anon
ganci.mark
ganci.mark
Right there with Babe
Right there with Babe (726 reputation)Right there with Babe (726 reputation)Right there with Babe (726 reputation)Right there with Babe (726 reputation)Right there with Babe (726 reputation)Right there with Babe (726 reputation)Right there with Babe (726 reputation)Right there with Babe (726 reputation)

Group: General Forum Members
Points: 726 Visits: 537
Do the dates always fall within the same year?
or
Can they be for example 10-20-2008 and 01-23-2009?
GSquared
GSquared
SSChampion
SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)

Group: General Forum Members
Points: 14363 Visits: 9729
The Numbers version can work across years, just have to have enough rows in the Numbers CTE (you can get quite a few with just sys.all_objects; if that's not enough, do a cross join). The "I've declared ten-million variables" version can work across a single year, so far as I can tell.

- Gus "GSquared", RSVP, OODA, MAP, NMVP, FAQ, SAT, SQL, DNA, RNA, UOI, IOU, AM, PM, AD, BC, BCE, USA, UN, CF, ROFL, LOL, ETC
Property of The Thread

"Nobody knows the age of the human race, but everyone agrees it's old enough to know better." - Anon
ganci.mark
ganci.mark
Right there with Babe
Right there with Babe (726 reputation)Right there with Babe (726 reputation)Right there with Babe (726 reputation)Right there with Babe (726 reputation)Right there with Babe (726 reputation)Right there with Babe (726 reputation)Right there with Babe (726 reputation)Right there with Babe (726 reputation)

Group: General Forum Members
Points: 726 Visits: 537
Good one SS!

might want to modify it slightly to include starting month?

;with Numbers (Number) as
(select row_number() over (order by object_id)
from sys.all_objects)
select dateadd(month, number-1, @StartDate)
from Numbers
where number-1<= datediff(month, @StartDate, @EndDate)
Jeff Moden
Jeff Moden
SSC-Forever
SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)SSC-Forever (44K reputation)

Group: General Forum Members
Points: 44802 Visits: 39845
GSquared (1/29/2009)
Ouch! Yeah, that piece of code might work, but it hurts to look at!


;with Numbers (Number) as
   (select row_number() over (order by object_id)
   from sys.all_objects)
select dateadd(month, number, @StartDate)
from Numbers
where number <= datediff(month, @StartDate, @EndDate)




Ahhhhh.... MUCH better. No loops... no recurrsion in the CTE... nice tight code...

The only thing that may be a problem is that (I believe... haven't tested the code) it looks like the day of the startdate and enddate are preserved instead of the whole month being included. Guess it all depends on what the op actually needs.

--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
     Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
Although they tell us that they want it real bad, our primary goal is to ensure that we dont actually give it to them that way.
Although change is inevitable, change for the better is usually not.
Just because you can do something in PowerShell, doesnt mean you should. Wink

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
GSquared
GSquared
SSChampion
SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)

Group: General Forum Members
Points: 14363 Visits: 9729
It'll depend on what he's looking for. If he needs the start month, it needs a -1 on the row_number function, so that it starts with 0 instead of 1. If he needs the names of the months, that'll need to be added to the final select. If he needs it to give the first day of each month, that'll require a slight modification to the final select. And so on. Since I don't have those details, I set up a skeleton, and the OP can either flesh it out, or ask questions about the details, or (all to common) never speak up again and we won't know what was actually needed.

- Gus "GSquared", RSVP, OODA, MAP, NMVP, FAQ, SAT, SQL, DNA, RNA, UOI, IOU, AM, PM, AD, BC, BCE, USA, UN, CF, ROFL, LOL, ETC
Property of The Thread

"Nobody knows the age of the human race, but everyone agrees it's old enough to know better." - Anon
feroz_tt
feroz_tt
SSC-Enthusiastic
SSC-Enthusiastic (152 reputation)SSC-Enthusiastic (152 reputation)SSC-Enthusiastic (152 reputation)SSC-Enthusiastic (152 reputation)SSC-Enthusiastic (152 reputation)SSC-Enthusiastic (152 reputation)SSC-Enthusiastic (152 reputation)SSC-Enthusiastic (152 reputation)

Group: General Forum Members
Points: 152 Visits: 70
Hi All,

I'm getting some problem here

;with Numbers (Number) as
   (select row_number() over (order by object_id)
   from sys.all_objects)
select dateadd(month, number, '2014-09-01')
from Numbers
where number <= datediff(month, '2014-09-01', '2016-03-31')

Low no of months.

Select datediff(month, '2014-09-01', '2016-03-31')
it should give 31 instead of 18.

I don't understand where i'm wrongUnsure
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