SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Query to find the start day of the week as Monday


Query to find the start day of the week as Monday

Author
Message
var05
var05
SSCommitted
SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)

Group: General Forum Members
Points: 1719 Visits: 437
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
Sean Lange
Sean Lange
SSC Guru
SSC Guru (150K reputation)SSC Guru (150K reputation)SSC Guru (150K reputation)SSC Guru (150K reputation)SSC Guru (150K reputation)SSC Guru (150K reputation)SSC Guru (150K reputation)SSC Guru (150K reputation)

Group: General Forum Members
Points: 150059 Visits: 18582
Sounds like you should look into a calendar table. Check out this article. http://www.sqlservercentral.com/articles/T-SQL/70482/

_______________________________________________________________

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.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
var05
var05
SSCommitted
SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)

Group: General Forum Members
Points: 1719 Visits: 437
Thanks WIll take a look at itSmile
arnipetursson
arnipetursson
Hall of Fame
Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)

Group: General Forum Members
Points: 3607 Visits: 1019
set DATEFIRST 1
declare @dt datetime
select @dt = '12/09/2012'

select previousMonday = dateadd(dd,(-1)*(datepart(dw,@dt)-1),@dt)

set DATEFIRST 7
var05
var05
SSCommitted
SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)SSCommitted (1.7K reputation)

Group: General Forum Members
Points: 1719 Visits: 437
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!
Lynn Pettis
Lynn Pettis
SSC Guru
SSC Guru (226K reputation)SSC Guru (226K reputation)SSC Guru (226K reputation)SSC Guru (226K reputation)SSC Guru (226K reputation)SSC Guru (226K reputation)SSC Guru (226K reputation)SSC Guru (226K reputation)

Group: General Forum Members
Points: 226148 Visits: 40424
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




Cool
Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
sgmunson
sgmunson
SSC-Forever
SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)

Group: General Forum Members
Points: 43662 Visits: 5422
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)
Smile Smile Smile
Health & Nutrition
Lynn Pettis
Lynn Pettis
SSC Guru
SSC Guru (226K reputation)SSC Guru (226K reputation)SSC Guru (226K reputation)SSC Guru (226K reputation)SSC Guru (226K reputation)SSC Guru (226K reputation)SSC Guru (226K reputation)SSC Guru (226K reputation)

Group: General Forum Members
Points: 226148 Visits: 40424
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




Cool
Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
Michael Valentine Jones
Michael Valentine Jones
SSC-Dedicated
SSC-Dedicated (36K reputation)SSC-Dedicated (36K reputation)SSC-Dedicated (36K reputation)SSC-Dedicated (36K reputation)SSC-Dedicated (36K reputation)SSC-Dedicated (36K reputation)SSC-Dedicated (36K reputation)SSC-Dedicated (36K reputation)

Group: General Forum Members
Points: 36270 Visits: 11933
select
a.*,
Monday = dateadd(dd,(datediff(dd,-53690,a.DATE)/7)*7,-53690)
from
( -- Test Data
select [Date] = getdate()-2 union all
select [Date] = getdate()-1 union all
select [Date] = getdate() union all
select [Date] = getdate()+1 union all
select [Date] = getdate()+2 union all
select [Date] = getdate()+3 union all
select [Date] = getdate()+4 union all
select [Date] = getdate()+5 union all
select [Date] = getdate()+6 union all
select [Date] = getdate()+7 union 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

Lynn Pettis
Lynn Pettis
SSC Guru
SSC Guru (226K reputation)SSC Guru (226K reputation)SSC Guru (226K reputation)SSC Guru (226K reputation)SSC Guru (226K reputation)SSC Guru (226K reputation)SSC Guru (226K reputation)SSC Guru (226K reputation)

Group: General Forum Members
Points: 226148 Visits: 40424
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()-2 union all
select [Date] = getdate()-1 union all
select [Date] = getdate() union all
select [Date] = getdate()+1 union all
select [Date] = getdate()+2 union all
select [Date] = getdate()+3 union all
select [Date] = getdate()+4 union all
select [Date] = getdate()+5 union all
select [Date] = getdate()+6 union all
select [Date] = getdate()+7 union 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()-2 union all
select [Date] = getdate()-1 union all
select [Date] = getdate() union all
select [Date] = getdate()+1 union all
select [Date] = getdate()+2 union all
select [Date] = getdate()+3 union all
select [Date] = getdate()+4 union all
select [Date] = getdate()+5 union all
select [Date] = getdate()+6 union all
select [Date] = getdate()+7 union all
select [Date] = getdate()+8
) a
order by
a.[Date]




Cool
Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum








































































































































































SQLServerCentral


Search