Skip to content
Free Excel Tutorials
  • Home
  • Excel For Beginners
  • Excel Intermediate
  • Advanced Excel For Experts

Data Analysis

  • Everything about Charts in Excel
  • Conditional Formatting New Rule with Formulas in Excel
  • Conditional Formatting Icon Sets Examples in Excel
  • How to Create Thermometer Chart in Excel
  • How To Create Frequency Distribution in Excel

References

  • Convert text string to valid reference in Excel using Indirect function
  • Last row number in range
  • How to use Excel TRANSPOSE Function
  • MATCH function: Description, Usage, Syntax, Examples and Explanation
  • How to use Excel OFFSET function

Data Validations

  • Excel Data validation don’t exceed total
  • Excel Data validation only dates between
  • Excel Data validation with conditional list
  • Excel Data validation unique values only
  • Excel Data validation date in next 30 days

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.

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.

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}.

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:

How to use Excel CHOOSE Function

Next Post:

Customize Ribbon 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

Logical Functions

  • Nested IF function example in Excel
  • IF function: Description, Usage, Syntax, Examples and Explanation
  • How to use Excel FALSE Function
  • IF with boolean logic in Excel
  • NOT function: Description, Usage, Syntax, Examples and Explanation

Date Time

  • Custom weekday abbreviation in Excel
  • HOUR function: Description, Usage, Syntax, Examples and Explanation
  • Convert date string to date time in Excel
  • Get days, months, and years between dates in Excel
  • Next biweekly payday from date in Excel

Grouping

  • Categorize text with keywords in Excel
  • Group times into 3 hour buckets in Excel
  • How to randomly assign people to groups in Excel
  • Group numbers with VLOOKUP in Excel
  • Group arbitrary text values in Excel

General

  • Common Errors in Excel
  • Check if multiple cells have same value in Excel
  • Sum by group in Excel
  • Print Excel Sheet In Landscape Or Portrait
  • How to generate random number between two numbers in Excel
© 2025 xlsoffice . All Right Reserved. | Teal Smiles | Abbreviations And Their Meaning