Date to age question

Rayrichard

New Member
Joined
Jan 20, 2014
Messages
4
Hi all
I am working on my family tree and thought I would create a spreadsheet that automatically updates the ages of all protagonists when the user opens the document. I have managed to achieve this successfully using the following formula:

=INT((H2-A2)/365)


excelissue1.jpg


The only issue I have is that the formula does not work for people born in the 1800 as you can see in the above image.

I have tried a number of other formulas with no success as yet.

I was hoping that there is a brain box out there who can solve this mystery for me or point me in the right direction.

Many thanks

Richard
 

Excel Facts

When did Power Query debut in Excel?
Although it was an add-in in Excel 2010 & Excel 2013, Power Query became a part of Excel in 2016, in Data, Get & Transform Data.
I have tried the following Formulas:

=INT((B2-A2)/365)

=DATEDIF(A2,NOW(),"y")

=ROUNDDOWN(YEARFRAC(A2, TODAY(), 1), 0)

=DATEDIF(A2,TODAY(),"Y") & " Years, " & DATEDIF(A2,TODAY(),"YM") & " Months, " & DATEDIF(A2,TODAY(),"MD") & " Days"


 
Upvote 0
A​
B​
C​
2​
01/01/1975​
43​
B2: =IFERROR(DATEDIF(A2, TODAY(), "y"), DATEDIF(LEFT(A2, 6) & 1900, TODAY(), "y") + 1900 - RIGHT(A2, 4))
3​
01/01/1943​
75​
4​
01/01/1902​
116​
5​
01/01/1868
150​
6​
01/01/1792
226​
7​
01/01/1492
526​
 
Upvote 0
Hi,
If you are updating their age of someone pre 1900, you can also include the date they passed away.

DoB in cell B2
Date passed away in cell C2
Age in cell D2 with this formua

Code:
=IF(ISBLANK(B2),"-",IF(ISBLANK(C2),"-",DATEDIF(IF(ISTEXT(B2),DATEVALUE(LEFT(B2,LEN(B2)-4)&RIGHT(B2,4)+1000),EDATE(B2,12000)),IF(ISTEXT(C2),DATEVALUE(LEFT(C2,LEN(C2)-4)&RIGHT(C2,4)+1000),EDATE(C2,12000)),"y")&" y "&DATEDIF(IF(ISTEXT(B2),DATEVALUE(LEFT(B2,LEN(B2)-4)&RIGHT(B2,4)+1000),EDATE(B2,12000)),IF(ISTEXT(C2),DATEVALUE(LEFT(C2,LEN(C2)-4)&RIGHT(C2,4)+1000),EDATE(C2,12000)),"ym") &" m " &DATEDIF(IF(ISTEXT(B2),DATEVALUE(LEFT(B2,LEN(B2)-4)&RIGHT(B2,4)+1000),EDATE(B2,12000)),IF(ISTEXT(C2),DATEVALUE(LEFT(C2,LEN(C2)-4)&RIGHT(C2,4)+1000),EDATE(C2,12000)),"md")&" d "))

Source of data is here
its worth reading it if you are using this for ancestry work
http://www.exceluser.com/formulas/earlydates.htm

cheers
Paul.
 
Upvote 0
Thank you so much shg, it's perfect for my requirements!

A​
B​
C​
2​
01/01/1975​
43​
B2: =IFERROR(DATEDIF(A2, TODAY(), "y"), DATEDIF(LEFT(A2, 6) & 1900, TODAY(), "y") + 1900 - RIGHT(A2, 4))
3​
01/01/1943​
75​
4​
01/01/1902​
116​
5​
01/01/1868
150​
6​
01/01/1792
226​
7​
01/01/1492
526​

<tbody>
</tbody>
 
Upvote 0
Great idea Paul, and a very welcomed contribution - thank you so much!

Hi,
If you are updating their age of someone pre 1900, you can also include the date they passed away.

DoB in cell B2
Date passed away in cell C2
Age in cell D2 with this formua

Code:
=IF(ISBLANK(B2),"-",IF(ISBLANK(C2),"-",DATEDIF(IF(ISTEXT(B2),DATEVALUE(LEFT(B2,LEN(B2)-4)&RIGHT(B2,4)+1000),EDATE(B2,12000)),IF(ISTEXT(C2),DATEVALUE(LEFT(C2,LEN(C2)-4)&RIGHT(C2,4)+1000),EDATE(C2,12000)),"y")&" y "&DATEDIF(IF(ISTEXT(B2),DATEVALUE(LEFT(B2,LEN(B2)-4)&RIGHT(B2,4)+1000),EDATE(B2,12000)),IF(ISTEXT(C2),DATEVALUE(LEFT(C2,LEN(C2)-4)&RIGHT(C2,4)+1000),EDATE(C2,12000)),"ym") &" m " &DATEDIF(IF(ISTEXT(B2),DATEVALUE(LEFT(B2,LEN(B2)-4)&RIGHT(B2,4)+1000),EDATE(B2,12000)),IF(ISTEXT(C2),DATEVALUE(LEFT(C2,LEN(C2)-4)&RIGHT(C2,4)+1000),EDATE(C2,12000)),"md")&" d "))

Source of data is here
its worth reading it if you are using this for ancestry work
http://www.exceluser.com/formulas/earlydates.htm

cheers
Paul.
 
Upvote 0

Forum statistics

Threads
1,215,465
Messages
6,124,975
Members
449,200
Latest member
Jamil ahmed

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top