Written by Allen Wyatt (last updated May 25, 2024)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021
Harold is trying to devise a formula that will tell him the last five years in which a particular date (say, May 10) occurred on a particular day of the week (say, Thursday).
There are a number of ways you can go about determining this information. One simple way is to, in a new worksheet, enter the date you want tested (such as 5/10/24) into cell A1. Just below that, in cell A2, enter a date a year earlier: 5/10/23. Select these two cells and drag the fill handle downward for however many cells desired, and you end up with a column containing the date May 10 on descending years. Next, in cell B1 enter the following formula:
=WEEKDAY(A1)
Copy this formula down for as many rows as you have dates in column A. This returns a value, 1 through 7, representing the day of the week for the dates in column A. Since 1=Sunday, 2=Monday, etc., that means that any value of 5 would represent a Thursday. Thus, you could place this formula into cell C1 and copy it down:
=IF(B1=5,YEAR(A1),"")
This "calls out" the years in which the date in column A is a Thursday. You could, if you prefer, simply forego adding column C and, instead, use filtering to show only those dates where the value in column B is 5 (Thursday).
You can also use a cool little formula to find the information you desire. First, select five cells in any column you'd like. Then, type the following in the Formula bar:
=LARGE((WEEKDAY(DATE(ROW(1924:2024),5,10))=5)*ROW(1924:2024),ROW(1:5))
If you are using an older version of Excel (2019 or earlier), you need to enter this as an array formula by pressing Ctrl+Shift+Enter. The result is that the five cells will contain the last five years in which May 10 was a Thursday. You could make the formula more versatile by replacing the key elements with named ranges, in this manner:
=LARGE((WEEKDAY(DATE(ROW(1924:2024),MO,DA))=DW)*ROW(1924:2024),ROW(1:5))
Now all you need to do is to create the named ranges MO (month), DA (day), and DW (day of week). As you change the values in these named ranges, the array formula updates the five cells to reflect the desired years.
A third way to find the information is to create a macro that asks for a starting date and a day of the week. The macro can then step backward a year at a time until it grabs five years that meet the criteria.
Sub CalcDates() Dim sTemp As String Dim dBegin As Date Dim dWork As Date Dim J As Integer Dim iDoW As Integer Dim iYears(5) As Integer sTemp = InputBox("Beginning Date?") dBegin = CDate(sTemp) If dBegin > 0 Then sTemp = InputBox("Day of Week?") sTemp = LCase(Trim(sTemp)) iDoW = 0 For J = 1 To 7 If sTemp = LCase(WeekdayName(J)) Then iDoW = J Next J If iDoW > 0 Then dWork = dBegin J = 0 While J < 5 If Weekday(dWork) = iDoW Then J = J + 1 iYears(J) = Year(dWork) End If dWork = DateAdd("yyyy", -1, dWork) Wend sTemp = "These are the previous five years in which " sTemp = sTemp & MonthName(Month(dBegin)) & " " & Day(dBegin) sTemp = sTemp & " falls on a " & WeekdayName(iDoW) & ":" sTemp = sTemp & vbCrLf & vbCrLf For J = 5 To 1 Step -1 sTemp = sTemp & iYears(J) & vbCrLf Next J MsgBox sTemp End If End If End Sub
When the macro finds the five years, it displays them in a message box.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (13529) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021.
Solve Real Business Problems Master business modeling and analysis techniques with Excel and transform data into bottom-line results. This hands-on, scenario-focused guide shows you how to use the latest Excel tools to integrate data from multiple tables. Check out Microsoft Excel 2013 Data Analysis and Business Modeling today!
When working with dates, it is often helpful to be able to calculate some date in the future based on a starting date. ...
Discover MoreWant to push a date to some pre-defined day of the month? Here are some ways to force the issue.
Discover MoreWhen working with dates in a worksheet, you may need to do some rather esoteric calculations on those dates. This tip ...
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 © 2024 Sharon Parq Associates, Inc.
Comments