October 13, 2005 at 1:03 pm
Comments posted to this topic are about the content posted at http://www.sqlservercentral.com/columnists/rScholl/findingthenextbusinessdayrecursively.asp
November 3, 2005 at 12:40 am
I have to quibble a bit on the definition of recursion and the article provides a hint to support this.
"Way back when", recursion was taught as "a function which calls itself with parameters|data|whatever in a simpler version of themselves [compared to what was passed in]. Eventually, you will reach a base or termination case which will cause the recursion to unravel itself and provide a solution.
November 3, 2005 at 12:56 am
Rob,
for some reason your function didn't work for me. I changed it a bit to get it working here and changed basically two things:
1) As we are using recursion there is no need for an explicit loop inside the function. The iteration is done using the consecutive calls to the function.
2) I get rid of the HH:MM:SS of the startDate in order to compare with the dates on the Holiday table. Otherwise the comparison would be like '2005-11-07 16:41:03' = '2005-11-07 00:00:00', which would evaluate to FALSE.
Below is the code with the changes.
Cheers,
Andre
create function fnGetNextBusinessDay (@startDate smalldatetime)
returns smalldatetime as
Begin
Declare @nextBusDay smalldatetime
Declare @weekDay tinyInt
set @nextBusDay = convert(datetime,left(convert(varchar,@startDate + 1,120),10),120) -- first get the raw next day
SET @weekDay =((@@dateFirst+datePart(dw,@nextBusDay)-2) % 7) + 1
if @weekDay in (6, 7) or exists (select 1 from holiday where holidayDate = @nextBusDay)
set @nextBusDay = dbo.fnGetNextBusinessDay(@nextBusDay)
return (@nextBusDay)
End
November 3, 2005 at 2:13 am
Hi Rob,
While the function uses some nifty tricks (I particularly like the trick to get correct results regardless of datefirst setting; this is a new trick for me), I'd never recommend using this function to anyone.
There are other ways to achieve this. Ways that are, in my opinion, better. Check out http://www.aspfaq.com/show.asp?id=2519, and especially the section titled "Pre-determine delivery dates".
Best, Hugo
November 3, 2005 at 3:07 am
Elegant solution (I too like the trick to get the correct day regardless of datefirst! Clever!). BUT... recursion in SQL is limited to 32 calls (XMAS holidays in schools, for example, go a lot longer than this) - it could easily have been done with a simple loop, or better yet, a simple select statement...
In our software where we have to keep track of days a clinic is open for business, rather than messing around with such procedures, we just have a dates table with one value for each day and a bit flag representing opened or closed... Makes reporting VERY easy and you can join to the table easily to group days together efficiently, etc. For similar ideas and more info on why just storing the data in a table can be efficient, look up "numbers table" on this site - Adam Machanic has quite a bit written about them.
But I still like that modulus trick!!
November 3, 2005 at 3:22 am
Cute, but I agree with Ian, if you are using a table why not maintain the correct dates in the table, it is MUCH easier to work with.
I did not know the 32 levels of recursion limitation, thanks
November 3, 2005 at 5:38 am
One thing to note.
@@Datefirst is affected by things like the defaultlanguage property of your language.
I believe that for the US @@Datefirst defaults to 7, whereas if you set up your login to use British English, as we brits often do, it will be 1.
This will affect what Datepart(weekday, getdate()) returns.
Just something to be aware of, I've had problems with this before.
November 3, 2005 at 5:50 am
Paul Cresham posted an elegant solution for this including working out holidays on the fly, albeit for the UK. It did contain a nifty Easter algorithm, as well as tackling the @@DATEFIRST problem. see
http://www.sqlservercentral.com/forums/shwmessage.aspx?forumid=23&messageid=110259
I documented it with an example of how we use it at
http://glossopian.co.uk/pmwiki.php?n=Main.WorkingDays
Dave Jackson
November 3, 2005 at 9:14 am
Here's another version of the Easter Calculation algorithm:
http://sqlservercentral.com/cs/blogs/michael_coles/archive/2005/07/16/49.aspx
And something for calculating "floating" American holidays:
http://sqlservercentral.com/cs/blogs/michael_coles/archive/2005/07/17/52.aspx
November 3, 2005 at 9:32 am
Rob- I like this example. It will work for our business because we don't take long holidays
Thanks, Matt
Matt Dolan
November 4, 2005 at 7:05 am
Here's another function that takes a simpler approach. If you are maintaining a holiday table, it would be simple enough to check the return value against it as well.
John
CREATE FUNCTION dbo.udf_GetNextBizDay (@dDateValue DATETIME)
RETURNS Datetime
AS
---------------------------------------------------------------------------------
--
-- Modification History:
--
-- Date Version Programmer Comments
-- ------------------ ------- ---------- ----------------------------
-- 2005-06-13 02:23:00 1.0 John McLaughlin
--
--
BEGIN
DECLARE @dReturnDate DATETIME
IF ISDATE(@dDateValue)=0
BEGIN
RETURN NULL
END
SET @dReturnDate = DATEADD(d,1,@dDateValue)
--Set to zero hour. Uncomment if needed.
--SET @dReturnDate = CAST(CONVERT(CHAR(10),@dReturnDate,101) AS DATETIME)
WHILE DATEPART(dw,@dReturnDate) in(1,7)
BEGIN
SET @dReturnDate = DATEADD(d,1,@dReturnDate)
END
RETURN @dReturnDate
END
November 3, 2006 at 9:34 am
I like the trick for handling the DATEFIRST. With it, you can write the function in 3 lines without recursion, which I think is a bit more elegant.
CREATE FUNCTION dbo.fnGetNextBusinessDay (@Date datetime) RETURNS datetime AS
BEGIN
SET @Date = DATEADD(dd, 1, CONVERT(datetime, (CONVERT(CHAR(10), @Date, 101))))
WHILE ((@@DATEFIRST + DATEPART(dw, @Date) - 1) % 7) + 1 IN (1, 7) OR @Date IN (SELECT HolidayDate FROM Holiday) SET @Date = DATEADD(dd, 1, @Date)
RETURN @Date
END
November 3, 2006 at 9:58 am
Hey Joe, don't you feel like you are talking for nothing sometimes???
Guys, Joe literally wrote the book on SQL, he wrote the ISO standards for SQL. I would strongly suggest you listen to him on this one... and basically any other post he makes .
Even if it seems like overkill this time, and the next time and the time after that. Won't you wish you had taken the time to write one when you decid to implement it the nth time... and then decid to make that the business rule to implement overall once you see the benefits??
November 9, 2006 at 5:57 pm
November 10, 2006 at 1:15 am
Hi Trigger,
The @numDays parameter is the number of business days to move forward in time.
To get 2006-12-27, you should have used:
SET @Date = dbo.fnGetNextBusinessDay ('2006-12-24', 1)
to get the "first" next business day. Your use of:
SET @Date = dbo.fnGetNextBusinessDay ('2006-12-24', 10)
should get the 10th next business day.
Viewing 15 posts - 1 through 15 (of 23 total)
You must be logged in to reply to this topic. Login to reply