COUNT rows until SUM value reached

steve manos

New Member
Joined
Mar 15, 2013
Messages
2
Howdy Folks! :biggrin:

I'm young to Excel, using XL 2010 with Windows 7, and was wondering if
there's a formula solution using COUNT and SUM in combination?

I used a helper column to get the answer to:
How many days does it take, before I clear $500 dollars?
The answer is 7.

I'd rather construct a simple formula though at the bottom of Column B ($/day)
to Count the number of rows, therfore days, until I reach my Sum value of $500.

Thanks,
Stevie!
Work day
$/day
helper column?
1
61.21
61.21
2
81.90
143.11
3
83.66
226.77
4
70.83
297.60
5
91.28
388.88
6
87.06
475.94
7
74.73
550.67
8
82.34
633.01
9
85.11
718.12

<TBODY>
</TBODY>
 

Excel Facts

Why are there 1,048,576 rows in Excel?
The Excel team increased the size of the grid in 2007. There are 2^20 rows and 2^14 columns for a total of 17 billion cells.
This would work Sum column until condition is reached - return number of cells in column counted « Chandoo.org - Learn Excel & Charting Online - Forums

Post by Kyle McGhee

Create 2 Names:
d - refers to: <code style="margin: 0px; padding: 0px; font-size: 1em; line-height: normal; font-family: Monaco, 'Courier New', monospace;">=Sheet1!$C$1:$C$9</code>
dMMULT - refers to: <code style="margin: 0px; padding: 0px; font-size: 1em; line-height: normal; font-family: Monaco, 'Courier New', monospace;">=MMULT(--(ROW(d)>=TRANSPOSE(ROW(d))),d)</code>

Then use this formula
<code style="margin: 0px; padding: 0px; font-size: 1em; line-height: normal; font-family: Monaco, 'Courier New', monospace;">=MATCH(TRUE,INDEX(dMMULT>500,,),0)</code>
The result is 4


Excel 2010
ABC
1161.2161.21
2281.9143.11
3383.66226.77
4470.83297.6
5591.28388.88
6687.06475.94
7774.73550.67
8882.34633.01
9985.11718.12
104
Sheet1
Cell Formulas
RangeFormula
B10=MATCH(TRUE,INDEX(dMMULT>500,,),0)
Named Ranges
NameRefers ToCells
d=Sheet1!$C$1:$C$9
dMMULT=MMULT(--(ROW(d)>=TRANSPOSE(ROW(d))),d)
 
Last edited:
Upvote 0
Thanks for the quick look Kyle.

The result of 4 - I'm not sure where that works,
it should return 7 using the criteria I was looking for.
...the 7th day of work COUNT, therfore 7th row, produced the SUM value earnings target of >= $500 dollars.

I'm looking to find through a formula how many work days does it take to earn $500 dollars. And in the example it should return 7.

Can you adjust the macro for this Kyle?


Thanks,
Stevie. :biggrin:
 
Upvote 0
Ahh my bad, I thought they were daily sales figures not cumulative.

That's much easier :D

=MATCH(TRUE,$C$1:$C$9>500,0)

Confirmed with Ctrl+Shift+Enter
 
Last edited:
Upvote 0
Ahh my bad, I thought they were daily sales figures not cumulative.

That's much easier :D

=MATCH(TRUE,$C$1:$C$9>500,0)

Confirmed with Ctrl+Shift+Enter

Just a question (5 years later haha): which sort will the formula respect? The sort in the array or the top ones? I have a similar doubt of his, but I would like to count until reach a value sorted by the top value cells.
 
Upvote 0
Comfy


Your Formula originates is correct, just change =Sheet1!$C$1:$C$9 to =Sheet1!$B$1:$B$9


Hope this helps


Decio
 
Upvote 0

Forum statistics

Threads
1,213,552
Messages
6,114,278
Members
448,560
Latest member
Torchwood72

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