Summing Only Cells Containing Formulas

Written by Allen Wyatt (last updated January 18, 2024)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365


3

Mandy wonders if there is a way to sum a data range and include in the sum only those cells that contain a formula. According to Mandy's needs, if a cell contains an explicit value and not a formula, then it should not be included in the sum.

There are many ways you could go about achieving the desired result, but I will focus on only a few of them.

First, if you only need to determine the sum a single time and not have it appear within the worksheet itself, then you can follow these steps:

  1. Select the cells that you want to sum.
  2. Press F5. Excel displays the Go To dialog box.
  3. Click the Special button. Excel displays the Go To Special dialog box.
  4. Select the Formulas radio button.
  5. Click on OK. Excel modifies the selected cells so that only those containing formulas are selected.

At this point you can look in the status bar (bottom of the Excel window) and see the sum of the selected cells—those containing formulas.

If you prefer a formula-based approach, one of the key factors here is going to be the version of Excel you are using. Microsoft introduced the ISFORMULA function with the release of Excel 2013, so if you are using that version (or later), determining the sum you want is quite easy. Just use this formula:

=SUMPRODUCT(A1:A5,--ISFORMULA(A1:A5))

This formula assumes that the data range you want to sum is A1:A5. The "double minus" sign before the ISFORMULA function is used to convert TRUE and FALSE values (as returned by ISFORMULA) to either 1 or 0.

If you prefer to use an array formula, you could use the following formula:

=SUM(IF(ISFORMULA(A1:A6),A1:A6))

Just remember to enter using Ctrl+Shift+Enter and you'll get the proper result.

If you are using a version of Excel older than Excel 2010, then these formulas won't work. Instead, you'll need to rely on a user-defined function to do the trick:

Function SumFormulas(ByVal r As Range)
    Dim c As Range
    Dim s As Double

    s = 0
    For Each c In r.Cells
    
        If c.HasFormula And IsNumeric(c) Then
            s = s + c.Value
        End If
    Next c
    SumFormulas = s
End Function

Note that the code checks to make sure that the cell contains a formula (using the HasFormula property) and checks to make sure it is numeric (using the IsNumeric function). Both are necessary because it is possible to have a text-based formula in a cell, and you don't want to try to include the results of such a formula in your sum.

In order to use the function, you would simply use the following in a worksheet cell, assuming you want to sum the range A1:C7:

=SumFormulas(A1:C7)

The macro-based approach will also work in versions of Excel beyond Excel 2010, if for some reason you don't want to rely on the ISFORMULA function. (For instance, if you have to ensure compatibility with older versions of Excel.)

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (13595) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Adding Excel Information to a Web Page

Besides saving a worksheet as a complete Web page, you can also save smaller portions of your data to an existing Web ...

Discover More

Printing a Document's Mirror Image

If you need to print the mirror image (backwards) of a document, you may think you are out of luck in Word. There are ...

Discover More

Using the Same Range Name on Different Worksheets

Defined names can be a great boon when working in a worksheet. Usually names are available throughout an entire workbook, ...

Discover More

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!

More ExcelTips (ribbon)

Identifying Digit-Only Part Numbers Excluding Special Characters

When working with data in Excel, you often need to determine if that data meets criteria that you specify. This tip ...

Discover More

Where Is that Text?

Looking for a formula that can return the address of a cell containing a text string? Look no further; the solution is in ...

Discover More

Counting Groupings Below a Threshold

When analyzing data, you may need to distill groupings from that data. This tip examines how you can use formulas and ...

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] (all 7 characters, in the sequence shown) in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is five more than 3?

2018-12-10 11:10:39

Roy

Yeah, hard to see a need for the IF().

Perhaps there is some odd situation in which it would matter? The logic in using it would not really seem to address anything.

Experimenting on seemingly non-applicable ideas shows that if a formula in the range refers to a text item, "horse" perhaps, not using IF() produces an error that IF() seems to avoid. However, IFERROR() (the more logical choice if looking at the error idea) yields a 0 when the same error exists while IF() gives the correct answer.

(Use three cells to reference, containing "horse", "1", and "2" but only reference the first and last, using an actual "2" instead in your "to sum" range. Using IF() yields 2, using IFERROR() yields 0 though using the "--" trick does clear the issue.

I wonder where else one can use IF() (with OR? without its thrid argument?) instead of IFERROR() and be able to avoid the "--" trick, or other tricks, yet achieve same result? Is it limited to array formulas for this, or normal ones? Why would it work so at all?

Lu-u-u-cy Excel! You got some 'splainin' to do!


2018-12-10 03:50:20

Mark

Hi Allen,

I can't work out how to get the formula to work. Where do I paste the macro?

regards,

Mark


2018-12-08 05:28:07

Michael Avidan

Array Formula:
=SUM(ISFORMULA(B1:B6)*B1:B6)


This Site

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.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.