Written by Allen Wyatt (last updated August 5, 2023)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021
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, Excel in Microsoft 365, and 2021.
Solve Real Business Problems Master business modeling and analysis techniques with Excel and transform data into bottom-line results. This hands-on, scenario-focused guide shows you how to use the latest Excel tools to integrate data from multiple tables. Check out Microsoft Excel 2013 Data Analysis and Business Modeling today!
Want to get rid of all the zero values in a range of cells? This tip provides a couple of different ways you can ...
Discover MoreWhen reading information from a text file, your macro may need to start reading at a place other than the beginning of ...
Discover MoreYou can run a Personal.xlsb macro from within your Workbook_Open code, but you may get an error if you don't make sure ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
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?
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.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2024 Sharon Parq Associates, Inc.
Comments