XL97: Using AddItem Method When RowSource Is Data Bound

Last reviewed: March 13, 1998
Article ID: Q161511
The information in this article applies to:
  • Microsoft Excel 97 for Windows

SYMPTOMS

When you use the AddItem method to add an item to the list of a ListBox or ComboBox control, you may receive the following error message:

   Run-time error '70':
   Permission denied.

CAUSE

This problem occurs when both of the following conditions are true:

  • You use the AddItem method to add an item to either a ListBox or ComboBox control.

    -and-

  • The ListBox or ComboBox control is data bound (the RowSource property is set to a range on a worksheet).

RESOLUTION

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 engineers 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.

To add an item to a ListBox or ComboBox control during runtime, you can use one of two methods, adding an item from a worksheet range, or adding an item from a variable. Which method you use depends on how you add the item to the list.

The examples in this article illustrate the two methods and assume you do the following to set up a worksheet and a UserForm:

  1. Close and Save any open workbooks and create a new workbook.

  2. Define the range A1:A3 in Sheet1 as "myrange" (without the quotation marks).

  3. Type the following data in Sheet1:

          A1: a
          A2: b
          A3: c
          A4: d
          A5: e
    

  4. Start the Visual Basic Editor (press ALT+F11).

  5. On the Insert menu, click UserForm.

  6. Click the ListBox control in the Toolbox, and then add a ListBox to the UserForm.

  7. If the Properties window is not visible, press F4.

  8. Change the RowSource property of the ListBox control to "Sheet1!myrange" (without the quotation marks).

  9. Add a CommandButton control to the UserForm.

Adding an Item from a Worksheet Range

This example assumes you want to extend the range for the RowSource control during run time. The following example macro increases the "myrange" reference by one cell each time you click the CommandButton on the UserForm, and updates the ListBox. To use the macro, do the following:

  1. Double-click the CommandButton on the UserForm to display the module associated with the UserForm.

  2. Type the following code for the Click event of CommandButton1:

          Private Sub CommandButton1_Click()
    
              Sheet1.Range("myrange").Resize _
                  (Sheet1.Range("myrange").Rows.Count + 1, 1).Name _
                  ="myrange"
       
              ListBox1.RowSource = "Sheet1!myrange"
       
          End Sub
    
    

  3. Run the UserForm.

Initially, the ListBox displays only the items from A1:A3.

  1. Click the CommandButton once.

The ListBox displays the items from A1:A4.

  1. Close the UserForm.

Adding an Item from a Variable

  1. Type the following code for the Click event of CommandButton1:

          Private Sub CommandButton1_Click()
    
              Dim myarray
              Dim mystring as String
       
              'The List property returns a variant array.
              myarray = ListBox1.List
       
              'Clear the RowSource property during run time.
              'The ListBox no longer is bound to the defined name.
              ListBox1.RowSource = ""
       
              'Set the List property for the ListBox to the array.
              ListBox1.List() = myarray
       
              mystring = InputBox("Type a text string")
    
              'You can use the AddItem method because the ListBox is not
              'bound to the worksheet cells (referenced by the defined 
              'name).
              ListBox1.AddItem mystring
       
          End Sub
       
    
2. Run the UserForm.

  1. Click the CommandButton in the UserForm.

  2. Type any text string in the InputBox and click OK.

The text you type in the InputBox is added to the ListBox.

  1. Close the UserForm.

STATUS

This behavior is by design of Microsoft Excel.

MORE INFORMATION

For additional information, please see the following article in the Microsoft Knowledge Base:

   ARTICLE-ID: Q161477
   TITLE     : XL97: Error Using RemoveItem Method

REFERENCES

For more information about the List property, click the Index tab in Visual Basic for Applications Help, type the following text

   list property

and then double-click the selected text to go to the "List Property" topic.


Additional query words: XL97
Keywords : kbcode kberrmsg kbprg xlvbahowto xlvbainfo
Version : WINDOWS:97
Platform : WINDOWS


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: March 13, 1998
© 1998 Microsoft Corporation. All rights reserved. Terms of Use.