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