Sum previous cells if previous cell was zero

KayserDK

New Member
Joined
Aug 29, 2019
Messages
4
Hello,

I'm stuck and I hope you guys can help me with this simple problem.

I'm trying to get the market returns (A) to sum over the days where the stock returns (B) is not available. I have tried with if and lookup function but I can't get it right.

I have copied a small section of the issue.

Best regards
/T

[TABLE="width: 500"]
<tbody>[TR]
[TD][TABLE="width: 256"]
<tbody>[TR]
[TD="width: 64"]Market[/TD]
[TD="class: xl67, width: 64"]Stock[/TD]
[TD="width: 64"]Result[/TD]
[TD="class: xl67, width: 64"][/TD]
[/TR]
[TR]
[TD="class: xl66, align: right"]-0,82%[/TD]
[TD="class: xl68, align: right"]-1,49%[/TD]
[TD="class: xl66, align: right"]-0,82%[/TD]
[TD="class: xl67"]A2[/TD]
[/TR]
[TR]
[TD="class: xl66, align: right"]1,22%[/TD]
[TD="class: xl68, align: right"]-0,77%[/TD]
[TD="class: xl66, align: right"]1,22%[/TD]
[TD="class: xl67"]A3[/TD]
[/TR]
[TR]
[TD="class: xl66, align: right"]1,25%[/TD]
[TD="class: xl68, align: right"]-0,27%[/TD]
[TD="class: xl66, align: right"]1,25%[/TD]
[TD="class: xl67"]..[/TD]
[/TR]
[TR]
[TD="class: xl66, align: right"]-0,99%[/TD]
[TD="class: xl68, align: right"]0,78%[/TD]
[TD="class: xl66, align: right"]-0,99%[/TD]
[TD="class: xl67"]..[/TD]
[/TR]
[TR]
[TD="class: xl66, align: right"]-0,83%[/TD]
[TD="class: xl68"][/TD]
[TD="class: xl66"][/TD]
[TD="class: xl67"]..[/TD]
[/TR]
[TR]
[TD="class: xl66, align: right"]-1,14%[/TD]
[TD="class: xl68"][/TD]
[TD="class: xl66"][/TD]
[TD="class: xl67"]..[/TD]
[/TR]
[TR]
[TD="class: xl66, align: right"]-0,91%[/TD]
[TD="class: xl68, align: right"]1,01%[/TD]
[TD="class: xl66, align: right"]-2,89%[/TD]
[TD="class: xl67"]SUM(A6:A8)[/TD]
[/TR]
[TR]
[TD="class: xl66, align: right"]0,01%[/TD]
[TD="class: xl68, align: right"]-2,27%[/TD]
[TD="class: xl66, align: right"]0,01%[/TD]
[TD="class: xl67"]A9[/TD]
[/TR]
[TR]
[TD="class: xl66, align: right"]0,14%[/TD]
[TD="class: xl68"][/TD]
[TD="class: xl66"][/TD]
[TD="class: xl67"]..[/TD]
[/TR]
[TR]
[TD="class: xl66, align: right"]0,31%[/TD]
[TD="class: xl68, align: right"]0,27%[/TD]
[TD="class: xl66, align: right"]0,46%[/TD]
[TD="class: xl67"]SUM(A10:A11)[/TD]
[/TR]
[TR]
[TD="class: xl66, align: right"]0,06%[/TD]
[TD="class: xl68, align: right"]2,58%[/TD]
[TD="class: xl65, align: right"]2,58%[/TD]
[TD="class: xl67"]A12[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[/TR]
</tbody>[/TABLE]
 

Excel Facts

Square and cube roots
The =SQRT(25) is a square root. For a cube root, use =125^(1/3). For a fourth root, use =625^(1/4).
If Column A all data are numeric value and % are in cell format

Then, in C2 formula copied down :

=IF((B2<>"")*(B1=""),SUM(INDEX(A$1:A1,MATCH(9^9,B$1:B1)+1):A2),IF(B2<>"",A2,""))

Regards
Bosco
 
Upvote 0
Try this array formula

<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:93.15px;" /><col style="width:82.69px;" /><col style="width:100.75px;" /></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></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >1</td><td >Market</td><td >Stock</td><td >Result</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >2</td><td style="text-align:right; ">-0.82%</td><td style="text-align:right; ">-1,49%</td><td style="text-align:right; ">-0.82%</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >3</td><td style="text-align:right; ">1.22%</td><td style="text-align:right; ">-0,77%</td><td style="text-align:right; ">1.22%</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >4</td><td style="text-align:right; ">1.25%</td><td style="text-align:right; ">-0,27%</td><td style="text-align:right; ">1.25%</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >5</td><td style="text-align:right; ">-0.99%</td><td style="text-align:right; ">0,78%</td><td style="text-align:right; ">-0.99%</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >6</td><td style="text-align:right; ">-0.83%</td><td > </td><td > </td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >7</td><td style="text-align:right; ">-1.14%</td><td > </td><td > </td></tr><tr style="height:32px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >8</td><td style="text-align:right; ">-0.91%</td><td style="text-align:right; ">1,01%</td><td style="text-align:right; ">-2.88%</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >9</td><td style="text-align:right; ">0.01%</td><td style="text-align:right; ">-2,27%</td><td style="text-align:right; ">0.01%</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >10</td><td style="text-align:right; ">0.14%</td><td > </td><td > </td></tr><tr style="height:32px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >11</td><td style="text-align:right; ">0.31%</td><td style="text-align:right; ">0,27%</td><td style="text-align:right; ">0.45%</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >12</td><td style="text-align:right; ">0.06%</td><td style="text-align:right; ">2,58%</td><td style="text-align:right; ">0.06%</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 >C2</td><td >{=IF(B2="","",IF(D1<>"",A2,SUM(INDIRECT("A"& MAX(IF($B1:B$2<>"",ROW($B1:B$2)))+1 ):A2)))}</td></tr></table></td></tr></table>

Array formulas
Entered with Ctrl+Shift+Enter. If entered correctly, Excel will surround with curly braces {}.
Note: Do not try and enter the {} manually yourself
 
Upvote 0
Or, the simple way

=IF(B3="","",SUM(A$2:A3)-SUM(E$1:E2))
 
Upvote 0

Forum statistics

Threads
1,223,248
Messages
6,171,027
Members
452,374
Latest member
keccles

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