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)

5

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

Running Out of Memory

Do you get an error when you try to insert just one more chart in your workbook? It could be because of an obscure ...

Discover More

Flashing Cells

Want to draw attention to some information in a particular cell? Make the cell flash, on and off. Here's how you can ...

Discover More

Using Multiple References to the Same Footnote

Do you want to have multiple footnote references to the same actual footnote in a document? The easiest way to do this is to ...

Discover More

Solve Real Business Problems Master business modeling and analysis techniques with Excel and transform data into bottom-line results. This hands-on, scenario-focused guide shows you how to use the latest Excel tools to integrate data from multiple tables. Check out Microsoft Excel 2013 Data Analysis and Business Modeling today!

MORE EXCELTIPS (MENU)

Counting Consecutive Negative Numbers

If you have a range of values that can be either positive or negative, you might wonder how to determine the largest ...

Discover More

Character Replacement in Simple Formulas

Do you see some small rectangular boxes appearing in your formula results? It could be because Excel is substituting that box ...

Discover More

Understanding Operators

At the heart of working with Excel is the process of creating formulas that calculate results based on information within a ...

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:

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}] in your comment text. You’ll be prompted to upload your image when you submit the comment. 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 two more than 9?

2014-08-04 03:06:09

Jackie

Hi, i failed to get this one, all i needed was to know the values below a certain number eg 26 where i would get 8. i think if we have the values put in an excel spreadsheet it would help


thanks


2014-04-01 05:34:28

Michael (Micky) Avidan

@Tim,
Thanks for checking the "Extreme case" - however, it looks as if you (like me) prefer formulas to be as short as possible - then "+(A2<E1)" will do the same job.
By the way - when using a single(!) formula, all the obsulute references ($$$) become superfluous.
Michael (Micky) Avidan
“Microsoft® Answers" - Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2014)
ISRAEL


2014-03-31 14:10:31

Tim Murphy

I took Micky formula and added an IF statement to the end. Not eloquent, but it works.

=SUM(N(($A$2:$A$16>=$E$1)+($A$1:$A$15<$E$1)=0))+IF($A$2<$E$1,1,0)


2014-03-31 14:05:35

Tim Murphy

If 28 is the test, it should be four groups.

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

If the first value is part of the group the suggested formulas don't work. They return 3 for an answer, except this suggestion (array formula).

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


2014-03-29 13:28:52

Michael (Micky) Avidan

To begin with, if you want to use the helper-column "B" - the formula can be a lot simplier.
Starting in "B2" type: =IF(OR(A2>=E$1,A1<E$1),,1) and copy down.

The more proffessional/appropriate way to count the groups into ONE SINGLE cell (without any helper cells) is the Array Formula:
=SUM(N((A2:A16>=E$1)+(A1:A15<E$1)=0))

Michael (Micky) Avidan
“Microsoft® Answers" - Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2014)
ISRAEL


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.

Links and Sharing