If what is hidden will not change, why not just reference the visible cells?
Jerry
Function IsVisible(ByVal Target As Excel.Range) As Variant
' must be manually recalculated since hidding/unhiding colums does not
trigger recalc
Dim Results()
ReDim Results(1 To 1, 1 To Target.Columns.Count)
i = 0
For Each c In Target.Columns
i = i + 1
Results(1, i) = Not c.EntireColumn.Hidden
Next c
IsVisible = Results
End Function
Jerry
>.
>
Option Explicit
Function SumVisible(myRng As Range) As Double
Application.Volatile
Dim myCell As Range
Dim mySum As Double
For Each myCell In myRng.Cells
If myCell.EntireRow.Hidden = True Then
'don't add it
Else
If IsNumeric(myCell.Value) Then
mySum = mySum + myCell.Value
End If
End If
Next myCell
SumVisible = mySum
End Function
But remember to calculate the worksheet before you trust the number. (Watch the
sum when you just hide/unhide a row).
in the worksheet: =sumVisible(a1:a10)
--
Dave Peterson
ec3...@msn.com
=SUMPRODUCT(IsVisible(A1:X1)*A1:X1)
uses my IsVisible() function to sum only the cells of A1:X1 that are not
in hidden columns. When you change the code in IsVisible() to deal with
rows then you can change the cell formula to sum down a column instead
of across a row.
In retrospect, a better name for my function would have been
IsVisibleCol(), and the suggested revision would be IsVisibleRow(), so
that both could coexist in an installed Add-In.
Jerry
This is much faster than creating a Range object consisting of the
visible rows and summing that range. It also separates the hiding task
from the summing task.
regards
Paul
Public Sub Create_Filtered_Array()
'Creates an array of true/false for a row not hidden/hidden
'array is named to be used by worksheet
'This array is used in worksheet functions to apply them to filtered
data only
Dim rgRow As Range
Dim FilterArray() As Boolean
Dim rownumber As Integer
Dim k As Integer
Dim Test_1 As Variant, L_Cert As Variant, Grade As Variant, Attendence
As Variant, Improvement As Variant
Application.ScreenUpdating = False
With Range("myRange") 'All cells in this range should be
occupied
rownumber = .Rows.Count
ReDim FilterArray(1 To rownumber, 1 To 1)
For k = 1 To rownumber
FilterArray(k, 1) = Not .Rows(k).EntireRow.Hidden
Next k
End With
Names.Add Name:="ShownRows", RefersTo:=FilterArray
'Creates a named array constant, consisting of a column of Booleans
End Sub
Dave Peterson <ec3...@msn.com> wrote in message news:<3F61312B...@msn.com>...
>.
>