Microsoft KB Archive/170782

From BetaArchive Wiki

Article ID: 170782

Article Last Modified on 6/12/2007



APPLIES TO

  • Microsoft Excel 97 Standard Edition



This article was previously published under Q170782


For a Microsoft Excel 2000 and 2002 version of this article, see 211736.

Article idea submitted by: John Walkenbach

SUMMARY

If you have a Microsoft Visual Basic for Applications macro that takes a long time to complete, you may want to give the user an indication that the macro is progressing normally. This article shows you how to create a progress bar with a user form.

MORE INFORMATION

Microsoft provides programming examples 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. This article assumes that you are familiar with the programming language being demonstrated and the tools used to create and debug procedures. Microsoft support professionals can help explain the functionality of a particular procedure, but they will not modify these examples to provide added functionality or construct procedures to meet your specific needs. If you have limited programming experience, you may want to contact a Microsoft Certified Partner or the Microsoft fee-based consulting line at (800) 936-5200. For more information about Microsoft Certified Partners, please visit the following Microsoft Web site:

For more information about the support options that are available and about how to contact Microsoft, visit the following Microsoft Web site:

Create the User Form

In the following example, a Visual Basic subroutine populates a large range of cells with a random number. This task takes several seconds to complete; the indicator shows you that the macro is running normally.

  1. Close and save any open workbooks, and 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
                            

Type the Macro Code

  1. Double-click the user form to open the Code window for the user form.
  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. Return to 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 user form. The procedure attached to the Activate event of the user form 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 takes just a bit longer to complete its intended tasks.

REFERENCES

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:

120802 Office: How to Add/Remove a Single Office Program or Component



Additional query words: XL97

Keywords: kbcode kbhowto kbmacro KB170782