Cumulative sum with max

401kspreadsheets

New Member
Joined
Mar 28, 2019
Messages
4
<style type="text/css">p.p1 {margin: 0.0px 0.0px 0.0px 0.0px; font: 12.0px Calibri; color: #000000}</style>I'm trying to calculate the cumulative total up to a certain maximum. In the example below, I need column D to calculate the contribution amount (by multiplying Column B and Column C), but column D should only total up to 19000. Once the cumulative total of 19000 is reached, the subsequent rows should be reduced.

[TABLE="class: grid, width: 395"]
<colgroup><col span="2"><col><col><col></colgroup><tbody>[TR]
[TD][/TD]
[TD]A[/TD]
[TD]B[/TD]
[TD]C[/TD]
[TD]D[/TD]
[/TR]
[TR]
[TD="align: right"]1[/TD]
[TD]Pay Date[/TD]
[TD]Wages[/TD]
[TD]% Elected[/TD]
[TD]Contribution Calculation[/TD]
[/TR]
[TR]
[TD="align: right"]2[/TD]
[TD="align: right"]1/1/19[/TD]
[TD="align: right"]$10,000.00[/TD]
[TD="align: right"]25%[/TD]
[TD="align: right"]$2,500.00[/TD]
[/TR]
[TR]
[TD="align: right"]3[/TD]
[TD="align: right"]1/15/19[/TD]
[TD="align: right"]$10,000.00[/TD]
[TD="align: right"]25%[/TD]
[TD="align: right"]$2,500.00[/TD]
[/TR]
[TR]
[TD="align: right"]4[/TD]
[TD="align: right"]1/29/19[/TD]
[TD="align: right"]$10,000.00[/TD]
[TD="align: right"]25%[/TD]
[TD="align: right"]$2,500.00[/TD]
[/TR]
[TR]
[TD="align: right"]5[/TD]
[TD="align: right"]2/12/19[/TD]
[TD="align: right"]$10,000.00[/TD]
[TD="align: right"]25%[/TD]
[TD="align: right"]$2,500.00[/TD]
[/TR]
[TR]
[TD="align: right"]6[/TD]
[TD="align: right"]2/26/19[/TD]
[TD="align: right"]$10,000.00[/TD]
[TD="align: right"]25%[/TD]
[TD="align: right"]$2,500.00[/TD]
[/TR]
[TR]
[TD="align: right"]7[/TD]
[TD="align: right"]3/12/19[/TD]
[TD="align: right"]$10,000.00[/TD]
[TD="align: right"]25%[/TD]
[TD="align: right"]$2,500.00[/TD]
[/TR]
[TR]
[TD="align: right"]8[/TD]
[TD="align: right"]3/26/19[/TD]
[TD="align: right"]$10,000.00[/TD]
[TD="align: right"]25%[/TD]
[TD="align: right"]$2,500.00[/TD]
[/TR]
[TR]
[TD="align: right"]9[/TD]
[TD="align: right"]4/9/19[/TD]
[TD="align: right"]$10,000.00[/TD]
[TD="align: right"]25%[/TD]
[TD="align: right"]$1,500.00[/TD]
[/TR]
[TR]
[TD="align: right"]10[/TD]
[TD="align: right"]4/23/19[/TD]
[TD="align: right"]$10,000.00[/TD]
[TD="align: right"]25%[/TD]
[TD="align: right"]$0.00[/TD]
[/TR]
[TR]
[TD="align: right"]11[/TD]
[TD="align: right"]5/7/19[/TD]
[TD="align: right"]$10,000.00[/TD]
[TD="align: right"]25%[/TD]
[TD="align: right"]$0.00[/TD]
[/TR]
</tbody>[/TABLE]
 

Excel Facts

Remove leading & trailing spaces
Save as CSV to remove all leading and trailing spaces. It is faster than using TRIM().
Try this

<b>Sheet</b><br /><br /><table border="1" cellspacing="0" style="font-family:Calibri,Arial; font-size:11pt; background-color:#ffffff; "> <colgroup><col style="font-weight:bold; width:30px; " /><col style="width:104px;" /><col style="width:100px;" /><col style="width:99px;" /><col style="width:176px;" /></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></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >1</td><td style="background-color:#ffff00; ">Pay Date</td><td style="background-color:#ffff00; ">Wages</td><td style="background-color:#ffff00; ">% Elected</td><td style="background-color:#ffff00; ">Contribution Calculation</td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >2</td><td style="text-align:right; ">01/01/2019</td><td style="text-align:right; ">$10,000.00</td><td style="text-align:right; ">25%</td><td style="text-align:right; ">2500</td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >3</td><td style="text-align:right; ">15/01/2019</td><td style="text-align:right; ">$10,000.00</td><td style="text-align:right; ">25%</td><td style="text-align:right; ">2500</td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >4</td><td style="text-align:right; ">29/01/2019</td><td style="text-align:right; ">$10,000.00</td><td style="text-align:right; ">25%</td><td style="text-align:right; ">2500</td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >5</td><td style="text-align:right; ">12/02/2019</td><td style="text-align:right; ">$10,000.00</td><td style="text-align:right; ">25%</td><td style="text-align:right; ">2500</td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >6</td><td style="text-align:right; ">26/02/2019</td><td style="text-align:right; ">$10,000.00</td><td style="text-align:right; ">25%</td><td style="text-align:right; ">2500</td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >7</td><td style="text-align:right; ">12/03/2019</td><td style="text-align:right; ">$10,000.00</td><td style="text-align:right; ">25%</td><td style="text-align:right; ">2500</td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >8</td><td style="text-align:right; ">26/03/2019</td><td style="text-align:right; ">$10,000.00</td><td style="text-align:right; ">25%</td><td style="text-align:right; ">2500</td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >9</td><td style="text-align:right; ">09/04/2019</td><td style="text-align:right; ">$10,000.00</td><td style="text-align:right; ">25%</td><td style="text-align:right; ">1500</td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >10</td><td style="text-align:right; ">23/04/2019</td><td style="text-align:right; ">$10,000.00</td><td style="text-align:right; ">25%</td><td style="text-align:right; ">0</td></tr><tr style="height:18px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >11</td><td style="text-align:right; ">07/05/2019</td><td style="text-align:right; ">$10,000.00</td><td style="text-align:right; ">25%</td><td style="text-align:right; ">0</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></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 >D2</td><td >=IF(B2*C2+SUM($D$1:D1)<=19000,B2*C2,19000-SUM($D$1:D1))</td></tr></table></td></tr></table> <br /><br />
 
Upvote 0
I'm glad to help you. Thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,223,893
Messages
6,175,242
Members
452,623
Latest member
russelllowellpercy

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