Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Weekdays in a Month.

Weekdays in a Month

Written by Allen Wyatt (last updated July 6, 2024)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021


2

Ever wonder how many of a particular weekday occurs within a given month? For some people, it is important to know how many Tuesdays there are in a month. And who doesn't want to know whether a particular month will have four or five Saturdays?

Excel does not include an intrinsic function that you can use to determine the number of times a particular weekday occurs within a given month. You can, however, create your own formulas and functions to accomplish the task.

First, consider the following formula.

=4+N((WEEKDAY(DATE(YEAR($A$1),MONTH($A$1),1)))+
(DAY(DATE(YEAR($A$1),MONTH($A$1)+1,0))-28)>(7*((
WEEKDAY(DATE(YEAR($A$1),MONTH($A$1),1)))>(1+ROW()-
ROW($A$2)))+(1+ROW()-ROW($A$2))))

The formula relies on a date in A1. This date should be from the month you want "tested." The formula is meant to be copied into a cell in row 2, and then copied to the six cells directly beneath that. For instance, you could copy this formula to the range of cells B2:B8. The first response (B2) is the number of Sundays in the month, the second (B3) is the number of Mondays, and so on.

The drawback to this formula is that it uses the position of the cell containing the formula as part of the formula. This means that the formula must be placed somewhere beginning in the second row.

Another drawback is that the formula is quite long and complex. You can fashion a shorter formula, such as the following. It assumes that you provide three arguments: the year (cell C2), the month (cell D2), and a weekday (cell E2). With these three items, the following formula works great:

=SUM(IF(WEEKDAY(DATE(C2, D2, ROW(INDIRECT("1:" &
DAY(DATE(C2, D2+1, 0))))))=E2, 1, 0))

In the most recent versions of Excel, this will work fine. In older versions you'll need to enter the formula as an array formula, which means that you must enter it by pressing Shift+Ctrl+Enter. In addition, the weekday value you enter in cell E2 must be in the range of 1 through 7, where 1 is Sunday, 2 is Monday, etc.

Another great formula you can use is the following:

=NETWORKDAYS.INTL(DATE(YEAR(A1),MONTH(A1),1),EOMONTH(A1,0),
REPT("1",B1-1) & "0" & REPT("1",7-B1))

This generalized formula needs only two values to work properly. The first is a date that is within the month you want to analyze; this goes into cell A1. In cell B1 you should place an indicator of the weekday you want to count. This value is different than in the previous formula—while it must still be in the range of 1 to 7, 1 is Monday, 2 is Tuesday, etc.

If your worksheet design doesn't allow for you to enter the year, month, and weekday in different cells, a clean solution is to create a user-defined function to return the count. The following macro is an example of this type of function.

Function MonthWeekDays(dDate As Date, iWeekDay As Integer)
    Dim dDate2 As Date

    If iWeekDay < 1 Or iWeekDay > 7 Then
        MonthWeekDays = CVErr(xlErrNum)
        Exit Function
    End If

    dDate2 = DateSerial(Year(dDate), Month(dDate), 1)
    MonthWeekDays = (4 - (Month(dDate2 - _
      Weekday(dDate2 - iWeekDay) + 35) = Month(dDate2)))
End Function

You use the function by entering the following in a cell:

=MonthWeekDays(A1,4)

In this usage, the first argument (cell A1) contains a date in the month being evaluated. The second argument is a numeric value representing the weekday that you want to count. This value must be in the range of 1 to 7, where 1 is Sunday, 2 is Monday, and so on.

Note:

If you would like to know how to use the macros described on this page (or on any other page on the ExcelTips sites), I've prepared a special page that includes helpful information. Click here to open that special page in a new browser tab.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (5684) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. You can find a version of this tip for the older menu interface of Excel here: Weekdays in a Month.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Calculating Expressions

Word can do some simple calculations for you, if you add a little-known tool to your toolbar. Here's how to add and use ...

Discover More

Counting Dates in a Range

Excel makes working with a list of dates relatively easy. If you have a list of dates, you may need to know how many of ...

Discover More

Special Symbols Followed by a Non-Breaking Space

When you want to automatically insert a special sequence of characters in a document, there are two methods you can use. ...

Discover More

Comprehensive VBA Guide Visual Basic for Applications (VBA) is the language used for writing macros in all Office programs. This complete guide shows both professionals and novices how to master VBA in order to customize the entire Office suite for their needs. Check out Mastering VBA for Office 2010 today!

More ExcelTips (ribbon)

Using a Single Digit for a Year

Excel works very well with dates and times. One thing you cannot do, however, is to create a custom format that displays ...

Discover More

Determining If a Year is a Leap Year

Need to figure out if a given year is a leap year? It's not as easy as you think! This tip provides a plethora of ways ...

Discover More

Rounding to the Nearest Quarter Hour

When entering times in a worksheet, you may have a need to round whatever you enter to the nearest 15-minute increment. ...

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] (all 7 characters, in the sequence shown) in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is 8 + 7?

2024-07-07 16:05:29

J. Woolley

The Tip asks how many times a particular weekday occurs within a given month.
My Excel Toolbox includes the following function to return the date of the last weekday of a given month:
=LastWeekdayOfMonth(DayNbr, MonthNbr, YearNbr)
where DayNbr is 1 for Sun, 2 for Mon, ..., MonthNbr is 1 for Jan, 2 for Feb, ..., and YearNbr is a four digit year greater than 1899. For example, the last Sunday in December 2022 is
=LastWeekdayOfMonth(1, 12, 2022)
which is Christmas Day.
The following LET function formula (Excel 2021 or later) is equivalent to LastWeekdayOfMonth:

=LET(eom, EOMONTH(DATE(YearNbr, MonthNbr, 1), 0), eom+1-WEEKDAY(eom+1-DayNbr))

So the last Sunday in December 2022 is
=LET(eom, EOMONTH(DATE(2022, 12, 1), 0), eom+1-WEEKDAY(eom+1-1))
Combined with Gavin's formula from a previous version of this Tip, here is the number of times a particular DayNbr occurs within a given MonthNbr and YearNbr:
=CEILING(DAY(LastWeekdayOfMonth(DayNbr, MonthNbr, YearNbr))/7, 1)
And here is the equivalent formula using LET:

=LET(eom, EOMONTH(DATE(YearNbr, MonthNbr, 1), 0), CEILING(DAY(eom+1-WEEKDAY(eom+1-DayNbr))/7, 1))

So the number of Sundays in December 2022 is

=LET(eom, EOMONTH(DATE(2022, 12, 1), 0), CEILING(DAY(eom+1-WEEKDAY(eom+1-1))/7, 1))

The result is 4, which can be visualized {[fig]} using the following dynamic array function in My Excel Toolbox:
=ListCalendar(YearNum, MonthNum, NumMonths, SkipHeader, FirstDayOfWeek)
See https://sites.google.com/view/MyExcelToolbox/


2024-07-07 06:49:05

Mike J

Perhaps a little more intuitive if wishing to change which day of the week:

=SUMPRODUCT(N(TEXT(ROW(INDIRECT(DATE(YEAR(A1),MONTH(A1),1)&":"&EOMONTH(DATE(YEAR(A1),MONTH(A1),1),0))),"ddd")="Tue"))


This Site

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.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.