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.

[TABLE="width: 500"]
<tbody>[TR]
[TD][/TD]
[TD]Jan[/TD]
[TD]Feb[/TD]
[TD]Mar[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]Failures[/TD]
[TD]1[/TD]
[TD]2[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]

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!
 

Excel Facts

Excel motto
Not everything I do at work revolves around Excel. Only the fun parts.
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:


Book1
ABCDEFGHIJKLMNO
1JanFebMarAprMayJunJulAugSepOctNovDecYTD
2Failures1212310112
3Cost10300103067.533.7501015020226.25
Sheet7
Cell Formulas
RangeFormula
B3=B2*CHOOSE(COLUMN(B2)-AGGREGATE(14,6,COLUMN($A2:A2)/(N(OFFSET($A2,0,COLUMN($A2:A2)-COLUMN($A2)))=0),1)+1,0,10,15,22.5,33.75,50.63,75.94,113.91,170.86,256.29,384.43,576.65,864.98)
O3=SUM(B3:M3)


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.
 
Upvote 0
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.
 
Upvote 0
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?
 
Upvote 0
I think you'd want to make a summary table like this:


Book1
ABCDEFGHIJKLMNOPQ
1JanFebMarAprMayJunJulAugSepOctNovDecJanFebMarApr
2Failures12123101121
3
4Years12345Total
5Total1460517
6Fee14060050170420
Sheet1
Cell Formulas
RangeFormula
B5=SUM(INDEX(2:2,(COLUMNS($B2:B2)-1)*12+2):INDEX(2:2,(COLUMNS($B2:B2)-1)*12+13))
B6=B5*CHOOSE(COLUMN(B2)-AGGREGATE(14,6,COLUMN($A5:A5)/(N(OFFSET($A5,0,COLUMN($A5:A5)-COLUMN($A5)))=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,864.98)
H6=SUM(B6:F6)


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.
 
Upvote 0

Forum statistics

Threads
1,223,214
Messages
6,170,771
Members
452,353
Latest member
strainu

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