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: Counting Groupings Below a Threshold.

Counting Groupings Below a Threshold

by Allen Wyatt
(last updated March 29, 2014)

Ronald imports a number of signal-level measurements as a series of values into Excel. He needs to count how many consecutive groups of values exist in this series which fall below a certain threshold. For example, he may have the following measurements:

27, 22, 22, 30, 32, 18, 22, 23, 28, 39, 24, 27, 35, 25, 21

If he wants to know the number of groupings where the members of those groupings were under 26, the answer would be 4. Note that this is the groupings of consecutive values below 26, not the number of individual values below 26. Thus, in this case, the four groupings would be shown by the brackets in the following:

27, [22, 22], 30, 32, [18, 22, 23], 28, 39, [24], 27, 35, [25, 21]

Ronald is wondering what sort of formula he can use to figure out the number of groupings that fall below some arbitrary threshold he might specify.

There are actually several different ways you can approach this. The first is to use a "results column" that essentially notes changes in threshold and sequence grouping. For instance, if you had the above values in column A of a worksheet (starting at cell A2) and the threshold value in cell E1, then you could use the following formula in every cell to the right of a value in column A:

=IF(A2>=$E$1,B1,IF(A1<$E$1,B1,B1+1))

The formula keeps a running sum of the groups below the threshold. The max (or last value) of column B provides the total number of groups below the threshold. The formula checks to see whether the value immediately to the left, in column A, is above or below the threshold. If it's above, or if not and the previous value in column A was also below, then it doesn't increment the running sum. Otherwise, it does increment because a new grouping is starting.

A related way of doing the count is to use this formula in column B, instead:

=IF(A2>=$E$1,0,IF(A1<$E$1,0,1))

This results in column B containing a series of 0 or 1 values. The only time that a 1 value occurs is at the start of a series that is below the threshold. This makes it easy to sum all the values in column B, which provides the count of groupings.

If you don't want to use the results column, you can use an array formula to figure out the count. The following formula assumes, again, that the values to be analyzed are in column A, beginning at A2, and that the threshold value is in cell E1. Remember, as well, that array formulas are entered by pressing Ctrl+Shift+Enter.

=SUM(IF((A2:A16<$E$1)*((A2:A16<$E$1)*1<>((A1:A15<$E$1)*ISNUMBER(A1:A15))),1))

The formula basically does what the previous results-column formula did (determines a 0 or 1 based on whether a below-threshold grouping is starting) and then sums those values.

Of course, if you do these types of comparisons a lot, you may want to develop your own user-defined function (a macro) to figure the count of groupings for you. The following is an example of such a function.

Function CountGroups(ByVal MyRange As Range, Threshold As Single)
    Dim Cell As Range
    Dim bInGroup As Boolean
    Dim iCount As Integer

    Application.Volatile
    iCount = 0
    bInGroup = False
    For Each Cell In MyRange
        If Application.IsNumber(Cell) Then
            If Cell < Threshold Then 'Less than the threshold?
                If Not bInGroup Then  'Only count if starting new group
                    iCount = iCount + 1
                    bInGroup = True     'Mark as being in group
                End If
            Else
                bInGroup = False        'No longer in a group
            End If
        End If
    Next
    CountGroups = iCount
End Function

The function looks through each cell in a range and calculates if it is the start of a new below-threshold group or not. You use the function by using a formula such as the following in your worksheet:

=CountGroups(A2:A16,E1)

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (3171) 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: Counting Groupings Below a Threshold.

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

Resetting Character Formatting in a Macro

Want your macro to get rid of the formatting applied to a selection of text? It's easy enough to do using the Reset method, ...

Discover More

Editing Individual Cells

Need to edit the data within a cell? There are any number of ways you can perform the edit; this tip documents them all.

Discover More

Standard Text before a Sequence Number

When you use fields to number items within a document, you may want to add some standard text before each field. There are a ...

Discover More

Professional Development Guidance! Four world-class developers offer start-to-finish guidance for building powerful, robust, and secure applications with Excel. The authors show how to consistently make the right design decisions and make the most of Excel's powerful features. Check out Professional Excel Development today!

MORE EXCELTIPS (MENU)

Tracking Down Invalid References

When you discover that there is an invalid reference in a workbook, you can have a bear of a time tracking down the problem. ...

Discover More

How Operators are Evaluated

Operators are used in formulas to instruct Excel what to do to arrive at a result. Not all operators are evaluated in the ...

Discover More

Summing Only the Largest Portion of a Range

Given a range of cells, you may at some time want to calculate the sum of only the largest values in that range. Here is an ...

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 for this tip:

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.

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.

Links and Sharing
Share