Find last date running total equalled zero

RandomTandem

New Member
Joined
Jul 10, 2017
Messages
17
If I have a list of dates (in chronological order) in Column A and a list of stock purchases or sales in column B. Is there a formula which will help me find the last date where the running total was equal to zero prior to a date I put in cell C1?

In the below example, If I put 13th Aug in cell C1, it would tell me 12th Aug but if I had 15th Aug in cell C1, it would put 14th Aug

DatePurchase/Sale Amount
10th Aug+5
11th Aug+10
12th Aug-15
13th Aug+80
14th Aug-80
15th Aug10

<tbody>
</tbody>


I would normally use a helper column to achieve this but I cannot do it in this example.

Thank you.
 
Are the values below A and B calculated by means of a formula? if so, care to post that formula?

No, they are hard coded. In fact, the values in columns A to C are all hard coded

By way of explanation, the spreadsheet is for a stock portfolio where I have a number of different brokerage accounts (these are the accounts A, B etc etc). If you are able (and thank you for all your help) to figure out the last time that the position was zero in any given account for any given date, it will help me work out my UK tax cost basis

Here's how it works:

Day 1: I buy 10 shares at a price of £10. My position is long 10 at an average price of £10
Day 2: I buy 10 shares at a price of £12. My position is long 20 at an average price of £11
Day 3: I sell 5 shares at a price of £15. My position is long 15 at an average price of £11 (my taxable profit is (£15-£11) per share on 5 share = £20. Note: my average buy price is not affected, it is still £11
Day 4: I sell the remaining 15 shares at £15, my tax able profit is £4 x 15 = £60.

As my position is now 0. The average price calculation resets

So, if on day 5,I buy 5 shares at £22, my cost basis is now long 5 at £22 i.e. none of the prices on days 1-4 matter.

So that's why I need to know at any point in time when was the last period that my position in a stock was 0 at each and every account.

Thanks again.
 
Upvote 0

Excel Facts

Spell Check in Excel
Press F7 to start spell check in Excel. Be careful, by default, Excel does not check Capitalized Werds (whoops)
How about the values in column D and E? I had these in mind when posing the question.


Cell D2: =SUMIF($A$2:A2,"A",$C$2:C2)


Cell E2: =SUMIF($A$2:A2,"B",$C$2:C2)

and so on.

I only put those two columns into help illustrate the problem

(there are actually about 10 brokerage accounts as well)
 
Upvote 0
Cell D2: =SUMIF($A$2:A2,"A",$C$2:C2)


Cell E2: =SUMIF($A$2:A2,"B",$C$2:C2)

and so on.

I only put those two columns into help illustrate the problem

(there are actually about 10 brokerage accounts as well)

Isthe following admissible?

Row\Col
A​
B​
C​
D​
E​
F​
G​
H​
I​
J​
K​
1​
AccountDateBuy/SellABCfirst datelast date
2​
B
16-Jul-17
200
-
200
-A
23-Jul-17
23-Jul-17
3​
A
17-Jul-17
50
50
--B
19-Jul-17
24-Jul-17
4​
A
18-Jul-17
10
10
--
5​
B
19-Jul-17
-200
-
-200
-
6​
A
20-Jul-17
-40
-40
--
7​
B
21-Jul-17
40
-
40
-
8​
A
22-Jul-17
50
50
--
9​
A
23-Jul-17
-70
-70
--
10​
B
24-Jul-17
-40
-
-40
-

In D2 just enter and copy across:

=IF($A2=D$1,SUMIFS($C2:C2,$A2:A2,$A2),"-")

In I2 control+shift+enter, not just enter, and copy down:

=INDEX($B$2:$B$10,MATCH(0,IF($A$2:$A$10=INDEX($D$1:$F$1,ROWS($I$2:I2)),SUBTOTAL(9,OFFSET(INDEX($D$2:$F$10,1,MATCH($H2,$D$1:$F$1,0)),0,0,ROW($B$2:$B$10)-ROW($B$2)+1)),"-"),0))

In K2 control+shift+enter, not just enter, and copy down:

=LOOKUP(9.99999999999999E+307,1/(IF($A$2:$A$10=INDEX($D$1:$F$1,ROWS($I$2:I2)),SUBTOTAL(109,OFFSET(INDEX($D$2:$F$10,1,MATCH($H2,$D$1:$F$1,0)),0,0,ROW($B$2:$B$10)-ROW($B$2)+1)),"-")=0),$B$2:$B$10)
 
Upvote 0

Forum statistics

Threads
1,214,985
Messages
6,122,606
Members
449,089
Latest member
Motoracer88

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