XL: How to Return Data from a Dialog Box to a Worksheet

Last reviewed: February 3, 1998
Article ID: Q141685
The information in this article applies to:
  • Microsoft Excel for the Macintosh, versions 5.0, 5.0a
  • Microsoft Excel 98 Macintosh Edition
  • Microsoft Excel for Windows, versions 5.0, 5.0c
  • Microsoft Excel for Windows 95, versions 7.0, 7.0a
  • Microsoft Excel 97 for Windows

SUMMARY

In Microsoft Excel, each type of control on a custom dialog box (a drop- down list, an edit box, and so on) has a distinct return value that can be returned to a worksheet. This article explains how to create a custom dialog box and contains a sample Microsoft Visual Basic for Applications macro that retrieves data from a dialog box control and places that data on a worksheet.

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 engineers 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 the Microsoft fee-based consulting line at (800) 936-5200. For more information about the support options available from Microsoft, please see the following page on the World Wide Web:

   http://www.microsoft.com/support/supportnet/refguide/default.asp

Creating the Dialog Box and Worksheet

Before you create the Visual Basic macro, create the sample workbook and dialog box. To do this, use the following steps:

  1. Create a new workbook. (The workbook must contain a sheet called "Sheet1.")

  2. In Microsoft Excel 5.0 or 7.0, point to Insert on the Macro menu, and then click Dialog.

    In Excel 97 for Windows, right-click any sheet tab, click Insert, and then click MS Excel 5.0 Dialog. In Excel 98 Macintosh Edition, press and hold the CONTROL key and then click any sheet tab. Click Insert, and then click MS Excel 5.0 Dialog.

    Note: The name of the inserted sheet must be "Dialog1."

  3. On the dialog sheet, create one of each type of control. 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 (left of the formula bar). Use the following table as a guide for creating and naming each dialog box element.

       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
    
    

Creating the Sample Macro

To create the sample macro, use the following steps:

  1. In Microsoft Excel 5.0 or 7.0, insert a Visual Basic module by clicking Module on the Insert menu.

    In Excel 97 for Windows and Excel 98 Macintosh Edition, press ALT+F11 to start the Visual Basic Editor. On the Insert menu, click Module.

  2. On 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
    
    

  3. To run the macro, place the insertion point in the "Sub test()" line and press F5.

    The dialog box appears.

Returning the Data to the Worksheet

  1. Display the dialog box that you created (run the macro to do this), and select each of the dialog box controls.

  2. In the dialog box, press ENTER or click OK.

  3. In Microsoft Excel 5.0 or 7.0, switch to Sheet1 by clicking the sheet tab.

    In Microsoft Excel 97, click Microsoft Excel on the taskbar or press ALT+Q to switch to Microsoft Excel 97 and switch to Sheet1.

  4. 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. For example, Sheet1 contains the following data:

          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
    
    

REFERENCES

"Visual Basic User's Guide," version 5.0, page 237

For more information about macro code that you can use to control custom dialog boxes, please see the following article in the Microsoft Knowledge Base:

   ARTICLE-ID: Q130372
   TITLE     : XL AppNote: Sample Code for Controlling Dialog Boxes(WE1162)

Microsoft Excel 97

For more information about returning data from a control, click the Index tab in Microsoft Excel Help, type the following text

   controls

and then double-click the selected text to go to the "About control properties for check boxes and option buttons" topic.

Microsoft Excel 5.0 or 7.0

For more information about returning data from a control, choose Index from the Help menu, and type:

   returning data from a control


Additional query words: 5.00 7.00 xl97 dialog dialogsheet worksheet
controls combobox dropdown listbox editbox optionbutton scrollbar
Keywords : kbcode kbprg PgmHowto
Version : WINDOWS:5.0,5.0c,7.0,7.0a,97; MACINTOSH:5.0
Platform : MACINTOSH WINDOWS
Issue type : kbhowto


THE INFORMATION PROVIDED IN THE MICROSOFT KNOWLEDGE BASE IS PROVIDED "AS IS" WITHOUT WARRANTY OF ANY KIND. MICROSOFT DISCLAIMS ALL WARRANTIES, EITHER EXPRESS OR IMPLIED, INCLUDING THE WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE. IN NO EVENT SHALL MICROSOFT CORPORATION OR ITS SUPPLIERS BE LIABLE FOR ANY DAMAGES WHATSOEVER INCLUDING DIRECT, INDIRECT, INCIDENTAL, CONSEQUENTIAL, LOSS OF BUSINESS PROFITS OR SPECIAL DAMAGES, EVEN IF MICROSOFT CORPORATION OR ITS SUPPLIERS HAVE BEEN ADVISED OF THE POSSIBILITY OF SUCH DAMAGES. SOME STATES DO NOT ALLOW THE EXCLUSION OR LIMITATION OF LIABILITY FOR CONSEQUENTIAL OR INCIDENTAL DAMAGES SO THE FOREGOING LIMITATION MAY NOT APPLY.

Last reviewed: February 3, 1998
© 1998 Microsoft Corporation. All rights reserved. Terms of Use.