I need to calculate the averages of a range without counting

afs24

Board Regular
Joined
Sep 26, 2002
Messages
237
I'm trying to calculate the average of a range of cells with the numbers (ex: 200,300,0,0). The answer should be 250 not 125 when dividing by 4. Zero shouldn't count because there's always a number for in spreadsheet. I'm adding up the sum of the four numbers and dividing it by the count but it's counting the zero? HELP????
 

Some videos you may like

Excel Facts

Test for Multiple Conditions in IF?
Use AND(test, test, test, test) or OR(test, test, test, ...) as the logical_test argument of IF.

Aladin Akyurek

MrExcel MVP
Joined
Feb 14, 2002
Messages
85,201
Let A2:A10 house the numbers of interest.

=SUM(A2:A10)/MAX(1,COUNT(A2:A10)-COUNTIF(A2:A10,0))

will produce the desired average of non-zero numbers.
 

VoG

Legend
Joined
Jun 19, 2002
Messages
63,650
With your numbers in A1 to A4, in A5

=SUMIF(A1:A4,">0")/4

gives 125
 

plettieri

Well-known Member
Joined
Sep 4, 2002
Messages
1,556
Platform
  1. MacOS
In the answer supplied by Vog(tm), if one of the numbers in the data base is less than 0 the answer would be different than in the answer supplied by Aladin. Also if the quantify of data is different than 4, you would have to modify that to the new total data counts .....Aladin's answer seem to account for both issue within the formular.

pll
 

VoG

Legend
Joined
Jun 19, 2002
Messages
63,650

ADVERTISEMENT

Good point plettieri.

=SUMIF(A1:A4,"<>0")/4

works correctly with negative numbers.
 

Aladin Akyurek

MrExcel MVP
Joined
Feb 14, 2002
Messages
85,201
[...]

=SUMIF(A1:A4,"<>0")/4

works correctly with negative numbers.

The question afs24 posed is:

[/quote]I'm trying to calculate the average of a range of cells with the numbers (ex: 200,300,0,0). The answer should be 250 not 125 when dividing by 4. Zero shouldn't count...[/b]

The SUMIF formula doesn't satisfy the requirements: It would just produce 125 as average when applied to: {200,300,0,0} entered in A1:A4, while

=SUM(A1:A4)/MAX(1,COUNT(A1:A4)-COUNTIF(A1:A4,0))

will produce the desired average of 250.

This formula "works correctly with negative numbers" too, as it should:

Enter {-200,300,0,0} in A1:A4...

The result should be 50 by afs24's specs.
 

VoG

Legend
Joined
Jun 19, 2002
Messages
63,650
Aladin Akyurek


Thank you. I must learn to read and think before posting (twice!).

P.S. this does work

=SUMIF(A1:A4,"<>0")/COUNTIF(A1:A4,"<>0")
This message was edited by VoG™ on 2002-09-29 08:28
 

Watch MrExcel Video

Forum statistics

Threads
1,122,518
Messages
5,596,630
Members
414,082
Latest member
sasmita

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
Top