Written by Allen Wyatt (last updated October 14, 2024)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and 2021
In Mani's country government employees retire on the last day of March following the day they turn 55 years old. (If they turn 55 on March 31, they retire that same day.) Given the employee's date of birth, Mani can figure out when they turn 55, but he can't figure out how to calculate the following March 31.
There are many ways you can go about calculating the March 31 after a person turns 55. The one thing that all the formulas have in common, however, is that they must somehow figure out if a person's birthday is before April 1 or not. (They could also figure out whether the birthday is before or on March 31, but the calculation is actually easier if you compare to April 1.)
Assuming the individual's birth date is in cell A1, here is one formula you could use:
=IF(DATE(YEAR(A1)+55,MONTH(A1),DAY(A1))<DATE(YEAR(A1)+55,4,1), DATE(YEAR(A1)+55,3,31),DATE(YEAR(A1)+56,3,31))
This compares the date the person turns 55 with the date of April 1 in the year he or she turns 55. If the date is before April 1, then March 31 of the year he or she turns 55 is used. If the date is later, then March 31 of the following year is used.
This could easily be shortened a bit by simply comparing the birth date to April 1 of that year, in the following manner:
=IF(A1<DATE(YEAR(A1),4,1),DATE(YEAR(A1)+55,3,31),DATE(YEAR(A1)+56,3,31))
Of course, you could shorten it even more by simply looking at the month in which the birthday occurs:
=IF(MONTH(A1)<4,DATE(YEAR(A1)+55,3,31),DATE(YEAR(A1)+56,3,31))
Another logical step in trying to shorten the formula even further is to do the comparison on the month within the DATE function itself, in this manner:
=DATE(YEAR(A1)+IF(MONTH(A1)<4,55,56),3,31)
You can shorten the formula even further by getting rid of the IF statement completely:
=DATE(YEAR(A1)+55+(MONTH(A1)>3),3,31)
This formula works because the comparison (MONTH(A1)>3) returns either 0 or 1 depending on whether it is false or true.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (9776) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and 2021. You can find a version of this tip for the older menu interface of Excel here: Calculating a Group Retirement Date.
Dive Deep into Macros! Make Excel do things you thought were impossible, discover techniques you won't find anywhere else, and create powerful automated reports. Bill Jelen and Tracy Syrstad help you instantly visualize information to make it actionable. You’ll find step-by-step instructions, real-world case studies, and 50 workbooks packed with examples and solutions. Check out Microsoft Excel 2019 VBA and Macros today!
How do you display a number of years, such as 3.67 years, as a number of years and months? It’s simple to do with a ...
Discover MoreGiven a starting date and an ending date, you may want to generate the names of all the months between those two dates. ...
Discover MoreThe NETWORKDAYS worksheet function can be used to easily determine the number of work days (Monday through Friday) within ...
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 © 2025 Sharon Parq Associates, Inc.
Comments