Summing Only Cells Containing Formulas

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


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.

You could also use this formula, which is shorter still:

=SUM(ISFORMULA(A1:A6)*A1:A6)

This will work as-is in Excel 2021 or later, but in Excel 2013, Excel 2016, and Excel 2019 you'll need to enter it as an array formula using Ctrl+Shift+Enter. In addition, note that the formula will only work if values in A1:A6 are either formulas or numeric values. If one of the cells contains a text value, you'll get a #VALUE! error. To get around this potential problem, wrap the inner portion of the formula in an IF function:

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

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, 2021, 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

Protecting Custom Shortcut Keys

If you spend time creating a rich set of custom shortcut keys, it can be rather frustrating if they suddenly disappear. ...

Discover More

Specifying Location for a Message Box

When writing macros, you may want to position a message box at a specific location on the screen. This can't be done in ...

Discover More

Setting Page Margins

When getting ready to print your worksheet, you may want to take a moment to check what margins Excel will use on the ...

Discover More

Program Successfully in Excel! This guide will provide you with all the information you need to automate any task in Excel and save time and effort. Learn how to extend Excel's functionality with VBA to create solutions not possible with the standard features. Includes latest information for Excel 2024 and Microsoft 365. Check out Mastering Excel VBA Programming today!

More ExcelTips (ribbon)

Pulling a Phone Number with a Known First and Last Name

When using an Excel worksheet to store data (such as names and phone numbers), you may need a way to easily look up a ...

Discover More

Producing an Array of Numbers

When working with arrays in a formula, it can be a bit confusing to understand how they work. In this tip I examine a ...

Discover More

Finding the Nth Occurrence of a Character

The FIND and SEARCH functions are great for finding the initial occurrence of a character in a text string, but what if ...

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 three more than 1?

There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)


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.