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

Data Analysis

  • How to calculate correlation coefficient Correlation in Excel
  • How to create running total in an Excel Table
  • Conflicting Multiple Conditional Formatting Rules in Excel
  • Managing Conditional Formatting Rules in Excel
  • How To Compare Two Lists in Excel

References

  • Two-column Lookup in Excel
  • How to get address of first cell in range in Excel
  • How to use Excel INDIRECT Function
  • Approximate match with multiple criteria in Excel
  • How to use Excel ROWS Function

Data Validations

  • Excel Data validation must not contain
  • Excel Data validation require unique number
  • Excel Data validation specific characters only
  • Excel Data validation must contain specific text
  • Excel Data validation allow weekday only

Count occurrences in entire Excel Workbook

by

This tutorial shows how to Count occurrences in entire Excel Workbook using the example below;

Formula

=SUMPRODUCT(COUNTIF(INDIRECT("'"&sheets&"'!"&range),criteria))

Explanation

To count matches in entire workbook, you can use a formula based on the COUNTIF and SUMPRODUCT functions. In the example shown, the formula in D5 is:

=SUMPRODUCT(COUNTIF(INDIRECT("'"&sheets&"'!A1:Z10000"),B5))

where “sheets” is the named range B8:B10.

Context

This workbook has four worksheets. Three of the worksheets, “Sheet1”, “Sheet2”, and “Sheet3” contain 1000 random first names in a table that looks like this:

Note: the range we are using in the formula, A1:Z10000, is arbitrary and should be adjusted to suit your data.

How this formula works

Working from the inside out, we first have this expression inside the INDIRECT function:

"'"&sheets&"'!A1:Z10000"

Because “sheets” is a named range that contains “Sheet1”, “Sheet2”, and “Sheet3”, we get an array like this once the expression is evaluated:

{"'Sheet1'!A1:Z10000";"'Sheet2'!A1:Z10000";"'Sheet3'!A1:Z10000"}

Inside the array, we have three values, and each is a sheet name joined via concatenation to the range A1:Z10000. Notice that these are all text values.

Next, the INDIRECT function is used to convert each text value to a proper reference, which are supplied to the COUNTIF function as the range argument, along with the value in D5 for criteria.

Since we’ve given COUNTIF three separate ranges, we get back three results in array like this:

{5;6;5}

Each item is a a count for one sheet.

Finally, SUMPRODUCT is used to sum the array, and returns a result of 16.

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

  • IF with boolean logic in Excel
  • IF, AND, OR and NOT Functions Examples in Excel
  • IFERROR function: Description, Usage, Syntax, Examples and Explanation
  • How to use Excel AND Function
  • Complete List of Excel Logical Functions, References and Examples

Date Time

  • How to calculate Quarter of Date in Excel
  • How to calculate working days left in month in Excel
  • Display Days until expiration date in Excel
  • Add decimal minutes to time in Excel
  • How to calculate most recent day of week in Excel

Grouping

  • Map inputs to arbitrary values in Excel
  • Group times into unequal buckets in Excel
  • Calculate conditional mode with criteria in Excel
  • How to randomly assign data to groups in Excel
  • Group arbitrary text values in Excel

General

  • How to generate random date between two dates in Excel
  • Cell References: Relative, Absolute and Mixed Referencing Examples
  • Check if range contains a value not in another range in Excel
  • Select, Insert, Rename, Move, Delete Worksheets in Excel
  • How to create dynamic worksheet reference in Excel
© 2026 xlsoffice . All Right Reserved. | Teal Smiles | Abbreviations And Their Meaning