Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Calculating the Interval between Occurrences.
Written by Allen Wyatt (last updated January 9, 2024)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
Roger asked if there was a way to calculate the interval between occurrences of values in a list. For instance, he has several thousand numbers in column A. Looking at the value in cell A351, the last time that value occurred in the list was in cell A246. He would like a formula that could be placed in cell B351 and return 105, the difference between 351 and 246.
This approach is difficult to implement in Excel because Excel is not very good at searching backwards—up a column. If the premise could be reversed, then the task becomes much simpler. For instance, if a formula in cell B246 could return the value 105, indicating the interval until the next occurrence of the value in cell A246, instead of calculating the last occurrence. The following formula calculates the next occurrence of the value in cell A1:
=MATCH(A1,A2:$A$65536,0)
Place this formula in cell B1 and copy it down however many cells are necessary. If the value in column A does not occur again in the column, then the formula returns the #N/A error. If you would rather have the formula return 0, then the following works:
=IF(ISNA(MATCH(A1,A2:$A$65536,0)),0,MATCH(A1,A2:$A$65536,0))
If you absolutely must count upwards (find the previous occurrence instead of the next occurrence), then the easiest way to do it is with a user-defined function. The following function, RowInterval, will look backward through a range you specify and return the desired interval:
Function RowInterval(TestCell As Range, LookHere As Range) As Long Dim varValue As Variant Dim lngRow As Long Application.Volatile varValue = TestCell.Value 'Check for occurrences of the test value in the search range If WorksheetFunction.CountIf(LookHere, varValue) > 0 Then With LookHere 'Get the last row of the search range lngRow = .Row + .Rows.Count - 1 'Start with the last cell in the search range and work up Do Until .Item(lngRow, 1).Value = varValue lngRow = lngRow - 1 Loop End With 'Subtract the number of the row containing the found occurrence 'from the number of the row containing the test value RowInterval = TestCell.Row - lngRow End If End Function
In order to use the function, you would put the following formula in cell B2, and then copy the formula down the number of desired cells:
=RowInterval(A2,A$1:A1)
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (10258) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Calculating the Interval between Occurrences.
Comprehensive VBA Guide Visual Basic for Applications (VBA) is the language used for writing macros in all Office programs. This complete guide shows both professionals and novices how to master VBA in order to customize the entire Office suite for their needs. Check out Mastering VBA for Office 2010 today!
One of the areas in which Excel provides worksheet functions is in the arena of statistical analysis. You may want to ...
Discover MoreNeed to get at the next-to-last value in a column, regardless of how many cells are used within that column? This tip ...
Discover MoreIt is easy to use Excel functions to sum values based on criteria you establish, unless those criteria involve the ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2021-01-30 12:51:55
Willy Vanhaelen
Although Excel is not very good at searching backwards, VBA certainly is. The user defined function (UDF) in this tip doesn't exactly do what Roger asks. You still need a helper column in which you have to copy down the function formula which is to much hassle. Besides the UDF is way to complicated.
What Roger exactly asks (and even more) can be done with this tiny macro:
Function RowInterval(Lookfor As Range) As Long
Application.Volatile
Dim X As Long
For X = Lookfor.Row - 1 To 1 Step -1
If Cells(X, 1) = Lookfor Then Exit For
Next
If X Then RowInterval = Lookfor.Row - X
End Function
To use this function place the cell pointer in cell B351 (or any cell of your choice) and enter as in the example (see 1st paragraph):
=RowInterval(A351) --> the cell yields 105. When no match is found the UDF returns zero.
2021-01-28 12:13:53
Randy Deinlein
Excel has seemed to replace MATCH with XMATCH so it can count upwards apparently. Have to attempted to perform this action using XMATCH?
2018-12-08 21:06:13
Steven
Allen,
I want to thank you for your helpful article here. You have written, what I regard to be, a very straight-forward and easy to understand function.
This particular subject: "Calculating the Interval between Occurrences" has been of interest to me for some time now. However, before finding your article, I had been struggling to accomplish the same task using Range .Find and .FindNext. I think I am pretty close to figuring it out. But, the method you have provided here is really appreciated.
I perceive that you are a person who would welcome helpful feedback. Therefore, I have decided to include with my comment a couple of very small corrections, which improve the code you have written so that the function will now calculate the expected results.
The following line of code does not allow the function to bring back the expected results consistently, when I tested it.
Do Until .Item(lngRow, 1).Value = varValue
However, simply adding this code " - .Row + 1" (omitting quotation marks) after lngRow does yield the expected results (assuming the "Interval to Next Occurrence" is desired).
If the "Interval Between Occurrences" is desired, then include a " - 1" (omitting quotation marks) at the end of the following line of code.
RowInterval = TestCell.Row - lngRow 'Interval to Next Occurrence
RowInterval = TestCell.Row - lngRow - 1 'Interval Between Occurrences
I hope this helps you and others as well. Thank you again.
Steven
2018-02-02 02:28:57
Curtis
Hey Allen, Great Tip!! Trying to do a little more with it..
So the formula will analyze a column (A) and put an interval amount in your selected cell (B). If you drag this down in B, you'll get intervals for every cell respectively downward in column A. SO..
Say I have 5 different names scattered randomly in column (A). Column (B) should show only intervals between the name Mark, and (C) between Ben's and so on. Or is there perhaps a way to leave it a your way and some how label intervals of certain names so those can be selected in put into their own distinct columns?
2017-02-17 09:00:33
Michael (Micky) Avidan
Zac Lay,
Try: =MATCH(8,G:G)-MATCH(8,A:A)-1
--------------------------
Michael (Micky) Avidan
“Microsoft® Answers" - Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2017)
ISRAEL
2017-02-16 20:04:26
Zac Lay
i am looking for info in to how to do this....
Example: A2 contains the number 18. G14 contains the number 18. There are 11 rows between occurrences. I would like to output that number to the cell this formula resides in. I tried MATCH but it is too limited.
Is there a way to do this?
2016-09-08 17:30:12
Curtis Z
Hi. Thank you for posting this it has been helpful. Could you help with something similar I am trying to accomplish?
I have data in M2:R1825
Any given cell in preceding or following rows may have duplicate data of any other cell in that range, just never on the same row.
I am trying to figure out a way to count the rows between occurrences, not counting the row of last occurrence or the row of current occurrence.
Example: M2 contains the number 18. Q14 contains the number 18. There are 11 rows between occurrences. I would like to output that number to the cell this formula resides in. I tried MATCH but it is too limited.
Thank you for any help.
Z
Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2024 Sharon Parq Associates, Inc.
Comments