July 24, 2013 at 1:55 am
I have now had some time to check the math for the formula.
The short story is that if the anchor date is a leapyear the algorithm fails. If you change the anchor date to 20000101 or 18960101, the algorithm will give wrong result. That gives us non-leapyears to work with.
Any non-leapyear starting not starting with monday will faill too.
First day of year is Monday
+-----+-----+
| Yes | No |
|-----+-----+
Yes | F | F |
+-----+-----+
No | W | F |
+-----+-----+
Leap year
Accidentally, the date 00010101 will work as it is a non-leapyear starting with monday, and so will 17530101 and 19000101.
N 56°04'39.16"
E 12°55'05.25"
July 25, 2013 at 9:39 pm
SwePeso (7/24/2013)
I have now had some time to check the math for the formula.The short story is that if the anchor date is a leapyear the algorithm fails. If you change the anchor date to 20000101 or 18960101, the algorithm will give wrong result. That gives us non-leapyears to work with.
Any non-leapyear starting not starting with monday will faill too.
First day of year is Monday
+-----+-----+
| Yes | No |
|-----+-----+
Yes | F | F |
+-----+-----+
No | W | F |
+-----+-----+
Leap year
Accidentally, the date 00010101 will work as it is a non-leapyear starting with monday, and so will 17530101 and 19000101.
That doesn't appear to be entirely correct but anything before '19000101' certainly appears to be screwed. Here's the proof code that shows that. I sure wish I had thought of this test when I wrote the article. :blush: I'll have Steve pull the article and see if I can come up with a simple fix. Thanks, Peter.
--===== Build all dates from 1753-01-01 through 9999-12-31
WITH cteGenDates AS
(
SELECT TOP (DATEDIFF(dd,'1753','9999-12-31')+1)
Date = DATEADD(dd,ROW_NUMBER() OVER (ORDER BY (SELECT NULL))-1,'1753')
FROM master.sys.all_columns ac1,
master.sys.all_columns ac2
) --=== Do the calculated ISOWk from the article and the built in function
-- and capture enough other data to find where the calculation is incorrect.
SELECT Date,
DOW = DATENAME(dw,Date),
CalculatedISOWk = (DATEPART(dy,DATEDIFF(dd,0,Date)/7*7+3)+6)/7,
BuiltInISOWk = DATEPART(isowk,Date),
IsLeapYear = ISDATE(DATENAME(yy,Date)+'0229')
INTO #MyHead
FROM cteGenDates
;
--===== Find first or last weeks of each year that have an error.
SELECT *
FROM #MyHead
WHERE (DATEPART(dy,Date) <= 8 OR DATEPART(dy,Date) >= 356)
AND CalculatedISOWk <> BuiltInISOWk
ORDER BY Date
;
--Jeff Moden
Change is inevitable... Change for the better is not.
July 25, 2013 at 10:42 pm
Ah... Missed it. You were talking about changing the BASE date of "0" to something else. I'll check on that, too1 Thanks again, Peter. I just sent an email to Steve and the WebMaster asking them to pull the article until I can come up with a fix (unless you beat me to it :-D).
--Jeff Moden
Change is inevitable... Change for the better is not.
July 25, 2013 at 11:14 pm
Well, I found the problem. The problem is with anything that has a base date of less than 0 or "1900-01-01". Any correct calculations before then are simply a lucky shot it in the dark. The reason is the difference between dates produces a difference of days and not a date serial number. When the DATEPART(dy....) does its implicit conversion back to DATETIME, it's doing it based on that number of days rather than a true date serial number. I just so happens that the number of days matches the date serial number IF and only if the base date is 0 (1900-01-01) AND the date being converted is >= the base date.
--Jeff Moden
Change is inevitable... Change for the better is not.
July 26, 2013 at 12:01 am
I still have some testing to do but it appears that converting the DATEDIFF back to a DATETIME using DATEADD instead of mistakenly allowing DATEPART to do it fixes all the problems. Here's the corrected formula. I'm using the base date of '1753' in this formula and it appears to be working correctly for all dates from 1753-01-01 through 9999-12-31. I still need to test it with the ranges of the "new" DATE datatype.
(DATEPART(dy,DATEADD(dd,DATEDIFF(dd,'1753',Date)/7*7+3 ,'1753'))+6)/7
--Jeff Moden
Change is inevitable... Change for the better is not.
July 26, 2013 at 1:38 am
Any January 1st will do, as long as it is a monday in a non-leapyear.
I am running on SQL Server 2012 and have tested every January 1st between 0001 and 1900. Only some of them work, and the common denominator is that the working ones are non-leapyears.
N 56°04'39.16"
E 12°55'05.25"
July 26, 2013 at 8:29 am
SwePeso (7/26/2013)
Any January 1st will do, as long as it is a monday in a non-leapyear.I am running on SQL Server 2012 and have tested every January 1st between 0001 and 1900. Only some of them work, and the common denominator is that the working ones are non-leapyears.
In the above, you tested the new formula or the old? Like I said, the old one was totally screwed for any date prior to 1900-01-01 and any semblance of actually working was purely accidental.
I got notice this morning that they took the article down as I requested. I'll have them put it back up after I make some changes.
Thanks again for finding the shortcoming, Peter. I appreciate it.
--Jeff Moden
Change is inevitable... Change for the better is not.
July 26, 2013 at 4:40 pm
Until Microsoft has fixed all date function to be DATE compliant, try thisCREATE FUNCTION dbo.fnISOWEEK
(
@Date DATE
)
RETURNS TINYINT
AS
BEGIN
RETURN(
SELECTCASE
WHEN nextYear <= theDate THEN 0
WHEN currYear <= theDate THEN (theDate - currYear) / 7
ELSE (theDate - prevYear) / 7
END + 1
FROM(
SELECT(CASE
WHEN prevYear % 400 = 0 THEN -366
WHEN prevYear % 100 = 0 THEN -365
WHEN prevYear % 4 = 0 THEN -366
ELSE -365
END + theDate - theDoY + 4) / 7 * 7 AS prevYear,
(theDate - theDoY + 4) / 7 * 7 AS currYear,
(CASE
WHEN currYear % 400 = 0 THEN 366
WHEN currYear % 100 = 0 THEN 365
WHEN currYear % 4 = 0 THEN 366
ELSE 365
END + theDate - theDoY + 4) / 7 * 7 AS nextYear,
theDate
FROM(
SELECTDATEPART(YEAR, @Date) - 1 AS prevYear,
DATEPART(YEAR, @Date) AS currYear,
DATEDIFF(DAY, '00010101', @Date) AS theDate,
DATEPART(DAYOFYEAR, @Date) AS theDoY
) AS d
) AS d
)
END
N 56°04'39.16"
E 12°55'05.25"
July 26, 2013 at 6:42 pm
Or this, if you want to get rid of all Microsoft dependencies.
This will work for SQL 2000 and onwards, and on all dates between 00010101 and 99991231.
CREATE FUNCTION dbo.fnISOWEEK
(
@Year SMALLINT,
@Month TINYINT,
@Day TINYINT
)
RETURNS TINYINT
AS
BEGIN
RETURN(
SELECTCASE
WHEN nextYearStart <= theDate THEN 0
WHEN currYearStart <= theDate THEN (theDate - currYearStart) / 7
ELSE (theDate - prevYearStart) / 7
END + 1
FROM(
SELECT(currJan4 - 365 - prevLeapYear) / 7 * 7 AS prevYearStart,
currJan4 / 7 * 7 AS currYearStart,
(currJan4 + 365 + currLeapYear) / 7 * 7 AS nextYearStart,
CASE @Month
WHEN 1 THEN @Day
WHEN 2 THEN 31 + @Day
WHEN 3 THEN 59 + @Day + currLeapYear
WHEN 4 THEN 90 + @Day + currLeapYear
WHEN 5 THEN 120 + @Day + currLeapYear
WHEN 6 THEN 151 + @Day + currLeapYear
WHEN 7 THEN 181 + @Day + currLeapYear
WHEN 8 THEN 212 + @Day + currLeapYear
WHEN 9 THEN 243 + @Day + currLeapYear
WHEN 10 THEN 273 + @Day + currLeapYear
WHEN 11 THEN 304 + @Day + currLeapYear
WHEN 12 THEN 334 + @Day + currLeapYear
END + currJan4 - 4 AS theDate
FROM(
SELECTCASE
WHEN (@Year - 1) % 400 = 0 THEN 1
WHEN (@Year - 1) % 100 = 0 THEN 0
WHEN (@Year - 1) % 4 = 0 THEN 1
ELSE 0
END AS prevLeapYear,
CASE
WHEN @Year % 400 = 0 THEN 1
WHEN @Year % 100 = 0 THEN 0
WHEN @Year % 4 = 0 THEN 1
ELSE 0
END AS currLeapYear,
365 * (@Year - 1) + (@Year - 1) / 400 - (@Year - 1) / 100 + (@Year - 1) / 4 + 3 AS currJan4
WHERE@Year BETWEEN 0 AND 9999
AND @Month BETWEEN 1 AND 12
AND @Day >= 1
AND 1 =CASE
WHEN @Month IN (1, 3, 5, 7, 8, 10, 12) AND @Day <= 31 THEN 1
WHEN @Month IN (4, 6, 9, 11) AND @Day <= 30 THEN 1
WHEN @Year % 400 = 0 AND @Day <= 29 THEN 1
WHEN @Year % 100 = 0 AND @Day <= 28 THEN 1
WHEN @Year % 4 = 0 AND @Day <= 29 THEN 1
WHEN @Day <= 28 THEN 1
ELSE 0
END
) AS d
) AS d
)
END
N 56°04'39.16"
E 12°55'05.25"
July 26, 2013 at 8:29 pm
Peter. I've receive several emails from you. Have you received any of mine?
--Jeff Moden
Change is inevitable... Change for the better is not.
July 27, 2013 at 3:40 am
Yes, I did indeed. However, the time at my place was 3 am and time to go to bed...
Here is a further reduced code (one less addition)(DATEPART(DAYOFYEAR, DATEADD(DAY, DATEDIFF(DAY, '17530101', @Date) / 7 * 7, '17530104')) + 6) / 7
My blog about this is here.
If you don't read Swedish well, use either Bing or Google.
N 56°04'39.16"
E 12°55'05.25"
July 27, 2013 at 10:25 am
SwePeso (7/27/2013)
Yes, I did indeed. However, the time at my place was 3 am and time to go to bed...Here is a further reduced code (one less addition)
(DATEPART(DAYOFYEAR, DATEADD(DAY, DATEDIFF(DAY, '17530101', @Date) / 7 * 7, '17530104')) + 6) / 7
My blog about this is here.
Thanks, Peter. I'll check out the formula.
My question was based on the fact that we weren't receiving each other's emails in the past.
--Jeff Moden
Change is inevitable... Change for the better is not.
October 23, 2015 at 7:47 am
Now what happens when a government decides to skip a day...
412-977-3526 call/text
October 23, 2015 at 8:04 am
robert.sterbal 56890 (10/23/2015)
Now what happens when a government decides to skip a day...
Then it's no longer "ISO". 😉
What's your real question?
--Jeff Moden
Change is inevitable... Change for the better is not.
October 23, 2015 at 8:13 am
I like the way your formula skips the leap year problem.
I still remember when the church moved the calendar by a couple of weeks - https://en.wikipedia.org/wiki/Gregorian_calendar
412-977-3526 call/text
Viewing 15 posts - 31 through 45 (of 79 total)
You must be logged in to reply to this topic. Login to reply