9 quick tips to improve your VBA macro performance

Microsoft

As part of our work to help enterprises upgrade to Office 365 ProPlus, we have found that some users have been experiencing slow running VBA, which can be frustrating. The good news is that there are steps which can be taken to improve performance.

This post aims to raise awareness of the steps that you can take to improve the performance of your macros, whether you are an end user, IT admin, or developer. We’ve collected the following steps from blog posts, Microsoft field engineers, and Microsoft MVPs like Charles Williams and Jan Karel Pieterse.

 

1. Turn off everything but the essentials in VBA

One of the first things to do when speeding up VBA code is to turn off unnecessary features such as animations, screen updating, automatic calculations and events while your macro is running. These features can add extra overhead and slow down the macro, particularly if the macro is modifying many cells and triggering lots of screen updates and recalculations.

 

The below code sample shows you how to enable/disable:

  • Manual calculations
  • Screen updates
  • Animations
Option Explicit
Dim lCalcSave As Long
Dim bScreenUpdate As Boolean
Sub SwitchOff(bSwitchOff As Boolean)
  Dim ws As Worksheet
    
  With Application
    If bSwitchOff Then 

      ' OFF 
      lCalcSave = .Calculation
	bScreenUpdate = .ScreenUpdating
      .Calculation = xlCalculationManual
      .ScreenUpdating = False
      .EnableAnimations = False
      
      '
      ' switch off display pagebreaks for all worksheets
      '
      For Each ws In ActiveWorkbook.Worksheets
        ws.DisplayPageBreaks = False
      Next ws
    Else
 
      ' ON
      If .Calculation <> lCalcSave And lCalcSave <> 0 Then .Calculation = lCalcSave
      .ScreenUpdating = bScreenUpdate
      .EnableAnimations = True
      
    End If
  End With
End Sub

Sub Main()
  SwitchOff(True) ‘ turn off these features
  MyFunction() ‘ do your processing here
  SwitchOff(False) ‘ turn these features back on
End Sub

 

2. Disabling Office animations through system settings

 

Animations can be disabled across Windows by accessing the Ease of Access Center.

Animations can be disabled in Excel specifically, under the Advanced or Ease of Access tab, within the File > Options menu.

  

Please see the following link for more information: https://support.office.com/en-us/article/turn-off-office-animations-9ee5c4d2-d144-4fd2-b670-22cef9fa...

 

3. Disabling Office animations through registry settings

Office animations can be disabled across multiple computers by setting the appropriate registry key via a group policy setting.

 

HIVE: HKEY_CURRENT_USER
Key Path: Software\Microsoft\Office\16.0\Common\Graphics
Key Name: DisableAnimations
Value type: REG_DWORD
Value data: 0x00000001 (1)

Warning: Using Registry Editor incorrectly can cause serious, system-wide problems that may require you to re-install Windows to correct them. Microsoft cannot guarantee that any problems resulting from the use of Registry Editor can be solved. Use this tool at your own risk.

 

 

4. Removing unnecessary selects

The select method is common to see in VBA code, however it is often added to the macro where it isn’t needed. Select can trigger cell events such as animations and conditional formatting which slow the macro down, so removing unnecessary selects can significantly speed up your macro.

The following example shows the code before and after making the change to remove unnecessary selects.

 

Before

Sheets("Order Details").Select
Columns("AC:AH").Select
Selection.ClearContents

After

Sheets("Order Details").Columns("AC:AH").ClearContents

 

5. Using the With statement to read object properties

When working with objects, use the With statement to reduce the number of times object properties are read. The following example shows the code before and after making the change to use the With statement.

 

Before

Range("A1").Value = “Hello”
Range("A1").Font.Name = “Calibri”
Range("A1").Font.Bold = True
Range("A1").HorizontalAlignment = xlCenter

After

With Range("A1")
  .Value2 = “Hello” 
  .HorizontalAlignment = xlCenter
    With .Font
      .Name = “Calibri”
      .Bold = True
    End With
End With

 

6. Using ranges and arrays

Reading and writing to cells in Excel from VBA is expensive. There is an overhead that is incurred every time data moves between VBA and Excel.

 

The mountain between Excel and VBAThe mountain between Excel and VBA

This means that you should try to reduce the number of times you pass data between VBA and Excel. This is where ranges are useful. Instead of reading and writing to each cell individually in a loop, read the entire range into an array at the start, loop through the array, and then write the entire array back at the end. The following example code shows how a range can be used to read and write the values once, instead of reading each cell individually.

 

Dim vArray As Variant
Dim iRow As Integer
Dim iCol As Integer
Dim dValue As Double
vArray = Range("A1:C10000").Value2 ‘ read all the values at once from the Excel cells, put into an array 

For iRow = LBound(vArray, 1) To UBound(vArray, 1)
  For iCol = LBound(vArray, 2) To UBound(vArray, 2)
    dValue = vArray (iRow, iCol)
    If dValue > 0 Then 
      dValue=dValue*dValue ‘ Change the values in the array, not the cells 
    vArray(iRow, iCol) = dValue
  End If
Next iCol
Next iRow
Range("A1:C10000").Value2 = vArray ‘ writes all the results back to the range at once

 

7. Use .Value2 instead of .Text or .Value

There are different ways that you can retrieve values from a cell, and which property you use can make a different in the performance of your code.

 

.Text is commonly used to retrieve the value of a cell – it returns the formatted value of a cell. Getting the formatting of a cell is more complex than just retrieving a value, and makes .Text quite slow.

 

.Value is an improvement over .Text, as this mostly gets the value from the cell, without formatting. However for cells formatted as a date or currency, .Value will return a VBA date or VBA currency (which may truncate decimal places).

 

.Value2 gives the underlying value of the cell. As it involves no formatting, .Value2 is faster than .Value. .Value2 is faster than .Value when processing numbers (there is no significant difference with text), and is much faster using a variant array.

 

For a more detailed explanation, please see Charles William’s blog post, “TEXT vs VALUE vs VALUE2”: https://fastexcel.wordpress.com/2011/11/30/text-vs-value-vs-value2-slow-text-and-how-to-avoid-it/

 

8. Bypass the clipboard (copy and paste)

When you use the Macro Recorder to record operations that use copy and paste, the code will use the copy and paste methods by default. However, within VBA code, it is much faster to bypass the clipboard and use internal operations instead. By default, copying will copy everything, including formulas, values and formatting. You can make copying faster by only copying values or formulas, without the formatting. The following example shows the code before and after making the change to bypass the clipboard.

 

Before

Range("A1").Select
Selection.Copy
Range("A2").Select
ActiveSheet.Paste

After

‘ Approach 1: copy everything (formulas, values and formatting
Range("A1").Copy Destination:=Range("A2")

‘ Approach 2: copy values only
Range("A2").Value2 = Range("A1").Value2

‘ Approach 3: copy formulas only
Range("A2").Formula = Range("A1").Formula

 

If you still find that a macro takes longer than expected to execute many individual copy and paste operations, you may want to apply the following hot fix: https://support.microsoft.com/en-in/help/2817672/macro-takes-longer-than-expected-to-execute-many-in...

 

9. Use Option Explicit to catch undeclared variables

Option Explicit is one of the available Module directives in VBA that instructs VBA how to treat the code within the code module. Setting Option Explicit requires all variables to be declared and will give compile errors if an undeclared variable is used. This helps catch incorrectly typed variable names and improves performance with all variable types being defined at compile time, instead of being inferred at runtime.

 

This can be set by typing: Option Explicit at the top of each module in your project or by checking the "Require Variable Declaration" option under Tools -> Options in the VBA editor. 

 

Additional Details on Module directives can be found here: https://docs.microsoft.com/en-us/dotnet/visual-basic/language-reference/statements/option-explicit-s...

 

Conclusion

We hope that this has helped highlight some of the ways that you can make your macros run faster. We’re sure that we haven’t covered everything, so please comment below with any other tips or tricks to improve the performance of your macros in Excel.

 

Further reading

https://blogs.office.com/en-us/2009/03/12/excel-vba-performance-coding-best-practices/

http://datapigtechnologies.com/blog/index.php/ten-things-you-can-do-to-speed-up-your-excel-vba-code/

https://www.ozgrid.com/VBA/SpeedingUpVBACode.htm

 

FAQs:

After using the new macro animations stopped working/it’s stuck on manual calculation.

It is possible the code disables the various settings, but the macro crashes before re-enabling these settings. To fix this, you will need to run the code to enable these settings again.

 

Other resources

https://www.thespreadsheetguru.com/blog/2015/2/25/best-way-to-improve-vba-macro-performance-and-prev... - The Best Way To Improve VBA Macro Performance And Prevent Slow Code Execution

https://www.ozgrid.com/VBA/SpeedingUpVBACode.htm - Optimize Slow VBA Code. Speeding Up Slow Excel VBA Code

 

 

About the co-authors

 

Charles Williams founded Decision Models in 1996 to provide advanced consultancy, decision support solutions, and tools based on Microsoft Excel and relational databases. Charles is the author of FastExcel, the widely used Excel performance profiler and performance toolset, and co-author of Name Manager, the popular utility for managing defined names. For more information about Excel calculation performance and methods, memory usage, and VBA user-defined functions, visit the Decision Models Web site.

 

Jan Karel Pieterse is a long time Excel MVP who develops custom solutions focused on Microsoft Office, with deep expertise in Excel and VBA. He runs the website JKP Application Development Services site, where you can find an interesting collection of articles, training events, and utilities. For a good overview of topics, see this list of in-depth articles. Jan develops some cool and useful utilities for Excel, including NameManager, RefTreeAnalyser, and Flexfind. You can find a full list on the downloads page.

 

6 Replies

Hi Mark,

 

Thank you very much for these valuable tips!

 

It's noteworthy to mention that the explicitly declare all variables with the appropriate data type increases performance.

You can force yourself to declare all variables by using Option Explicit statement.

 

In addition, avoid using the Variant data type as much as possible because it will cost the VBA interpreter/compiler some extra steps to determine what the most appropriate data type should be used!

Mark,
re: use of With statement

Ken Getz (author of the VBA Developers Handbook - many years ago) pointed out, that when using the With statement, you must reduce the number of dots used in order to improve efficiency.
Otherwise you are just saving typing time.
'---
Jim Cone
https://goo.gl/IUQUN2

IIRC the Application.EnableAnimations property does not work (but we'd like it to!!!)

Thanks for your feedback, Haytham, it's great to hear more tips that can improve performance. I've updated the post to include information on using Option Explicit to catch issues with undeclared variables.

@Mark Johnson, AMAZING!!!  THANK YOU!!!

This took me from more than 11 minutes to less than 10 seconds to iterate over 21 million records to selectively update them!

#6 was incredibly helpful!!

@Mark Johnson 

Thank you. These tips are really useful. They help me to have big improvement of VBA code handling.