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

Data Analysis

  • Error Bars in Excel
  • Add Outline to Data in Excel
  • How to create running total in an Excel Table
  • Number and Text Filters Examples in Excel
  • Get column name from index in Excel Table

References

  • Create hyperlink with VLOOKUP in Excel
  • How to retrieve first match between two ranges in Excel
  • VLOOKUP function: Description, Usage, Syntax, Examples and Explanation
  • Extract data with helper column in Excel
  • Multi-criteria lookup and transpose in Excel

Data Validations

  • Excel Data validation allow weekday only
  • Excel Data validation date in next 30 days
  • Excel Data validation number multiple 100
  • Excel Data validation date in specific year
  • Excel Data validation only dates between

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

  • AND function: Description, Usage, Syntax, Examples and Explanation
  • Excel If, Nested If, And/Or Criteria Examples
  • Nested IF function example in Excel
  • Invoice status with nested if in Excel
  • How to use Excel OR Function

Date Time

  • Convert Excel time to decimal hours in Excel
  • Two ways to sum time over 30 minutes in Excel
  • Get project end date in Excel
  • Next biweekly payday from date in Excel
  • Calculate years between dates in Excel

Grouping

  • Map inputs to arbitrary values in Excel
  • Map text to numbers in Excel
  • Calculate conditional mode with criteria in Excel
  • How to randomly assign data to groups in Excel
  • How to randomly assign people to groups in Excel

General

  • Index and match on multiple columns in Excel
  • Freeze and Unfreeze Panes in Excel
  • Share Excel data with Word documents
  • Excel Autofill Cell Ranges, Copy, Paste
  • Common Errors in Excel
© 2025 xlsoffice . All Right Reserved. | Teal Smiles | Abbreviations And Their Meaning