Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase 123»»»

Query to find the start day of the week as Monday Expand / Collapse
Author
Message
Posted Tuesday, December 4, 2012 7:55 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Friday, August 1, 2014 8:41 AM
Points: 101, 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
Post #1392504
Posted Tuesday, December 4, 2012 8:21 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Yesterday @ 3:12 PM
Points: 13,441, Visits: 12,303
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 Moden's 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)
Post #1392529
Posted Tuesday, December 4, 2012 8:40 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Friday, August 1, 2014 8:41 AM
Points: 101, Visits: 437
Thanks WIll take a look at it:)
Post #1392552
Posted Tuesday, December 4, 2012 9:10 AM
SSC Veteran

SSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC Veteran

Group: General Forum Members
Last Login: Sunday, August 31, 2014 11:45 AM
Points: 275, Visits: 863
set DATEFIRST 1
declare @dt datetime
select @dt = '12/09/2012'

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

set DATEFIRST 7
Post #1392563
Posted Tuesday, December 4, 2012 9:23 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Friday, August 1, 2014 8:41 AM
Points: 101, 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!
Post #1392571
Posted Tuesday, December 4, 2012 10:04 AM


SSC-Insane

SSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-Insane

Group: General Forum Members
Last Login: Yesterday @ 6:47 PM
Points: 23,396, Visits: 32,229
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





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)
Post #1392598
Posted Tuesday, December 4, 2012 10:54 AM
SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Monday, September 8, 2014 4:07 PM
Points: 1,669, Visits: 2,215
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)

Internet ATM Machine
Post #1392622
Posted Tuesday, December 4, 2012 11:04 AM


SSC-Insane

SSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-Insane

Group: General Forum Members
Last Login: Yesterday @ 6:47 PM
Points: 23,396, Visits: 32,229
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





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)
Post #1392627
Posted Tuesday, December 4, 2012 11:07 AM
Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Yesterday @ 9:15 PM
Points: 3,136, Visits: 11,492
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
Post #1392630
Posted Tuesday, December 4, 2012 11:17 AM


SSC-Insane

SSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-Insane

Group: General Forum Members
Last Login: Yesterday @ 6:47 PM
Points: 23,396, Visits: 32,229
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]





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)
Post #1392634
« Prev Topic | Next Topic »

Add to briefcase 123»»»

Permissions Expand / Collapse