Skip to content
xlsoffice. All Rights Reserved
  • Home
  • Excel For Beginners
  • Excel Intermediate
  • Advanced Excel For Experts

Lookup and Reference Examples

  • How to get last row in numeric data in Excel
  • Basic INDEX MATCH approximate in Excel
  • How to get relative row numbers in a range in Excel
  • How to use Excel OFFSET function
  • How to use Excel INDIRECT Function

Data Analysis Examples

  • How To Perform and Interpret Regression Analysis in Excel
  • Understanding Pivot Tables in Excel
  • How to count table rows in Excel
  • How To Sort One Column or Multiple Columns in Excel
  • How to create Gauge Chart in Excel

Data Validation Examples

  • Prevent invalid data entering in specific cells
  • Excel Data validation allow uppercase only
  • Excel Data validation must contain specific text
  • Excel Data validation only dates between
  • Excel Data validation number multiple 100

Count rows with at least n matching values

by

This tutorial shows how to Count rows with at least n matching values using the example below;

Formula

{=SUM(--(MMULT(--(criteria),TRANSPOSE(COLUMN(data)^0))>=N))}

Explanation

To count rows that contain specific values, you can use an array formula based on the MMULT, TRANSPOSE, COLUMN, and SUM functions. In the example shown, the formula in K6 is:

{=SUM(--(MMULT(--((data)<70),TRANSPOSE(COLUMN(data)^0))>=2))}

where data is the named range C5:I14.

Note this is an array formula and must be entered with control shift enter.

Worked Example:   How to get first column number in range in Excel

How this formula works

Working from the inside out, the logical criteria used in this formula is:

(data)<70

where data is the named range C5:I14. This generates a TRUE / FALSE result for every value in data, and the double negative coerces the TRUE FALSE values to 1 and 0 to yield an array like this:

{0,0,0,1,0,1,0;0,0,0,0,0,0,0;0,0,0,0,0,0,0;0,1,1,0,0,1,0;0,0,0,0,0,0,0;0,0,0,0,0,0,0;0,0,0,0,0,0,0;0,1,0,0,0,0,0;0,0,0,0,0,0,0;0,0,0,0,0,0,0}

Like the original data, this array is 10 rows by 7 columns (10 x 7) and goes into the MMULT function as array1. The next argument, array2 is created with:

TRANSPOSE(COLUMN(data)^0))

Here, the COLUMN function is used as a way to generate a numeric array of the right size, since matrix multiplication requires the column count in array1 (7) to equal the row count in array2.

Worked Example:   Convert column letter to number in Excel

The COLUMN function returns the 7-column array {3,4,5,6,7,8,9}. By raising this array to a power of zero, we end up with a 7 x 1 array like {1,1,1,1,1,1,1}, which TRANSPOSE changes to a 1 x 7 array like {1;1;1;1;1;1;1}.

Worked Example:   MMULT function: Description, Usage, Syntax, Examples and Explanation

MMULT then runs and returns a 10 x 1 array result {2;0;0;3;0;0;0;1;0;0}, which is processed with the logical expression >=2, resulting in an array of TRUE FALSE values:

{TRUE;FALSE;FALSE;TRUE;FALSE;FALSE;FALSE;FALSE;FALSE;FALSE}.

We again coerce TRUE FALSE to 1 and 0 with a double negative to get a final array inside SUM:

=SUM({1;0;0;1;0;0;0;0;0;0})

Which correctly returns 2, the number of names with at least 2 scores below 70.

Post navigation

Previous Post:

Count visible rows only with criteria in Excel

Next Post:

Count rows that contain specific values in Excel

Leave a Reply Cancel reply

Your email address will not be published. Required fields are marked *

Learn Basic Excel

Ribbon
Workbook
Worksheets
Format Cells
Find & Select
Sort & Filter
Templates
Print
Share
Protect
Keyboard Shortcuts

Categories

  • Charts
  • Data Analysis
  • Data Validation
  • Excel Functions
    • Cube Functions
    • Database Functions
    • Date and Time Functions
    • Engineering Functions
    • Financial Functions
    • Information Functions
    • Logical Functions
    • Lookup and Reference Functions
    • Math and Trig Functions
    • Statistical Functions
    • Text Functions
    • Web Functions
  • Excel VBA
  • Excel Video Tutorials
  • Formatting
  • Grouping
  • Others
  • Normalize text by removing punctuations, extra spaces and more in Excel
  • Join cells with comma in Excel
  • Get last name from name with comma — Manipulating NAMES in Excel
  • How to check if cell contains some words but not others in Excel
  • Extract most frequently occurring text in Excel
  • Calculate years between dates in Excel
  • How to calculate months between dates in Excel
  • DATE function: Description, Usage, Syntax, Examples and Explanation
  • Add months to date in Excel
  • How to calculate quarter from date in Excel
  • COUPDAYS function: Description, Usage, Syntax, Examples and Explanation
  • ODDFYIELD function: Description, Usage, Syntax, Examples and Explanation
  • YIELDDISC function: Description, Usage, Syntax, Examples and Explanation
  • MIRR function: Description, Usage, Syntax, Examples and Explanation
  • INTRATE function: Description, Usage, Syntax, Examples and Explanation
© 2022 xlsoffice . All Right Reserved. | Teal Smiles