December 4, 2012 at 7:55 am
Hi All,
How to specify the start day of the week as Monday for the below records
I have tow fields Record and Load date... Want to have another additional Col start date of the week
Results as below:
Record Loaddate Start date of the week (As Monday)
A 03/12/2012 03/12/2012
B 04/12/2012 03/12/2012
C 05/12/2012 03/12/2012
D 09/12/2012 03/12/2012
I used the below query
select CONVERT(varchar(10), DATEADD(WK, DATEDIFF(WK, 0, '12/04/2012'), 0),101) AS Week
The above query works fine and fetches the start day of the week As monday only if the day is between Monday - Saturday.
But say for Sunday '12/09/2012', the start day of the week is considered as the subsequent Monday 12/10/2012... But for the Sunday 12/09/2012, I wanted the start date of the week as '12/03/2012'
Any help on this?
Thanks
December 4, 2012 at 8:21 am
Sounds like you should look into a calendar table. Check out this article. http://www.sqlservercentral.com/articles/T-SQL/70482/[/url]
_______________________________________________________________
Need help? Help us help you.
Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.
Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.
Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/
December 4, 2012 at 8:40 am
Thanks WIll take a look at it:)
December 4, 2012 at 9:23 am
Thanks for the reply.
I used the below case statement in my Select statement to get the starting day as Monday:
(CASE WHEN datename(dw,date) <> 'Sunday' THEN CONVERT(varchar(10), DATEADD(WK, DATEDIFF(WK, 0, date), 0),
103) ELSE CONVERT(varchar(10), DATEADD(WK, DATEDIFF(WK, 0, date), - 7), 103) END)
Thanks all!
December 4, 2012 at 10:04 am
Compare:
DECLARE @date DATE = '20121202';
SELECT
CASE WHEN datename(dw,@date) <> 'Sunday' THEN CONVERT(varchar(10), DATEADD(WK, DATEDIFF(WK, 0, @date), 0),
103) ELSE CONVERT(varchar(10), DATEADD(WK, DATEDIFF(WK, 0, @date), - 7), 103) END
go
DECLARE @date DATE = '20121203';
SELECT
CASE WHEN datename(dw,@date) <> 'Sunday' THEN CONVERT(varchar(10), DATEADD(WK, DATEDIFF(WK, 0, @date), 0),
103) ELSE CONVERT(varchar(10), DATEADD(WK, DATEDIFF(WK, 0, @date), - 7), 103) END
go
DECLARE @date DATE = '20121202';
select dateadd(wk, datediff(wk, 0, DATEADD(dd,-1,@Date)), 0);
GO
DECLARE @date DATE = '20121203';
select dateadd(wk, datediff(wk, 0, DATEADD(dd,-1,@Date)), 0);
GO
December 4, 2012 at 10:54 am
How about:
CASE
WHEN DATEPART(dw, THE_DATE) = 1 THEN DATEADD(dd, -6, THE_DATE)
ELSE DATEADD(dd, 0 - (DATEPART(dw, THE_DATE) - 2), THE_DATE)
END
where THE_DATE is assumed to be the date field...
Steve (aka sgmunson) 🙂 🙂 🙂
Rent Servers for Income (picks and shovels strategy)
December 4, 2012 at 11:04 am
sgmunson (12/4/2012)
How about:
CASE
WHEN DATEPART(dw, THE_DATE) = 1 THEN DATEADD(dd, -6, THE_DATE)
ELSE DATEADD(dd, 0 - (DATEPART(dw, THE_DATE) - 2), THE_DATE)
END
where THE_DATE is assumed to be the date field...
No conditional logic required:
DECLARE @date DATE = '20121202';
select dateadd(wk, datediff(wk, 0, DATEADD(dd,-1,@Date)), 0);
GO
DECLARE @date DATE = '20121203';
select dateadd(wk, datediff(wk, 0, DATEADD(dd,-1,@Date)), 0);
GO
December 4, 2012 at 11:07 am
select
a.*,
Monday = dateadd(dd,(datediff(dd,-53690,a.DATE)/7)*7,-53690)
from
( -- Test Data
select [Date]= getdate()-2union all
select [Date]= getdate()-1union all
select [Date]= getdate()union all
select [Date]= getdate()+1union all
select [Date]= getdate()+2union all
select [Date]= getdate()+3union all
select [Date]= getdate()+4union all
select [Date]= getdate()+5union all
select [Date]= getdate()+6union all
select [Date]= getdate()+7union all
select [Date]= getdate()+8
) a
order by
a.[Date]
Results:
Date Monday
----------------------- -----------------------
2012-12-02 13:05:22.770 2012-11-26 00:00:00.000
2012-12-03 13:05:22.803 2012-12-03 00:00:00.000
2012-12-04 13:05:22.803 2012-12-03 00:00:00.000
2012-12-05 13:05:22.803 2012-12-03 00:00:00.000
2012-12-06 13:05:22.803 2012-12-03 00:00:00.000
2012-12-07 13:05:22.803 2012-12-03 00:00:00.000
2012-12-08 13:05:22.803 2012-12-03 00:00:00.000
2012-12-09 13:05:22.803 2012-12-03 00:00:00.000
2012-12-10 13:05:22.803 2012-12-10 00:00:00.000
2012-12-11 13:05:22.803 2012-12-10 00:00:00.000
2012-12-12 13:05:22.803 2012-12-10 00:00:00.000
December 4, 2012 at 11:17 am
Michael Valentine Jones (12/4/2012)
select
a.*,
Monday = dateadd(dd,(datediff(dd,-53690,a.DATE)/7)*7,-53690)
from
( -- Test Data
select [Date]= getdate()-2union all
select [Date]= getdate()-1union all
select [Date]= getdate()union all
select [Date]= getdate()+1union all
select [Date]= getdate()+2union all
select [Date]= getdate()+3union all
select [Date]= getdate()+4union all
select [Date]= getdate()+5union all
select [Date]= getdate()+6union all
select [Date]= getdate()+7union all
select [Date]= getdate()+8
) a
order by
a.[Date]
Results:
Date Monday
----------------------- -----------------------
2012-12-02 13:05:22.770 2012-11-26 00:00:00.000
2012-12-03 13:05:22.803 2012-12-03 00:00:00.000
2012-12-04 13:05:22.803 2012-12-03 00:00:00.000
2012-12-05 13:05:22.803 2012-12-03 00:00:00.000
2012-12-06 13:05:22.803 2012-12-03 00:00:00.000
2012-12-07 13:05:22.803 2012-12-03 00:00:00.000
2012-12-08 13:05:22.803 2012-12-03 00:00:00.000
2012-12-09 13:05:22.803 2012-12-03 00:00:00.000
2012-12-10 13:05:22.803 2012-12-10 00:00:00.000
2012-12-11 13:05:22.803 2012-12-10 00:00:00.000
2012-12-12 13:05:22.803 2012-12-10 00:00:00.000
Or:
select
a.*,
Monday = dateadd(wk, datediff(wk, 0, DATEADD(dd,-1,a.Date)), 0)
from
( -- Test Data
select [Date]= getdate()-2union all
select [Date]= getdate()-1union all
select [Date]= getdate()union all
select [Date]= getdate()+1union all
select [Date]= getdate()+2union all
select [Date]= getdate()+3union all
select [Date]= getdate()+4union all
select [Date]= getdate()+5union all
select [Date]= getdate()+6union all
select [Date]= getdate()+7union all
select [Date]= getdate()+8
) a
order by
a.[Date]
December 4, 2012 at 11:18 am
Lynn Pettis (12/4/2012)
Compare:
DECLARE @date DATE = '20121202';
SELECT
CASE WHEN datename(dw,@date) <> 'Sunday' THEN CONVERT(varchar(10), DATEADD(WK, DATEDIFF(WK, 0, @date), 0),
103) ELSE CONVERT(varchar(10), DATEADD(WK, DATEDIFF(WK, 0, @date), - 7), 103) END
go
DECLARE @date DATE = '20121203';
SELECT
CASE WHEN datename(dw,@date) <> 'Sunday' THEN CONVERT(varchar(10), DATEADD(WK, DATEDIFF(WK, 0, @date), 0),
103) ELSE CONVERT(varchar(10), DATEADD(WK, DATEDIFF(WK, 0, @date), - 7), 103) END
go
DECLARE @date DATE = '20121202';
select dateadd(wk, datediff(wk, 0, DATEADD(dd,-1,@Date)), 0);
GO
DECLARE @date DATE = '20121203';
select dateadd(wk, datediff(wk, 0, DATEADD(dd,-1,@Date)), 0);
GO
Yup, you have it right. I didn't get to see your post before I posted my answer. I'd sure like to understand a bit more about why that works. It's using the number of weeks since date zero through yesterday, then re-adding the same number of weeks to date zero, which suggests that perhaps the week is defined based on Monday ? Or is it Sunday, and thus why yesterday is used instead of today?
Steve (aka sgmunson) 🙂 🙂 🙂
Rent Servers for Income (picks and shovels strategy)
December 4, 2012 at 11:22 am
sgmunson (12/4/2012)
Lynn Pettis (12/4/2012)
Compare:
DECLARE @date DATE = '20121202';
SELECT
CASE WHEN datename(dw,@date) <> 'Sunday' THEN CONVERT(varchar(10), DATEADD(WK, DATEDIFF(WK, 0, @date), 0),
103) ELSE CONVERT(varchar(10), DATEADD(WK, DATEDIFF(WK, 0, @date), - 7), 103) END
go
DECLARE @date DATE = '20121203';
SELECT
CASE WHEN datename(dw,@date) <> 'Sunday' THEN CONVERT(varchar(10), DATEADD(WK, DATEDIFF(WK, 0, @date), 0),
103) ELSE CONVERT(varchar(10), DATEADD(WK, DATEDIFF(WK, 0, @date), - 7), 103) END
go
DECLARE @date DATE = '20121202';
select dateadd(wk, datediff(wk, 0, DATEADD(dd,-1,@Date)), 0);
GO
DECLARE @date DATE = '20121203';
select dateadd(wk, datediff(wk, 0, DATEADD(dd,-1,@Date)), 0);
GO
Yup, you have it right. I didn't get to see your post before I posted my answer. I'd sure like to understand a bit more about why that works. It's using the number of weeks since date zero through yesterday, then re-adding the same number of weeks to date zero, which suggests that perhaps the week is defined based on Monday ? Or is it Sunday, and thus why yesterday is used instead of today?
Will explain tonight.
December 4, 2012 at 12:47 pm
Lynn Pettis (12/4/2012)
Michael Valentine Jones (12/4/2012)
select
a.*,
Monday = dateadd(dd,(datediff(dd,-53690,a.DATE)/7)*7,-53690)
from
( -- Test Data
select [Date]= getdate()-2union all
select [Date]= getdate()-1union all
select [Date]= getdate()union all
select [Date]= getdate()+1union all
select [Date]= getdate()+2union all
select [Date]= getdate()+3union all
select [Date]= getdate()+4union all
select [Date]= getdate()+5union all
select [Date]= getdate()+6union all
select [Date]= getdate()+7union all
select [Date]= getdate()+8
) a
order by
a.[Date]
Results:
Date Monday
----------------------- -----------------------
2012-12-02 13:05:22.770 2012-11-26 00:00:00.000
2012-12-03 13:05:22.803 2012-12-03 00:00:00.000
2012-12-04 13:05:22.803 2012-12-03 00:00:00.000
2012-12-05 13:05:22.803 2012-12-03 00:00:00.000
2012-12-06 13:05:22.803 2012-12-03 00:00:00.000
2012-12-07 13:05:22.803 2012-12-03 00:00:00.000
2012-12-08 13:05:22.803 2012-12-03 00:00:00.000
2012-12-09 13:05:22.803 2012-12-03 00:00:00.000
2012-12-10 13:05:22.803 2012-12-10 00:00:00.000
2012-12-11 13:05:22.803 2012-12-10 00:00:00.000
2012-12-12 13:05:22.803 2012-12-10 00:00:00.000
Or:
select
a.*,
Monday = dateadd(wk, datediff(wk, 0, DATEADD(dd,-1,a.Date)), 0)
from
( -- Test Data
select [Date]= getdate()-2union all
select [Date]= getdate()-1union all
select [Date]= getdate()union all
select [Date]= getdate()+1union all
select [Date]= getdate()+2union all
select [Date]= getdate()+3union all
select [Date]= getdate()+4union all
select [Date]= getdate()+5union all
select [Date]= getdate()+6union all
select [Date]= getdate()+7union all
select [Date]= getdate()+8
) a
order by
a.[Date]
Not completely the same, though:
select
a.*,
Monday = dateadd(dd,(datediff(dd,-53690,a.DATE)/7)*7,-53690)
from
( select [Date]= convert(datetime,'17530101') ) a
select
a.*,
Monday = dateadd(wk, datediff(wk, 0, DATEADD(dd,-1,a.Date)), 0)
from
( select [Date]= convert(datetime,'17530101') )
Results:
Date Monday
----------------------- -----------------------
1753-01-01 00:00:00.000 1753-01-01 00:00:00.000
(1 row(s) affected)
Date Monday
----------------------- -----------------------
Msg 517, Level 16, State 1, Line 7
Adding a value to a 'datetime' column caused an overflow.
December 4, 2012 at 4:09 pm
Michael Valentine Jones (12/4/2012)
Lynn Pettis (12/4/2012)
Michael Valentine Jones (12/4/2012)
select
a.*,
Monday = dateadd(dd,(datediff(dd,-53690,a.DATE)/7)*7,-53690)
from
( -- Test Data
select [Date]= getdate()-2union all
select [Date]= getdate()-1union all
select [Date]= getdate()union all
select [Date]= getdate()+1union all
select [Date]= getdate()+2union all
select [Date]= getdate()+3union all
select [Date]= getdate()+4union all
select [Date]= getdate()+5union all
select [Date]= getdate()+6union all
select [Date]= getdate()+7union all
select [Date]= getdate()+8
) a
order by
a.[Date]
Results:
Date Monday
----------------------- -----------------------
2012-12-02 13:05:22.770 2012-11-26 00:00:00.000
2012-12-03 13:05:22.803 2012-12-03 00:00:00.000
2012-12-04 13:05:22.803 2012-12-03 00:00:00.000
2012-12-05 13:05:22.803 2012-12-03 00:00:00.000
2012-12-06 13:05:22.803 2012-12-03 00:00:00.000
2012-12-07 13:05:22.803 2012-12-03 00:00:00.000
2012-12-08 13:05:22.803 2012-12-03 00:00:00.000
2012-12-09 13:05:22.803 2012-12-03 00:00:00.000
2012-12-10 13:05:22.803 2012-12-10 00:00:00.000
2012-12-11 13:05:22.803 2012-12-10 00:00:00.000
2012-12-12 13:05:22.803 2012-12-10 00:00:00.000
Or:
select
a.*,
Monday = dateadd(wk, datediff(wk, 0, DATEADD(dd,-1,a.Date)), 0)
from
( -- Test Data
select [Date]= getdate()-2union all
select [Date]= getdate()-1union all
select [Date]= getdate()union all
select [Date]= getdate()+1union all
select [Date]= getdate()+2union all
select [Date]= getdate()+3union all
select [Date]= getdate()+4union all
select [Date]= getdate()+5union all
select [Date]= getdate()+6union all
select [Date]= getdate()+7union all
select [Date]= getdate()+8
) a
order by
a.[Date]
Not completely the same, though:
select
a.*,
Monday = dateadd(dd,(datediff(dd,-53690,a.DATE)/7)*7,-53690)
from
( select [Date]= convert(datetime,'17530101') ) a
select
a.*,
Monday = dateadd(wk, datediff(wk, 0, DATEADD(dd,-1,a.Date)), 0)
from
( select [Date]= convert(datetime,'17530101') )
Results:
Date Monday
----------------------- -----------------------
1753-01-01 00:00:00.000 1753-01-01 00:00:00.000
(1 row(s) affected)
Date Monday
----------------------- -----------------------
Msg 517, Level 16, State 1, Line 7
Adding a value to a 'datetime' column caused an overflow.
Not saying that there aren't, but most database applications don't nned to go that far back in time. I'd call that an edge case.
December 4, 2012 at 5:08 pm
Then substitute a 0 for Michael's -53690. 😀
That, not withstanding, it's always the "edge cases" that cause panic stricken calls at 3 in the morning.
--Jeff Moden
Change is inevitable... Change for the better is not.
Viewing 15 posts - 1 through 15 (of 23 total)
You must be logged in to reply to this topic. Login to reply