Averaging

willquill

New Member
Joined
Jan 11, 2010
Messages
19
I have a column of approx 350 entries. Generally the data is as follows

<style><!--table {mso-displayed-decimal-separator:"\."; mso-displayed-thousand-separator:"\,";}td {padding:0px; mso-ignore:padding; color:black; font-size:11.0pt; font-weight:400; font-style:normal; text-decoration:none; font-family:Calibri, sans-serif; mso-font-charset:0; mso-number-format:General; text-align:general; vertical-align:bottom; border:none; mso-background-source:auto; mso-pattern:auto; mso-protection:locked visible; white-space:nowrap; mso-rotate:0;}.xl24 {color:#333333; font-size:9.0pt; font-family:"Courier New", monospace; mso-font-charset:0; text-align:left; vertical-align:middle; border:1.0pt solid black;}ruby {ruby-align:left;}rt {color:windowtext; font-size:8.0pt; font-weight:400; font-style:normal; text-decoration:none; font-family:"Times New Roman", serif; mso-font-charset:0; mso-char-type:none; display:none;}--></style>[TABLE="width: 178"]
<colgroup><col width="178"> </colgroup><tbody>[TR]
<!--StartFragment--> [TD="class: xl24, width: 178"]28 years 9 months 30 days[/TD]
<!--EndFragment--> [/TR]
</tbody>[/TABLE]

The formatting is general, is there a way to average the column?

Thank you,

willquill
 

Excel Facts

Using Function Arguments with nested formulas
If writing INDEX in Func. Arguments, type MATCH(. Use the mouse to click inside MATCH in the formula bar. Dialog switches to MATCH.
The formatting is general, is there a way to average the column?
That tells me that the data in that column is entered as Text, so your answer would be no (you cannot average text, only numbers).
So I think you would need to first convert those entries to numbers if you wanted to average them.
 
Upvote 0
To the best of my knowledge, the format "28 years 9 months 30 days" is not a date format that Excel will recognize and average. Your best bet is to convert the time periods into one unit of measure, i.e. days, and average the values that way.

If you want it in your originally stated format, you could always use this beast... where E6 is the average value in days

Code:
=ROUNDDOWN(E6/365,0)&" years "&ROUNDDOWN(12*(E6/365-ROUNDDOWN(E6/365,0)),0)&" months "&ROUND(((12*(E6/365-ROUNDDOWN(E6/365,0))-ROUNDDOWN(12*(E6/365-ROUNDDOWN(E6/365,0)),0))*30),0) & " days"
 
Upvote 0
Here is another possible option that can be tried:


Excel 2013/2016
ABCDEFG
110 years 9 months 15 daysAvg Days576015 years9 months15 days
220 years 9 months 15 days
Sheet1
Cell Formulas
RangeFormula
D1=SUMPRODUCT(("0"&TRIM(MID(SUBSTITUTE(A1:A2," ",REPT(" ",99)),{1,3,5}*99-98,99)))*{365,30,1})/COUNTA(A1:A2)
E1=INT(D1/365)&" years"
F1=INT(MOD(D1,365)/30)&" months"
G1=MOD(MOD(D1,365),30) &" days"
 
Upvote 0
<style><!--table {mso-displayed-decimal-separator:"\."; mso-displayed-thousand-separator:"\,";}td {padding:0px; mso-ignore:padding; color:black; font-size:11.0pt; font-weight:400; font-style:normal; text-decoration:none; font-family:Calibri, sans-serif; mso-font-charset:0; mso-number-format:General; text-align:general; vertical-align:bottom; border:none; mso-background-source:auto; mso-pattern:auto; mso-protection:locked visible; white-space:nowrap; mso-rotate:0;}.xl24 {color:#333333; font-size:9.0pt; font-family:"Courier New", monospace; mso-font-charset:0; text-align:left; vertical-align:middle; border:1.0pt solid black;}ruby {ruby-align:left;}rt {color:windowtext; font-size:8.0pt; font-weight:400; font-style:normal; text-decoration:none; font-family:"Times New Roman", serif; mso-font-charset:0; mso-char-type:none; display:none;}--></style>[TABLE="width: 178"]
<tbody>[TR]
[TD="class: xl24, width: 178"]28 years 9 months 30 days[/TD]
[/TR]
</tbody>[/TABLE]

Is this derived from a DATEDIF formula? It's easier to average the dates rather than trying to average text values (as previously advised) so if you have DOBS in A2:A350, for example and your DATEDIF is calculating age at today's date then for average age you can use just

=DATEDIF(AVERAGE(A2:A350),TODAY(),"y")&" years "&DATEDIF(AVERAGE(A2:A350),TODAY(),"ym")&" months "&DATEDIF(AVERAGE(A2:A350),TODAY(),"md")&" days"

If A2:A350 contains any blanks they will be ignored so you can make the range larger for future expansion purposes if you want
 
Upvote 0
This formula actually averages using just the text values, assumes no blanks in the range

=TEXTJOIN(" ",1,DATEDIF(0,AVERAGE(MMULT(MID(0&B2:B350,FIND({"y","m","d"},0&B2:B350)-3,2)+0,{365.25;30.5;1})),{"y","ym","md"})&{" years"," months"," days"})

This uses TEXTJOIN function which is only available if you have Office 365 subscription I think

Without TEXTJOIN you can do essentially the same but DATEDIF is repeated 3 times like this

=DATEDIF(0,AVERAGE(MMULT(MID(0&B2:B350,FIND({"y","m","d"},0&B2:B350)-3,2)+0,{365.25;30.5;1})),"y")&" years "&DATEDIF(0,AVERAGE(MMULT(MID(0&B2:B350,FIND({"y","m","d"},0&B2:B350)-3,2)+0,{365.25;30.5;1})),"ym")&" months "&DATEDIF(0,AVERAGE(MMULT(MID(0&B2:B350,FIND({"y","m","d"},0&B2:B350)-3,2)+0,{365.25;30.5;1})),"md")&" days"
 
Upvote 0

Forum statistics

Threads
1,223,908
Messages
6,175,304
Members
452,633
Latest member
DougMo

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