Please start any new threads on our new
site at https://forums.sqlteam.com. We've got lots of great SQL Server
experts to answer whatever question you can come up with.
| Author |
Topic |
|
veparala
Starting Member
30 Posts |
Posted - 2007-03-28 : 11:28:39
|
| Hi I would like to display Monday and Friday's dates of the next week. Anybody help me?.like 04/02/2007 and 04/05/2007 |
|
|
SwePeso
Patron Saint of Lost Yaks
30421 Posts |
Posted - 2007-03-28 : 11:34:23
|
| MVJ has an excellent function START_OF_WEEK found herehttp://www.sqlteam.com/forums/topic.asp?TOPIC_ID=47307select dbo.F_START_OF_WEEK(getdate() + 7, 2) as nextmonday, dbo.F_START_OF_WEEK(getdate() + 7, 6) as nextfridayPeter LarssonHelsingborg, Sweden |
 |
|
|
veparala
Starting Member
30 Posts |
Posted - 2007-03-28 : 11:41:16
|
| I don't have dbo.F_START_OF_WEEK function in my SQL server. It is giving error 'Invalid object name'.Please advice me |
 |
|
|
SwePeso
Patron Saint of Lost Yaks
30421 Posts |
Posted - 2007-03-28 : 11:44:07
|
| You could follow the link above, and copy the code for the user defined function to new query window and run the code.Then empty the code window and runselect dbo.F_START_OF_WEEK(getdate() + 7, 2) as nextmonday, dbo.F_START_OF_WEEK(getdate() + 7, 6) as nextfridayPeter LarssonHelsingborg, Sweden |
 |
|
|
SwePeso
Patron Saint of Lost Yaks
30421 Posts |
Posted - 2007-03-28 : 11:45:37
|
This partcreate function dbo.F_START_OF_WEEK( @DATE datetime, -- Sun = 1, Mon = 2, Tue = 3, Wed = 4 -- Thu = 5, Fri = 6, Sat = 7 -- Default to Sunday @WEEK_START_DAY int = 1 )/*Find the fisrt date on or before @DATE that matches day of week of @WEEK_START_DAY.*/returns datetimeasbegindeclare @START_OF_WEEK_DATE datetimedeclare @FIRST_BOW datetime-- Check for valid day of weekif @WEEK_START_DAY between 1 and 7 begin -- Find first day on or after 1753/1/1 (-53690) -- matching day of week of @WEEK_START_DAY -- 1753/1/1 is earliest possible SQL Server date. select @FIRST_BOW = convert(datetime,-53690+((@WEEK_START_DAY+5)%7)) -- Verify beginning of week not before 1753/1/1 if @DATE >= @FIRST_BOW begin select @START_OF_WEEK_DATE = dateadd(dd,(datediff(dd,@FIRST_BOW,@DATE)/7)*7,@FIRST_BOW) end endreturn @START_OF_WEEK_DATEend Peter LarssonHelsingborg, Sweden |
 |
|
|
Michael Valentine Jones
Yak DBA Kernel (pronounced Colonel)
7020 Posts |
Posted - 2007-03-28 : 13:46:22
|
quote: Originally posted by Peso You could follow the link above, and copy the code for the user defined function to new query window and run the code.Then empty the code window and runselect dbo.F_START_OF_WEEK(getdate() + 7, 2) as nextmonday, dbo.F_START_OF_WEEK(getdate() + 7, 6) as nextfridayPeter LarssonHelsingborg, Sweden
I don't think the Friday date is correct. The F_START_OF_WEEK returns the day of week that occurs on or before the date passed. Since it is only Wednesday, the Friday it returns for a week from today is Friday of this week.If you assume that the current week runs from Sunday to Saturday, this should give the correct result. Basically, it finds the start of the week (Sunday), and adds 1 day to get Monday and 5 days to find Friday.select dbo.F_START_OF_WEEK(getdate()+7,1)+1 as NextMonday, dbo.F_START_OF_WEEK(getdate()+7,1)+5 as NextFriday Results:NextMonday NextFriday ----------------------- -----------------------2007-04-02 00:00:00.000 2007-04-06 00:00:00.000(1 row(s) affected) Edit:This also seems to work OK for weeks that run Sunday to Saturday:select dbo.F_START_OF_WEEK(getdate()+8,2) as NextMonday, dbo.F_START_OF_WEEK(getdate()+12,6) as NextFriday CODO ERGO SUM |
 |
|
|
veparala
Starting Member
30 Posts |
Posted - 2007-03-28 : 16:02:16
|
| Thanks..It is working |
 |
|
|
|
|
|
|
|