Written by Allen Wyatt (last updated October 18, 2025)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, 2021, 2024, 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.
Provided you are using Excel 2021, 2024, or Microsoft 365, the calculation is rather easy to do using the XMATCH function. Let's assume that Roger's values in column A begin in cell A1. You could put this formula in cell B2:
=XMATCH(A2,A$1:A1,0,-1)
It compares cell A2 with the range of cells in A1:A1, searching upwards. This may not seem very useful, but if you copy it down column B, what you end up with is the comparison range growing so that XMATCH is always comparing the value to the left with the range of cells above it, search up the column. Thus, if the formula is copied to cell B351, it will look like this:
=XMATCH(A351,A$1:A350,0,-1)
This is much handier, with one exception: XMATCH returns the row in which the last occurrence occurred, or it returns an #N/A value. Roger doesn't want the row, he wants the interval between the current row and the previous row. He certainly doesn't want #N/A values, either. So, the solution is to test for the #N/A value and, if it is found, return a blank. If a row is returned, then calculate the interval. That is done by placing the following in cell B2:
=IF(ISNA(XMATCH(A2,A$1:A1,0,-1)),"",ROW(A2)-XMATCH(A2,A$1:A1,0,-1))
If you enlist the help of the LET function, you can make the formula even shorter:
=LET(a,XMATCH(A2,A$1:A1,0,-1),IF(ISNA(a),"",ROW(A2)-a))
If you are using a version of Excel that doesn't include XMATCH (it was introduced in Excel 2021), then Roger's task becomes much more difficult because there was no way to search backwards, up a column. If the premise could be reversed, then the task becomes much simpler. For instance, if a formula in B246 could return the value 105, indicating the interval until the next occurrence of the value in cell 246, instead of calculating the last occurrence. The following formula, placed in cell B1, indicates the next occurrence of the value in cell A1:
=MATCH(A1,A2:A$10000,0)
Copy the formula 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$10000,0)),0,MATCH(A1,A2:A$10000,0))
Remember, in the above examples, that you may need to adjust the row indicator (10000) to something that reflects the largest row number you anticipate.
If you absolutely must count upwards and you cannot use XMATCH, 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 Variant Dim X As Long Application.Volatile RowInterval = "" If LookHere.Columns.Count > 1 Then RowInterval = "Too many columns" Else For X = LookHere.Rows.Count To 1 Step -1 If LookHere.Rows(X).Cells(1) = TestCell Then RowInterval = TestCell.Row - X Exit For End If Next X End If End Function
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, 2021, 2024, 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.
Create Custom Apps with VBA! Discover how to extend the capabilities of Office 365 applications with VBA programming. Written in clear terms and understandable language, the book includes systematic tutorials and contains both intermediate and advanced content for experienced VB developers. Designed to be comprehensive, the book addresses not just one Office application, but the entire Office suite. Check out Mastering VBA for Microsoft Office 365 today!
When you edit a worksheet, adding and deleting rows and columns, Excel automatically updates references to cells ...
Discover MoreNeed to count the number of cells in a range that are not blank? You can use the COUNTA function of a more complex ...
Discover MoreIf you have a long numeric value in a cell, you may have a need to remove the last digit of that value. You can do so ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
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 © 2025 Sharon Parq Associates, Inc.
Comments