Written by Allen Wyatt (last updated June 27, 2023)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
Ernest needs either a formula or a macro to first determine the Nth Sunday of the year (let's say the 23rd Sunday of the year) and then return the name of the month in which that Sunday occurs. He's at a loss as to how such a formula or macro would be constructed.
This task could be accomplished with a macro, but it is very easy to accomplish with a formula, so we'll go with that route. Since Excel uses serial numbers for dates, it makes it very easy to do the math necessary to figure out such things as the Nth Sunday.
The trick to figuring out the proper formula is to figure out the last Sunday of the previous year. (Yes, the last Sunday.) This can be done in any number of ways, but here is a good method, assuming that the four-digit year you want is stored in cell A1:
=DATE(A1,1,1)-WEEKDAY(DATE(A1,1,1)-1)
This works because the WEEKDAY function, by default, returns a value of 1 through 7 (Sunday through Saturday). Let's say, for instance, that the year in A1 is 2019. This means that WEEKDAY will return the value 3 for January 1, 2019, meaning that it falls on a Tuesday. Subtract 1 from that, giving you 2, which you then subtract from the actual date for January 1. The result is the date of the last Sunday in 2018, which is December 30.
With that date in hand, all you need to do is to multiply the number of the Sunday desired (let's say that is in cell B1) by 7. Add it to the date calculated above, and you have the date of the Nth Sunday in the desired year:
=(DATE(A1,1,1)-WEEKDAY(DATE(A1,1,1)-1))+(B1*7)
At this point you have two options. One is that you can apply a custom format to the cell in which the above formula is located. Using a custom format of "mmmm" will show the result as a full month name. I tend to prefer the alternative option, which is to wrap the entire formula in the TEXT function, in this manner:
=TEXT((DATE(A1,1,1)-WEEKDAY(DATE(A1,1,1)-1))+(B1*7), "mmmm")
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (1564) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365.
Program Successfully in Excel! John Walkenbach's name is synonymous with excellence in deciphering complex technical topics. With this comprehensive guide, "Mr. Spreadsheet" shows how to maximize your Excel experience using professional spreadsheet application development tips from his own personal bookshelf. Check out Excel 2013 Power Programming with VBA today!
It is no secret that Excel allows you to work with dates in your worksheets. Getting your information into a format that ...
Discover MoreSometimes it is handy to know how many days are left in the current year. This tip provides a quick formula that ...
Discover MoreExcel can easily store dates. If you want to increment a date by one month, there are a number of ways you can accomplish ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2018-09-04 04:33:12
Ivan
Alex, many thanks for the explanation.
2018-09-04 02:58:58
Alex B
@Ivan, it seems be just a coincidence. You have 2019 in Cell A1. Date(2019,1,1) is Tuesday 01/01/2019 which is week day 3.
Internally Excel stores dates as a number and 01/01/2019 is represented by 43466.
When you omit the Date function, excel is now taking the 2019 as being the numeric representation of the date and translates it as being 11/07/1905. This also happens to be a Tuesday. This is why you are getting a 3 in both instances.
There are a number of years for which this just happens to be the case (including the years 2017-2020). Pick years outside of that range and you will find your weekday formula with and without the date function will differ.
2018-09-03 05:43:54
Ivan
Hi. I am new to this. I tested this formula =DATE(A1,1,1)-WEEKDAY(DATE(A1,1,1)-1), but I omitted Date function and used WEEKDAY(A1)-1. The formula resulted in 12/28/2018, though both =WEEKDAY(DATE(A1,1,1)) and =WEEKDAY(A1) return 3 when tested separately. Can someone exlpain why please.
2018-09-01 09:38:32
Brian
Very clever & efficient approach! Thanks for the tip.
2018-09-01 08:34:39
Alex B
If you set the Weekday return type to 2 for Mon =1 through to Sun =7, you get a slightly shorter formula.
=DATE(A1,1,1+7*B1-WEEKDAY(DATE(A1,1,1),2))
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 © 2023 Sharon Parq Associates, Inc.
Comments