LinkBack Thread Tools Search this Thread Display Modes
Prev Previous Post   Next Post Next
  #6   Report Post  
Ron Rosenfeld
 
Posts: n/a
Default NETWORKDAYS question

On Fri, 4 Nov 2005 11:38:02 -0800, "Seymour"
wrote:

Does NETWORKDAYS work with arrays?

The third column uses NETWOKDAYS(Q3,P3). The fourth column uses the ranges
(either as named ranges or Q3:Q6, P3:P6) and the array command
(Ctrl+Shift+Enter). I cannot get any permutation of the fourth column to
work and I suspect NETWORKDAYS does not work with arrays. Please, someone
tell me I'm wrong!

5/10/2005 5/12/2005 3 #VALUE!
4/28/2005 6/10/2005 32 #VALUE!
4/25/2005 6/15/2005 38 #VALUE!
4/8/2005 8/8/2005 87 #VALUE!




I don't believe NETWORKDAYS will accept arrays as arguments for start_date or
end_date; nor will it output arrays as a result.

However, you can use this VBA routine which will take the arrays and feed them
"one at a time" to the networkdays function, and then output the result as an
array. You can then "AVERAGE" or "SUM" the result.

Naming your ranges StartDates and EndDates, the formula:

=AVERAGE(NWDarray(StartDates,EndDates)) will return 40

To use this, you must enter VBA code and also set a Reference.

1. <alt-F11 opens the VB Editor.
2. Ensure your project is highlighted in the Project Explorer window, then
Insert/Module and paste the code below into the window that opens.
4. On the top menu bar, select Tools/References and check atpvbaen.xls (this
is the Analysis Tool Pak.

Now you can use formulas like the above to work on arrays.

Note that the way this UDF is written, StartDate and EndDate must be in single
column ranges. I did not write to handle array constants, or ranges set out in
rows, although it could certainly be modified to do so, if that is a
requirement.

The Holidays argument can be used, optionally.

==================================
Option Explicit

Function NWDArray(StartDate As Range, EndDate As Range, Optional Holidays As
Range)
Dim i As Long
Dim Temp()

'List of start and end dates must be entered in arrays of _
one column each

If StartDate.Count < EndDate.Count Or _
StartDate.Columns.Count < 1 Or _
EndDate.Columns.Count < 1 Then
NWDArray = CVErr(xlErrValue)
End If

If Holidays Is Nothing Then
For i = 1 To StartDate.Count
If i StartDate.Count Then Exit For
ReDim Preserve Temp(i - 1)
Temp(UBound(Temp)) = networkdays(StartDate.Cells(i, 1),
EndDate.Cells(i, 1))
Next i
Else
For i = 1 To StartDate.Count
If i StartDate.Count Then Exit For
ReDim Preserve Temp(i - 1)
Temp(UBound(Temp)) = networkdays(StartDate.Cells(i, 1),
EndDate.Cells(i, 1), Holidays)
Next i
End If

NWDArray = Temp
End Function
===================================


--ron
 
Thread Tools Search this Thread
Search this Thread:

Advanced Search
Display Modes

Posting Rules

Smilies are On
[IMG] code is On
HTML code is Off
Trackbacks are On
Pingbacks are On
Refbacks are On


Similar Threads
Thread Thread Starter Forum Replies Last Post
Follow-Up (Clarification) to MIN question Odawg Excel Discussion (Misc queries) 4 October 20th 05 04:04 AM
Benefits many people - Question ebgehringer Excel Discussion (Misc queries) 0 October 7th 05 09:22 PM
How do I find and replace a question mark in Excel? Ranpalandil Excel Discussion (Misc queries) 1 September 7th 05 10:20 PM
Hints And Tips For New Posters In The Excel Newsgroups Gary Brown Excel Worksheet Functions 0 April 15th 05 05:47 PM
An easy macro question and one I believe to be a little more diffi TroutKing Excel Worksheet Functions 3 January 18th 05 09:17 PM


All times are GMT +1. The time now is 03:09 AM.

Powered by vBulletin® Copyright ©2000 - 2025, Jelsoft Enterprises Ltd.
Copyright ©2004-2025 ExcelBanter.
The comments are property of their posters.
 

About Us

"It's about Microsoft Excel"