Please Note: This article is written for users of the following Microsoft Excel versions: 97, 2000, 2002, and 2003. If you are using a later version (Excel 2007 or later), this tip may not work for you. For a version of this tip written specifically for later versions of Excel, click here: Calculating the Interval between Occurrences.
Written by Allen Wyatt (last updated September 21, 2024)
This tip applies to Excel 97, 2000, 2002, and 2003
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 (2338) applies to Microsoft Excel 97, 2000, 2002, and 2003. You can find a version of this tip for the ribbon interface of Excel (Excel 2007 and later) here: Calculating the Interval between Occurrences.
Create Custom Apps with VBA! Discover how to extend the capabilities of Office 2013 (Word, Excel, PowerPoint, Outlook, and Access) with VBA programming, using it for writing macros, automating Office applications, and creating custom applications. Check out Mastering VBA for Office 2013 today!
When working with large amounts of data, it is a good idea to make sure that the data all consistently follows a pattern. ...
Discover MoreYou can easily sum a series of values in Excel, but it is not so easy to sum the absolute values of each value in a ...
Discover MoreExcel provides several different ways that you can split apart the contents of a cell. One way it doesn't provide is to ...
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 menu interface (Excel 97, Excel 2000, Excel 2002, or Excel 2003)? This site is for you! If you use a later version of Excel, visit our ExcelTips site focusing on the ribbon 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