How to use the NETWORKDAYS.INTL function
What is the NETWORKDAYS.INTL function?
The NETWORKDAYS.INTL function calculate the number of working days between two dates, excluding weekends. It also allows you to ignore a list of holiday dates that you can specify. You may specify which days are weekend days.
What is the difference between the NETWORKDAYS.INTL function and the NETWORKDAYS function?
Related functions
Excel Function | Description |
---|---|
NETWORKDAYS.INTL(start_date, end_date, weekend) | Returns the number of workdays between two dates, excluding custom weekend parameters |
NETWORKDAYS(start_date, end_date) | Returns the number of workdays between two dates, excluding weekends |
WORKDAY(start_date, days) | Returns a date adjusted by a number of workdays, excluding weekends |
DATEDIF(start_date, end_date, unit) | Calculates the time between two dates in specified units like years, months, days |
DAYS(end_date, start_date) | Returns the number of days between two specified dates |
1. NETWORKDAYS.INTL Syntax
NETWORKDAYS.INTL(start_date, end_date, [weekend], [holidays])
2. NETWORKDAYS.INTL Arguments
start_date | Required. |
end_date | Required. |
[weekend] | Optional. Allows you to specify which days are weekend days using a number o a string. |
[holidays] | Optional. Excludes date(s) from being counted. |
Weekend numbers
Number | Weekend days |
1 (default value) | Saturday, Sunday |
2 | Sunday, Monday |
3 | Monday, Tuesday |
4 | Tuesday, Wednesday |
5 | Wednesday, Thursday |
6 | Thursday, Friday |
7 | Friday, Saturday |
11 | Sunday only |
12 | Monday only |
13 | Tuesday only |
14 | Wednesday only |
15 | Thursday only |
16 | Friday only |
17 | Saturday only |
You may also specify weekend days using a string containing only 1 and 0 (zero).
- 1 - weekend
- 0 - workday
Example, 1110011 considers only Thursdays and Fridays as workdays, all other days in the week are weekend days.
3. NETWORKDAYS.INTL example
Formula in cell D3:
4. NETWORKDAYS.INTL example - count a specific weekday between two dates
NETWORKDAYS function returns the number of whole workdays between two dates, however the array formula I am going to demonstrate in this article counts, for example, Mondays or any weekday in a date range. Later in this article, I will show you how to exclude holidays.
Update! I recommend using the NETWORKDAYS.INTL function to count weekdays, it is a lot smaller and easier to work with.
Regular formula in cell D2:
Copy cell D2 and paste to cell range E2:J2. You need to change "1000000" to "0100000" in cell E2, in cell F2 change it to "0010000" and so on.
The text string "1000000" allows you to specify which days are weekdays and which are weekends. There are seven characters and they can be 1 or 0 (zero), 1 indicates it is to be counted and 0 not to be counted.
However, in this case, I am using the string to exclude specific days, I am not using it to define which days are weekends.
4.1 Exclude holidays
Update! You can use the NETWORKDAYS.INTL function to count weekdays and ignore holidays as well.
Formula in cell D7:
Array formula in cell D7 (old formula):
How to create an array formula
- Select cell D7.
- Paste array formula.
- Press and hold Ctrl + Shift.
- Press Enter.
How to copy array formula
- Copy cell D7.
- Select cell range E7:J7.
- Paste.
5. Count a specific weekday between two dates - alternative formula
Array formula in cell D2 (old formula):
How to create an array formula
- Select cell D2.
- Paste array formula.
- Press and hold Ctrl + Shift simultaneously.
- Press Enter.
- Release all keys.
How to copy array formula
- Copy cell D2.
- Select cell range E2:J2.
- Paste.
Explaining formula in cell D2
Step 1 - Create dates in the date range
$B$1+(ROW($A$1:INDEX($A$1:$A$1000, $B$2-($B$1-1)))-1)
becomes
41000+(ROW($A$1:INDEX($A$1:$A$1000, 41029-(41000-1)))-1)
becomes
41000+(ROW($A$1:INDEX($A$1:$A$1000, 41029-40999))-1)
becomes
41000+(ROW($A$1:INDEX($A$1:$A$1000, 41029-40999))-1)
becomes
41000+(ROW($A$1:INDEX($A$1:$A$1000, 30))-1)
becomes
41000+(ROW($A$1:$A$30)-1)
becomes
41000+({1, 2, 3, 4, 5, 6, 7, 8, 9, 10, 11, 12, 13, 14, 15, 16, 17, 18, 19, 20, 21, 22, 23, 24, 25, 26, 27, 28, 29, 30}-1)
becomes
41000+{0, 1, 2, 3, 4, 5, 6, 7, 8, 9, 10, 11, 12, 13, 14, 15, 16, 17, 18, 19, 20, 21, 22, 23, 24, 25, 26, 27, 28, 29}
and returns
{41000, 41001, 41002, 41003, 41004, 41005, 41006, 41007, 41008, 41009, 41010, 41011, 41012, 41013, 41014, 41015, 41016, 41017, 41018, 41019, 41020, 41021, 41022, 41023, 41024, 41025, 41026, 41027, 41028, 41029}
Step 2 - Convert dates to days of the week
TEXT($B$1+(ROW($A$1:INDEX($A$1:$A$1000, $B$2-($B$1-1)))-1), "ddd")
becomes
TEXT({41000, 41001, 41002, 41003, 41004, 41005, 41006, 41007, 41008, 41009, 41010, 41011, 41012, 41013, 41014, 41015, 41016, 41017, 41018, 41019, 41020, 41021, 41022, 41023, 41024, 41025, 41026, 41027, 41028, 41029}, "ddd")
and returns
{"Sun", "Mon", "Tue", "Wed", "Thu", "Fri", "Sat", "Sun", "Mon", "Tue", "Wed", "Thu", "Fri", "Sat", "Sun", "Mon", "Tue", "Wed", "Thu", "Fri", "Sat", "Sun", "Mon", "Tue", "Wed", "Thu", "Fri", "Sat", "Sun", "Mon"}
Step 3 - Check if values in array are equal to the value in cell D1 (Mon)
IF(TEXT($B$1+(ROW($A$1:INDEX($A$1:$A$1000, $B$2-($B$1-1)))-1), "ddd")=D1, 1, 0)
becomes
IF({"Sun", "Mon", "Tue", "Wed", "Thu", "Fri", "Sat", "Sun", "Mon", "Tue", "Wed", "Thu", "Fri", "Sat", "Sun", "Mon", "Tue", "Wed", "Thu", "Fri", "Sat", "Sun", "Mon", "Tue", "Wed", "Thu", "Fri", "Sat", "Sun", "Mon"}, "ddd")="Mon", 1, 0)
and returns
{0, 1, 0, 0, 0, 0, 0, 0, 1, 0, 0, 0, 0, 0, 0, 1, 0, 0, 0, 0, 0, 0, 1, 0, 0, 0, 0, 0, 0, 1}
Step 4 - Sum values in array
SUMPRODUCT(IF(TEXT($B$1+(ROW($A$1:INDEX($A$1:$A$1000, $B$2-($B$1-1)))-1), "ddd")=D1, 1, 0))
becomes
SUMPRODUCT({0, 1, 0, 0, 0, 0, 0, 0, 1, 0, 0, 0, 0, 0, 0, 1, 0, 0, 0, 0, 0, 0, 1, 0, 0, 0, 0, 0, 0, 1})
and returns 5 in cell D2.
'NETWORKDAYS.INTL' function examples
The following article has a formula that contains the NETWORKDAYS.INTL function.
NETWORKDAYS function returns the number of whole workdays between two dates, however the array formula I am going to demonstrate […]
Functions in 'Date and Time' category
The NETWORKDAYS.INTL function function is one of many functions in the 'Date and Time' category.
How to comment
How to add a formula to your comment
<code>Insert your formula here.</code>
Convert less than and larger than signs
Use html character entities instead of less than and larger than signs.
< becomes < and > becomes >
How to add VBA code to your comment
[vb 1="vbnet" language=","]
Put your VBA code here.
[/vb]
How to add a picture to your comment:
Upload picture to postimage.org or imgur
Paste image link to your comment.
Contact Oscar
You can contact me through this contact form