ID: Q170782
The information in this article applies to:
Article idea submitted by: John Walkenbach
If you have a Visual Basic for Applications macro that requires a long period of time to complete, you may want to give your user an indication that the macro is progressing normally. This article contains an example that illustrates how to create a progress bar with a UserForm.
In the following example, a Visual Basic subroutine populates a large range of cells with a random number. This task will take several seconds to complete; the indicator gives you an indication that the macro is running normally.
Microsoft provides examples of Visual Basic for Applications procedures for illustration only, without warranty either expressed or implied, including, but not limited to the implied warranties of merchantability and/or fitness for a particular purpose. The Visual Basic procedures in this article are provided 'as is' and Microsoft does not guarantee that they can be used in all situations. While Microsoft support professionals can help explain the functionality of a particular macro, they will not modify these examples to provide added functionality, nor will they help you construct macros to meet your specific needs. If you have limited programming experience, you may want to consult one of the Microsoft Solution Providers. Solution Providers offer a wide range of fee-based services, including creating custom macros. For more information about Microsoft Solution Providers, call Microsoft Customer Information Service at (800) 426-9400.
1. Close and save any open workbooks. Then, open a new workbook.
2. Start the Visual Basic Editor, (press ALT+F11).
3. If the Properties window is not visible, click Properties on the
View menu (or press F4).
4. On the Insert menu, click UserForm.
5. Draw a Label control on the UserForm.
6. Change the following properties of the Label control to the
following values:
Property Value
--------------------------------------------
Caption Now updating. Please wait...
7. Draw a Frame control on the UserForm
8. Change the following properties of the Frame control to the
following values:
Property Value
-----------------------------
Name FrameProgress
9. Draw a Label control on the Frame control.
10. Change the following properties of the Label control to the
following values:
Property Value
-------------------------------------
Name LabelProgress
BackColor &H000000FF&
SpecialEffect fmSpecialEffectRaised
1. Double-click on the UserForm to open the Code window for the UserForm.
2. In the module, type the following code for the UserForm Activate event:
Private Sub UserForm_Activate()
' Set the width of the progress bar to 0.
UserForm1.LabelProgress.Width = 0
' Call the main subroutine.
Call Main
End Sub
3. On the Insert Menu, click Module.
4. In the Code window for the module, type the following code:
Sub ShowUserForm()
UserForm1.Show
End Sub
Sub Main()
Dim Counter As Integer
Dim RowMax As Integer, ColMax As Integer
Dim r As Integer, c As Integer
Dim PctDone As Single
Application.ScreenUpdating = False
' Initialize variables.
Counter = 1
RowMax = 100
ColMax = 25
' Loop through cells.
For r = 1 To RowMax
For c = 1 To ColMax
'Put a random number in a cell
Cells(r, c) = Int(Rnd * 1000)
Counter = Counter + 1
Next c
' Update the percentage completed.
PctDone = Counter / (RowMax * ColMax)
' Call subroutine that updates the progress bar.
UpdateProgressBar PctDone
Next r
' The task is finished, so unload the UserForm.
Unload UserForm1
End Sub
Sub UpdateProgressBar(PctDone As Single)
With UserForm1
' Update the Caption property of the Frame control.
.FrameProgress.Caption = Format(PctDone, "0%")
' Widen the Label control.
.LabelProgress.Width = PctDone * _
(.FrameProgress.Width - 10)
End With
' The DoEvents allows the UserForm to update.
DoEvents
End Sub
5. Activate Microsoft Excel (press ALT+F11).
6. Run the ShowUserForm subroutine.
A dialog box is displayed with a red progress bar that increases in size as the Main subroutine populates the cells on the worksheet.
The ShowUserForm subroutine shows the UserForm. The procedure attached to the Activate event of the UserForm calls the Main subroutine. The Main subroutine, in addition to its main task (populating cells with random numbers), calls the UpdateProgressBar subroutine, which updates the Label control on the UserForm.
NOTE: Using this technique, your macro will take just a bit longer to complete its intended task(s).
For more information about the Activate event, click the Office Assistant in the Visual Basic Editor, type "activate event," click Search, and then click to view "Activate, Deactivate Events."
NOTE: If the Assistant is hidden, click the Office Assistant button on the Standard toolbar. If Microsoft Help is not installed on your computer, please see the following article in the Microsoft Knowledge Base:
ARTICLE-ID: Q120802
TITLE : Office: How to Add/Remove a Single Office
Program or Component
Additional query words: XL97
Keywords : kbcode kbmacro
Version : WINDOWS:97
Platform : WINDOWS
Issue type : kbhowto
Last Reviewed: May 17, 1999