Count of entries below cumulative threshold without helper column

Dashnick

New Member
Joined
Sep 10, 2015
Messages
35
Hi, I have the following little table. I'd like a formula that finds the number of values where the cumulative total (of column G) is less than some threshold, tx.

I tried

Code:
{=MIN((SUM(OFFSET(G3,0,0,F3:F19))>tx)*F3:F19)-1}

but OFFSET doesn't seem to be arrayable like that. Obviously, this would be trivial with a helper column, but for certain reasons that is not possible.

So the correct answer here should be 10.

FGHIJ
2rank%
310.112106tx0.8
420.110982
530.091959
640.082163
750.073292
860.072408
970.071646
1080.061647
1190.060114
12100.057566
13110.050342
14120.048227
15130.043207
16140.039405
17150.012914
18160.007603
19170.004417

<tbody>
</tbody>
Sheet1
 

Excel Facts

Can a formula spear through sheets?
Use =SUM(January:December!E7) to sum E7 on all of the sheets from January through December
Try...

=SUMPRODUCT(--(SUBTOTAL(9,OFFSET(G2:G18,,,ROW(G2:G18)-ROW(G2)+1))<=J2))

Hope this helps!
 
Upvote 0
Sorry - would you just mind explaining what SUMPRODUCT() and SUBTOTAL() are doing here that SUM() itself wouldn't normally do? (SUMPRODUCT() is only taking one argument...)
 
Upvote 0
Basically, OFFSET returns an array of references, where each reference refers to a range. In turn, each range is passed to the SUBTOTAL function. And, since the function number for SUBTOTAL is 9, it sums each range and returns an array of values. This array of values is then passed to SUMPRODUCT, which calculates how many times each sum is less than or equal to the target amount. Here are a few things to keep in mind...

Code:
ROW(G2:G18)-ROW(G2)+1 returns the following array of values:

1
2
3
'
'
'
17

Code:
OFFSET(G2:G18,,,ROW(G2:G18)-ROW(G2)+1) returns an array of references to the following ranges:

G2
G2:G3
G2:G4
'
'
'
G2:G18

Code:
SUBTOTAL(9,OFFSET(G2:G18,,,ROW(G2:G18)-ROW(G2)+1)) returns the following array of values:

0.112106
0.223088
0.315047
'
'
'
0.999998

And so it's evaluated as follows:

Code:
=SUMPRODUCT(--({0.112106;0.223088;0.315047 . . . 0.999998}<=0.8))

=SUMPRODUCT(--({TRUE;TRUE;TRUE . . . FALSE}))

=SUMPRODUCT({1;1;1; . . . 0})

Based on your sample data, SUMPRODUCT returns 10. In Excel, you can see for yourself the step by step evaluation of the formula...

1) Select the cell containing the formula.

2) On the ribbon, select Formulas > Formula Auditing > Evaluate Formula

3) Click on "Evaluate" for evaluating each part of the formula.

If you have any questions, don't hesitate to post back.

Hope this helps!
 
Upvote 0

Forum statistics

Threads
1,215,465
Messages
6,124,982
Members
449,201
Latest member
Lunzwe73

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