How to Use a VBA Macro to Sum Only Visible Cells (150363)



The information in this article applies to:

  • Microsoft Excel 97 for Windows
  • Microsoft Excel for Windows 95
  • Microsoft Excel for Windows 5.0
  • Microsoft Excel 98 Macintosh Edition

This article was previously published under Q150363

SUMMARY

If you have a range of cells that includes hidden rows or hidden columns, Microsoft Excel does not provide an easy way to sum only the visible cells.

The SUM function totals all the cells in a range, including hidden cells. The SUBTOTAL function ignores hidden rows only if they are part of a filtered list that was created using the AutoFilter or Advanced Filter command.

The following custom function sums only the visible cells in a range. To use the custom function, type the following into a cell on a worksheet

=Sum_Visible_Cells(A1:A5)

where A1:A5 is the range that you want to sum.

MORE INFORMATION

Microsoft provides programming examples for illustration only, without warranty either expressed or implied. This includes, but is not limited to, the implied warranties of merchantability or fitness for a particular purpose. This article assumes that you are familiar with the programming language that is being demonstrated and with the tools that are used to create and to debug procedures. Microsoft support engineers can help explain the functionality of a particular procedure, but they will not modify these examples to provide added functionality or construct procedures to meet your specific requirements.

Sample Visual Basic Procedure

   Function Sum_Visible_Cells(Cells_To_Sum As Object)
       Application.Volatile
       For Each cell In Cells_To_Sum
           If cell.Rows.Hidden = False Then
               If cell.Columns.Hidden = False Then
                   total = total + cell.Value
               End If
           End If
       Next
       Sum_Visible_Cells = total
   End Function
				
Note that if you hide or unhide cells after you enter the formula into the worksheet, the formula will not recalculate automatically, even if Calculation is set to automatic. You can make the formulas recalculate if Calculation is set to automatic and you take any of the following actions:

  • You edit any cell on the sheet. -or-

  • You press F9, which forces a recalculation. -or-

  • You close the workbook.

REFERENCES

For more information about creating custom functions in Microsoft Excel 97, from the Visual Basic Editor, click the Office Assistant, type function statement, click Search, and then click to view "Function Statement."

NOTE: If the Assistant is hidden, click the Office Assistant button on the Standard toolbar. If the Assistant is not able to answer your query, please see the following article in the Microsoft Knowledge Base:

176476 OFF: Office Assistant Not Answering Visual Basic Questions

"Visual Basic User's Guide," version 5.0, Chapter 3, "Creating a User- Defined Function"

Modification Type:MinorLast Reviewed:10/11/2006
Keywords:kbdtacode kbhowto kbProgramming KB150363