View Single Post
  #12   Report Post  
Posted to microsoft.public.excel.programming
Peter T Peter T is offline
external usenet poster
 
Posts: 5,600
Default Code runs to slow

Was that making a union of 2k areas (loop of 4000 cells) or 20k areas (40k
cells). If the if the latter I can only assume your machine runs on a
combination of nitrous-oxide and steroids. For my curiosity how long for you
to run this -

Sub SteroidTest()
Dim i As Long
Dim t As Single
Dim rng As Range

t = Timer

For i = 1 To 40000 Step 2
If rng Is Nothing Then
Set rng = Cells(i, 1)
Else
Set rng = Union(rng, Cells(i, 1))
End If
Next
Debug.Print Timer - t ' ?
Debug.Print rng.Areas.Count ' 20,000

End Sub

Regards,
Peter T


"Rick Rothstein (MVP - VB)" wrote in
message ...
I got a difference of 1.18359375 seconds when I ran your code; but I have

a
pretty fast computer here, so that time differential may not be
representative. In any case, point taken... limit the unionizing to groups
of 100 or so... even doing that should still produce an enormous

improvement
over doing it in the straight forward, one-at-a-time iteration approach.
Thanks for pointing that out.

Rick


"Peter T" <peter_t@discussions wrote in message
...
One thing to watch out for with Union is that it becomes exponentially
slower if/as the number of discontiguous areas in the unioned range
increase. Typically it's faster to process batches of 50-400 areas at a
time. The exact qty of areas depends on what the process is but a good
rule
of thumb is limit to about 80-100.

The following should demonstrate the difference, trying to union 20k

areas
is not viable.

Sub UnionDemo()
Dim bFastTest As Boolean
Dim bGotRng As Boolean
Dim i As Long
Dim arr() As Long
Dim rHide As Range

Rows.Hidden = False
Columns(1).Clear

Set rng = Range("A1:A40000")

ReDim arr(1 To rng.Rows.Count, 1 To 1)
For i = 1 To UBound(arr) Step 2
arr(i, 1) = 1
Next

rng.Value = arr

bFastTest = True
' bFastTest = False ' reduce rng size above to say 4k or less for
testing

t = Timer ' sensitive timer not required !

If bFastTest Then

For Each cell In rng
If cell.Value = 0 Then
If bGotRng Then
Set rHide = Union(rHide, cell)
If rHide.Areas.Count 100 Then
rHide.EntireRow.Hidden = True
Set rHide = Nothing
bGotRng = False
End If
Else
Set rHide = cell
bGotRng = True
End If
End If
Next

If Not rHide Is Nothing Then ' or If bGotRng ...
rHide.EntireRow.Hidden = True
End If

Else ' do ctrl-break if it's taking to long
Set rHide = Nothing
For Each cell In rng
If cell.Value = 0 Then
If rHide Is Nothing Then
Set rHide = cell
Else
Set rHide = Union(rHide, cell)
End If
End If
Next

If Not rHide Is Nothing Then
rHide.EntireRow.Hidden = True
End If

End If
Debug.Print Timer - t

End Sub

Regards,
Peter T


"Rick Rothstein (MVP - VB)" wrote

in
message ...
I know you have a different solution now, but your comment about the
speed
of the code I posted for you earlier got me to thinking. Probably the

speed
problem is due to the continual hiding of the rows one-by-one. I'm

thinking
the code below should be more efficient. If you have the chance, I

would
be
interested in how fast the code below is compared to the code I gave

you
earlier.

Sub HideRowIfZeroInJ()
Dim R As Range
Dim RowsToHide As Range
Dim LastRow As Long
Application.ScreenUpdating = False
With Worksheets("Sheet3")
LastRow = .Cells(Rows.Count, "J").End(xlUp).Row
For Each R In .Range("J3:J" & CStr(LastRow))
If R.Value = 0 And R.Value < "" Then
If RowsToHide Is Nothing Then
Set RowsToHide = R
Else
Set RowsToHide = Union(R, RowsToHide)
End If
End If
Next
If Not RowsToHide Is Nothing Then RowsToHide.EntireRow.Hidden =

True
End With
Application.ScreenUpdating = True
End Sub

Rick

<snip