August 8, 2014 at 8:35 am
Hi All,
I want to list Dates for particular day between two dates.
for eg. if user enters 08/01/2014 and 08/31/2014 with value 0 then all the Sundays and related dates should be display.
if above contamination with 1 then all Mondays,
Kindly help.
Thanks
Abhas
August 8, 2014 at 9:34 am
Hi All,
I want to list Dates for particular day between two dates.
for eg. if user enters 08/01/2014 and 08/31/2014 with value 0 then all the Sundays and related dates should be display.
if above Combination with 1 then all Mondays date,
Kindly help.
Thanks
Abhas
August 8, 2014 at 9:56 am
You can use a recursive common table expression to achieve this.
DECLARE @startDate DATETIME = '8/1/2014'
DECLARE @endDate DATETIME = '8/31/2014'
DECLARE @dayOfWeek INT = 1 -- 1=Sun, 7=Sat
;WITH cte_Recursion AS
(
SELECT @startDate AS [Date]
UNION ALL
SELECT DATEADD(DAY, 1, [Date])
FROM cte_Recursion
WHERE [Date] < @endDate
)
SELECT [Date]
FROM cte_Recursion
WHERE DATEPART(WEEKDAY, [Date]) = @dayOfWeek
OPTION (MAXRECURSION 0) -- MaxRecursion 0 is needed when dates are more than 100 days apart
August 8, 2014 at 10:14 am
kherald provided a solution. Here's my take which still lets you use 0 for Sunday instead of 1 and also takes into account the Language setting of your SQL Server because some languages (actually most in the version of SQL Server I have installed) use Monday as day 1 not Sunday. You can combine both solutions to make it fit your purposes:
DECLARE @StartDate DATE = '2014-08-01',
@EndDate DATE = '2014-08-31',
@DayNo TINYINT = 6;
/* this is a virtual numbers/tally table that is used to get all the days
between the days. If you already have a calendar table or a table that has
the dates you are querying this isn't necessary */
WITH nums
AS (
SELECT
ROW_NUMBER() OVER (ORDER BY (
SELECT
NULL
)) - 1 AS N
FROM
sys.all_columns AS AC
),
Calendar
AS (
SELECT
CONVERT(DATE, DATEADD(DAY, n, @StartDate)) AS theDate
FROM
nums
),
WeekDays
AS (
SELECT
*,
/* figure what day is the first day of the week. This setting is controlled by the
language of the SQL Server and you can see the values for DateFirst in sys.syslanguages */
CASE @@DateFirst
/* First day of week is monday (1) and last day of week is Sunday (7)*/
WHEN 1 THEN CASE DATEPART(WEEKDAY, theDate)
WHEN 7 THEN 0
ELSE DATEPART(WEEKDAY, theDate)
END
/* 1 and 7 are the only options for @@DATEFIRST currently so
Sunday is first day of week when @@DATEFIRS isn't 1 */
ELSE DATEPART(WEEKDAY, theDate) - 1
END AS DayNo,
DATENAME(WEEKDAY, theDate) AS DayName
FROM
Calendar
)
SELECT
*
FROM
WeekDays
WHERE
WeekDays.theDate BETWEEN @StartDate
AND @EndDate AND
WeekDays.DayNo = @DayNo;
Jack Corbett
Consultant - Straight Path Solutions
Check out these links on how to get faster and more accurate answers:
Forum Etiquette: How to post data/code on a forum to get the best help
Need an Answer? Actually, No ... You Need a Question
August 8, 2014 at 10:18 am
kherald69 (8/8/2014)
You can use a recursive common table expression to achieve this.
That's a recursive CTE that counts. Please see the following article for why that's a bad idea even for small date ranges.
http://www.sqlservercentral.com/articles/T-SQL/74118/
--Jeff Moden
Change is inevitable... Change for the better is not.
August 8, 2014 at 10:40 am
Jeff Moden (8/8/2014)
kherald69 (8/8/2014)
You can use a recursive common table expression to achieve this.That's a recursive CTE that counts. Please see the following article for why that's a bad idea even for small date ranges.
You can use the Itzik style cross join to replace reading sys.all_columns to get the numbers cte I created in my solution and get rid of all reads in my solution. Like this:
SET STATISTICS IO ON;
DECLARE
@StartDate DATE = '2014-08-01',
@EndDate DATE = '2014-08-31',
@DayNo TINYINT = 6;
/* this is a virtual numbers/tally table that is used to get all the days
between the days. If you already have a calendar table or a table that has
the dates you are querying this isn't necessary */
WITH E1(N)
AS (
SELECT
1
UNION ALL
SELECT
1
UNION ALL
SELECT
1
UNION ALL
SELECT
1
UNION ALL
SELECT
1
UNION ALL
SELECT
1
UNION ALL
SELECT
1
UNION ALL
SELECT
1
UNION ALL
SELECT
1
UNION ALL
SELECT
1
), -- 1*10^1 or 10 rows
E2(N)
AS (
SELECT
1
FROM
E1 a,
E1 b
), -- 1*10^2 or 100 rows
E4(N)
AS (
SELECT
1
FROM
E2 a,
E2 b
), -- 1*10^4 or 10,000 rows
E8(N)
AS (
SELECT
1
FROM
E4 a,
E4 b
), -- 1*10^8 or 100,000,000 rows
nums
AS (
SELECT TOP (4000)
ROW_NUMBER() OVER (ORDER BY (
SELECT
NULL
)) - 1 AS N
FROM
E8
),
Calendar
AS (
SELECT
CONVERT(DATE, DATEADD(DAY, n, @StartDate)) AS theDate
FROM
nums
),
WeekDays
AS (
SELECT
*,
/* figure what day is the first day of the week. This setting is controlled by the
language of the SQL Server and you can see the values for DateFirst in sys.syslanguages */
CASE @@DateFirst
/* First day of week is monday (1) and last day of week is Sunday (7)*/
WHEN 1 THEN CASE DATEPART(WEEKDAY, theDate)
WHEN 7 THEN 0
ELSE DATEPART(WEEKDAY, theDate)
END
/* 1 and 7 are the only options for @@DATEFIRST currently so
Sunday is first day of week when @@DATEFIRS isn't 1 */
ELSE DATEPART(WEEKDAY, theDate) - 1
END AS DayNo,
DATENAME(WEEKDAY, theDate) AS DayName
FROM
Calendar
)
SELECT
*
FROM
WeekDays
WHERE
WeekDays.theDate BETWEEN @StartDate AND @EndDate AND
WeekDays.DayNo = @DayNo;
GO
DECLARE
@StartDate DATE = '2014-08-01',
@EndDate DATE = '2014-08-31',
@DayNo TINYINT = 6;
;
WITH cte_Recursion
AS (
SELECT
@startDate AS [Date]
UNION ALL
SELECT
DATEADD(DAY, 1, [Date])
FROM
cte_Recursion
WHERE
[Date] < @endDate
)
SELECT
[Date]
FROM
cte_Recursion
WHERE
DATEPART(WEEKDAY, [Date]) = @DayNo
OPTION
(MAXRECURSION 0)
--
SET STATISTICS IO OFF;
This is an interesting situation where, if you tune based on execution plan, the recursive cte looks better because if you run both in a batch the recursive cte solution says it's cost is 0% of the batch even though the top solution does 0 reads and the recursive cte does 187. The reason is that no matter how many rows you need to return the cost estimate for the recursive CTE remains the same.
For instance if you set the StartDate to 0001-08-01 and leave the EndDate as 2014-08-31 then the recursive CTE (on my laptop) takes ~6500 ms adn the virtual tally table solution takes ~900 ms.
Jack Corbett
Consultant - Straight Path Solutions
Check out these links on how to get faster and more accurate answers:
Forum Etiquette: How to post data/code on a forum to get the best help
Need an Answer? Actually, No ... You Need a Question
August 8, 2014 at 10:51 am
Hi All,
Thank you so much. All solutions are suitable.
Thank yoy very much. 🙂 🙂
Thanks
Abhas.
August 8, 2014 at 10:56 am
Using the date table function on the link below, here are the queries you can use.
Date Table Function F_TABLE_DATE
http://www.sqlteam.com/forums/topic.asp?TOPIC_ID=61519
select
Sunday = [Date]
from
F_TABLE_DATE('08/01/2014','08/31/2014')
where
-- Select Sunday
ISO_DAY_OF_WEEK = 7
select
Monday = [Date]
from
F_TABLE_DATE('08/01/2014','08/31/2014')
where
-- Select Monday
ISO_DAY_OF_WEEK = 1
Results:
Sunday
-----------------------
2014-08-03 00:00:00.000
2014-08-10 00:00:00.000
2014-08-17 00:00:00.000
2014-08-24 00:00:00.000
2014-08-31 00:00:00.000
Monday
-----------------------
2014-08-04 00:00:00.000
2014-08-11 00:00:00.000
2014-08-18 00:00:00.000
2014-08-25 00:00:00.000
August 8, 2014 at 2:01 pm
Jack's solution made me think of this:
declare @dtmStart datetime = '06/01/2014',
@dtmEnd datetime = '09/01/2014';
with dates_in_range(date_date, date_name) as (
select DATEADD(day, t.N - 1, @dtmStart), datename(weekday, DATEADD(day, t.N - 1, @dtmStart))
from dbo.Tally t
where t.N < DATEDIFF(day, @dtmStart, @dtmEnd) + 1)
select date_date, date_name
from dates_in_range
where date_name = 'Wednesday';
You need to have a tally table or use Itzik's approach like Jack did to do it. If you aren't familiar with Tally tables yet, check out the article in my signature. They'll change the way you look at data.
August 8, 2014 at 2:57 pm
Expanding on Jacks solution, but eliminating the need to "hope" for @@DateFirst being either 1 or 0, here's an approach that's totally independent on the setting of @@DateFirst.
the biggest difference is the way to calculate DayNo:
DATEDIFF(dd,-1,theDate)%7 AS DayNo,
This code snippet is based on the fact that "day Zero" = 1900-01-01, which is a Monday.
The Modulo 7 will return the number of weekdays between 1900-01-01 an theDate, Zero, if theDate is a Monday and 6 if theDate is Sunday.
By shifting the day using -1 it'll start with Zero for Sunday to 6 for Saturday.
This code is also independent of any language setting (whereas Ed's solution for instance will fail if there's a SET LANGUAGE "GERMAN" is involved before his code).
@jack-2 and Ed: I'm sorry, but I'm a strong advocate against any form of non-deterministic date functions that'll rely on DATEFIRST and/or LANGUAGE settings. At least as long as there are alternatives available 😉
DECLARE @StartDate DATE = '20140801',
@EndDate DATE = '20140831',
@DayNo TINYINT = 0;
/* this is a virtual numbers/tally table that is used to get all the days
between the days. If you already have a calendar table or a table that has
the dates you are querying this isn't necessary */
WITH E1(N)
AS (
SELECT
1
UNION ALL
SELECT
1
UNION ALL
SELECT
1
UNION ALL
SELECT
1
UNION ALL
SELECT
1
UNION ALL
SELECT
1
UNION ALL
SELECT
1
UNION ALL
SELECT
1
UNION ALL
SELECT
1
UNION ALL
SELECT
1
), -- 1*10^1 or 10 rows
E2(N)
AS (
SELECT
1
FROM
E1 a,
E1 b
), -- 1*10^2 or 100 rows
E4(N)
AS (
SELECT
1
FROM
E2 a,
E2 b
), -- 1*10^4 or 10,000 rows
E8(N)
AS (
SELECT
1
FROM
E4 a,
E4 b
), -- 1*10^8 or 100,000,000 rows
nums
AS (
SELECT TOP (4000)
ROW_NUMBER() OVER (ORDER BY (
SELECT
NULL
)) - 1 AS N
FROM
E8
),
Calendar
AS (
SELECT
CONVERT(DATE, DATEADD(DAY, n, @StartDate)) AS theDate
FROM
nums
),
WeekDays
AS (
SELECT
*,
DATEDIFF(dd,-1,theDate)%7 AS DayNo,
DATENAME(WEEKDAY, theDate) AS DayName
FROM
Calendar
)
SELECT
*
FROM
WeekDays
WHERE
WeekDays.theDate BETWEEN @StartDate
AND @EndDate AND
WeekDays.DayNo = @DayNo;
August 11, 2014 at 5:48 am
LutzM (8/8/2014)
This code is also independent of any language setting (whereas Ed's solution for instance will fail if there's a SET LANGUAGE "GERMAN" is involved before his code).@jack-2 and Ed: I'm sorry, but I'm a strong advocate against any form of non-deterministic date functions that'll rely on DATEFIRST and/or LANGUAGE settings. At least as long as there are alternatives available 😉
That's quite all right. In fact, one of the things I love about this site is that to a seemingly simple question asked, the OP gets multiple solutions. 😉
August 11, 2014 at 7:00 am
LutzM (8/8/2014)
Expanding on Jacks solution, but eliminating the need to "hope" for @@DateFirst being either 1 or 0, here's an approach that's totally independent on the setting of @@DateFirst.the biggest difference is the way to calculate DayNo:
DATEDIFF(dd,-1,theDate)%7 AS DayNo,
This code snippet is based on the fact that "day Zero" = 1900-01-01, which is a Monday.
The Modulo 7 will return the number of weekdays between 1900-01-01 an theDate, Zero, if theDate is a Monday and 6 if theDate is Sunday.
By shifting the day using -1 it'll start with Zero for Sunday to 6 for Saturday.
This code is also independent of any language setting (whereas Ed's solution for instance will fail if there's a SET LANGUAGE "GERMAN" is involved before his code).
@jack-2 and Ed: I'm sorry, but I'm a strong advocate against any form of non-deterministic date functions that'll rely on DATEFIRST and/or LANGUAGE settings. At least as long as there are alternatives available 😉
No need to apologize to me. As Ed already said, I love seeing alternate and better solutions to what I proposed. I never would have thought of your solution and I felt like a genius for remembering that the way SQL does days of the week could change. I'd actually argue that the best solution is a true calendar table so you don't have to do any of the things we did.
Jack Corbett
Consultant - Straight Path Solutions
Check out these links on how to get faster and more accurate answers:
Forum Etiquette: How to post data/code on a forum to get the best help
Need an Answer? Actually, No ... You Need a Question
August 12, 2014 at 10:21 pm
Fun problem. Guess I'll throw my hat into the ring, as well.
I took a slightly different tack. Rather than calculating all of the dates in the range and then selecting only about 1/7th of those, I calculate the first occurance (Day1 in the code) of the desired weekday on or after the start date and then use a Tally Function to add weeks based on the number of weeks from Day1 to the end date.
Here's the function (Looks ok but haven't completed all testing, yet. Caveat Emptor!)...
CREATE FUNCTION dbo.WeekDayRange
/**********************************************************************************************************************
Purpose:
Given a start and end date in the correct order along with the desired weekday integer, return all of those given
weekdays that occur in the date range formed by the start and end dates inclusively.
Usage:
--===== Basic syntax example
SELECT * FROM dbo.WeekDayRange(@pStartDate, @pEndDate, @pDay);
Programmer's Notes:
1. Setup to work with the DATETIME datatype. If you need something that falls outside of the Gregorian calendar, you
may be using the wrong tool.
2. @pDay should be MOD(7) where the desired values are...
--0=Su, 1=Mo, 2=Tu, 3=We, 4=Th, 5=Fr, 6=Sa
Yep... I agree. ISO Weeks would have been better but following the requirements of the OP.
3. The date of 1753-01-07 is the first Sunday of the DATETIME datatype.
4. The "Day1" calculation returns the first available given weekday on or after the start date.
Revision History:
Rev 01 - 13 Aug 2014 - Jeff Moden - Initial creation
**********************************************************************************************************************/
--===== Define the I/O for this function using obvious names
(
@pStartDate DATETIME
,@EndDate DATETIME
,@pDay INT
)
RETURNS TABLE WITH SCHEMABINDING AS
RETURN (
WITH
cteDay1 (Day1) AS (SELECT DATEADD(dd,(7-DATEDIFF(dd,'17530107',@pStartDate)%7+@pDay)%7,@pStartDate)),
cteWeeks(Day1,Weeks) AS (SELECT Day1,DATEDIFF(dd,Day1,DATEADD(wk,1,@EndDate))/7 FROM cteDay1)
SELECT Occurance = t.N+1
,[Date] = DATEADD(wk,t.N,w.Day1)
FROM cteWeeks w
CROSS APPLY dbo.fnTally(0,w.Weeks-1)t
)
;
In case you don't have one, here's my Tally Function (sorry about the "fn" but I also keep a Tally Table)...
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE FUNCTION [dbo].[fnTally]
/**********************************************************************************************************************
Purpose:
Return a column of BIGINTs from @ZeroOrOne up to and including @MaxN with a max value of 10 Quadrillion.
Usage:
--===== Syntax example
SELECT t.N
FROM dbo.fnTally(@ZeroOrOne,@MaxN) t
;
Notes:
1. Based on Itzik Ben-Gan's cascading CTE (cCTE) method for creating a "readless" Tally Table source of BIGINTs.
Refer to the following URL for how it works. http://sqlmag.com/sql-server/virtual-auxiliary-table-numbers
2. To start a sequence at 0, @ZeroOrOne must be 0 or NULL. Any other value that's convertable to the BIT data-type
will cause the sequence to start at 1.
3. If @ZeroOrOne = 1 and @MaxN = 0, no rows will be returned.
5. If @MaxN is negative or NULL, a "TOP" error will be returned.
6. @MaxN must be a positive number from >= the value of @ZeroOrOne up to and including 10 Quadrillion. If a larger
number is used, the function will silently truncate after 10 Quadrillion. If you actually need a sequence with
that many values, you should consider using a different tool. ;-)
7. There will be a substantial reduction in performance if "N" is sorted in descending order. If a descending
sort is required, use code similar to the following. Performance will decrease by about 27% but it's still
very fast especially compared with just doing a simple descending sort on "N", which is about 20 times slower.
If @ZeroOrOne is a 0, in this case, remove the "+1" from the code.
DECLARE @MaxN BIGINT;
SELECT @MaxN = 1000;
SELECT DescendingN = @MaxN-N+1
FROM dbo.fnTally(1,@MaxN);
8. There is no performance penalty for sorting "N" in ascending order because the output is explicity sorted by
ROW_NUMBER() OVER (ORDER BY (SELECT NULL))
Revision History:
Rev 00 - Unknown - Jeff Moden
- Initial creation with error handling for @MaxN.
Rev 01 - 09 Feb 2013 - Jeff Moden
- Modified to start at 0 or 1.
Rev 02 - 16 May 2013 - Jeff Moden
- Removed error handling for @MaxN because of exceptional cases.
Rev 03 - 07 Sep 2013 - Jeff Moden
- Change the max for @MaxN from 10 Billion to 10 Quadrillion to support an experiment.
This will also make it much more difficult for someone to actually get silent truncation in the future.
**********************************************************************************************************************/
(@ZeroOrOne BIT, @MaxN BIGINT)
RETURNS TABLE WITH SCHEMABINDING AS
RETURN WITH
E1(N) AS (SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1 UNION ALL
SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1) --10 rows
, E4(N) AS (SELECT 1 FROM E1 a, E1 b, E1 c, E1 d) --10 thousand rows
,E16(N) AS (SELECT 1 FROM E4 a, E4 b, E4 c, E4 d) --10 quadrillion rows
SELECT N = 0 WHERE ISNULL(@ZeroOrOne,0)= 0 --Conditionally start at 0.
UNION ALL
SELECT TOP(@MaxN) N = ROW_NUMBER() OVER (ORDER BY (SELECT NULL)) FROM E16
;
Here's the code I ran against those ...
SET NOCOUNT ON
;
DECLARE @pStartDate DATETIME
,@pEndDate DATETIME
;
SELECT @pStartDate = '08/01/2014'
,@pEndDate = '08/31/2014'
;
--set statistics time,io on
SELECT Occurance,SundayDate = [Date] FROM dbo.WeekDayRange(@pStartDate, @pEndDate, 0);
SELECT Occurance,MondayDate = [Date] FROM dbo.WeekDayRange(@pStartDate, @pEndDate, 1);
SELECT Occurance,TuesdayDate = [Date] FROM dbo.WeekDayRange(@pStartDate, @pEndDate, 2);
SELECT Occurance,WednesdayDate = [Date] FROM dbo.WeekDayRange(@pStartDate, @pEndDate, 3);
SELECT Occurance,ThursdayDate = [Date] FROM dbo.WeekDayRange(@pStartDate, @pEndDate, 4);
SELECT Occurance,FridayDate = [Date] FROM dbo.WeekDayRange(@pStartDate, @pEndDate, 5);
SELECT Occurance,SaturdayDate = [Date] FROM dbo.WeekDayRange(@pStartDate, @pEndDate, 6);
SELECT Occurance,SundayDate = [Date] FROM dbo.WeekDayRange(@pStartDate, @pEndDate, 7);
SELECT Occurance,MondayDate = [Date] FROM dbo.WeekDayRange(@pStartDate, @pEndDate, 8);
And here's the results...
Occurance SundayDate
-------------------- -----------------------
1 2014-08-03 00:00:00.000
2 2014-08-10 00:00:00.000
3 2014-08-17 00:00:00.000
4 2014-08-24 00:00:00.000
5 2014-08-31 00:00:00.000
Occurance MondayDate
-------------------- -----------------------
1 2014-08-04 00:00:00.000
2 2014-08-11 00:00:00.000
3 2014-08-18 00:00:00.000
4 2014-08-25 00:00:00.000
Occurance TuesdayDate
-------------------- -----------------------
1 2014-08-05 00:00:00.000
2 2014-08-12 00:00:00.000
3 2014-08-19 00:00:00.000
4 2014-08-26 00:00:00.000
Occurance WednesdayDate
-------------------- -----------------------
1 2014-08-06 00:00:00.000
2 2014-08-13 00:00:00.000
3 2014-08-20 00:00:00.000
4 2014-08-27 00:00:00.000
Occurance ThursdayDate
-------------------- -----------------------
1 2014-08-07 00:00:00.000
2 2014-08-14 00:00:00.000
3 2014-08-21 00:00:00.000
4 2014-08-28 00:00:00.000
Occurance FridayDate
-------------------- -----------------------
1 2014-08-01 00:00:00.000
2 2014-08-08 00:00:00.000
3 2014-08-15 00:00:00.000
4 2014-08-22 00:00:00.000
5 2014-08-29 00:00:00.000
Occurance SaturdayDate
-------------------- -----------------------
1 2014-08-02 00:00:00.000
2 2014-08-09 00:00:00.000
3 2014-08-16 00:00:00.000
4 2014-08-23 00:00:00.000
5 2014-08-30 00:00:00.000
Occurance SundayDate
-------------------- -----------------------
1 2014-08-03 00:00:00.000
2 2014-08-10 00:00:00.000
3 2014-08-17 00:00:00.000
4 2014-08-24 00:00:00.000
5 2014-08-31 00:00:00.000
Occurance MondayDate
-------------------- -----------------------
1 2014-08-04 00:00:00.000
2 2014-08-11 00:00:00.000
3 2014-08-18 00:00:00.000
4 2014-08-25 00:00:00.000
--Jeff Moden
Change is inevitable... Change for the better is not.
Viewing 13 posts - 1 through 12 (of 12 total)
You must be logged in to reply to this topic. Login to reply