Written by Allen Wyatt (last updated March 28, 2020)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
Rob wondered if there is a way to count the number of cells containing formulas in a row or column. The answer is quite simple, using the Go To feature of Excel. Follow these steps:
Figure 1. The Go To Special dialog box.
That's it. Excel selects all the cells in the row or column that contain formulas. (If you skip step 2, Excel selects all the formulas in the entire worksheet.) At the bottom of the screen, in the status bar, you can see a count of the number of cells selected. (See Figure 2.)
Figure 2. The status bar shows a count of selected cells.
If, for some reason, you don't see a count in the status bar, you should check to make sure you have your status bar configured to show counts. Just right-click any blank spot on the status bar and choose Count form the resulting options.
If you are using Excel 2013 or a more recent version, you could also use a formula to figure out how many formulas are in a range of cells, as shown here:
=SUMPRODUCT(--ISFORMULA(A:A))
This example returns the count of all the formulas in column A; you could just as easily substitute a different range of cells in the formula. Whatever range you specify, it should not include the cell where you place this particular formula—that would result in a circular reference and a probable error.
You could also, if desired, use a macro to determine the count. The following example uses the same approach to determine a count as was manually described in the earlier steps:
Sub CountFormulas1() Dim Source As Range Dim iCount As Integer Set Source = ActiveSheet.Range("A:A") iCount = Source.SpecialCells(xlCellTypeFormulas, 23).Count ActiveSheet.Range("D1") = iCount End Sub
This subroutine returns, very quickly, a count of all the formula-containing cells in column A and stuffs that value into cell D1.
It would be very helpful if this approach could be turned into a user-defined function, such as this:
Function CountFormulas2(Source As Range) CountFormulas2 = Source.SpecialCells(xlCellTypeFormulas, 23).Count End Function
This won't work, however. The function always returns the count of the cells in the Source range, not the count of the cells containing formulas. It is an esoteric bug in Excel's VBA that SpecialCells doesn't work in functions; it only works in subroutines. Microsoft hasn't even documented this one (that I can find), thus my reference to it as a "bug" instead of as a "limitation."
There is an actual limitation to what the SpecialCells method can do, however: It can only contain a range of up to 8,192 cells. You can analyze a range that is much larger (as is the case when you have it look at an entire column), but the resulting subset—the resulting range—can only contain up to 8,192 cells. If it contains more, then SpecialCells will "fail" and return a range (and therefore a count) that is equal to the number of cells in the original range.
If you want to create a user-defined function to determine the count, you'll need to rely on something other than the SpecialCells method. Here's an approach that uses the HasFormula property:
Function CountFormulas3(Source As Range) Dim c As Range Dim iCount As Integer iCount = 0 For Each c In Source If c.HasFormula Then iCount = iCount + 1 Next CountFormulas3 = iCount End Function
If you choose to have this macro evaluate an entire column or an entire row, then be prepared to wait a bit—it can take a while for the macro to step through each cell in a column or row. The SpecialCells method is much faster at deriving results than stepping through each cell.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (13330) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365.
Professional Development Guidance! Four world-class developers offer start-to-finish guidance for building powerful, robust, and secure applications with Excel. The authors show how to consistently make the right design decisions and make the most of Excel's powerful features. Check out Professional Excel Development today!
If you have a special need to find cell values that meet two different criteria, where to start can be daunting. This tip ...
Discover MoreWhen creating a workbook, you can include formulas that reference data stored in other workbooks. Some functions will ...
Discover MoreExcel provides several different ways that you can split apart the contents of a cell. One way it doesn't provide is to ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2021-04-22 01:06:17
Norm Graf
How to count in a column that contains a formula. When counting a row or column whose cells contain a formula, you get a count even if the cell appears blank. The following formula allows you to get an accurate count in row or column that contains numbers.
I searched everywhere and was unable to find a solution for this problem. I thought you might like to post this for others to use.
=COUNTIF(Q26:Q76,">0")- COUNTIF(Q26:Q76,"<-0")*(-1)
Yours Truly,
Norm
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 © 2024 Sharon Parq Associates, Inc.
Comments