Written by Allen Wyatt (last updated January 14, 2023)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, 2021, and Excel in Microsoft 365
Kirk is using the SUM function in many of his worksheets to (naturally) determine the sum of a range of values. The problem he is running into, however, is that the range he is summing contains some hidden rows, and he doesn't want those values—the hidden ones—included in the sum.
The SUM function is pretty simplistic in how it does its work; it simply sums a range. You can change the function you use and get the desired results, however. For instance, let's assume that you want to sum the range of A3:A45, and that you don't want any hidden values to be included in the sum. You should use the SUBTOTAL function in the following manner:
=SUBTOTAL(109,A3:A45)
The first parameter of the function (109) indicates how you want SUBTOTAL to do its work. In this case, it means you want SUBTOTAL to sum the range, using the SUM function, and you don't want any hidden values included in the value returned. (You can find out more about the controlling SUBTOTAL parameters if you look in the online Help for the SUBTOTAL function.)
If you don't want to use the SUBTOTAL function for some reason, you can create your own user-defined function (a macro) that will only sum the visible values in a range. Consider this macro:
Function Sum_Visible(Cells_To_Sum As Object) Dim vTotal As Variant Dim c As Range Application.Volatile vTotal = 0 For Each c In Cells_To_Sum If Not c.Rows.Hidden Then If Not c.Columns.Hidden Then vTotal = vTotal + c.Value End If End If Next Sum_Visible = vTotal End Function
To use the function, simply use a formula like this wherever you want your sum to appear:
=Sum_Visible(A1:A1000)
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (12123) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, 2021, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Summing Only Visible Values.
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!
When you open multiple workbooks, the way in which Excel sizes them is not the best for your needs. This tip looks at a ...
Discover MoreNeed to specify which directory on your hard drive should be used by a macro? It's easy to do using the ChDir command.
Discover MoreDo you often need to know the difference between two values in your worksheet? This tip shares a quick little macro that ...
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 © 2025 Sharon Parq Associates, Inc.
Comments