Excel.Tips.Net ExcelTips (Menu Interface)

Weekdays in a Month

Please Note: This article is written for users of the following Microsoft Excel versions: 97, 2000, 2002, and 2003. If you are using a later version (Excel 2007 or later), this tip may not work for you. For a version of this tip written specifically for later versions of Excel, click here: Weekdays in a Month.

Ever wonder how many of a particular weekday occur 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.


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. If you want a shorter formula, then you need to turn to an array formula. One handy formula you can use 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:

DAY(DATE(C2, D2+1, 0))))))=E2, 1, 0))

Remember that this is 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 approach—this one not relying on an array formula—is to test the date in cell A1 for whatever weekday is desired, as specified in E2. (Again, a value of 1 through 7, as in the previous example.)


The formula basically checks to see if there is a fifth instance in the month of whatever weekday you are checking. If there is, then the value 5 is returned; if not, then the value 4 is returned. (The formula rightly assumes that there can only be 4 or 5 instances of any given weekday—never less and never more.)

Macro-based solutions are also available. One such solution follows:

Function MonthWeekDays(dDate As Date, iWeekDay As Integer)
    Dim dLoop As Date
    If iWeekDay < 1 Or iWeekDay > 7 Then
        MonthWeekDays = CVErr(xlErrNum)
        Exit Function
    End If
    MonthWeekDays = 0
    dLoop = DateSerial(Year(dDate), Month(dDate), 1)
    Do While Month(dLoop) = Month(dDate)
        If WeekDay(dLoop) = iWeekDay Then _
            MonthWeekDays = MonthWeekDays + 1
        dLoop = dLoop + 1
End Function

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


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.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (2183) applies to Microsoft Excel 97, 2000, 2002, and 2003. You can find a version of this tip for the ribbon interface of Excel (Excel 2007 and later) here: Weekdays in a Month.

Related Tips:

Excel Smarts for Beginners! Featuring the friendly and trusted For Dummies style, this popular guide shows beginners how to get up and running with Excel while also helping more experienced users get comfortable with the newest features. Check out Excel 2013 For Dummies today!


Leave your own comment:

  Notify me about new comments ONLY FOR THIS TIP
Notify me about new comments ANYWHERE ON THIS SITE
Hide my email address
*What is 5+3 (To prevent automated submissions and spam.)
           Commenting Terms

Comments for this tip:

Willy Vanhaelen    19 Aug 2014, 14:09
Oops! I should have mentioned that for this formula the date in A1 has to be the first of the month (01/10/2014, 01/01/2015, 01/04/2015...). It's more than a year ago that I "played" with those formulas so I forgot about that :-(
Michael (Micky) Avidan    18 Aug 2014, 11:34
As for your second formula:
How many THURSDAYs are in a month regarding the following dates (in European Format):
Michael (Micky) Avidan
“Microsoft® Answers" - Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2015)
Willy Vanhaelen    17 Aug 2014, 13:28
When I looked at the first formula in this tip I thought, Leonardo da Vinci's saying "simplicity is the ultimate sophistication" in mind, there has to be a simpler solution. In fact all you have to do is check if a fifth instance of a particular day is still in the same month.


Note that this formula can be entered anywhere in the sheet and copied down 6 rows.

This same formula can even be used in the macro that becomes also much smaller:

Function MonthWeekDays(dDate As Date, iWeekDay As Integer)
    If iWeekDay < 1 Or iWeekDay > 7 Then
        MonthWeekDays = CVErr(xlErrNum)
        Exit Function
    End If
    dDate = DateSerial(Year(dDate), Month(dDate), 1)
    MonthWeekDays = IIf(Month(dDate + 35 - Weekday(dDate - iWeekDay)) = Month(dDate), 5, 4)
End Function
Willy Vanhaelen    17 Aug 2014, 13:25
@Micky, here are 2 shorter ones and they are even not array formulas:

1) =4+(MONTH(DATE(C2,D2,-WEEKDAY(DATE(C2,D2,1)-E2))+36)=D2)

2) =4+(MONTH(A1-WEEKDAY(A1-E2)+35)=MONTH(A1))
Michael (Micky) Avidan    16 Aug 2014, 05:11
1) There is no need for an IF check.
The Array Formula can look like:
=SUM(N(WEEKDAY(DATE(C2,D2, ROW(INDIRECT("1:" &DAY(DATE(C2,D2+1, 0))))))=E2))

2) If you provide a full date in cell A1 then the formula will look like:

Michael (Micky) Avidan
“Microsoft® Answers" - Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2015)

Our Company

Sharon Parq Associates, Inc.

About Tips.Net

Contact Us


Advertise with Us

Our Privacy Policy

Our Sites


Beauty and Style




DriveTips (Google Drive)

ExcelTips (Excel 97–2003)

ExcelTips (Excel 2007–2016)



Home Improvement

Money and Finances


Pests and Bugs

Pets and Animals

WindowsTips (Microsoft Windows)

WordTips (Word 97–2003)

WordTips (Word 2007–2016)

Our Products

Helpful E-books

Newsletter Archives


Excel Products

Word Products

Our Authors

Author Index

Write for Tips.Net

Copyright © 2016 Sharon Parq Associates, Inc.