Pini has a range of whole numbers (let's say C2:J2) and some of the numbers can be odd and some even. He would like a formula to count the number of odd values in the range and another to count the number of even values in the range.
There are a couple of ways to derive the desired counts, without resorting to intermediate values or macros. One way is to use an array formula, such as the following, to determine a count of odd values:
=SUM((MOD(C2:J2,2)<>0)*1)
Enter the formula using Ctrl+Shift+Enter and you get the desired count. Only a small change is required for the array formula to return the count of even numbers:
=SUM((MOD(C2:J2,2)=0)*1)
If you prefer to not use an array formula, you could use SUMPRODUCT to return the same count, as a regular formula. For example, here is the formula to return a count of odd values:
=SUMPRODUCT(--(MOD(C2:J2,2)=1),--(C2:J2<>""))
This is the formula for even values:
=SUMPRODUCT(--(MOD(C2:J2,2)=0),--(C2:J2<>""))
Another advantage of using the SUMPRODUCT approach is that it compensates for possible blank cells in your range. The earlier array formulas will always count blank cells as if they contain an even value.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (7987) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Office 365. You can find a version of this tip for the older menu interface of Excel here: Counting Odds and Evens.
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!
Looking for a formula that can return the address of a cell containing a text string? Look no further; the solution is in ...
Discover MoreAt the heart of working with Excel is the process of creating formulas that calculate results based on information within ...
Discover MoreThere are times when it can be beneficial to combine both numbers and text in the same cell. This can be easily done ...
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 © 2021 Sharon Parq Associates, Inc.
Comments