Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, and 2013. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Counting Groupings Below a Threshold.
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)
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (8888) applies to Microsoft Excel 2007, 2010, and 2013. You can find a version of this tip for the older menu interface of Excel here: Counting Groupings Below a Threshold.
Excel Smarts for Beginners! Featuring the friendly and trusted For Dummies style, this popular guide shows beginners how to get up and running with Excel while also helping more experienced users get comfortable with the newest features. Check out Excel 2013 For Dummies today!
Excel allows you to enter two different types of formulas in a cell: A regular formula or an array formula. If you need ...
Discover MoreNeed to know a count of unique values in a range of cells? There are a couple of ways you can tackle the problem.
Discover MoreWhen processing huge amounts of data, it can be a challenge to figure out how to derive the aggregate values you need. ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2018-12-10 18:11:15
Yvan Loranger
The array formula is good but the 2 preceding formulae come 1 short if the sequence begins with a number below the threshold; ie the formulae indicate 3 instead of 4 groups.
2015-11-25 16:17:39
Tom Watkins
I have just read about this tip in your book, "Amazing Array Formulas", and attempted to set up this scenario in Excel myself to experiment.
All went as you published until I entered 28 as the arbitrary threshold in cell E1.
So I see that to make this method work, the first number in the series (27 in this case) must be above the threshold that I want to measure against.
Now to go on and read the part about using arrays :-).
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 © 2024 Sharon Parq Associates, Inc.
Comments