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:
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.
Professional Development Guidance! Four world-class developers offer start-to-finish guidance for building powerful, robust, and secure applications with Excel. The authors show how to consistently make the right design decisions and make the most of Excel's powerful features. Check out Professional Excel Development today!
There are calendar days and then there are business days. Excel provides the NETWORKDAYS function that is helpful to ...
Discover MoreExcel allows you to store times in a worksheet. If you want to use Excel to time certain events, there are a couple of ...
Discover MoreFor many Excel users—particularly beginners—working with elapsed time can be bewildering. This tip explains ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2014-08-19 14:09:52
Willy Vanhaelen
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 :-(
2014-08-18 11:34:04
Michael (Micky) Avidan
@Willy,
As for your second formula:
=4+(MONTH(A1-WEEKDAY(A1-E2)+35)=MONTH(A1))
How many THURSDAYs are in a month regarding the following dates (in European Format):
06/10/2014
04/01/2015
04/04/2015
Michael (Micky) Avidan
“Microsoft® Answers" - Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2015)
ISRAEL
2014-08-17 13:28:37
Willy Vanhaelen
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.
=IF(MONTH(DATE(YEAR(A$1),MONTH(A$1),1)+35-WEEKDAY(DATE(YEAR(A$1),MONTH(A$1),1)-ROW(A1)))=MONTH(A$1),5,4)
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
2014-08-17 13:25:38
Willy Vanhaelen
@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))
2014-08-16 05:11:17
Michael (Micky) Avidan
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:
=SUM(N(WEEKDAY(ROW(INDIRECT(A1&":"&EOMONTH(A1,0))))=E2))
Michael (Micky) Avidan
“Microsoft® Answers" - Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2015)
ISRAEL
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.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2022 Sharon Parq Associates, Inc.
Comments