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 Microsoft Advisory Services. For more information, visit these Microsoft Web sites:
Microsoft Certified
Partners -
https://partner.microsoft.com/global/30000104Microsoft Advisory Services -
http://support.microsoft.com/gp/advisoryservice
For more information about the support options that are available and about how to contact Microsoft, visit the following Microsoft Web site:
http://support.microsoft.com/default.aspx?scid=fh;EN-US;CNTACTMSCreating the Dialog Box and Worksheet
Before you create the Microsoft Visual Basic macro, create the sample workbook and dialog box. To do so, follow these steps:
- Start Excel, and then create a new workbook.
NOTE: This example uses the default worksheet name "Sheet1." - Right-click the Sheet2 tab (any sheet will work), click Insert, click MS Excel 5.0 Dialog, and then click OK.
NOTE: This example uses the default dialog sheet name "Dialog1." - On the dialog sheet, create and name each type of control in the following table.
NOTE: To create a control, click the appropriate button on the Forms toolbar. To name a control, select it, and then type the name in the Name box (to the left of the formula bar).
Control type Control name
------------------------------------------------------------------------
Label Label 4
Edit box Edit Box 5
Button Button 6
Check box Check Box 7
Option button Option Button 8
List box List Box 9
Drop-down (or Combo Box) Drop Down 10
Scroll bar Scroll Bar 11
Spinner Spinner 12
If you want to insert a UserForm instead of a dialog sheet, follow these steps:
- Press ALT+F11 to start the Visual Basic Editor.
- On the Insert menu, click UserForm.
- On the UserForm, create one of each type of control that you want.
NOTE: To create a control, click the appropriate button on the UserForm toolbox. To name a control, select it, and then type the name in the Name box (Properties pane). - In the following sample macro, change the control names to reflect the control that you are using in the UserForm.
Creating the Sample Macro
To create the sample macro, follow these steps:
- Press ALT+F11 to start the Visual Basic Editor.
- In the On the Insert menu, click Module.
- In the module sheet, type the following code:
Sub Test()
' Dimension variables.
Dim diag As Object
Dim wkst As Object
Dim x As Integer
Dim counter As Integer
' Set objects.
Set diag = DialogSheets("Dialog1")
Set wkst = Worksheets("Sheet1")
' Clear edit box, drop-down list, and list box.
diag.EditBoxes("Edit Box 5").Text = ""
diag.ListBoxes("List Box 9").RemoveAllItems
diag.DropDowns("Drop Down 10").RemoveAllItems
' Set spinner and scrollbar back to 0.
diag.ScrollBars("Scroll Bar 11").Value = 0
diag.Spinners("Spinner 12").Value = 0
' Insert data into list box and drop-down list.
myarray = Array("Tom", "Fred", "Sam", "Wilma", "Sandy")
For x = 0 To 4
diag.ListBoxes("List Box 9").AddItem myarray(x)
diag.DropDowns("Drop Down 10").AddItem myarray(x)
Next x
' Clear the edit box.
diag.EditBoxes("Edit Box 5").Text = ""
' Set spinner and scrollbar back to 0
diag.ScrollBars("Scroll Bar 11").Value = 0
diag.Spinners("Spinner 12").Value = 0
' Show Custom Dialog Box.
diag.Show
counter = 1
' Loop through controls on dialog and return name
' and value or caption to Sheet1.
' OK button is 1 and Cancel button is 2.
For x = 3 To 11
' Place name of control in column A.
wkst.Cells(counter, 1) = diag.DrawingObjects(x).Name
Select Case diag.DrawingObjects(x).Name
Case "Label 4"
wkst.Cells(counter, 2) = diag.Labels("Label 4").Caption
Case "Edit Box 5"
' Check control to see if it is blank. If it
' is blank, change the font to red.
If diag.EditBoxes("Edit Box 5").Text = "" Then
wkst.Cells(counter, 2) = "You Left This Control Empty"
wkst.Range("B" & counter).Font.ColorIndex = 3
Else
wkst.Cells(counter, 2) = _
diag.EditBoxes("Edit Box 5").Text
End If
Case "Button 6"
wkst.Cells(counter, 2) = diag.Buttons("Button 6").Caption
Case "Check Box 7"
' If the value is 1, option was selected.
' If the value is not 1, it is blank.
If diag.CheckBoxes("Check Box 7").Value = 1 Then
wkst.Cells(counter, 2) = "On"
Else
wkst.Cells(counter, 2) = "Off"
End If
Case "Option Button 8"
' If the value is 1, option was selected.
' If the value is not 1, it is blank.
If diag.OptionButtons("Option Button 8").Value = 1 Then
wkst.Cells(counter, 2) = "On"
Else
wkst.Cells(counter, 2) = "Off"
End If
Case "List Box 9"
' Check control to see if it is blank. If so, change font
' to red.
If diag.ListBoxes("List Box 9").ListIndex = 0 Then
wkst.Cells(counter, 2) = "You Left This Control " _
& "Empty."
wkst.Range("B" & counter).Font.ColorIndex = 3
Else
wkst.Cells(counter, 2) = _
diag.ListBoxes("List Box 9").List _
(diag.ListBoxes("List Box 9").ListIndex)
End If
Case "Drop Down 10"
' Check control to see if it is blank. If so, change the
' font to red.
If diag.ListBoxes("List Box 9").ListIndex = 0 Then
wkst.Cells(counter, 2) = "You Left This Control " _
& "Empty."
wkst.Range("B" & counter).Font.ColorIndex = 3
Else
wkst.Cells(counter, 2) = diag. _
DropDowns("Drop Down 10").List _
(diag.DropDowns("Drop Down 10").ListIndex)
End If
Case "Scroll Bar 11"
wkst.Cells(counter, 2) = _
diag.ScrollBars("Scroll Bar 11").Value
Case "Spinner 12"
wkst.Cells(counter, 2) = _
diag.Spinners("Spinner 12").Value
End Select
' Increment counter.
counter = counter + 1
Next x
' Select Sheet1.
wkst.Activate
' Autofit columns.
Columns("A:B").Select
Selection.Columns.AutoFit
Range("a1").Select
End Sub
Returning the Data to the Worksheet
- Run the macro to display the dialog box (or UserForm) that you created.
To run the macro, follow these steps:- In Excel, on the Tools menu, point to Macro, and then click Macros.
- In the Macro name list, click Test, and then click Run.
- Click each of the dialog box controls, select a name in both the list box and the drop-down list, and then click OK.
- Click the Sheet1 tab.
- On Sheet1, the name of each control is displayed in column A, and the
value that is returned by the control appears in column B.
Sheet1 contains the data similar to the following (depending on which controls you clicked and the names that you selected):
A1: Label 4 B1: Label 4
A2: Edit Box 5 B2: You Left This Control Empty
A3: Button 6 B3: Button 6
A4: Check Box 7 B4: On
A5: Option Button 8 B5: On
A6: List Box 9 B6: Wilma
A7: Drop Down 10 B7: Fred
A8: Scroll Bar 11 B8: 1
A9: Spinner 12 B9: 1