Delaying in a Macro

Written by Allen Wyatt (last updated August 5, 2023)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, 2021, and Excel in Microsoft 365


3

Chris is developing an Excel macro that displays a series of items to the user. He would like to introduce a delay in the macro of, say, one second between each piece of information he displays, and he wonders if there is an easy way to add such a delay.

There are a few ways you can introduce a delay into your macro. The traditional way is to use the Wait method, which is used with the Application object. You use it to introduce a one-second delay in this manner:

Application.Wait (Now() + TimeValue("0:00:01"))

Note that the parameter required by the Wait method is the time at which you want your macro to resume running. In other words, it is the "wait until" time. That is why the above example uses the current time (from the Now function) incremented by a single second.

If you prefer to not use the Wait method (for whatever reason), you can also just use a loop to bide your time:

Dim WaitTime As Date

WaitTime = Now() + TimeValue("0:00:01")
Do While Now < WaitTime
Loop

A variant on this approach relies on the Timer function, which returns the number of seconds since midnight:

Dim Endpoint as Single

Endpoint = Timer + 1
Do While Timer < Endpoint
Loop

When using a loop in this manner, it probably won't be a big issue if you are delaying for only a second. If you need to delay for a longer time, you'll probably want to place the DoEvents function into the loop:

Dim Endpoint as Single

Endpoint = Timer + 1
Do While Timer < Endpoint
    DoEvents
Loop

The reason is simple—if you don't, then Excel won't respond to any other events while in the loop. This can make it seem like your system has frozen or hung while waiting.

If you need more granularity on your delays (down to the millisecond range), you may want to rely on the Sleep function, which is part of the Windows API. (It is not a part of VBA.) In order to use it, you'll need to include a declaration at the beginning of your module, in the declarations area, before any procedures:

#If VBA7 And Win64 Then
    Public Declare PtrSafe Sub Sleep Lib "kernel32"(ByVal dwMilliseconds As Long)
#Else
    Public Declare Sub Sleep Lib "kernel32"(ByVal dwMilliseconds As Long)
#End If

Then, within your macro you can use the Sleep function in this manner:

Sleep(1000)

This pauses the system for 1000 milliseconds, which is 1 second.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (5134) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, 2021, and Excel in Microsoft 365.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Saving All Open Documents

Got a lot of open documents you are working with? You can save them all at one time by just holding down the Shift key ...

Discover More

Creating Scenario Summaries

If you've defined a variety of scenarios for your workbook, Excel can provide a handy way to compare the effects of those ...

Discover More

Read-Only Files

Read-only documents (those that cannot be updated) are part and parcel of working with Word. There are many ways that a ...

Discover More

Program Successfully in Excel! This guide will provide you with all the information you need to automate any task in Excel and save time and effort. Learn how to extend Excel's functionality with VBA to create solutions not possible with the standard features. Includes latest information for Excel 2024 and Microsoft 365. Check out Mastering Excel VBA Programming today!

More ExcelTips (ribbon)

Using Macros in Protected Workbooks

Having problems with using macros in a protected workbook? There could be any number of causes (and solutions) as ...

Discover More

Stopping a Checked Box from being Unchecked

When creating user forms for use in Excel, you are provided with a range of controls you can add, including check boxes. ...

Discover More

Deleting Old Data from a Worksheet

If you keep on-going data in a worksheet, some of your data�"over time�"may need to be deleted. If you have an ...

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] (all 7 characters, in the sequence shown) in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is seven more than 7?

2023-08-07 09:56:14

J. Woolley

Or use InputBox to enter a value.


2023-08-07 05:38:54

Dave S

A simple way to achieve this would be to use MsgBox:

MsgBox "Press <OK> to continue", vbOKOnly, "Execution paused:"


2023-08-06 14:29:41

David Zannino

Is there a way to have a macro PAUSE and wait for keyboard input then execute afterwards?


This Site

Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu interface.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.