Please Note: This article is written for users of the following Microsoft Excel versions: 97, 2000, 2002, and 2003. If you are using a later version (Excel 2007 or later), this tip may not work for you. For a version of this tip written specifically for later versions of Excel, click here: Calculating a Group Retirement Date.
Written by Allen Wyatt (last updated September 24, 2022)
This tip applies to Excel 97, 2000, 2002, and 2003
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 (9775) 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: Calculating a Group Retirement Date.
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!
If you use Excel to maintain a collection of data, you may need to find information in one column based on information in ...
Discover MoreWhen you have a huge amount of daily data to analyze, you may want to calculate an average of values for any given date ...
Discover MoreSome industries (such as the military) have special formatting that they use to represent dates. Here is one such format ...
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 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 © 2024 Sharon Parq Associates, Inc.
Comments