Subtotal of Abs of a range?

G

G Lykos

Greetings! Am stumped. Need a sum of the absolute value of row-filtered
elements in a column. SUBTOTAL does this admirably, but it appears that
SUBTOTAL does not accommodate anything but a simple range as it target, in
the pseudo-syntax SUBTOTAL(Function,Range). SUM, on the other hand, allows
for a function such as ABS to be embedded as its argument, but does not
screen out filtered values.

A work-around is to create an intermediate column that ABS's the original
column and then apply SUBTOTAL to it. However, in the interest of
compactness, the question becomes: is there a way to cause SUM to skip
filtered-out elements, or a way to create the equivalent of
SUBTOTAL(9,ABS(Range)).

Thanks!
George
 
G

G Lykos

Incidentally, SUM as imagined here would be expressed as {SUM(ABS(Range))},
an array formula, that in this form doesn't skip filtered-out rows. It
appears that SUBTOTAL does not support array usage (or is it vice versa?).
 
G

G Lykos

{=SUM(ABS(Range))}, to be more exact ...


G Lykos said:
Incidentally, SUM as imagined here would be expressed as {SUM(ABS(Range))},
an array formula, that in this form doesn't skip filtered-out rows. It
appears that SUBTOTAL does not support array usage (or is it vice versa?).
 
T

T. Valko

Try this:

The range to sum is B2:B10 (filtered or unfiltered):

Array entered:

=SUM(IF(SUBTOTAL(3,OFFSET(B2:B10,ROW(B2:B10)-MIN(ROW(B2:B10)),,1)),ABS(B2:B10)))

Biff
 

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