Microsoft provides programming examples for illustration only, without warranty either expressed or implied, including, but not limited to, the implied warranties of merchantability and/or fitness for a particular purpose. This article assumes that you are familiar with the programming language being demonstrated and the tools used to create and debug procedures. Microsoft support professionals 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 needs.
If you have limited programming experience, you may want to contact a Microsoft Certified Partner or Microsoft Advisory Services. For more information, visit these Microsoft Web sites:
Microsoft Certified Partners -
https://partner.microsoft.com/global/30000104Microsoft Advisory Services -
http://support.microsoft.com/gp/advisoryserviceFor more information about the support options that are available and about how to contact Microsoft, visit the following Microsoft Web site:
http://support.microsoft.com/default.aspx?scid=fh;EN-US;CNTACTMS
To create and use a sample a sample Visual Basic function to sum only visible cells in a range, use the steps in the following example:
- Start Excel, and then press ALT+F11 to start the Visual Basic editor.
- On the Insert menu, click Module.
- In the module sheet enter the following sample code:
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
- Press ALT+F11 to return to Excel.
- Create the following spreadsheet:
A1: 1 B1: 2
A2: 2 B2: 4
A3: 3 B3: 6
A4: 4 B4: 8
A5: 5 B5: 10
- Select Row 3.
- On the Format menu, point to Row, and then click Hide.
Row 3 disappears. - In cell A6, type the following formula:
=Sum(A1:B5)
The formula returns 45, the sum of all of the cells including the hidden cells. - In cell A7, type the following formula:
=Sum_Visible_Cells(A1:A5)
The formula returns 36, the sum of only the visible cells.
NOTE: If you hide or unhide cells after you enter the formula into the worksheet, the formula will not recalculate automatically. You can make the formulas recalculate if
Calculation is set to
Automatic (click
Options on the
Tools menu) 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.