Find month when criteria has been met (sum of project cost)

chet645

Board Regular
Joined
Nov 10, 2010
Messages
67
Office Version
  1. 365
Platform
  1. Windows
All, wondering if someone can help me with a formula. I need a formula that will calculate the month when total project cost has been spent (e.g. 500 in the table below). In the table below, the correct month is 5.


Month
0​
1​
2​
3​
4​
5​
6​
7​
8​
9​
10​
11​
Project Cost​

100​
100​
100​
100​
100​



















Total Project Cost​
500​











Month of Completion​
5











<tbody>
</tbody>

Thank you in advance for your help.

Chet
 

Excel Facts

Highlight Duplicates
Home, Conditional Formatting, Highlight Cells, Duplicate records, OK to add pink formatting to any duplicates in selected range.
See if this is what you want. I have added a few examples for checking.
Formula in B5 copied across.

Excel Workbook
ABCDEFGHIJKLM
1Month01234567891011
2Project Cost10010010010010050200100
3
4Total Project Cost5001501000780
5Month of Completion528
Cost Spent
 
Upvote 0
Hi Peter,

You beat me, but using your layout here's another approach "=MIN(IF(SUBTOTAL(9,(OFFSET($C2:L2,0,0,1,ROW(INDIRECT("1:100")))))>=C4,ROW(INDIRECT("1:100"))),100000)" Note that the formula does not use the month row. Also, I think your formula is more elegant and I'm adding mine only because it took me such a long time to get it to work.
 
Upvote 0
Hi Peter. I must admit I hadn't noticed that. By the way, my formula could be slightly less inelegant as "=1+MAX(IF(SUBTOTAL(9,(OFFSET($C2:L2,0,0,1,ROW(INDIRECT("1:100")))))<C4,ROW(INDIRECT("1:100"))),0)
 
Last edited by a moderator:
Upvote 0
By the way, my formula could be slightly less inelegant as ...
Some comments:
1. I fixed your latest formula as it was cut off at the < sign
2. You hadn't mentioned that your formulas require Ctrl+Shift+Enter confirmation.
3. Your formulas return incorrect values if the project cost has not yet been spent (eg cells D4:D5 of my sample data)
 
Upvote 0
Thanks for the comments Peter and the correction and for taking the trouble to work through it. The following fixes the problem when the value isn't achieved "=(1+MAX(IF(SUBTOTAL(9,(OFFSET($C2:L2,0,0,1,ROW(INDIRECT("1:100")))))<C4,ROW(INDIRECT("1:100"))),0))*(SUM(C2:J2)>=C4)". But it isn't an array formula. You just enter it normally.
 
Upvote 0
Thanks for the comments Peter and the correction and for taking the trouble to work through it. The following fixes the problem when the value isn't achieved "=(1+MAX(IF(SUBTOTAL(9,(OFFSET($C2:L2,0,0,1,ROW(INDIRECT("1:100")))))<C4,ROW(INDIRECT("1:100"))),0))*(SUM(C2:J2)>=C4)". But it isn't an array formula. You just enter it normally.
Again your formula is truncated. If you post a formula with a < followed immediately by a letter that happens. You can avoid it by entering a space character after the <
The formula you tried to post was
=(1+MAX(IF(SUBTOTAL(9,(OFFSET($C2:L2,0,0,1,ROW(INDIRECT("1:100")))))< C4,ROW(INDIRECT("1:100"))),0))*(SUM(C2:J2)>=C4)

However, I disagree that it can be entered normally. In my sheet below, I have entered your formula normally in C5 and with Ctrl+Shift+Enter in C6. C6 has the correct answer, not C5

<b>Cost Spent (2)</b><br /><br /><table border="1" cellspacing="0" cellpadding="0" style="font-family:Arial,Arial; font-size:8pt; background-color:#ffffff; padding-left:2pt; padding-right:2pt; "> <colgroup><col style="font-weight:bold; width:30px; " /><col style="width:140px;" /><col style="width:40px;" /><col style="width:40px;" /><col style="width:61px;" /><col style="width:40px;" /><col style="width:40px;" /><col style="width:40px;" /><col style="width:33px;" /><col style="width:40px;" /><col style="width:40px;" /><col style="width:26px;" /><col style="width:33px;" /><col style="width:33px;" /></colgroup><tr style="background-color:#cacaca; text-align:center; font-weight:bold; font-size:8pt; "><td > </td><td >A</td><td >B</td><td >C</td><td >D</td><td >E</td><td >F</td><td >G</td><td >H</td><td >I</td><td >J</td><td >K</td><td >L</td><td >M</td></tr><tr style="height:21px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >1</td><td style="font-size:10pt; ">Month</td><td style="font-size:10pt; text-align:right; ">0</td><td style="font-size:10pt; text-align:right; ">1</td><td style="font-size:10pt; text-align:right; ">2</td><td style="font-size:10pt; text-align:right; ">3</td><td style="font-size:10pt; text-align:right; ">4</td><td style="font-size:10pt; text-align:right; ">5</td><td style="font-size:10pt; text-align:right; ">6</td><td style="font-size:10pt; text-align:right; ">7</td><td style="font-size:10pt; text-align:right; ">8</td><td style="font-size:10pt; text-align:right; ">9</td><td style="font-size:10pt; text-align:right; ">10</td><td style="font-size:10pt; text-align:right; ">11</td></tr><tr style="height:21px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >2</td><td style="font-size:10pt; ">Project Cost</td><td style="font-size:10pt; "> </td><td style="font-size:10pt; text-align:right; ">100</td><td style="font-size:10pt; text-align:right; ">100</td><td style="font-size:10pt; text-align:right; ">100</td><td style="font-size:10pt; text-align:right; ">100</td><td style="font-size:10pt; text-align:right; ">100</td><td style="font-size:10pt; text-align:right; ">50</td><td style="font-size:10pt; text-align:right; ">200</td><td style="font-size:10pt; text-align:right; ">100</td><td style="font-size:10pt; "> </td><td style="font-size:10pt; "> </td><td style="font-size:10pt; "> </td></tr><tr style="height:21px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >3</td><td style="font-size:10pt; "> </td><td style="font-size:10pt; "> </td><td style="font-size:10pt; "> </td><td style="font-size:10pt; "> </td><td style="font-size:10pt; "> </td><td style="font-size:10pt; "> </td><td style="font-size:10pt; "> </td><td style="font-size:10pt; "> </td><td style="font-size:10pt; "> </td><td style="font-size:10pt; "> </td><td style="font-size:10pt; "> </td><td style="font-size:10pt; "> </td><td style="font-size:10pt; "> </td></tr><tr style="height:21px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >4</td><td style="font-size:10pt; ">Total Project Cost</td><td style="font-size:10pt; "> </td><td style="font-size:10pt; text-align:right; ">500</td><td style="font-size:10pt; "> </td><td style="font-size:10pt; "> </td><td style="font-size:10pt; "> </td><td style="font-size:10pt; "> </td><td style="font-size:10pt; "> </td><td style="font-size:10pt; "> </td><td style="font-size:10pt; "> </td><td style="font-size:10pt; "> </td><td style="font-size:10pt; "> </td><td style="font-size:10pt; "> </td></tr><tr style="height:21px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >5</td><td style="font-size:10pt; ">Month of Completion</td><td style="font-size:10pt; "> </td><td style="font-size:10pt; text-align:right; ">2</td><td style="font-size:10pt; "> </td><td style="font-size:10pt; "> </td><td style="font-size:10pt; "> </td><td style="font-size:10pt; "> </td><td style="font-size:10pt; "> </td><td style="font-size:10pt; "> </td><td style="font-size:10pt; "> </td><td style="font-size:10pt; "> </td><td style="font-size:10pt; "> </td><td style="font-size:10pt; "> </td></tr><tr style="height:21px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >6</td><td style="font-size:10pt; "> </td><td style="font-size:10pt; "> </td><td style="font-size:10pt; text-align:right; ">5</td><td style="font-size:10pt; "> </td><td style="font-size:10pt; "> </td><td style="font-size:10pt; "> </td><td style="font-size:10pt; "> </td><td style="font-size:10pt; "> </td><td style="font-size:10pt; "> </td><td style="font-size:10pt; "> </td><td style="font-size:10pt; "> </td><td style="font-size:10pt; "> </td><td style="font-size:10pt; "> </td></tr></table><br /><table style="font-family:Arial; font-size:10pt; border-style: groove ;border-color:#00ff00;background-color:#fffcf9; color:#000000; "><tr><td ><b>Spreadsheet Formulas</b></td></tr><tr><td ><table border = "1" cellspacing="0" cellpadding="2" style="font-family:Arial; font-size:9pt;"><tr style="background-color:#cacaca; font-size:10pt;"><td >Cell</td><td >Formula</td></tr><tr><td >C5</td><td >=(1+MAX<span style=' color:008000; '>(IF<span style=' color:#0000ff; '>(SUBTOTAL<span style=' color:#ff0000; '>(9,<span style=' color:#804000; '>(OFFSET<span style=' color:#ff7837; '>($C2:L2,0,0,1,ROW<span style=' color:#8000ff; '>(INDIRECT<span style=' color:#545fa5; '>("1:100")</span>)</span>)</span>)</span>)</span>< C4,ROW<span style=' color:#ff0000; '>(INDIRECT<span style=' color:#804000; '>("1:100")</span>)</span>)</span>,0)</span>)*(SUM<span style=' color:008000; '>(C2:J2)</span>>=C4)</td></tr><tr><td >C6</td><td >{=(1+MAX<span style=' color:008000; '>(IF<span style=' color:#0000ff; '>(SUBTOTAL<span style=' color:#ff0000; '>(9,<span style=' color:#804000; '>(OFFSET<span style=' color:#ff7837; '>($C2:L2,0,0,1,ROW<span style=' color:#8000ff; '>(INDIRECT<span style=' color:#545fa5; '>("1:100")</span>)</span>)</span>)</span>)</span>< C4,ROW<span style=' color:#ff0000; '>(INDIRECT<span style=' color:#804000; '>("1:100")</span>)</span>)</span>,0)</span>)*(SUM<span style=' color:008000; '>(C2:J2)</span>>=C4)}</td></tr></table></td></tr><tr><td ><span style=' font-family:Arial,Arial; font-size:9pt; font-weight:bold;'>Formula Array:</span><span style=' font-family:Arial,Arial; font-size:9pt;'><br />Produce enclosing </span><span style=' font-family:Arial,Arial; font-size:9pt; font-weight:bold;'>{ }</span><span style=' font-family:Arial,Arial; font-size:9pt;'> by entering<br />formula with CTRL+SHIFT+ENTER!</span></td></tr></table> <br />Excel tables to the web - Excel Jeanie Html 4
 
Upvote 0
Hi Peter. I hope you don't get annoyed with my dogged perseverance, and thanks for the tip about the space after ">", but I copied your corrected formula into my sheet and I get a 5. I'm using the same numbers as you, but the result is different. I get a 5 whether I enter the formula as an array or if I enter it normally. Can you think of any explanation why I get the same results, but you get different results? I have tried it with 150 (2) 1000 (0) and 780 (8). In each case, there is no difference between my formula entered as an array and the formula entered normally.
 
Upvote 0
Hi Peter. I hope you don't get annoyed with my dogged perseverance,
No, I don't get annoyed - you can only report what is happening for you. :)


Can you think of any explanation why I get the same results, but you get different results?
No, I don't know why that might happen. For me, without the array entry ROW(INDIRECT("1:100")) in the formula returns just 1. With the array entry it returns the expected 1,2,3,...,100 (checked by selecting the formula cell and stepping through the formula evaluation process with the 'Evaluate Formula' facility in the Formula Auditing section of the Formulas ribbon tab)
 
Upvote 0

Forum statistics

Threads
1,213,563
Messages
6,114,329
Members
448,564
Latest member
ED38

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