Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


To Find the First Saturday of any month


To Find the First Saturday of any month

Author
Message
DavidH-768896
DavidH-768896
SSC Journeyman
SSC Journeyman (96 reputation)SSC Journeyman (96 reputation)SSC Journeyman (96 reputation)SSC Journeyman (96 reputation)SSC Journeyman (96 reputation)SSC Journeyman (96 reputation)SSC Journeyman (96 reputation)SSC Journeyman (96 reputation)

Group: General Forum Members
Points: 96 Visits: 150
I still prefer the following to get to the first of the month:

SET @dt = DATEADD(d,1-DAY(@dt),@dt)




Nigel, nice! Your arithmetic is very crafty and gets a solution in a single statement. But I always prefer code that is easily understood and maintainable by the programmers that come after me, even if there are a couple extra lines and temporary variables.

When I am working on a problem I never think about beauty. I think only how to solve the problem. But when I have finished, if the solution is not beautiful, I know it is wrong.
— R. Buckminster Fuller

(from Code Complete, 2nd Edition, www.cc2e.com)
nigel.
nigel.
Ten Centuries
Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)

Group: General Forum Members
Points: 1333 Visits: 2823
publicdh-tech (8/11/2009)
I still prefer the following to get to the first of the month:

SET @dt = DATEADD(d,1-DAY(@dt),@dt)




Nigel, nice! Your arithmetic is very crafty and gets a solution in a single statement. But I always prefer code that is easily understood and maintainable by the programmers that come after me, even if there are a couple extra lines and temporary variables.


Thanks.

A guess a few comments may solve the readability and maintainability issue (sorry didn't have the luxury of time) ;-).

The only problem with variables is that you can't have them in a view.

I like your method of calculating the first of the month, one minor issue is that it needs to refer to the date twice. Which is ok when that's a simple variable as in your example. It can become a bit hairy when the date itself is a more complex calculation.

Nigel

--
Nigel
Useful Links:
How to post data/code on a forum to get the best help
The "Numbers" or "Tally" Table - Jeff Moden

anand.ramanan
anand.ramanan
SSC Rookie
SSC Rookie (41 reputation)SSC Rookie (41 reputation)SSC Rookie (41 reputation)SSC Rookie (41 reputation)SSC Rookie (41 reputation)SSC Rookie (41 reputation)SSC Rookie (41 reputation)SSC Rookie (41 reputation)

Group: General Forum Members
Points: 41 Visits: 70
Nigel,
I think you missed my post on page 1. It has as a similar implementation, and it allows to find the first sunday - saturday of the month. I did not spend time modifying the calculation of the first of the month. Your implementation is nice though.

So here is the modified code applying the new first day of month logic

declare @dw int
set @dw = 7 -- [Sunday - Saturday] == [1 - 7]

declare @d datetime
set @d = '7/21/2009'

declare @first datetime
set @first = DATEADD(d,1-DAY(@d),@d)

declare @dayofweek int
set @dayofweek = DATEPART(dw,@first)

print @first + (7+(@dw - @dayofweek))%7


wildh
wildh
SSC Veteran
SSC Veteran (292 reputation)SSC Veteran (292 reputation)SSC Veteran (292 reputation)SSC Veteran (292 reputation)SSC Veteran (292 reputation)SSC Veteran (292 reputation)SSC Veteran (292 reputation)SSC Veteran (292 reputation)

Group: General Forum Members
Points: 292 Visits: 675
One thing to be mindful with - SET @dt = DATEADD(d,1-DAY(@dt),@dt) is that when it's used with getdate() the result includes the time as well as the date.



nigel.
nigel.
Ten Centuries
Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)

Group: General Forum Members
Points: 1333 Visits: 2823
anand.ramanan (8/11/2009)
Nigel,
I think you missed my post on page 1. It has as a similar implementation, and it allows to find the first sunday - saturday of the month. I did not spend time modifying the calculation of the first of the month. Your implementation is nice though.

Anand,

Only problem with your solution is that it relies on DATEFIRST having the default value of 7, as you mentioned in your first post.

Although I do like the option to adjust which day to calculate.

This can also be done in my solution by adjusting the constant value of 14. ie 15 will give you the first Sunday and 20 the first Friday etc.

--
Nigel
Useful Links:
How to post data/code on a forum to get the best help
The "Numbers" or "Tally" Table - Jeff Moden

nigel.
nigel.
Ten Centuries
Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)

Group: General Forum Members
Points: 1333 Visits: 2823
wildh (8/12/2009)
One thing to be mindful with - SET @dt = DATEADD(d,1-DAY(@dt),@dt) is that when it's used with getdate() the result includes the time as well as the date.


Wildh,

Good point, I'd overlooked that.

Nigel

--
Nigel
Useful Links:
How to post data/code on a forum to get the best help
The "Numbers" or "Tally" Table - Jeff Moden

DavidH-768896
DavidH-768896
SSC Journeyman
SSC Journeyman (96 reputation)SSC Journeyman (96 reputation)SSC Journeyman (96 reputation)SSC Journeyman (96 reputation)SSC Journeyman (96 reputation)SSC Journeyman (96 reputation)SSC Journeyman (96 reputation)SSC Journeyman (96 reputation)

Group: General Forum Members
Points: 96 Visits: 150
Nigel/Wildh,

In my original post (768063), I convert the result to style 101 (mm/dd/yyyy), so it doesn't matter if @dt has a time or not.


DECLARE @dt datetime
SET @dt = GetDate()
-- Change to first of the month
SET @dt = DATEADD(d,1-DAY(@dt),@dt)
IF DATEPART(dw,@dt) <> 7
-- If not already Saturday, add a day until it is Saturday
WHILE DATEPART(dw, @dt) <> 7
SET @dt = DATEADD(d,1,@dt)
PRINT CONVERT(nvarchar(30), @dt, 101)



David
nigel.
nigel.
Ten Centuries
Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)

Group: General Forum Members
Points: 1333 Visits: 2823
publicdh-tech (8/12/2009)
Nigel/Wildh,

In my original post (768063), I convert the result to style 101 (mm/dd/yyyy), so it doesn't matter if @dt has a time or not.

David


David,

That is true in your example. I think, however, Wildh was talking more generally about that method of finding the first of the month.

In many cases it may not matter at all that the time component is present, but there will be some when it does - (Sods Law). :-)

Nigel

--
Nigel
Useful Links:
How to post data/code on a forum to get the best help
The "Numbers" or "Tally" Table - Jeff Moden

DavidH-768896
DavidH-768896
SSC Journeyman
SSC Journeyman (96 reputation)SSC Journeyman (96 reputation)SSC Journeyman (96 reputation)SSC Journeyman (96 reputation)SSC Journeyman (96 reputation)SSC Journeyman (96 reputation)SSC Journeyman (96 reputation)SSC Journeyman (96 reputation)

Group: General Forum Members
Points: 96 Visits: 150
Optimally, in SQL 2008, we would declare @dt as a date type instead of datetime and there would be no time issue. Then we would remove the CONVERT from the PRINT statement and the result would be a true date type instead of varchar.
gerald.drouin
gerald.drouin
SSC-Enthusiastic
SSC-Enthusiastic (176 reputation)SSC-Enthusiastic (176 reputation)SSC-Enthusiastic (176 reputation)SSC-Enthusiastic (176 reputation)SSC-Enthusiastic (176 reputation)SSC-Enthusiastic (176 reputation)SSC-Enthusiastic (176 reputation)SSC-Enthusiastic (176 reputation)

Group: General Forum Members
Points: 176 Visits: 283
declare @DayToFind tinyint, @AnyDayInAMonth datetime
select @DayToFind = 1, --Monday
@AnyDayInAMonth = '2009-04-15' --Target month

select dateadd(day, (datepart(d, @AnyDayInAMonth) - datepart(dw, @AnyDayInAMonth) - @@datefirst + @DayToFind) % 7, dateadd(day, 1-datepart(d, @AnyDayInAMonth), @AnyDayInAMonth))


Seems like a nice single-select statement to me.
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