Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, 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: Tombstone Date Math.
Written by Allen Wyatt (last updated March 18, 2023)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021
Robert loves to work on genealogy. Sometimes when he finds an older cemetery, instead of the birth and death dates being visible on a tombstone, just one date is visible and an age. For example, "born: Jan 18, 1801, died 81 yrs, 11 mths, 17 days" or "age: 93 yrs, 8 mths, 22 days, died March 18, 1901." Robert is wondering if there is any way to calculate the missing date to the day.
There is a way to do this, but it doesn't involve the use of regular worksheet functions. While Excel includes a rich assortment of worksheet functions that allow you to manipulate dates, the "basis date" for Excel is January 1, 1900; this is the date from which all dates are calculated. (You can change the basis date, but only by four years, to 1904. This capability is provided for compatibility with Excel on the Mac.) This means that older dates—such as those you would find in the cemetery for genealogy purposes—can't be directly calculated in Excel.
Fortunately, VBA doesn't have this limitation. This means that you can easily create a user-defined function (a macro) that will do the math for you. Start by placing the starting date (either birth or death date) in cell B1. Then, in cells B2:B4 enter the number of years, months, and days by which you want to adjust the starting date. Thus, if B1 contains a birth date, then cells B2:B4 should be positive (you want to add them to the starting date). If B1 contains a death date, then B2:B4 should be negative (you want to subtract them from the starting date).
Then, create this macro:
Function FindDate(Start As Date, iYrs As Integer, _ iMths As Integer, iDays As Integer) Application.Volatile Dim D As Date D = DateAdd("yyyy", iYrs, Start) D = DateAdd("m", iMths, D) D = DateAdd("d", iDays, D) FindDate = Format(D, "m/d/yyyy") End Function
In whatever cell you want to display the calculated date you can enter the following formula:
=FindDate(B1,B2,B3,B4)
The result of the function is a formatted date that represents the start date adjusted by the years, months, and days you specify. So if cell B1 contains 1/18/1801, cell B2 contains 81, cell B3 contains 11, and cell B4 contains 17, then the function will return 1/4/1883. Similarly, if cell B1 contains 3/18/1901, cell B2 contains -93, cell B3 contains -8, and cell B4 contains -22, then the result returned will be 6/26/1807.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (12277) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. You can find a version of this tip for the older menu interface of Excel here: Tombstone Date Math.
Excel Smarts for Beginners! Featuring the friendly and trusted For Dummies style, this popular guide shows beginners how to get up and running with Excel while also helping more experienced users get comfortable with the newest features. Check out Excel 2013 For Dummies today!
The NETWORKDAYS worksheet function can be used to easily determine the number of work days (Monday through Friday) within ...
Discover MoreEveryone seems to determine the difference between dates differently. Nicole has a need to calculate contact weeks (the ...
Discover MoreExcel includes a large number of functions that can be used in evaluating the data in a worksheet. In this tip you learn ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2023-03-19 01:37:13
Alex Blakenburg
@J. Woolley - Thanks for posting that.
I had someone ask me about archaeology timelines which go even further back.
2023-03-18 14:23:51
J. Woolley
For extended Date functions (01/01/0100 to 12/31/9999) see Chapter 8 of J. Walkenbach, Excel 2013 Power Programming with VBA Examples, which is available by clicking Download at the bottom of this web page:
https://www.wiley.com/en-us/Excel+2013+Power+Programming+with+VBA-p-9781118490402
These functions include XDATE, XDATEADD, XDATEDIF, XDATEYEARDIF, XDATEYEAR, XDATEMONTH, XDATEDAY, and XDATEDOW.
2023-03-18 11:04:40
Brian Lair
Great tip! I too like to “do genealogy”, and this will come in handy! I always assumed Excel’s 1900 basis date applied to VBA, too, and never even tried to use macros to process old-timey dates. Note I know better!
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