Written by Allen Wyatt (last updated October 5, 2024)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021
Mike has a column in his worksheet that contains numeric values. Some are static values, while others are the result of formulas. He needs a count of all values in the column that are within 10% of a target value. So, if the target value is 5, then Mike needs a count of all values in the column that are between 4.5 and 5.5.
This can be done with the COUNTIFS function, which counts the number of values that match multiple criteria. In generating a count, it doesn't really matter if the values in the column are static or generated by a formula. Here, for instance, is a formula that will produce the count that Mike needs:
=COUNTIFS(A:A,">=4.5",A:A,"<=5.5")
The COUNTIFS function requires "pairs" of parameters, with the first one being the range to be evaluated and the second being the comparison that needs to be used against the range. So, in this instance, all the values in column A are compared to see if they are greater than or equal to 4.5 and the same range is compared to see if the values are less than or equal to 5.5.
You can make the formula more flexible by using the desired target value and calculating the 10% below and above, in this manner:
=COUNTIFS(A:A,">="&5*0.9,A:A,"<="&5*1.1)
In this case, notice that the comparison can be considered TRUE (and thus included in the count) if the value is inclusively between 4.5 and 5.5. If you prefer that the match not be inclusive, then you simply have to change the comparison operator:
=COUNTIFS(A:A,">"&5*0.9,A:A,"<"&5*1.1)
You could, of course, replace the in-formula target value with a cell reference that would, in turn, contain the target value:
=COUNTIFS(A:A,">"&B1*0.9,A:A,"<"&B1*1.1)
There are other approaches you can use besides the COUNTIFS function, if you prefer. For instance, either of the following will work just fine, once the target value is in cell B1:
=SUMPRODUCT((A:A>=B1*0.9)*(A:A<=B1*1.1)) =SUM(--(ABS(A:A/B1-1)<=0.1))
If you are using an older version of Excel (older than Excel 2021 or the Excel in Microsoft 365), then you'll need to enter these as array formulas using Ctrl+Shift+Enter.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (6070) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021.
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 data in Excel, you often need to determine if that data meets criteria that you specify. This tip ...
Discover MoreYou can use the naming capabilities of Excel to name both ranges and formulas. Accessing that named information in a ...
Discover MoreSometimes it can be confusing to figure out the source of an error that is displayed in your worksheet. Excel provides a ...
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 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