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.

Weekdays in a Month

Written by Allen Wyatt (last updated July 23, 2022)
This tip applies to Excel 97, 2000, 2002, and 2003


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.

=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. 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:

=SUM(IF(WEEKDAY(DATE(C2, D2, ROW(INDIRECT("1:" &
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.)

=IF(MONTH(DATE(YEAR(A1),MONTH(A1),1)-WEEKDAY(DATE(YEAR(A1),MONTH(A1),1)-E2)+35)=MONTH(A1),5,4)

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
    Loop
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 (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.

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

Short-Lived Book1

If you have a problem that crops up when you first start Excel, it can be a bear to track down the cause of the problem. ...

Discover More

Conditionally Formatting Non-Integers

The conditional formatting capabilities of Excel are very helpful when you want to call attention to different values ...

Discover More

ExcelTips: Amazing Array Formulas (Table of Contents)

Array formulas allow you to accomplish amazing things with your data, including things you cannot do with regular ...

Discover More

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!

More ExcelTips (menu)

Calculating Business Days

There are calendar days and then there are business days. Excel provides the NETWORKDAYS function that is helpful to ...

Discover More

Using the EOMONTH Function

If you need to determine the date of the last day in a month, it's hard to beat the flexibility of the EOMONTH function. ...

Discover More

The EDATE Function

Want to figure a date a certain number of months in the future or past? The EDATE function may be just what you need for ...

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 0 + 7?

There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)


This Site

Got a version of Excel that uses the menu interface (Excel 97, Excel 2000, Excel 2002, or Excel 2003)? This site is for you! If you use a later version of Excel, visit our ExcelTips site focusing on the ribbon 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.