Last occurrence respective to current Cell

ItalianPlatinum

Well-known Member
Joined
Mar 23, 2017
Messages
857
Office Version
  1. 365
  2. 2019
Platform
  1. Windows
In google sheets I am looking for help to determine the below. I need to know the the duration between each condition as shown below

Book2
ABCDEFG
1DateMeansElapsed TimeElapsed Time From LastSHOULD BE
22/10/2023A
32/19/2023T9blankno last occurrence
42/25/2023T66
53/12/2023H15blankno last occurrence
63/21/2023T924
73/27/2023A645
83/30/2023A33
94/5/2023A66
104/11/2023A66
114/14/2023H333
124/23/2023B9blankno last occurrence
134/28/2023T538
144/30/2023A219
155/7/2023A77
165/11/2023A44
175/14/2023A33
185/19/2023A55
195/24/2023T526
205/29/2023A510
216/3/2023B541
226/9/2023A611
236/15/2023A66
246/19/2023A44
256/23/2023A44
Sheet1
Cell Formulas
RangeFormula
D3:D25D3=A3-A2
 

Excel Facts

Highlight Duplicates
Home, Conditional Formatting, Highlight Cells, Duplicate records, OK to add pink formatting to any duplicates in selected range.
I can't vouch for Google Sheets, but this works in Excel:

Book1
ABCDEF
1DateMeansElapsed TimeElapsed Time From LastSHOULD BE
22/10/2023A
32/19/2023T9 
42/25/2023T66
53/12/2023H15 
63/21/2023T924
73/27/2023A645
83/30/2023A33
94/5/2023A66
104/11/2023A66
114/14/2023H333
124/23/2023B9 
134/28/2023T538
144/30/2023A219
155/7/2023A77
165/11/2023A44
175/14/2023A33
185/19/2023A55
195/24/2023T526
205/29/2023A510
216/3/2023B541
226/9/2023A611
236/15/2023A66
246/19/2023A44
256/23/2023A44
Sheet5
Cell Formulas
RangeFormula
D3:D25D3=A3-A2
F3:F25F3=IFERROR(SUM(INDEX(D$3:D3,XMATCH(B3,B$2:B2,0,-1)):D3),"")
 
Upvote 0
Solution
Is that an Excel 365 only formula? currently using my 2019 version and kicks back blanks in excel. But it is actually working in google sheets. I in the meantime also came up with this they seems to both be yielding same results. Which is promising so thank you!

=A3-IF(MAXIFS($A$2:$A2,$B$2:$B2,B3)=0,A3,MAXIFS($A$2:$A2,$B$2:$B2,B3))
 
Upvote 0
XMATCH is only in Excel 2021 and newer. But after looking at your formula, I came up with another version that doesn't use XMATCH:

=IFERROR(A3-1/(1/MAXIFS(A$2:A2,B$2:B2,B3)),"")
 
Upvote 0
It works in google sheets so its fine. there is no drawback using XMATCH is there?
 
Upvote 0

Forum statistics

Threads
1,223,892
Messages
6,175,236
Members
452,621
Latest member
Laura_PinksBTHFT

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