Formula Help - racheting

Excel1990

New Member
Joined
Nov 7, 2019
Messages
3
I would really appreciate help with the following formula as I just can't get it to work.

For each failure during a month I get charged 10
If I fail three months in a row I get charged and extra 50%, so 15 per failure.

If I fail again in the next month I get an additional 50% on top, so it's now 22.5 per failure.

If I don't fail then it automatically goes back to being charged 10.

3 or more consecutive months of failure incur the 50% premium, increasing by 50% each failure.

JanFebMar
Failures12

<tbody>
</tbody>

I need the formula to be in the total for the year column, totally all months, including any premiums for 3 consecutive failures.

Please help if you , I'm tearing my hair out with this!
 

Eric W

MrExcel MVP
Joined
Aug 18, 2015
Messages
8,808
Welcome to the forum!

I don't blame you for pulling your hair out, this is a toughie! About the only way I see to do it via formulas is with a helper row. Consider this:

<b></b><table cellpadding="2.5px" rules="all" style=";background-color: rgb(255,255,255);border: 1px solid;border-collapse: collapse; border-color: rgb(187,187,187)"><colgroup><col width="25px" style="background-color: rgb(218,231,245)" /><col /><col /><col /><col /><col /><col /><col /><col /><col /><col /><col /><col /><col /><col /><col /></colgroup><thead><tr style=" background-color: rgb(218,231,245);text-align: center;color: rgb(22,17,32)"><th></th><th>A</th><th>B</th><th>C</th><th>D</th><th>E</th><th>F</th><th>G</th><th>H</th><th>I</th><th>J</th><th>K</th><th>L</th><th>M</th><th>N</th><th>O</th></tr></thead><tbody><tr ><td style="color: rgb(22,17,32);text-align: center;">1</td><td style="text-align: right;;"></td><td style=";">Jan</td><td style=";">Feb</td><td style=";">Mar</td><td style=";">Apr</td><td style=";">May</td><td style=";">Jun</td><td style=";">Jul</td><td style=";">Aug</td><td style=";">Sep</td><td style=";">Oct</td><td style=";">Nov</td><td style=";">Dec</td><td style="text-align: right;;"></td><td style=";">YTD</td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">2</td><td style=";">Failures</td><td style="text-align: right;;">1</td><td style="text-align: right;;">2</td><td style="text-align: right;;"></td><td style="text-align: right;;">1</td><td style="text-align: right;;">2</td><td style="text-align: right;;">3</td><td style="text-align: right;;">1</td><td style="text-align: right;;">0</td><td style="text-align: right;;">1</td><td style="text-align: right;;">1</td><td style="text-align: right;;"></td><td style="text-align: right;;">2</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">3</td><td style=";">Cost</td><td style="text-align: right;;">10</td><td style="text-align: right;;">30</td><td style="text-align: right;;">0</td><td style="text-align: right;;">10</td><td style="text-align: right;;">30</td><td style="text-align: right;;">67.5</td><td style="text-align: right;;">33.75</td><td style="text-align: right;;">0</td><td style="text-align: right;;">10</td><td style="text-align: right;;">15</td><td style="text-align: right;;">0</td><td style="text-align: right;;">20</td><td style="text-align: right;;"></td><td style="text-align: right;;">226.25</td></tr></tbody></table><p style="width:4.8em;font-weight:bold;margin:0;padding:0.2em 0.6em 0.2em 0.5em;border: 1px solid rgb(187,187,187);border-top:none;text-align: center;background-color: rgb(218,231,245);color: rgb(22,17,32)">Sheet7</p><br /><br /><table width="85%" cellpadding="2.5px" rules="all" style=";border: 2px solid black;border-collapse:collapse;padding: 0.4em;background-color: rgb(255,255,255)" ><tr><td style="padding:6px" ><b>Worksheet Formulas</b><table cellpadding="2.5px" width="100%" rules="all" style="border: 1px solid;text-align:center;background-color: rgb(255,255,255);border-collapse: collapse; border-color: rgb(187,187,187)"><thead><tr style=" background-color: rgb(218,231,245);color: rgb(22,17,32)"><th width="10px">Cell</th><th style="text-align:left;padding-left:5px;">Formula</th></tr></thead><tbody><tr><th width="10px" style=" background-color: rgb(218,231,245);color: rgb(22,17,32)">B3</th><td style="text-align:left">=B2*CHOOSE(<font color="Blue">COLUMN(<font color="Red">B2</font>)-AGGREGATE(<font color="Red">14,6,COLUMN(<font color="Green">$A2:A2</font>)/(<font color="Green">N(<font color="Purple">OFFSET(<font color="Teal">$A2,0,COLUMN(<font color="#FF00FF">$A2:A2</font>)-COLUMN(<font color="#FF00FF">$A2</font>)</font>)</font>)=0</font>),1</font>)+1,0,10,15,22.5,33.75,50.63,75.94,113.91,170.86,256.29,384.43,576.65,864.98</font>)</td></tr><tr><th width="10px" style=" background-color: rgb(218,231,245);color: rgb(22,17,32)">O3</th><td style="text-align:left">=SUM(<font color="Blue">B3:M3</font>)</td></tr></tbody></table></td></tr></table><br />

Put the B3 formula in and drag to the right. Then the O3 formula is a basic SUM. If you don't want to see the individual months, you can hide that row and just include the SUM in a location of your choosing.

I can vaguely picture a way to do it in one cell, but it would be enormously complicated. The other option would be to write a User-Defined Function in VBA which would not be too hard if you want to go that route.
 

Eric W

MrExcel MVP
Joined
Aug 18, 2015
Messages
8,808
Looks like I had a slight goof, the formula should be:

=B2*CHOOSE(COLUMN(B2)-AGGREGATE(14,6,COLUMN($A2:A2)/(N(OFFSET($A2,0,COLUMN($A2:A2)-COLUMN($A2)))=0),1)+1,0,10,10,15,22.5,33.75,50.63,75.94,113.91,170.86,256.29,384.43,576.65)

The second month should also be 10.
 

Excel1990

New Member
Joined
Nov 7, 2019
Messages
3
Looks like I had a slight goof, the formula should be:

=B2*CHOOSE(COLUMN(B2)-AGGREGATE(14,6,COLUMN($A2:A2)/(N(OFFSET($A2,0,COLUMN($A2:A2)-COLUMN($A2)))=0),1)+1,0,10,10,15,22.5,33.75,50.63,75.94,113.91,170.86,256.29,384.43,576.65)

The second month should also be 10.




If I had scenario like this but for 5 years (still split out with one column per month) and the premium was applied on an annual basis, how could I do that.

I would need to include a sum of the 12 months into the formula. So if the sum of year 1 is over 0, and the sum of year 2 is over 0, then the sum of year 3 will incur a 50% premium?
 

Eric W

MrExcel MVP
Joined
Aug 18, 2015
Messages
8,808
I think you'd want to make a summary table like this:

<b></b><table cellpadding="2.5px" rules="all" style=";background-color: rgb(255,255,255);border: 1px solid;border-collapse: collapse; border-color: rgb(187,187,187)"><colgroup><col width="25px" style="background-color: rgb(218,231,245)" /><col /><col /><col /><col /><col /><col /><col /><col /><col /><col /><col /><col /><col /><col /><col /><col /><col /></colgroup><thead><tr style=" background-color: rgb(218,231,245);text-align: center;color: rgb(22,17,32)"><th></th><th>A</th><th>B</th><th>C</th><th>D</th><th>E</th><th>F</th><th>G</th><th>H</th><th>I</th><th>J</th><th>K</th><th>L</th><th>M</th><th>N</th><th>O</th><th>P</th><th>Q</th></tr></thead><tbody><tr ><td style="color: rgb(22,17,32);text-align: center;">1</td><td style="text-align: right;;"></td><td style=";">Jan</td><td style=";">Feb</td><td style=";">Mar</td><td style=";">Apr</td><td style=";">May</td><td style=";">Jun</td><td style=";">Jul</td><td style=";">Aug</td><td style=";">Sep</td><td style=";">Oct</td><td style=";">Nov</td><td style=";">Dec</td><td style=";">Jan</td><td style=";">Feb</td><td style=";">Mar</td><td style=";">Apr</td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">2</td><td style=";">Failures</td><td style="text-align: right;;">1</td><td style="text-align: right;;">2</td><td style="text-align: right;;"></td><td style="text-align: right;;">1</td><td style="text-align: right;;">2</td><td style="text-align: right;;">3</td><td style="text-align: right;;">1</td><td style="text-align: right;;">0</td><td style="text-align: right;;">1</td><td style="text-align: right;;">1</td><td style="text-align: right;;"></td><td style="text-align: right;;">2</td><td style="text-align: right;;">1</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">3</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">4</td><td style=";">Years</td><td style="text-align: right;;">1</td><td style="text-align: right;;">2</td><td style="text-align: right;;">3</td><td style="text-align: right;;">4</td><td style="text-align: right;;">5</td><td style="text-align: right;;"></td><td style=";">Total</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">5</td><td style=";">Total</td><td style="text-align: right;;">14</td><td style="text-align: right;;">6</td><td style="text-align: right;;">0</td><td style="text-align: right;;">5</td><td style="text-align: right;;">17</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">6</td><td style=";">Fee</td><td style="text-align: right;;">140</td><td style="text-align: right;;">60</td><td style="text-align: right;;">0</td><td style="text-align: right;;">50</td><td style="text-align: right;;">170</td><td style="text-align: right;;"></td><td style="text-align: right;;">420</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr></tbody></table><p style="width:4.8em;font-weight:bold;margin:0;padding:0.2em 0.6em 0.2em 0.5em;border: 1px solid rgb(187,187,187);border-top:none;text-align: center;background-color: rgb(218,231,245);color: rgb(22,17,32)">Sheet1</p><br /><br /><table width="85%" cellpadding="2.5px" rules="all" style=";border: 2px solid black;border-collapse:collapse;padding: 0.4em;background-color: rgb(255,255,255)" ><tr><td style="padding:6px" ><b>Worksheet Formulas</b><table cellpadding="2.5px" width="100%" rules="all" style="border: 1px solid;text-align:center;background-color: rgb(255,255,255);border-collapse: collapse; border-color: rgb(187,187,187)"><thead><tr style=" background-color: rgb(218,231,245);color: rgb(22,17,32)"><th width="10px">Cell</th><th style="text-align:left;padding-left:5px;">Formula</th></tr></thead><tbody><tr><th width="10px" style=" background-color: rgb(218,231,245);color: rgb(22,17,32)">B5</th><td style="text-align:left">=SUM(<font color="Blue">INDEX(<font color="Red">2:2,(<font color="Green">COLUMNS(<font color="Purple">$B2:B2</font>)-1</font>)*12+2</font>):INDEX(<font color="Red">2:2,(<font color="Green">COLUMNS(<font color="Purple">$B2:B2</font>)-1</font>)*12+13</font>)</font>)</td></tr><tr><th width="10px" style=" background-color: rgb(218,231,245);color: rgb(22,17,32)">B6</th><td style="text-align:left">=B5*CHOOSE(<font color="Blue">COLUMN(<font color="Red">B2</font>)-AGGREGATE(<font color="Red">14,6,COLUMN(<font color="Green">$A5:A5</font>)/(<font color="Green">N(<font color="Purple">OFFSET(<font color="Teal">$A5,0,COLUMN(<font color="#FF00FF">$A5:A5</font>)-COLUMN(<font color="#FF00FF">$A5</font>)</font>)</font>)=0</font>),1</font>)+1,0,10,10,15,22.5,33.75,50.63,75.94,113.91,170.86,256.29,384.43,576.65,864.98</font>)</td></tr><tr><th width="10px" style=" background-color: rgb(218,231,245);color: rgb(22,17,32)">H6</th><td style="text-align:left">=SUM(<font color="Blue">B6:F6</font>)</td></tr></tbody></table></td></tr></table><br />

The amounts in row 2 go out for 60 columns (5 years). Then put the formula in B5 and copy to the right to get the annual totals. Then you can use the same basic formula from before in B6 (adapted for the different location) and copy that to the right.
 

Forum statistics

Threads
1,078,444
Messages
5,340,322
Members
399,368
Latest member
Sataman

Some videos you may like

This Week's Hot Topics

  • Problem with Radio Button's format control
    I am creating an employee evaluation template (a sample is below) Column A is the category Column B, C D, E and F will be ratings (unacceptable...
  • Last Display on userform to a Listbox
    [CODE=vba] lstdisplay.ColumnCount = 15 lstdisplay.RowSource = "A1:O600000" [/CODE] So when i do this it Displays everything on the sheet i am...
  • Rename and move files to a new location
    Dear all, I have an excel file with the following information. The actual file name is at column A but i want to rename it using the following...
  • Help with True/False Formula
    Hello! Am stumped how to fix this formula, in which my result returns 'True', but it should return False. =IF(AG2=True...
  • Clear extra characters from a provided range of cells
    Dear All, I have following code which gives me desired output to remove extra characters from a provided range. But it takes too much time when...
  • Help with Current and highest streaks
    Hi there, I've just joined the forum and this is my first post. I've already spent quite a bit of time searching the net and this forum for a...
Top