March 1, 2013 at 4:40 am
This is my criteria for the SQL below:
From Date 07 Jan 2013 To Date 18 Mar 2013
1 - First Sunday After 07 Jan 2013 is 13 Jan 2013 - Done (FirstSunday) 2 - First Sunday Before 18 Mar 2013 is 17 Mar 2013 - Done (LastSunday) 3 - How many days between 13 Jan 2013 and 17 Mar 2013 = 63, Divide 63 by 7 = 9, +1 = 10
So what I need my datediff to do is use the results from the 1st and 2nd rows above (First and Last Sundays date) so I get the correct result for section 3. Can you help?
Declare @From Datetime
Declare @To Datetime
Set @From = '07 Jan 2013'
Set @To = '18 Mar 2013'
Select dateadd(dd, CASE WHEN datepart(weekday, @From) = 1 THEN 0 ELSE 8 - datepart(weekday, @From) END,@From) as FirstSunday,
dateadd(dd, CASE WHEN datepart(weekday, @To) = 1 THEN 0 ELSE 1 - datepart(weekday, @To) END,@To) as LastSunday
,datediff(d,@From, @To)
March 1, 2013 at 6:34 am
What happens if your initial FROMdate or TOdate happen to be a sunday? This batch shows solutions either way:
-- Recalculating startdate
;WITH SampleData AS (
SELECT TheDate = CAST('06 Jan 2013' AS DATE) UNION ALL
SELECT TheDate = '07 Jan 2013' UNION ALL -- StartDate
SELECT TheDate = '08 Jan 2013' UNION ALL
SELECT TheDate = '09 Jan 2013' UNION ALL
SELECT TheDate = '10 Jan 2013' UNION ALL
SELECT TheDate = '11 Jan 2013' UNION ALL
SELECT TheDate = '12 Jan 2013' UNION ALL
SELECT TheDate = '13 Jan 2013' UNION ALL
SELECT TheDate = '14 Jan 2013' UNION ALL
SELECT TheDate = '15 Jan 2013' UNION ALL
SELECT TheDate = '16 Jan 2013' UNION ALL
SELECT TheDate = '17 Jan 2013' UNION ALL
SELECT TheDate = '18 Jan 2013' UNION ALL
SELECT TheDate = '19 Jan 2013' UNION ALL
SELECT TheDate = '20 Jan 2013' UNION ALL
SELECT TheDate = '21 Jan 2013'
)
SELECT
DATENAME(weekday,TheDate),
TheDate,
FirstSundayAfterTheDate1 = DATEADD(dd,6-DATEDIFF(dd,7,TheDate)%7,TheDate), -- use this
FirstSundayAfterTheDate2 = DATEADD(dd,7-DATEDIFF(dd,6,TheDate)%7,TheDate) -- or this
FROM SampleData
CROSS APPLY ( -- workings - helps to explain the solution
SELECT
calc1 = DATEDIFF(dd,7,TheDate),
calc2 = 6-DATEDIFF(dd,7,TheDate)%7
) x
-- Recalculating enddate
;WITH SampleData AS (
SELECT TheDate = CAST('06 Mar 2013' AS DATE) UNION ALL
SELECT TheDate = '07 Mar 2013' UNION ALL
SELECT TheDate = '08 Mar 2013' UNION ALL
SELECT TheDate = '09 Mar 2013' UNION ALL
SELECT TheDate = '10 Mar 2013' UNION ALL
SELECT TheDate = '11 Mar 2013' UNION ALL
SELECT TheDate = '12 Mar 2013' UNION ALL
SELECT TheDate = '13 Mar 2013' UNION ALL
SELECT TheDate = '14 Mar 2013' UNION ALL
SELECT TheDate = '15 Mar 2013' UNION ALL
SELECT TheDate = '16 Mar 2013' UNION ALL
SELECT TheDate = '17 Mar 2013' UNION ALL
SELECT TheDate = '18 Mar 2013' UNION ALL -- enddate
SELECT TheDate = '19 Mar 2013' UNION ALL
SELECT TheDate = '20 Mar 2013' UNION ALL
SELECT TheDate = '21 Mar 2013'
)
SELECT
DATENAME(weekday,TheDate),
TheDate,
calc1 = DATEDIFF(dd,6,TheDate),
calc2 = DATEDIFF(dd,6,TheDate)%7,
LastSundayBeforeEnddate1 = DATEADD(dd,0-DATEDIFF(dd,6,TheDate)%7,TheDate), -- use this
LastSundayBeforeEnddate2 = DATEADD(dd,-1-DATEDIFF(dd,7,TheDate)%7,TheDate) -- or this
FROM SampleData
For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
March 1, 2013 at 8:09 am
Thanks Chris, I have figured it out now:
Declare @From Datetime
Declare @To Datetime
Set @From = '07 Jan 2013'
Set @To = '18 Mar 2013'
SELECT Datediff(Week, dateadd(dd, CASE WHEN datepart(weekday, @From) = 1 THEN 0 ELSE 8 - datepart(weekday, @From) END,@From),
dateadd(dd, CASE WHEN datepart(weekday, @To) = 1 THEN 0 ELSE 1 - datepart(weekday, @To) END,@To))+1
March 1, 2013 at 8:34 am
wafw1971 (3/1/2013)
Thanks Chris, I have figured it out now:Declare @From Datetime
Declare @To Datetime
Set @From = '07 Jan 2013'
Set @To = '18 Mar 2013'
SELECT Datediff(Week, dateadd(dd, CASE WHEN datepart(weekday, @From) = 1 THEN 0 ELSE 8 - datepart(weekday, @From) END,@From),
dateadd(dd, CASE WHEN datepart(weekday, @To) = 1 THEN 0 ELSE 1 - datepart(weekday, @To) END,@To))+1
Be careful with datepart. From BOL:
"When datepart is week (wk, ww) or weekday (dw), the return value depends on the value that is set by using SET DATEFIRST." The first day of the week is sunday in the US, monday in the UK.
For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
Viewing 4 posts - 1 through 3 (of 3 total)
You must be logged in to reply to this topic. Login to reply