Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase 12»»

Select all months bewtween two dates Expand / Collapse
Author
Message
Posted Thursday, January 29, 2009 1:00 PM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Wednesday, August 13, 2014 2:16 PM
Points: 149, Visits: 78
Please help me in finding a query to get all months the between two dates.
Post #646320
Posted Thursday, January 29, 2009 1:33 PM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Thursday, December 18, 2014 9:58 AM
Points: 13,872, Visits: 9,600
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
Post #646353
Posted Thursday, January 29, 2009 2:10 PM
Valued Member

Valued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued Member

Group: General Forum Members
Last Login: Thursday, June 26, 2014 9:35 AM
Points: 71, Visits: 323
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
Post #646393
Posted Thursday, January 29, 2009 2:14 PM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Thursday, December 18, 2014 9:58 AM
Points: 13,872, Visits: 9,600
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
Post #646398
Posted Thursday, January 29, 2009 2:46 PM
Say Hey Kid

Say Hey KidSay Hey KidSay Hey KidSay Hey KidSay Hey KidSay Hey KidSay Hey KidSay Hey Kid

Group: General Forum Members
Last Login: Tuesday, December 9, 2014 1:18 PM
Points: 677, Visits: 475
Do the dates always fall within the same year?
or
Can they be for example 10-20-2008 and 01-23-2009?

Post #646437
Posted Thursday, January 29, 2009 2:52 PM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Thursday, December 18, 2014 9:58 AM
Points: 13,872, Visits: 9,600
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
Post #646445
Posted Thursday, January 29, 2009 3:00 PM
Say Hey Kid

Say Hey KidSay Hey KidSay Hey KidSay Hey KidSay Hey KidSay Hey KidSay Hey KidSay Hey Kid

Group: General Forum Members
Last Login: Tuesday, December 9, 2014 1:18 PM
Points: 677, Visits: 475
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)
Post #646450
Posted Thursday, January 29, 2009 3:11 PM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Today @ 2:11 PM
Points: 35,772, Visits: 32,441
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."

(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #646460
Posted Friday, January 30, 2009 7:27 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Thursday, December 18, 2014 9:58 AM
Points: 13,872, Visits: 9,600
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
Post #646937
Posted Wednesday, April 16, 2014 4:14 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Sunday, November 9, 2014 4:13 AM
Points: 152, Visits: 69
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
Post #1562220
« Prev Topic | Next Topic »

Add to briefcase 12»»

Permissions Expand / Collapse