Written by Allen Wyatt (last updated June 1, 2024)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021
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:
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, Excel in Microsoft 365, and 2021.
Comprehensive VBA Guide Visual Basic for Applications (VBA) is the language used for writing macros in all Office programs. This complete guide shows both professionals and novices how to master VBA in order to customize the entire Office suite for their needs. Check out Mastering VBA for Office 2010 today!
When you discover that there is an invalid reference in a workbook, you can have a bear of a time tracking down the ...
Discover MoreWhen working with text phrases stored in cells, it might be helpful to be able to extract words from the phrase. In this ...
Discover MoreSometimes it can be tricky to figure out how to get exactly what you want from a dataset. In this tip, you discover how ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
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