August 18, 2011 at 1:16 am
Hi,
How to get date of first monday of the given year?
August 18, 2011 at 3:00 am
Check the below code
Declare @year varchar(10)='2011' -- Input
Declare @Dpart Tinyint
set @year = @year+'-01-01'
set @Dpart= Datepart(DW,@year)
Select Case When @Dpart = 2 Then @year When @Dpart < 2 Then DateAdd(dd,2-@Dpart,@year) Else DateAdd(dd,(7-Datepart(DW,@year))+2,@year) End
August 18, 2011 at 5:06 am
The above code relies on the first day of the week being a Sunday, the US default. Your first day may be different (mine is), which will give an incorrect result using that code. Check out @@DATEFIRST and SET DATEFIRST in BOL if you want to use it.
August 18, 2011 at 5:57 am
Fast and accurate:
SELECT [FirstMonday] = DATEADD(dd,CASE x.wd WHEN 'mo' THEN 0 WHEN 'su' THEN 1 WHEN 'sa' THEN 2 WHEN 'fr' THEN 3 WHEN 'th' THEN 4 WHEN 'we' THEN 5 WHEN 'tu' THEN 6 END,d.FirstDayOfYear)
FROM (SELECT [FirstDayOfYear] = DATEADD(YEAR,DATEDIFF(YEAR,0,GETDATE()),0)) d
CROSS APPLY(SELECT [wd] = LEFT(DATENAME(weekday,d.[FirstDayOfYear]),2)) x
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
August 19, 2011 at 3:15 am
Fast and accurate, but dependent on the Language of the server.
This code relies only on knowning the date of some known monday (but is perhaps a little clunky)...
;withDayOne as (select dateadd(year,dateDiff(year,0,@dt),0) as dt)
,KnownMonday as (select cast('1900-03-05' as date) as dt)
,DayOneOffset as (select DateDiff(day,KnownMonday.dt,dateadd(year,dateDiff(year,0,@dt),0))%7 as num from KnownMonday)
selectdateadd(day,(7-DayOneOffset.num)%7,DayOne.dt) as FirstMonday
fromDayOne, DayOneOffset;
August 19, 2011 at 3:39 am
Oh, what a can of worms date handling in SQL Server is!!
declare @known_monday varchar(10) = '1900-03-05'
set dateformat dmy
select cast(@known_monday as date) as Date05Mar1900
, cast(@known_monday as datetime) as DateTime05Mar1900
, cast(@known_monday as datetime2) as DateTime05Mar1900
set dateformat ymd
select cast(@known_monday as date) as Date05Mar1900
, cast(@known_monday as datetime) as DateTime05Mar1900
, cast(@known_monday as datetime2) as DateTime05Mar1900
Date05Mar1900DateTime05Mar1900DateTime05Mar1900
1900-03-051900-05-03 00:00:00.0001900-03-05 00:00:00.0000000
Date05Mar1900DateTime05Mar1900DateTime05Mar1900
1900-03-051900-03-05 00:00:00.0001900-03-05 00:00:00.0000000
Don't know what others get, but for me (as shwon above) the above code returns 5th March 1900 for five out of the six conversions above. However, when DateFormat is set to DMY (which being British is the "normal" setting for me), it returns 3rd May when converted to DateTime.
DatePart and DateName also return 3rd May when DateFormat is set to DMY:
declare @known_monday varchar(10) = '1900-03-05'
set dateformat dmy
selectdatepart(dw,@known_monday) as WeekDay05Mar1900, datepart(day,@known_monday) as Day05Mar1900, datepart(month,@known_monday) as Month05Mar1900, datepart(year,@known_monday) as Year05Mar1900
,datepart(dw,'1900-03-05') as WeekDay05Mar1900, datepart(day,'1900-03-05') as Day05Mar1900, datepart(month,'1900-03-05') as Month05Mar1900, datepart(year,'1900-03-05') as Year05Mar1900
,datename(dw,'1900-03-05') as WeekDay05Mar1900, datename(day,'1900-03-05') as Day05Mar1900, datename(month,'1900-03-05') as Month05Mar1900, datename(year,'1900-03-05') as Year05Mar1900
set dateformat ymd
selectdatepart(dw,@known_monday) as WeekDay05Mar1900, datepart(day,@known_monday) as Day05Mar1900, datepart(month,@known_monday) as Month05Mar1900, datepart(year,@known_monday) as Year05Mar1900
,datepart(dw,'1900-03-05') as WeekDay05Mar1900, datepart(day,'1900-03-05') as Day05Mar1900, datepart(month,'1900-03-05') as Month05Mar1900, datepart(year,'1900-03-05') as Year05Mar1900
,datename(dw,'1900-03-05') as WeekDay05Mar1900, datename(day,'1900-03-05') as Day05Mar1900, datename(month,'1900-03-05') as Month05Mar1900, datename(year,'1900-03-05') as Year05Mar1900
WeekDay05Mar1900Day05Mar1900Month05Mar1900Year05Mar1900WeekDay05Mar1900Day05Mar1900Month05Mar1900Year05Mar1900WeekDay05Mar1900Day05Mar1900Month05Mar1900Year05Mar1900
43519004351900Thursday3May1900
WeekDay05Mar1900Day05Mar1900Month05Mar1900Year05Mar1900WeekDay05Mar1900Day05Mar1900Month05Mar1900Year05Mar1900WeekDay05Mar1900Day05Mar1900Month05Mar1900Year05Mar1900
15319001531900Monday5March1900
August 19, 2011 at 3:47 am
Quite easy with a calendar table.
Select top 1 * FROM dbo.Calendar WHERE Y = 2011 AND DW = <whatever fits your setting> ORDER BY dt.
August 19, 2011 at 3:51 am
Ninja's_RGR'us (8/19/2011)
Quite easy with a calendar table.Select top 1 * FROM dbo.Calendar WHERE Y = 2011 AND DW = <whatever fits your setting> ORDER BY dt.
Just as easy without. Make one for the first week of the year and pick the correct row from it π
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
August 19, 2011 at 6:12 am
Are you, by any chance, working on getting the iso week number? Because if you are, have a look at this article[/url] (remember to follow the discussions link, there are many examples in there, including one of myself recently) and if the end product is to run on SQL 2008, simply use datepart(isowk, <your date>)
August 19, 2011 at 7:10 am
R.P.Rozema (8/19/2011)
Are you, by any chance, working on getting the iso week number? Because if you are, have a look at this article[/url] (remember to follow the discussions link, there are many examples in there, including one of myself recently) and if the end product is to run on SQL 2008, simply use datepart(isowk, <your date>)
R.P.Rozema I saw that thread, and actually added the IsoWeek to my calendar table because of it. Never know when or if it might be handy.
Sure enough, less than a week later, a post that could benefit from it;
for my specific calendarTable the WHERE statement would be:
WHERE YearNumber = 2011 AND IsoWeek = 1 AND DayOfWeek = 'Monday'
Lowell
August 19, 2011 at 7:12 am
ChrisM@Work (8/19/2011)
Ninja's_RGR'us (8/19/2011)
Quite easy with a calendar table.Select top 1 * FROM dbo.Calendar WHERE Y = 2011 AND DW = <whatever fits your setting> ORDER BY dt.
Just as easy without. Make one for the first week of the year and pick the correct row from it π
Too many good uses to not have 1.
Since my table is less than 2 MB and that I can query the table with an <clustered>index I don't really see the point of trying to go much faster than that. Not saying it's impossible, just never had that need! π
August 19, 2011 at 12:27 pm
Ninja's_RGR'us (8/19/2011)
ChrisM@Work (8/19/2011)
Ninja's_RGR'us (8/19/2011)
Quite easy with a calendar table.Select top 1 * FROM dbo.Calendar WHERE Y = 2011 AND DW = <whatever fits your setting> ORDER BY dt.
Just as easy without. Make one for the first week of the year and pick the correct row from it π
Too many good uses to not have 1.
Since my table is less than 2 MB and that I can query the table with an <clustered>index I don't really see the point of trying to go much faster than that. Not saying it's impossible, just never had that need! π
I agree with Remi on this one. There are just too many uses for calendar tables not to have them. When properly done they give better performance than complicated date math in most cases. You can spell out a month name any way you want in any language and have it displayed correctly. Very simple aggregating and grouping. All sorts of uses.
Todd Fifield
August 19, 2011 at 12:50 pm
The code to find the first Monday of the year is fairly simple:
First find the 7th day of the year (Jan 7):
dateadd(yy,datediff(yy,0,a.DT),6)
and then find the Monday on or before that date:
dateadd(dd,(datediff(dd,0, JanuarySeventh )/7)*7,0)
Does not depend on any setting of language or datefirst.
select
DT,
FirstMonday =
dateadd(dd,(datediff(dd,0,dateadd(yy,datediff(yy,0,a.DT),6))/7)*7,0)
from
( -- Test Data
select DT = getdate()union all
select DT = '20111231'union all
select DT = '20121231'union all
select DT = '20131231'union all
select DT = '20141231'union all
select DT = '20110101'union all
select DT = '20080229'
) a
Results:
DT FirstMonday
------------------------ -----------------------
2011-08-19 14:42:26.310 2011-01-03 00:00:00.000
2011-12-31 00:00:00.000 2011-01-03 00:00:00.000
2012-12-31 00:00:00.000 2012-01-02 00:00:00.000
2013-12-31 00:00:00.000 2013-01-07 00:00:00.000
2014-12-31 00:00:00.000 2014-01-06 00:00:00.000
2011-01-01 00:00:00.000 2011-01-03 00:00:00.000
2008-02-29 00:00:00.000 2008-01-07 00:00:00.000
August 23, 2011 at 2:33 am
That's the same algorithm I posted further up the thread, although rather better explained.
The only assumption that is made is that you know a Monday, which in your case is day 0.
I rather unnecessarily tied myself in knots trying to make that assumption explicit and avoid dates before February 1900, to avoid leap year confusions.
August 23, 2011 at 9:03 am
paul_ramster (8/23/2011)
That's the same algorithm I posted further up the thread, although rather better explained.The only assumption that is made is that you know a Monday, which in your case is day 0.
I rather unnecessarily tied myself in knots trying to make that assumption explicit and avoid dates before February 1900, to avoid leap year confusions.
If you are concerned about dates before 1900-01-01, then you could use 1753-01-01, which is the earliest possible datetime and also a Monday. Ask me how I knew that. π
Start of Week Function
Viewing 15 posts - 1 through 15 (of 15 total)
You must be logged in to reply to this topic. Login to reply