Home > Articles > Home & Office Computing > Microsoft Applications

The Next Step Beyond the Macro Recorder in VBA Programming

Don’t rely solely on the macro recorder to teach you VBA programming; it’s meant only as an introduction, and you can’t rely on it for more advanced programming methods. Tracy Syrstad, co-author of Excel 2016 VBA and Macros, provides 10 macro recorder tips that will take your VBA programming skills up a level or two.
Like this article? We recommend

Like this article? We recommend

The macro recorder is a good introduction into the world of VBA programming, but it's not meant to be your only teacher. It provides a simplistic approach to coding with Excel’s object model, but is by far not a teacher of advanced or efficient programming methods. You can even pick up some bad habits if you rely on it as your only means of learning VBA. Like many other programmers, I did start off with the recorder but eventually moved to the next level.

Here are 10 things I had to learn to take my programming skill up a notch.

1. The Macro Recorder Is a Terrible Teacher, But You Can Learn from It.

I'm not saying to throw out the recorder and never use it again. In truth, most of the time I find it more useful then Microsoft’s help files when I need to look up an object or its properties and methods. Need the code for creating a pivot table? Then go ahead and record it so you can see the objects and steps involved. But then improve the code by using the advice below.

2. Declare Your Variables!

In the early days when RAM was so expensive, every byte counted. That was a major argument for declaring variables: Undeclared variables are of type variant, with a minimum size of 16 bytes, whereas if you declare a variable as type integer, you use only 2 bytes.

Now that high RAM is so common, some have thrown out the argument and don’t bother declaring variables. But then, they’ve forgotten the other reason for variable declaration, one which has saved me a lot of frustration: When you require variable declaration, Excel will point out unknown variables during compilation. And if you mix upper-and lowercase in your variable naming, you can spot mistakes right away, because Excel will keep the case the same for you as you are typing your code.

You have to manually turn on the variable declaration requirement: In the VBE, go to Tools, Options and check the box for Require Variable Declaration. Once that’s done, any new workbooks will have Option Explicit at the top of every module. For your older workbooks, you can type in Option Explicit at the top of a module, forcing variable declaration.

3. There’s No Need to Use Select or Activate.

Probably one of the worst actions the recorder teaches is that objects must be selected before they can be manipulated. If you provide Excel with the specific object you want to manipulate, such as a sheet name or cell address, then you don’t need to activate the sheet or select the cell. So, while the macro recorder provides this:

Sheets("Sheet1").Select
Range("A1").Select
ActiveCell.FormulaR1C1 = "5"
Range("A2").Select
ActiveCell.FormulaR1C1 = "6"
Range("A3").Select
ActiveCell.FormulaR1C1 = "=SUM(R[-2]C:R[-1]C)"

All that’s really needed is this:

Sheets("Sheet1").Range(“A1”).Value = 5
Sheets("Sheet1").Range(“A2”).Value = 6
Sheets("Sheet1").Range("A3").Formula = "=SUM(A1:A2)"

Not only does this shorten the number of lines, but it also makes it easier to read the code because right away you know what object (Sheet1, cell A1) is being modified. Changing FormulaR1C1 to Value is mainly a style preference; I prefer to use FormulaR1C1 when actually entering an R1C1-style formula. The change to Formula in the last line is also personal; I’m an A1-style gal, most of the time. By including the sheet object (Sheets("Sheet1")) each time, it doesn’t matter what sheet is actually the active sheet. Excel will always update Sheet1. This is a great way to hide data you’re entering from users.

4. Indent Your Code to Improve Readability.

It seems to be such a small matter, but indention of loops goes a long way in making code easier to read. Whenever someone posts unindented code at a forum, the first thing I do is indent it

5. Get the Last Row and Last Column of a Data Set.

Even when you use keyboard shortcuts to select the last row and column of your data set, the recorder returns a specific range. Of course, this means the next time you run your macro, it may miss some data. Even if you think your data will always be the same size, it’s a good idea to get in the habit of having Excel find the last row and column. It doesn’t take it very long to calculate the information, and it makes your code more flexible for the future.

The following code sample finds the last row (LastRow) by starting in the very last cell in column A and going up the rows until it finds a value. The last column (LastColumn) is found by starting in the very last cell in row 1 and going left until it finds a value. The range is then bolded and italicized.

Dim LastRow As Long, LastColumn As Long
LastRow = Range("A" & Rows.Count).End(xlUp).Row
LastColumn = Cells(1, Columns.Count).End(xlToLeft).Column
Range("A1").Resize(LastRow, LastColumn).Font.Bold = True
Range("A1").Resize(LastRow, LastColumn).Font.Italic = True

6. Declare Objects for Simpler Code.

In the previous code sample, I had to type the range twice: once to bold it and again to italicize it. Can you imagine if I also wanted to change the number format? Copy it? That’s a lot of typing, and it’s so easy to make a mistake. To avoid these two issues, declare an object.

Declare the object variable as the type of object you want it to be, such as a workbook, a worksheet, or in the case of the previous example, a range. Then use the keyword Set to assign the value to the object.

Dim rng as Range
Set rng = Range("A1").Resize(LastRow, LastColumn)

Once you’ve done that, wherever you reference the wordy range resize statement, use rng instead:

rng.Font.Bold = True
rng.Font.Italic = True

This is also very handy when you need to switch between objects, such as sheets. You’ve already learned that you don’t need to activate a sheet to access it, but typing the sheet reference over and over again, especially if you have a long sheet name, can be tedious. Instead, set objects to the sheets and use those references as needed.

In the following example, we have two sheets: one with a data set and the other for the report. The code uses the object references to copy the header from the data sheet to the report sheet.

Dim wksData As Worksheet, wksReport As Worksheet
Set wksData = Worksheets("January Data Dump")
Set wksReport = Worksheets("January Report by Sales")
wksData.Range("A1:C1").Copy wksReport.Range("A1")

When you’re done with the object variables, you want to release them, freeing up system memory but also avoiding possible coding issues later, such as when you want to use the variables again. To do this, set them to Nothing:

Set rng = Nothing
Set wksData = Nothing
Set wksData = Nothing 

7. Use the With..End With Statement for Cleaner Code.

Whether you declare your own objects or not, it can be tiresome to type the same object in one line of code after another. That’s where With..End With can help simplify your code. You only have to specify the object once at the beginning of the statement, and then any lines that need to allude to it, will. For those lines to reference the object, you start those lines with a period (.). In the following sample, the .Name property gets its object reference from the With Worksheets(1) statement. The second With statement also gets its reference from the first With statement, while the .Font.Bold property gets its object from the second With statement.

With Worksheets(1)
    .Range("A1").Value = .Name
    With .Range("A2")
        .Font.Bold = True
    End With
End With

8. Split Up Your Code.

There’s nothing wrong with having a thousand lines of code in a single procedure; it’s just a bit difficult to read. If you have a procedure that performs multiple tasks such as importing data, formatting that data, and then calculating with the data, you're better off with taking the code for each task and placing it in its own procedure. You can then create a single procedure that calls the other procedures.

Another reason you want to split up your code is to reduce duplication. Imagine you have a workbook with 100 sheets and you are formatting each sheet the same way. You could have a procedure that formats each specific sheet, one after another, but this would be a long procedure. And when you need to change the formatting, you will have to edit each instance.

A better way to code this would be to have a separate procedure that does the formatting. The formatting procedure has a sheet argument. Your main procedure simply calls the formatting procedure, providing the sheet object as the argument. You might have the same call 100 times, once for each sheet, but when you have to go and update the formatting, all you have to do is update a single procedure.

Sub FormatAllTheSheets()
Dim wks As Worksheet
For Each wks In Worksheets
    FormatThisSheet wks
Next wks
End Sub
Sub FormatThisSheet(ByVal wks As Worksheet)
With wks
    '...do formatting stuff
End With
End Sub

9. Manage Unhandled Errors.

An unhandled error is one that pops up the debug dialog box. This dialog box can confuse your user, so instead provide an information window and then exit the procedure properly.

The command to enable an error handling routine is On Error GoTo line label. When it runs into an error, the code will jump to the line label and run the code after it.

In the following example, the code includes a line to disable events. If the code runs into an unhandled error, when the user clicks the End button in the dialog box, events remain turned off. Using an error handler, you can turn the events back on and exit the procedure properly.

Sub CalculateSummaries()
Application.EnableEvents = False
On Error GoTo errHandler
'...your procedure code here
GoTo ExitSub 'if the code runs fine, when it reaches here it jumps to the ExitSub label
errHandler: 'if there's an error, the code will jump here
MsgBox "There was an unknown error" & Chr(10) & _
    Err.Number & ": " & Err.Description
ExitSub: 'no matter what, the following line will run
Application.EnableEvents = True
End Sub

10. Speed It Up.

There are two ways you can speed up your code. The first involves adding lines of code at the beginning and end of your main procedure. The second method requires processing of data in memory, instead of on the sheet.

There are a couple of lines of code you can include in every project that might help speed it up. Just remember, when you turn something off in Excel you need to turn it back on at the end of the program.

  • Application.ScreenUpdating: This is the property behind most of the screen flickering you see when your program runs. By setting this to False, you might be able to speed up the program because Excel doesn’t spend time updating the screen. Just remember to set it back to True at the end of your program.
  • Application.Calculation: This is the property behind Excel's calculation mode. By setting it to Manual, you ensure that Excel will only calculate a cell when it is updated. Because the workbook may already be set to Manual or another mode, save the existing mode in a variable, switch to Manual, and at the end the program load the variable back into the property.
Sub MakeItFaster()
Dim CalcMode As XlCalculation
Application.ScreenUpdating = False
CalcMode = Application.Calculation
Application.Calculation = xlCalculationManual
'your code
Application.ScreenUpdating = True
Application.Calculation = CalcMode
End Sub

By processing your data in the computer’s memory (for example, by using an array), you can greatly decrease the time it takes for a program to process data. Even with ScreenUpdating turned off, if the code is looping through rows, it takes longer than if it looped through an array. You can go a step further by placing the results of the program into an array and then “dumping” the results onto the sheet once, instead of writing to the sheet for each result. Basically, the less Excel has to interact with the sheet, the faster the program.

The next two examples demonstrate the running time difference between looping and processing in memory. The first procedure loops through 500,000 rows, placing a value in each cell. It took about 14 seconds to run on my machine. Turning off ScreenUpdating didn’t significantly affect the time.

Sub SlowFill()
Dim i As Long
Dim StartTime As Date, EndTime As Date
Application.ScreenUpdating = False
StartTime = Now()
For i = 1 To 500000
    Cells(i, 1).Value = i
Next i
EndTime = Now()
Range("B1").Value = Format(EndTime - StartTime, "hh:mm:ss.0 ")
Application.ScreenUpdating = True
End Sub

The second procedure does all the processing in memory using an array and then places the results once on the sheet. It ran in less than one second.

Sub FastFill()
Dim i As Long
Dim arr(1 To 500000, 1 To 1)
Dim StartTime As Date, EndTime As Date
StartTime = Now()
For i = 1 To UBound(arr)
    arr(i, 1) = i
Next i
Range("D1").Resize(UBound(arr)).Value = arr
EndTime = Now()
Range("E1").Value = Format(EndTime - StartTime, "hh:mm:ss.0")
End Sub

Final Thoughts

The macro recorder is a good way to begin writing your own code, but as a teacher, it falls a little short. With a few tweaks, you can make your code more efficient, easier to read, and even run faster. These pointers are just the tip of the iceberg when it comes to taking your coding skill to the next level or higher.

InformIT Promotional Mailings & Special Offers

I would like to receive exclusive offers and hear about products from InformIT and its family of brands. I can unsubscribe at any time.

Overview


Pearson Education, Inc., 221 River Street, Hoboken, New Jersey 07030, (Pearson) presents this site to provide information about products and services that can be purchased through this site.

This privacy notice provides an overview of our commitment to privacy and describes how we collect, protect, use and share personal information collected through this site. Please note that other Pearson websites and online products and services have their own separate privacy policies.

Collection and Use of Information


To conduct business and deliver products and services, Pearson collects and uses personal information in several ways in connection with this site, including:

Questions and Inquiries

For inquiries and questions, we collect the inquiry or question, together with name, contact details (email address, phone number and mailing address) and any other additional information voluntarily submitted to us through a Contact Us form or an email. We use this information to address the inquiry and respond to the question.

Online Store

For orders and purchases placed through our online store on this site, we collect order details, name, institution name and address (if applicable), email address, phone number, shipping and billing addresses, credit/debit card information, shipping options and any instructions. We use this information to complete transactions, fulfill orders, communicate with individuals placing orders or visiting the online store, and for related purposes.

Surveys

Pearson may offer opportunities to provide feedback or participate in surveys, including surveys evaluating Pearson products, services or sites. Participation is voluntary. Pearson collects information requested in the survey questions and uses the information to evaluate, support, maintain and improve products, services or sites, develop new products and services, conduct educational research and for other purposes specified in the survey.

Contests and Drawings

Occasionally, we may sponsor a contest or drawing. Participation is optional. Pearson collects name, contact information and other information specified on the entry form for the contest or drawing to conduct the contest or drawing. Pearson may collect additional personal information from the winners of a contest or drawing in order to award the prize and for tax reporting purposes, as required by law.

Newsletters

If you have elected to receive email newsletters or promotional mailings and special offers but want to unsubscribe, simply email information@informit.com.

Service Announcements

On rare occasions it is necessary to send out a strictly service related announcement. For instance, if our service is temporarily suspended for maintenance we might send users an email. Generally, users may not opt-out of these communications, though they can deactivate their account information. However, these communications are not promotional in nature.

Customer Service

We communicate with users on a regular basis to provide requested services and in regard to issues relating to their account we reply via email or phone in accordance with the users' wishes when a user submits their information through our Contact Us form.

Other Collection and Use of Information


Application and System Logs

Pearson automatically collects log data to help ensure the delivery, availability and security of this site. Log data may include technical information about how a user or visitor connected to this site, such as browser type, type of computer/device, operating system, internet service provider and IP address. We use this information for support purposes and to monitor the health of the site, identify problems, improve service, detect unauthorized access and fraudulent activity, prevent and respond to security incidents and appropriately scale computing resources.

Web Analytics

Pearson may use third party web trend analytical services, including Google Analytics, to collect visitor information, such as IP addresses, browser types, referring pages, pages visited and time spent on a particular site. While these analytical services collect and report information on an anonymous basis, they may use cookies to gather web trend information. The information gathered may enable Pearson (but not the third party web trend services) to link information with application and system log data. Pearson uses this information for system administration and to identify problems, improve service, detect unauthorized access and fraudulent activity, prevent and respond to security incidents, appropriately scale computing resources and otherwise support and deliver this site and its services.

Cookies and Related Technologies

This site uses cookies and similar technologies to personalize content, measure traffic patterns, control security, track use and access of information on this site, and provide interest-based messages and advertising. Users can manage and block the use of cookies through their browser. Disabling or blocking certain cookies may limit the functionality of this site.

Do Not Track

This site currently does not respond to Do Not Track signals.

Security


Pearson uses appropriate physical, administrative and technical security measures to protect personal information from unauthorized access, use and disclosure.

Children


This site is not directed to children under the age of 13.

Marketing


Pearson may send or direct marketing communications to users, provided that

  • Pearson will not use personal information collected or processed as a K-12 school service provider for the purpose of directed or targeted advertising.
  • Such marketing is consistent with applicable law and Pearson's legal obligations.
  • Pearson will not knowingly direct or send marketing communications to an individual who has expressed a preference not to receive marketing.
  • Where required by applicable law, express or implied consent to marketing exists and has not been withdrawn.

Pearson may provide personal information to a third party service provider on a restricted basis to provide marketing solely on behalf of Pearson or an affiliate or customer for whom Pearson is a service provider. Marketing preferences may be changed at any time.

Correcting/Updating Personal Information


If a user's personally identifiable information changes (such as your postal address or email address), we provide a way to correct or update that user's personal data provided to us. This can be done on the Account page. If a user no longer desires our service and desires to delete his or her account, please contact us at customer-service@informit.com and we will process the deletion of a user's account.

Choice/Opt-out


Users can always make an informed choice as to whether they should proceed with certain services offered by InformIT. If you choose to remove yourself from our mailing list(s) simply visit the following page and uncheck any communication you no longer want to receive: www.informit.com/u.aspx.

Sale of Personal Information


Pearson does not rent or sell personal information in exchange for any payment of money.

While Pearson does not sell personal information, as defined in Nevada law, Nevada residents may email a request for no sale of their personal information to NevadaDesignatedRequest@pearson.com.

Supplemental Privacy Statement for California Residents


California residents should read our Supplemental privacy statement for California residents in conjunction with this Privacy Notice. The Supplemental privacy statement for California residents explains Pearson's commitment to comply with California law and applies to personal information of California residents collected in connection with this site and the Services.

Sharing and Disclosure


Pearson may disclose personal information, as follows:

  • As required by law.
  • With the consent of the individual (or their parent, if the individual is a minor)
  • In response to a subpoena, court order or legal process, to the extent permitted or required by law
  • To protect the security and safety of individuals, data, assets and systems, consistent with applicable law
  • In connection the sale, joint venture or other transfer of some or all of its company or assets, subject to the provisions of this Privacy Notice
  • To investigate or address actual or suspected fraud or other illegal activities
  • To exercise its legal rights, including enforcement of the Terms of Use for this site or another contract
  • To affiliated Pearson companies and other companies and organizations who perform work for Pearson and are obligated to protect the privacy of personal information consistent with this Privacy Notice
  • To a school, organization, company or government agency, where Pearson collects or processes the personal information in a school setting or on behalf of such organization, company or government agency.

Links


This web site contains links to other sites. Please be aware that we are not responsible for the privacy practices of such other sites. We encourage our users to be aware when they leave our site and to read the privacy statements of each and every web site that collects Personal Information. This privacy statement applies solely to information collected by this web site.

Requests and Contact


Please contact us about this Privacy Notice or if you have any requests or questions relating to the privacy of your personal information.

Changes to this Privacy Notice


We may revise this Privacy Notice through an updated posting. We will identify the effective date of the revision in the posting. Often, updates are made to provide greater clarity or to comply with changes in regulatory requirements. If the updates involve material changes to the collection, protection, use or disclosure of Personal Information, Pearson will provide notice of the change through a conspicuous notice on this site or other appropriate way. Continued use of the site after the effective date of a posted revision evidences acceptance. Please contact us if you have questions or concerns about the Privacy Notice or any objection to any revisions.

Last Update: November 17, 2020