average without zeros

Fyr

Active Member
Joined
Jan 20, 2009
Messages
375
I'm using this formula:
=AVERAGE(C4,E4,G4,I4,K4,M4)

It a cell contains zero's, it does not average it right.
How can I use the above code to ignore zeros?
 

Excel Facts

Copy formula down without changing references
If you have =SUM(F2:F49) in F50; type Alt+' in F51 to copy =SUM(F2:F49) to F51, leaving the formula in edit mode. Change SUM to COUNT.
I'm using this formula:
=AVERAGE(C4,E4,G4,I4,K4,M4)

It a cell contains zero's, it does not average it right.
How can I use the above code to ignore zeros?

If the relevant cells are supposed to house numbers >= 0, then:

=SUM(C4,E4,G4,I4,K4,M4)/INDEX(FREQUENCY((C4,E4,G4,I4,K4,M4),{0}),2)
 
Upvote 0
Fyr,

Aladin's formula is shorter.

But, this also works:
=SUM(SUMIF(INDIRECT({"C4","E4","G4","I4","K4","M4"}),">0"))/INDEX(FREQUENCY((C4,E4,G4,I4,K4,M4),0),2)


Have a great day,
Stan
 
Upvote 0
For positive/negative excluding zero/empty/error values, array formula:
{=AVERAGE(IF((MOD(COLUMN(C4:M4)-COLUMN(C4),2)=0)*ISNUMBER(1/C4:M4),C4:M4))}
 
Last edited:
Upvote 0
For positive/negative excluding zero/empty/error values, array formula:
{=AVERAGE(IF((MOD(COLUMN(C4:M4)-COLUMN(C4),2)=0)*ISNUMBER(1/C4:M4),C4:M4))}
The same, but a little bit simpler (array formula):
{=AVERAGE(IF({1,0,1,0,1,0,1,0,1,0,1}*ISNUMBER(1/C4:M4),C4:M4))}
 
Upvote 0
For positive/negative excluding zero/empty/error values, array formula:
{=AVERAGE(IF((MOD(COLUMN(C4:M4)-COLUMN(C4),2)=0)*ISNUMBER(1/C4:M4),C4:M4))}

Control+shift+enter:
Code:
=AVERAGE(
  IF(MOD(COLUMN(C4:M4)-COLUMN(C4),2)=0,
  IF(ISNUMBER(C4:M4),
  IF(C4:M4 > 0,
   C4:M4))))

which is an expensive piece formula for a set of 6 cells.

BTW, the matchematicians dislike the idea of exluding 0's if the data set is something like:

3,-3,0,2,1

although either an average of figures > 0 or < 0 is readily accepted.
 
Upvote 0

Forum statistics

Threads
1,213,491
Messages
6,113,963
Members
448,536
Latest member
CantExcel123

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