XL2000: How to Use ADO to Return Data to a ListBox or ComboBox (244761)



The information in this article applies to:

  • Microsoft Excel 2000

This article was previously published under Q244761

SUMMARY

In Microsoft Excel, you can use the ActiveX Data Objects (ADO) library in a Visual Basic for Applications macro to work with a SQL database. This article contains a sample macro that returns the results of your query to a ComboBox control or a ListBox control in a Microsoft Excel workbook or user form.

MORE INFORMATION

Microsoft provides programming examples for illustration only, without warranty either expressed or implied. This includes, but is not limited to, the implied warranties of merchantability or fitness for a particular purpose. This article assumes that you are familiar with the programming language that is being demonstrated and with the tools that are used to create and to 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 requirements. For more information about how to use the sample code in this article, click the article number below to view the article in the Microsoft Knowledge Base:

212536 OFF2000: How to Run Sample Code from Knowledge Base Articles

The PopulateControl Macro

  1. In Microsoft Excel, open the Visual Basic Editor. To do this, point to Macro on the Tools menu, and then click Visual Basic Editor.
  2. Insert a user form. To do this, click UserForm on the Insert menu.
  3. Add a combo box to the user form. To do this, click the ComboBox button in the Control Toolbox, and then click the user form. Resize the control to the size and shape that you want.
  4. Create a reference to the ActiveX object library. To do this, click References on the Tools menu. In the References dialog box, click to select the Microsoft ActiveX Data Objects 2.5 Library check box. Click OK.
  5. Add a standard module. To do this, click Module on the Insert menu. Type the following macro:
    Public Sub PopulateControl()
    
        Dim cnn1 As ADODB.Connection
        Dim rstEmployees As ADODB.Recordset
        Dim strCnn As String
    
        ' Open connection. Replace the word servername next to Data Source 
        ' with the actual name of the SQL Server. Replace the User Id and Password 
        ' with an account that has appropriate permissions to the database.
        strCnn = "Provider=sqloledb; Data Source=servername;Initial Catalog=pubs;" & _
          "User Id=<username>;Password=<strong password>; "
        Set cnn1 = New ADODB.Connection
        cnn1.Open strCnn
    
        ' Open employee table.
        Set rstEmployees = New ADODB.Recordset
        rstEmployees.CursorType = adOpenKeyset
        rstEmployees.LockType = adLockOptimistic
        rstEmployees.Open "employee", cnn1, , , adCmdTable
    
        ' Moves to the first record in the record set.
        rstEmployees.MoveFirst
    
        ' Loops through each entry in the record set and adds the last name
        ' for each entry into the combo box.
        Do Until rstEmployees.EOF
            UserForm1.ComboBox1.AddItem rstEmployees!lName
            ' To use a ListBox control, use the following statement instead
            ' of the one above:
            '   UserForm1.ListBox1.AddItem rstEmployees!lName
            '
            ' If the ComboBox or ListBox is on a worksheet instead of
            ' a UserForm, reference the worksheet instead of the UserForm:
            '   ActiveSheet.ComboBox1.AddItem rstEmployees!lName
            rstEmployees.MoveNext
        Loop
    
        ' Displays the user form. You don't need this if you are not using
        ' a UserForm object.
        UserForm1.Show
    
        ' Closes the table.
        rstEmployees.Close
        ' Closes the connection.
        cnn1.Close
    
    End Sub
    					
  6. On the File menu, click Close and Return to Microsoft Excel.
  7. To run the macro, point to Macro on the Tools menu, and then click Macros. Click PopulateControl, and then click Run.

REFERENCES

Microsoft Office 2000 Visual Basic Programmer's Guide, Chapter 14. "Working with the Data Access Components of an Office Solution."

Modification Type:MinorLast Reviewed:10/11/2006
Keywords:kbdtacode kbhowto KB244761