Working out a future date with formulas

C

cufc1210

in cell A2 date, in cell B2 the amount of days i want to add (not including
sundays) i am using this formula

=IF(WEEKDAY(A7)=2,A7-1-WEEKDAY(A7-1,3)+INT(7/6*(B7+MIN(WEEKDAY(A7-1,3))))-1,A7-1-WEEKDAY(A7-1,3)+INT(7/6*(B7+MIN(WEEKDAY(A7-1,3)))))

which works fine but in cells H2:O2 i have dates (Bank Holidays etc) that i
dont want to be included when it works out the dats

E.g

start date 24/08/09 add 10 days finish date at the moment shows 03/09/09
which is correct but there is one bank holiday in there 28/09 so finish date
needs to show as 04/09

is there some thing I can add to the formula above to remove these dates

Cheers
 
M

Mike H

Hi,

Try this array formula. see below for array formula instructions. You must
create a named range called Holidays that contains your holiday dates

=A2+SIGN(B2)*SMALL(IF((WEEKDAY(A2+SIGN(B2)*(ROW(INDIRECT("1:"&ABS(B2)*10))))={2,3,4,5,6,7})
ISNA(MATCH(A2+SIGN(B2)*(ROW(INDIRECT("1:"&ABS(B2)*10))),Holidays,0)),ROW(INDIRECT("1:"&ABS(B2)*10))),ABS(B2))

This is an array formula which must be entered by pressing CTRL+Shift+Enter
'and not just Enter. If you do it correctly then Excel will put curly brackets
'around the formula {}. You can't type these yourself. If you edit the formula
'you must enter it again with CTRL+Shift+Enter.

As you will see this is a bit long winded so for some time I've been working
on a shorter version that I can't get into a single cell yet!! Here's how far
I've got so far

A1 =start date
A2 = =WORKDAY(A1,7,Holidays)
A3 = =A2-SUMPRODUCT(--(WEEKDAY(ROW(INDIRECT(A1&":"&A2)))=7))


Mike
 
J

Jacob Skaria

Just to add on to Mikes post..

If WORKDAY() function is not available, and returns the #NAME? error,
install and load the Analysis ToolPak add-in. From menu Tools>Add-Ins> check
'Analysis ToolPak' and hit OK

If this post helps click Yes
 

Ask a Question

Want to reply to this thread or ask your own question?

You'll need to choose a username for the site, which only take a couple of moments. After that, you can post your question and our members will help you out.

Ask a Question

Top