Delaying in a Macro

by Allen Wyatt
(last updated December 23, 2017)

2

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, and 2016.

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

Making Pictures Show in Word

What are you to do if you can't see all the pictures you know are in your document? The answer may lie in where those ...

Discover More

Forcing Input to Uppercase

If you type information into a workbook, you may want to make sure that what you type is always stored in uppercase. ...

Discover More

Excel 2013 Serious Sorting (Table of Contents)

Sorting data means that you organize it in whatever order you desire. Excel's sorting feature can be used in a variety of ...

Discover More

Save Time and Supercharge Excel! Automate virtually any routine task and save yourself hours, days, maybe even weeks. Then, learn how to make Excel do things you thought were simply impossible! Mastering advanced Excel macros has never been easier. Check out Excel 2010 VBA and Macros today!

More ExcelTips (ribbon)

Develop Macros in Their Own Workbook

If you develop macros and edit them quite a bit, you may be running the risk of causing problems with the macros or with ...

Discover More

Creating a Floating Macro Button

Macros can make your use of Excel much more powerful. If you have a macro that is triggered by an on-screen button, you ...

Discover More

Making Common Functions Available to Others

When you use macros to create functions, you might want to share those functions with othersâ€"particularly if they ...

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}] 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 four more than 2?

2017-12-25 06:20:20

Willy Vanhaelen

For current use you don't need the granularity down to miliseconds, you can use this macro for which you don't need to declare API functions:

Sub Sleep(s As Integer)
Application.Wait Now + TimeSerial(0, 0, s)
End Sub

You use it this way for a 5 seconds delay
call Sleep( 5) or simply Sleep 5
Or even for a half second:
Sleep 0.5


2017-12-23 09:30:37

jean-pierre degroote (aka JP Ronse)

Hi Allen,

Useful tips but all have the disadvantage that they stop/delay the execution of the macro where it can be a requirement that some further code need to be executed.

See discussion: https://answers.microsoft.com/en-us/msoffice/forum/msoffice_excel-mso_winother-mso_2007/vba-macros/7d4f6b0d-0a59-4810-a09c-23d8cbb24a8e


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.