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.

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:

If you would like to know how to use the macros described on this page (or on any other page on the ExcelTips sites), I've prepared a special page that includes helpful information. Click here to open that special page in a new browser tab.

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.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Pulling Apart Characters in a Long String

You can easily use formulas to pull apart text stored in a cell. For instance, if you need to pull individual characters ...

Discover More

Controlling the Bold Text Attribute

When processing a document in a macro, you may need to make some of your text bold. It's easy to do using the Bold ...

Discover More

Using the Style Area

The style area is an esoteric feature of Word that allows you to easily see the styles applied to the paragraphs in your ...

Discover More

Program Successfully in Excel! This guide will provide you with all the information you need to automate any task in Excel and save time and effort. Learn how to extend Excel's functionality with VBA to create solutions not possible with the standard features. Includes latest information for Excel 2024 and Microsoft 365. Check out Mastering Excel VBA Programming today!

More ExcelTips (menu)

Summing Digits in a Value

Want to add up all the digits in a given value? It's a bit trickier than it may at first seem.

Discover More

Automatically Numbering Rows

Adding row numbers to a column of your worksheet is easy; you just need to use a formula to do it. Here's a quick look at ...

Discover More

Simulating Alt+Enter in a Formula

You can use the Alt+Enter keyboard shortcut while entering information in order to force your data onto multiple lines in ...

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] (all 7 characters, in the sequence shown) in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is 8 - 4?

There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)


This Site

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.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.