Written by Allen Wyatt (last updated January 21, 2023)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, 2021, and Excel in Microsoft 365
Sunil can use the NETWORKDAYS function to return the number of regular business days between two dates. The function assumes that Saturday and Sunday are not work days, but in Sunil's organization only Sunday counts as a non-work day. He wonders if there is a way to use NETWORKDAYS and specify that only Sunday should be excluded from the count returned.
You can determine this by using a formula based on the NETWORKDAYS function. Assuming that the starting date is in A1 and the ending date is in B1, the following formula examines the days between the two dates and essentially return a count of non-Sunday days in that range:
=NETWORKDAYS(A1,B1)+SUMPRODUCT(--(WEEKDAY (ROW(INDIRECT(A1&":"&B1)))=7))
Of course, since Sundays are the only day of the week being excluded, you could simply skip the use of NETWORKDAYS and use SUMPRODUCT to figure out if the day should be counted or not:
=SUMPRODUCT(--(WEEKDAY(ROW(INDIRECT(A1&":"&B1)))>1))
If you expect that there may be holidays in the range, and that those holidays are in the named range “holidays,” then you'll need to go back to using NETWORKDAYS in the formula:
=NETWORKDAYS(A1,B1,holidays)+SUMPRODUCT(-- (WEEKDAY(ROW(INDIRECT(A1&":"&B1)))=7),-- (NOT(ISNUMBER(MATCH(ROW(INDIRECT(A1&":"&B1)) ,holidays,0)))))
Of course, if you are using Excel 2010 or later, you can use the NETWORKDAYS.INTL function, which does more than the older NETWORKDAYS function. The biggest difference between the two is that NETWORKDAYS.INTL allows you to specify how the function should handle weekends. So, for instance, in Sunil's case where only Sundays should be considered "the weekend," you could use the following formula:
=NETWORKDAYS.INTL(A1,B1,11,Holidays)
Note that the only difference between this and full version of the NETWORKDAYS function is the inclusion of a new third parameter. In this case, the value 11 indicates that only Sundays should be considered weekends, but you could use any other the other parameter values, depending on your needs.
Number | Weekend Days | |
---|---|---|
1 | Saturday, Sunday | |
2 | Sunday, Monday | |
3 | Monday, Tuesday | |
4 | Tuesday, Wednesday | |
5 | Wednesday, Thursday | |
6 | Thursday, Friday | |
7 | Friday, Saturday | |
11 | Sunday | |
12 | Monday | |
13 | Tuesday | |
14 | Wednesday | |
15 | Thursday | |
16 | Friday | |
17 | Saturday |
You can perform other magic with NETWORKDAYS.INTL, as well, but that is best left to different ExcelTips.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (12450) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, 2021, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Specifying Different Weekends with NETWORKDAYS.
Save Time and Supercharge Excel! Automate virtually any routine task and save yourself hours, days, maybe even weeks. Then, learn how to make Excel do things you thought were simply impossible! Mastering advanced Excel macros has never been easier. Check out Excel 2010 VBA and Macros today!
If you use Excel to track information based on dates, you may wonder how to get a sum for only certain dates that you ...
Discover MoreNeed to print an elapsed date in a strange format? It's easier to do than may appear at first glance. Here's a discussion ...
Discover MoreThose in Europe use a date format that is different than those in the US; this is not news. But what if you need to ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2025 Sharon Parq Associates, Inc.
Comments