Standard Deviation

S

Soccerboy83

Is it possible to form an equation that will give me a standard deviation for
all numbers above a certain value. I know there are SUMIF and COUNTIF
formulas and if you want the average you actually have to do (SUMIF/COUNTIF)
because there is no AVERAGEIF. I guess what i am asking is if there is a way
to do a standard deviation for only a certain range of numbers.
 
D

Domenic

Soccerboy83 said:
Is it possible to form an equation that will give me a standard deviation for
all numbers above a certain value. I know there are SUMIF and COUNTIF
formulas and if you want the average you actually have to do (SUMIF/COUNTIF)
because there is no AVERAGEIF. I guess what i am asking is if there is a way
to do a standard deviation for only a certain range of numbers.


Assuming that A2:A100 contains the data, and that C2 contains the value
of interest, try the following formula that needs to be confirmed with
CONTROL+SHIFT+ENTER...

=STDEV(IF($A$2:$A$100>C2,$A$2:$A$100))
 
S

smartin

Soccerboy83 said:
Is it possible to form an equation that will give me a standard deviation for
all numbers above a certain value. I know there are SUMIF and COUNTIF
formulas and if you want the average you actually have to do (SUMIF/COUNTIF)
because there is no AVERAGEIF. I guess what i am asking is if there is a way
to do a standard deviation for only a certain range of numbers.

Suppose you have in A1:A5

1
3
5
3
1

Then this array* formula will give STDEV where the input value is >2
=STDEV(IF(A1:A5>2,A1:A5))

*Very important: array formulas must be committed by pressing
Ctrl+Shift+Enter, not just Enter.

The same technique can be applied with some other functions, e.g.,
=AVERAGE(IF((A1:A5>2),A1:A5))
=MEDIAN(IF((A1:A5>2),A1:A5))
 

Ask a Question

Want to reply to this thread or ask your own question?

You'll need to choose a username for the site, which only take a couple of moments. After that, you can post your question and our members will help you out.

Ask a Question

Top