Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, and 2021. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Calculating a Group Retirement Date.

Calculating a Group Retirement Date

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.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Getting Rid of the Startup Spreadsheet

When you start Excel, you normally see a blank worksheet displayed. Here's how to get rid of it.

Discover More

Printing Document Properties

Word maintains quite a bit of information about a document in a special collection of items called "properties." You can ...

Discover More

Creating Labels

Using Word to create and print labels is a snap. All you need to do is provide the text you want on the labels, pick a ...

Discover More

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!

More ExcelTips (ribbon)

Tombstone Date Math

Doing math with dates is easy in Excel. Doing math with old dates, such as those you routinely encounter in genealogy, is ...

Discover More

Calculating Months for Billing Purposes

Different businesses have different ways to calculate elapsed time for billing purposes. Figuring out a formula that ...

Discover More

Pushing Dates Into Last Month

Excel is great when it comes to working with dates and times. You can even do math on dates. One such easy manipulation ...

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] (all 7 characters, in the sequence shown) in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is three less than 9?

There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)


This Site

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.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.