March 13, 2009 at 9:47 am
Hi All,
I need to select dates between "02/15/2009" and "02/19/2009" how do I do that?
Thanks
March 13, 2009 at 10:24 am
More information please!
Do you want to select all the records in some table or view where the value of a datetime column is between two dates, or do you want to return a contiguous set of dates, i.e. one row per day between the specified dates.
Also is your date range inclusive? i.e. do you want to include rows associated with the specified end date in your resultset?
March 13, 2009 at 10:35 am
I want to select dates between "02/15/2009" and "02/19/2009", one day per row like,
02/15/2009
02/16/2009
02/17/2009
02/18/2009
02/19/2009
so the end date should be included
thanks
March 13, 2009 at 10:53 am
You need some form of Tally table (or Numbers table). These can be permanent tables or can be generated on the fly. The Tally table I'm using below has the following structure:
CREATE TABLE dbo.Tally (
N int NOT NULL PRIMARY KEY CLUSTERED
)
There's plenty of information on Tally tables elsewhere on this site. Here's the T-SQL to return the list of sequential dates. In this case, the Tally table must contain the sequential integers between 0 and the maximum number of rows you are ever likely to require.
DECLARE @startDate datetime
DECLARE @endDate datetime
SELECT @startDate = '20090215', @endDate = '20090219'
SELECT DATEADD(day, T.N, @StartDate) AS [Date]
FROM dbo.Tally T
WHERE (T.N >= 0 AND T.N <= DATEDIFF(day, @startDate, @endDate))
ORDER BY T.N
March 13, 2009 at 12:12 pm
Thanks Andrew, that really worked.
April 12, 2010 at 11:35 am
Hello all,
I'm really (I mean really) new to this so thanks for the info, I've learned a ton about Tally tables. However, I still don't understand how I get say a specific column of dates from a table into the Tally table?
As an example:
If I wanted to get the month begin/end from somecolumnname.tablename into the Tally table?? I guess I'm a little lost at where the Tally table gets it's data from initially
April 12, 2010 at 12:41 pm
A tally table is something that you need to generate. Here's an article about it including several scripts to create it:
July 16, 2012 at 6:17 pm
If you have SQL 2005+ you can use a CTE to get the results:
DECLARE @StartDate DATETIME;
DECLARE @EndDate DATETIME;
SET @StartDate = '4/1/2012';
SET @EndDate = '6/15/2012';
;WITH
n AS (SELECT num = ROW_NUMBER() OVER (ORDER BY (SELECT 1)) FROM sys.all_columns a1 CROSS JOIN sys.all_columns a2),
dt AS (SELECT [date] = DATEADD(day, n.num - 1, @StartDate) FROM n WHERE n.num BETWEEN 1 AND DATEDIFF(day, @StartDate, @EndDate) + 1)
SELECT * FROM dt;
Viewing 8 posts - 1 through 7 (of 7 total)
You must be logged in to reply to this topic. Login to reply