XL97: How to Programmatically Create a Collection

Article translations Article translations
Article ID: 161215 - View products that this article applies to.
This article was previously published under Q161215
This article has been archived. It is offered "as is" and will no longer be updated.
Expand all | Collapse all

SUMMARY

New programming functionality in Microsoft Excel 97 allows you to create a collection. A collection is a predefined object that stores groups of related objects. A collection makes it easier to work with the object group. For example, you can use a For Each looping structure to loop through the collection. Each time the macro executes the loop it references a different object in the collection until all objects in the collection are referenced once.

This article includes a sample Visual Basic for Applications macro that creates and references a collection.

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 Microsoft Advisory Services. For more information, visit these Microsoft Web sites:

Microsoft Certified Partners - https://partner.microsoft.com/global/30000104

Microsoft 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;CNTACTMS In general, declare an object as a new collection to create the collection. After you create the Collection object, add items to the collection using the Add method or remove items using the Remove method.

  1. Create a new workbook and start the Visual Basic Editor (press ALT+F11).
  2. On the Insert menu, click Class Module.
  3. In the class module, type the following declaration:
           Public EmployeeName As String
    						
    You typically use a public variable in a class modules to define properties for the class.
  4. If the Properties window is not visible, click Properties on the View menu.
  5. If the Project Explorer window is not visible, click Project Explorer on the view menu.
  6. In the Project Explorer, click the class module you inserted in the project in step 2.
  7. In the Properties window, change the (Name) property of the class module to EmpClass.
  8. On the Insert menu, click Module.
  9. In this module, type the following code:
                  Sub MyCollection()
    
               Dim employees As New Collection   'Create the collection object.
               Dim num As Integer
    
               num = 0    'Counter for number of employees added to the
                          'collection.
    
               Do
                   Dim employee As New EmpClass    'Create new instance of the
                                                   'EmpClass class.
                   num = num + 1
    
                   newname = InputBox("Enter new employee name" & Chr(13) _
                       & "or press Cancel to see list of employees.")
    
                   If newname <> "" Then   'You did not press Cancel.
    
                       employee.EmployeeName = newname
                       employees.Add Item:=employee, key:=CStr(num)
    
                       Set employee = Nothing    'Clear the current reference
                                                 'in preparation for next one.
    
                   End If
    
               Loop Until newname = ""  'You pressed Cancel.
    
               For Each x In employees
                   MsgBox x.EmployeeName 'Display the employee name.
               Next
    
               MsgBox employees.Count  'Current number of employees in
    collection.
    
               For Each x In employees
                   employees.Remove 1   'Remove each employee from the
    collection.
               Next
    
               MsgBox employees.Count 'Display a count of zero because
                                      'all employees were removed from the
                                      'collection.
    
           End Sub
  10. Run the MyCollection macro.
  11. When you are prompted, type any names, and then click Cancel to stop typing names.
Message boxes that display each of the names you typed appear. Then, a message box that displays a count of the names you typed appears. Another message box with a count of zero appears because the last For Each loop removes each employee from the collection.

REFERENCES

For more information about the Add Method, click the Index tab in Visual Basic for Applications Help, type the following text
add method
and then double-click the selected text to go to the "Add Method (Visual Basic for Applications)" topic.

For more information about Collections, click the Index tab in Visual Basic for Applications Help, type the following text
collections, described
and then double-click the selected text to go to the "Collection Object" topic.

Properties

Article ID: 161215 - Last Review: October 4, 2013 - Revision: 2.4
APPLIES TO
  • Microsoft Excel 97 Standard Edition
Keywords: 
kbnosurvey kbarchive kbdtacode kbprogramming KB161215

Contact us for more help

Contact us for more help
Connect with Answer Desk for expert help.
Get more support from smallbusiness.support.microsoft.com