Written by Allen Wyatt (last updated April 20, 2024)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021
In the United States, the fourth Thursday of November is Thanksgiving, a federal holiday. Thomas wonders if there is a formula he can use to return the date of Thanksgiving for the next five occurrences based on today's date? In other words, if today's date is before Thanksgiving, then the generated dates would include this year's holiday. If today's date is after Thanksgiving, then this year's holiday would not be included because it is already past.
Getting the desired results using a single formula can be challenging. An easier way is to break the task into parts and thereby accomplish the results. For instance, you could place this formula into cell A1:
=YEAR(TODAY())+(TODAY()>DATE(YEAR(TODAY()),11,1+((4-(5>=WEEKDAY(DATE(YEAR(TODAY()),11,1))))*7)+(5-WEEKDAY(DATE(YEAR(TODAY()),11,1)))))
All it does is figure out the "current year" based on whether the current date is before or after this year's Thanksgiving date. If the current year is 2024, then that is what the formula returns unless today's date is after Thanksgiving. In that case, the formula returns 2025.
The formula, as you can tell, is a bit long. If you are using Excel 2021 or the Excel in Microsoft 365, you could shorten it a bit using the LET function to define repetitive elements of the formula, in this manner:
=LET(a,YEAR(TODAY()),b,DATE(a,11,1),c,WEEKDAY(b),a+(TODAY()>b+(4-(5>=c)*7)+(5-c)))
Once this initial year is determined, then you can in cell A2 enter a very simple formula:
=A1+1
Copy this formula down for as many cells as desired, and you have your range of years. Now you can calculate Thanksgiving for each of those years by using either of the following formulas:
=DATE(A1,11,29)-WEEKDAY(DATE(A1,11,3)) =DATE(A1,11,22)+CHOOSE(WEEKDAY(DATE(A1,11,1)),4,3,2,1,,6,5)
Whichever formula you use, copy it down for however many cells there are in your range of years, and you'll have all the Thanksgiving dates you want.
If you want to have a single formula return the five Thanksgiving dates, then the only way you can do it is with a user-defined function. Here are two macros that you can use for this purpose:
Function SingleThanks(Year As Integer) As Date 'Return the date of Thanksgiving for Year, where Year > 1899. Dim Nov1 As Date Nov1 = DateSerial(Year, 11, 1) SingleThanks = Nov1 - Day(Nov1) + 29 - Weekday(Nov1 - Day(Nov1) + 3) End Function
Function Next5Thanks() As Date() Dim Next5(0 To 4) As Date Dim Year1 As Integer Dim n As Integer Year1 = Year(Date) 'today's year If Date > SingleThanks(Year1) Then Year1 = Year1 + 1 For n = 0 To 4 Next5(n) = SingleThanks(Year1 + n) Next n Next5Thanks = Next5 End Function
You could use the SingleThanks function to return the date for a single Thanksgiving in this manner:
=SingleThanks("2024")
However, if you want to get five years' worth of dates, then you don't need to pass a value to the function:
=Next5Thanks()
What is returned is an array of five values. If you are using Excel 2019, 2021, or Excel in Microsoft 365, the values will spill into five horizontal cells.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (13917) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021.
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!
Need to know how many days there are between two dates? It's easy to figure out—unless you need the figure in ...
Discover MoreWhen doing data entry into a worksheet, you might want to enter dates without the need to type the separators that are ...
Discover MoreCalculating a retirement date can be as simple as doing some date math to see when a person reaches a certain age. ...
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