January 29, 2009 at 1:00 pm
Please help me in finding a query to get all months the between two dates.
January 29, 2009 at 1:33 pm
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
January 29, 2009 at 2:10 pm
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
January 29, 2009 at 2:14 pm
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
January 29, 2009 at 2:46 pm
Do the dates always fall within the same year?
or
Can they be for example 10-20-2008 and 01-23-2009?
January 29, 2009 at 2:52 pm
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
January 29, 2009 at 3:00 pm
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)
January 29, 2009 at 3:11 pm
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
Change is inevitable... Change for the better is not.
January 30, 2009 at 7:27 am
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
April 16, 2014 at 4:14 am
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 wrong:unsure:
April 16, 2014 at 4:32 am
feroz_tt (4/16/2014)
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 wrong:unsure:
How did you calculate 31?
April 19, 2014 at 3:47 pm
feroz_tt (4/16/2014)
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 wrong:unsure:
I'm not sure why you think there should be "31". I can understand why someone would insist that the correct answer is "19" but not "31".
with Numbers (Number) as
(select row_number() over (order by object_id) -1
from sys.all_objects)
select Number+1,dateadd(month, number, '2014-09-01')
from Numbers
where number <= datediff(month, '2014-09-01', '2016-03-31')
;
Results:
-------------------- -----------------------
1 2014-09-01 00:00:00.000
2 2014-10-01 00:00:00.000
3 2014-11-01 00:00:00.000
4 2014-12-01 00:00:00.000
5 2015-01-01 00:00:00.000
6 2015-02-01 00:00:00.000
7 2015-03-01 00:00:00.000
8 2015-04-01 00:00:00.000
9 2015-05-01 00:00:00.000
10 2015-06-01 00:00:00.000
11 2015-07-01 00:00:00.000
12 2015-08-01 00:00:00.000
13 2015-09-01 00:00:00.000
14 2015-10-01 00:00:00.000
15 2015-11-01 00:00:00.000
16 2015-12-01 00:00:00.000
17 2016-01-01 00:00:00.000
18 2016-02-01 00:00:00.000
19 2016-03-01 00:00:00.000
(19 row(s) affected)
--Jeff Moden
Change is inevitable... Change for the better is not.
Viewing 12 posts - 1 through 11 (of 11 total)
You must be logged in to reply to this topic. Login to reply