Average Of Time Values, Ignore Errors

mouse88

Board Regular
Joined
May 24, 2011
Messages
148
I have the following formula:

{=AVERAGE(TIMEVALUE(I4:I9))}

This works fine until one of the values in the range has a #N/A! error. Is there any way I can get it to ignore these errors and only use the time values?

Thanks

Matt
 
Both these formulas work:

=(SUMIF(E6:E8,"<>#N/A"))/COUNTIF(E6:E8,"<>#N/A")

=AVERAGE(IF(ISNUMBER(I4:I9),I4:I9))

But if all values in the range have the #N/A error then it returns a #DIV/0 error.
Try one of these...

Both formulas are array formulas**.

If you're using Excel 2007 or later...

=IFERROR(AVERAGE(IF(ISNUMBER(I4:I9),I4:I9)),"")

This one will work in ANY version of Excel:

=IF(COUNT(I4:I9),AVERAGE(IF(ISNUMBER(I4:I9),I4:I9)),"")

** array formulas need to be entered using the key
combination of CTRL,SHIFT,ENTER (not just ENTER).
Hold down both the CTRL key and the SHIFT key
then hit ENTER.
 
Upvote 0

Excel Facts

Lock one reference in a formula
Need 1 part of a formula to always point to the same range? use $ signs: $V$2:$Z$99 will always point to V2:Z99, even after copying
In Excel 2007 you could also use AVERAGEIF function

=IFERROR(AVERAGEIF(I4:I9,"<>#N/A"),0)

normally entered

or in earlier versions

=SUMIF(I4:I9,"<>#N/A")/MAX(1,COUNTIF(I4:I9,"<>#N/A"))
 
Upvote 0

Forum statistics

Threads
1,224,550
Messages
6,179,462
Members
452,915
Latest member
hannnahheileen

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