The first thing that comes to mind is that Excel 2003 has 65,536 rows
by 256 columns, for a total of 16 million cells. Excel 2007, on the
other hand, has about 1,000,000 rows by about 18,000 columns, for a
total of 17 Billion cells, which means that there are about 1000 times
as many cells on an XL2007 sheet as there are on a XL2003 sheet. For
every cell calculated in XL2003, a poorly designed XL2007 workbook may
calculate 1000 cells.
If your code doesn't restrict its operations to only the used range of
a worksheet but instead references entire rows and columns, you could
be processing up to 1000 times as many cells in 2007 than you were in
2003. This would easily cause the calculation time to increase
tremendously.
Also, it has been reported that calculations are often slower in 2007
than in 2003, even though 2007 has a multi-thread calculation engine.
Some general tips to improve speed of code:
1) Don't Select anything. Instead of
Range("A1").Select
Selection.Value = 123
' use
Range("A1").Value =123
Select is (almost) never necessary and slows things down considerably.
2) Turn off screen updating. If Excel has to refresh and display an
updated image every time as cell is modified, this takes a LOT of
time. Use code like
Application.ScreenUpdating = False
' your code
Application.ScreenUpdating = True
3) If you do not need to rely on the intermediate calculated value
changes during the execution of the code, set Calculation to Manual.
Application.Calculation = xlCalculationManual
' your code here
Application.Calculation = xlCalculationAutomatic
4) If you do not need any events to fire during the course of the code
execution, turn off events.
Application.EnableEvents = False
' your code here
Application.EnableEvents = True
5) If your code delete a lot of rows and or columns, don't delete them
one by one. Instead, store references to the rows/columns to be
deleted in a Range variable and then call Delete one time on that
variable. E.g,
Dim DeleteThese As Range
For X = 1 To 1000
If DeleteTheRow Then
If DeleteThese Is Nothing Then
Set DeleteThese = Rows(X)
Else
Set DeleteThese = _
Application.Union(DeleteThese,Rows(x))
End If
End If
Next X
If DeleteThese IsNot Nothing Then
DeleteThese.Delete
End If
This calls Delete only once, which is much faster than deleting one at
a time.
6) If you are transferring a lot of data from VBA to worksheet cells,
it is much faster to build an array in VBA, fill that array, and then
assign the array to a worksheet range:
Dim MyArray(1 To 10, 1 To 1) As Variant
MyArray(1, 1) = 111
MyArray(2, 1) = 222
' fill up MyArray
Range("D1").Resize(UBound(MyArray) - LBound(MyArray) + 1).Value =
MyArray
Cordially,
Chip Pearson
Microsoft Most Valuable Professional
Excel Product Group, 1998 - 2009
Pearson Software Consulting, LLC
www.cpearson.com
(email on web site)