Need Help with "SUM" AND "ABS" in same formula

R

Randy

The cells in a SUM formula all include formulas that provide the cells with
negative numbers, positive numbers and blank cells. Need to have the
respective values to be used in another formula as absolute values. Need to
have the negative values in the range to stay displayed as negatives and the
blank cells in the range to stay displayed as blank. Tried using
=sum(abs(range)), which works fine if the blank cells are omitted from the
range. If the blank cells are part of the range the result is "#VALUE!". Is
there something to add to resolve the error message?
 
J

JoeU2004

Randy said:
Tried using
=sum(abs(range)), which works fine if the blank cells are omitted from the
range. If the blank cells are part of the range the result is "#VALUE!".

You need to enter =SUM(ABS(range)) as an array formula. That is, press with
ctrl-shift-Enter instead of just Enter. At this point, you can select the
cell, press F2, then press ctrl-shift-Enter.

Alternatively, use the formula =SUMPRODUCT(ABS(range)), which is not an
array formula; simply press Enter.


----- original message -----
 
J

JoeU2004

PS....

Randy said:
Tried using =sum(abs(range)), which works fine if the blank cells are
omitted from the range. If the blank cells are part of the range the
result
is "#VALUE!".

Hmm.... There might be something wrong with my understanding of your
problem. SUM(ABS(range)) should __always__ return #VALUE unless you enter
the formula as an array formula. And if you enter an array formula,
SUM(ABS(range)) should __always__ work regardless of the presence of empty
cells in the range.

But if the "blank cells" contain text, notably "", you will need the
following array formula (again, commit with ctrl-shift-Enter, not just
Enter):

=SUM(IF(range<>"",ABS(range)))

Also note: the SUMPRODUCT alternative will not work as a non-array formula.


----- original message -----
 
E

Eduardo

Opps, I didn't realize you posted your formula, try

=SUMPRODUCT(ABS(C11:C14))

change c11:c14 for your range
 
H

Harlan Grove

Randy said:
The cells in a SUM formula all include formulas that provide the cells with
negative numbers, positive numbers and blank cells.  Need to have the
respective values to be used in another formula as absolute values.  Need to
have the negative values in the range to stay displayed as negatives and the
blank cells in the range to stay displayed as blank.  Tried using
=sum(abs(range)), which works fine if the blank cells are omitted from the
range.  If the blank cells are part of the range the result is "#VALUE!"..  Is
there something to add to resolve the error message?

Another alternative,

=SUMIF(range,">0")-SUMIF(range,"<0")
 
T

T. Valko

Try this array formula** :

=SUM(IF(ISNUMBER(A1:A10),ABS(A1:A10)))

** 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.
 
R

RagDyer

How about a couple of *non* array formulas:

=SUMIF(A1:A10,">0")-SUMIF(A1:A10,"<0")

=SUM(ABS(SUMIF(A1:A10,{">0","<0"})))
 
R

Randy

"T. Valko"
-Thank You, the formula works fine.

T. Valko said:
Try this array formula** :

=SUM(IF(ISNUMBER(A1:A10),ABS(A1:A10)))

** 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.
 
R

Randy

"RagDyer"
-Thank You, they both work fine.

RagDyer said:
How about a couple of *non* array formulas:

=SUMIF(A1:A10,">0")-SUMIF(A1:A10,"<0")

=SUM(ABS(SUMIF(A1:A10,{">0","<0"})))
 

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