Home > Articles > Programming > Windows Programming

This chapter is from the book

Creating a Collection

Now that we have a Cell object we want to create many instances of the object so we can analyze a worksheet or ranges of cells within a worksheet. The easiest way to manage these new objects is to store them in a collection. VBA provides a Collection object that you can use to store objects and data. The Collection object has four methods:

  • Add
  • Count
  • Item
  • Remove

There is no restriction on the type of data that can be stored within a Collection object, and items with different data types can be stored in the same Collection object. In our case, we want to be consistent and store just Cell objects in our collection.

To create a new Collection, the first step is to add a new standard module to contain global variables. This module will be called MGlobals. Next, add the following variable declaration to the MGlobals module to declare a global Collection object variable to hold the collection, as follows:

Public gcolCells As Collection

Now add the CreateCellsCollection procedure shown in Listing 7-4 to the MEntryPoints module. The modified code is contained in the Analysis2.xls workbook in the \Concepts\Ch07 – Using Class Modules to Create Objects folder on the CD that accompanies this book.

Listing 7-4. Creating a Collection of Cell Objects

Public Sub CreateCellsCollection()

    Dim clsCell As CCell
    Dim rngCell As Range

    ' Create new Cells collection
    Set gcolCells = New Collection

    ' Create Cell objects for each cell in Selection
    For Each rngCell In Application.Selection
        Set clsCell = New CCell
        Set clsCell.Cell = rngCell
        clsCell.Analyze
        'Add the Cell to the collection
        gcolCells.Add Item:=clsCell, Key:=rngCell.Address
    Next rngCell

    ' Display the number of Cell objects stored
    MsgBox "Number of cells stored: " & CStr(gcolCells.Count)

End Sub

We declare gcolCells as a public object variable so that it persists for as long as the workbook is open and is visible to all procedures in the VBA project. The CreateCellsCollection procedure creates a new instance of the collection and loops through the currently selected cells, creating a new instance of the Cell object for each cell and adding it to the collection. The address of each cell, in $A$1 reference style, is used as a key to uniquely identify it and to provide a way of accessing the Cell object later.

We can loop through the objects in the collection using a For...Each loop or we can access individual Cell objects by their position in the collection or by using the key value. Because the Item method is the default method for the collection, we can use code like the following to access a specific Cell object:

Set clsCell = gcolCells(3)
Set clsCell = gcolCells("$A$3")

Creating a Collection Object

The collection we have established is easy to use, but it lacks some features we would like to have. As it stands, there is no control over the type of objects that can be added to the collection. We would also like to add a method to the collection that enables us to highlight cells of the same type and another method to remove the highlights.

We first add two new methods to the CCell class module. The Highlight method adds color to the Cell object according to the CellType. The UnHighlight method removes the color. The new code is shown in Listing 7-5.

Note that we are applying the principle of encapsulation. All the code that relates to the Cell object is contained in the CCell class module, not in any other module. Doing this ensures that the code can be easily found and maintained and means that it can be easily transported from one project to another.

Listing 7-5. New Code for the CCell Class Module

Public Sub Highlight()
  Cell.Interior.ColorIndex = Choose(muCellType + 1, 5, 6, 7, 8)
End Sub

Public Sub UnHighlight()
  Cell.Interior.ColorIndex = xlNone
End Sub

We can now create a new class module named CCells to contain the Cells collection, as shown in Listing 7-6. The complete code is contained in the Analysis3.xls workbook in the \Concepts\Ch07 – Using Class Modules to Create Objects folder on the CD that accompanies this book.

Listing 7-6. The CCells ClassModule

Option Explicit

Private mcolCells As Collection

Property Get Count() As Long
    Count = mcolCells.Count
End Property

Property Get Item(ByVal vID As Variant) As CCell
    Set Item = mcolCells(vID)
End Property

Private Sub Class_Initialize()
    Set mcolCells = New Collection
End Sub

Public Sub Add(ByRef rngCell As Range)
    Dim clsCell As CCell
    Set clsCell = New CCell
    Set clsCell.Cell = rngCell
    clsCell.Analyze
    mcolCells.Add Item:=clsCell, Key:=rngCell.Address
End Sub

Public Sub Highlight(ByVal uCellType As anlCellType)
    Dim clsCell As CCell
    For Each clsCell In mcolCells
        If clsCell.CellType = uCellType Then
            clsCell.Highlight
        End If
    Next clsCell
End Sub

Public Sub UnHighlight(ByVal uCellType As anlCellType)
    Dim clsCell As CCell
    For Each clsCell In mcolCells
        If clsCell.CellType = uCellType Then
            clsCell.UnHighlight
        End If
    Next clsCell
End Sub

The mcolCells Collection object variable is declared as a private, module-level variable and is instantiated in the Initialize procedure of the class module. Since the Collection object is now hidden from the outside world, we need to write our own Add method for it. We also have created Item and Count property procedures to emulate the corresponding properties of the collection. The input argument for the Item property is declared as a Variant data type because it can be either a numeric index or the string key that identifies the collection member.

The Highlight method loops through each member of the collection. If the CellType property of the Cell object is the same as the type specified by the uCellType argument, we execute the Cell object's Highlight method. The UnHighlight method loops through the collection and executes the UnHighlight method of all Cell objects whose type is the same as the type specified by the uCellType argument.

We modified the public Collection variable declaration in MGlobals to refer to our new custom collection class as shown here:

Public gclsCells As CCells

We also modified the CreateCellsCollection procedure in the MEntryPoints module to instantiate and populate our custom collection, as shown in Listing 7-7.

Listing 7-7. MEntryPoints Code to Create a Cells Object Collection

Public Sub CreateCellsCollection()

    Dim clsCell As CCell
    Dim lIndex As Long
    Dim lCount As Long
    Dim rngCell As Range

    Set gclsCells = New CCells

    For Each rngCell In Application.ActiveSheet.UsedRange
        gclsCells.Add rngCell
    Next rngCell

    ' Count the number of formula cells in the collection.
    For lIndex = 1 To gclsCells.Count
        If gclsCells.Item(lIndex).CellType = anlCellTypeFormula Then
            lCount = lCount + 1
        End If
    Next lIndex

    MsgBox "Number of Formulas = " & CStr(lCount)

End Sub

We declare gclsCells as a public object variable to contain our custom Cells collection object. The CreateCellsCollection procedure instantiates gclsCells and uses a For...Each loop to add all the cells in the active worksheet's used range to the collection. After loading the collection, the procedure counts the number of cells that contain formulas and displays the result.

The MEntryPoints module contains a ShowFormulas procedure that can be executed to highlight and unhighlight the formula cells in the worksheet. Several additional variations are provided for other cell types.

This code illustrates two shortcomings of our custom collection class. You can't process the members of the collection in a For...Each loop. You must use an index and the Item property instead. Also, our collection has no default property, so you can't shortcut the Item property using the standard collection syntax gclsCells(1) to access a member of the collection. You must specify the Item property explicitly in your code. We explain how to solve these problems using Visual Basic 6 or just a text editor in the next section.

Addressing Class Collection Shortcomings

It is possible to make your custom collection class behave like a built-in collection. It requires nothing more than a text editor to make the adjustments, but first we'll explain how to do it by setting procedure attributes using Visual Basic 6 (VB6) to better illustrate the nature of the changes required.

Using Visual Basic 6

In VB6, unlike Visual Basic for Applications used in Excel, you can specify a property to be the default property of the class. If you declare the Item property to be the default property, you can omit .Item when referencing a member of the collection and use a shortcut such as gclsCells(1) instead.

If you have VB6 installed you can export the code module CCells to a file and open that file in VB6. Place your cursor anywhere within the Item property procedure and select Tools > Procedure Attributes from the menu to display the Procedure Attributes dialog. Next, click the Advanced >> button and under the Advanced options select (Default) from the Procedure ID combo box. This makes the Item property the default property for the class.

When you save your changes and import this file back into your Excel VBA project, the attribute will be recognized even though there is no way to set attribute options within the Excel Visual Basic Editor. VB6 also allows you to set up the special procedure shown in Listing 7-8.

Listing 7-8. Code to Allow the Collection to Be Referenced in a For...Each Loop

Public Function NewEnum() As IUnknown
    Set NewEnum = mcolCells.[_NewEnum]
End Function

This procedure must be given an attribute value of 4, which you enter directly into the Procedure ID combo box in the Procedure Attributes dialog. Giving the NewEnum procedure this attribute value enables a For...Each loop to process the members of the collection. Once you have made this addition to your class module in VB6 and saved your changes, you can load the module back into your Excel VBA project, and once again the changes will be recognized.

Using a Text Editor

Even without VB6 you can easily create these procedures and their attributes using a text editor such as NotePad. Export the CCells class module to a file and open it using the text editor. Modify your code to look like the example shown in Listing 7-9.

Listing 7-9. Viewing the Code in a Text Editor

Property Get Item(ByVal vID As Variant) As CCell
Attribute Item.VB_UserMemId = 0
    Set Item = mcolCells(vID)
End Property

Public Function NewEnum() As IUnknown
Attribute NewEnum.VB_UserMemId = -4
    Set NewEnum = mcolCells.[_NewEnum]
End Function

When the modified class module is imported back into your project the Attribute lines will not be visible, but the procedures will work as expected. You can now refer to a member of the collection as gclsCells(1) and use your custom collection class in a For...Each loop as shown in Listing 7-10.

Listing 7-10. Referencing the Cells Collection in a For...Each Loop

  For Each clsCell In gclsCells
      If clsCell.CellType = anlCellTypeFormula Then
          lCount = lCount + 1
      End If
  Next clsCell

InformIT Promotional Mailings & Special Offers

I would like to receive exclusive offers and hear about products from InformIT and its family of brands. I can unsubscribe at any time.

Overview


Pearson Education, Inc., 221 River Street, Hoboken, New Jersey 07030, (Pearson) presents this site to provide information about products and services that can be purchased through this site.

This privacy notice provides an overview of our commitment to privacy and describes how we collect, protect, use and share personal information collected through this site. Please note that other Pearson websites and online products and services have their own separate privacy policies.

Collection and Use of Information


To conduct business and deliver products and services, Pearson collects and uses personal information in several ways in connection with this site, including:

Questions and Inquiries

For inquiries and questions, we collect the inquiry or question, together with name, contact details (email address, phone number and mailing address) and any other additional information voluntarily submitted to us through a Contact Us form or an email. We use this information to address the inquiry and respond to the question.

Online Store

For orders and purchases placed through our online store on this site, we collect order details, name, institution name and address (if applicable), email address, phone number, shipping and billing addresses, credit/debit card information, shipping options and any instructions. We use this information to complete transactions, fulfill orders, communicate with individuals placing orders or visiting the online store, and for related purposes.

Surveys

Pearson may offer opportunities to provide feedback or participate in surveys, including surveys evaluating Pearson products, services or sites. Participation is voluntary. Pearson collects information requested in the survey questions and uses the information to evaluate, support, maintain and improve products, services or sites, develop new products and services, conduct educational research and for other purposes specified in the survey.

Contests and Drawings

Occasionally, we may sponsor a contest or drawing. Participation is optional. Pearson collects name, contact information and other information specified on the entry form for the contest or drawing to conduct the contest or drawing. Pearson may collect additional personal information from the winners of a contest or drawing in order to award the prize and for tax reporting purposes, as required by law.

Newsletters

If you have elected to receive email newsletters or promotional mailings and special offers but want to unsubscribe, simply email information@informit.com.

Service Announcements

On rare occasions it is necessary to send out a strictly service related announcement. For instance, if our service is temporarily suspended for maintenance we might send users an email. Generally, users may not opt-out of these communications, though they can deactivate their account information. However, these communications are not promotional in nature.

Customer Service

We communicate with users on a regular basis to provide requested services and in regard to issues relating to their account we reply via email or phone in accordance with the users' wishes when a user submits their information through our Contact Us form.

Other Collection and Use of Information


Application and System Logs

Pearson automatically collects log data to help ensure the delivery, availability and security of this site. Log data may include technical information about how a user or visitor connected to this site, such as browser type, type of computer/device, operating system, internet service provider and IP address. We use this information for support purposes and to monitor the health of the site, identify problems, improve service, detect unauthorized access and fraudulent activity, prevent and respond to security incidents and appropriately scale computing resources.

Web Analytics

Pearson may use third party web trend analytical services, including Google Analytics, to collect visitor information, such as IP addresses, browser types, referring pages, pages visited and time spent on a particular site. While these analytical services collect and report information on an anonymous basis, they may use cookies to gather web trend information. The information gathered may enable Pearson (but not the third party web trend services) to link information with application and system log data. Pearson uses this information for system administration and to identify problems, improve service, detect unauthorized access and fraudulent activity, prevent and respond to security incidents, appropriately scale computing resources and otherwise support and deliver this site and its services.

Cookies and Related Technologies

This site uses cookies and similar technologies to personalize content, measure traffic patterns, control security, track use and access of information on this site, and provide interest-based messages and advertising. Users can manage and block the use of cookies through their browser. Disabling or blocking certain cookies may limit the functionality of this site.

Do Not Track

This site currently does not respond to Do Not Track signals.

Security


Pearson uses appropriate physical, administrative and technical security measures to protect personal information from unauthorized access, use and disclosure.

Children


This site is not directed to children under the age of 13.

Marketing


Pearson may send or direct marketing communications to users, provided that

  • Pearson will not use personal information collected or processed as a K-12 school service provider for the purpose of directed or targeted advertising.
  • Such marketing is consistent with applicable law and Pearson's legal obligations.
  • Pearson will not knowingly direct or send marketing communications to an individual who has expressed a preference not to receive marketing.
  • Where required by applicable law, express or implied consent to marketing exists and has not been withdrawn.

Pearson may provide personal information to a third party service provider on a restricted basis to provide marketing solely on behalf of Pearson or an affiliate or customer for whom Pearson is a service provider. Marketing preferences may be changed at any time.

Correcting/Updating Personal Information


If a user's personally identifiable information changes (such as your postal address or email address), we provide a way to correct or update that user's personal data provided to us. This can be done on the Account page. If a user no longer desires our service and desires to delete his or her account, please contact us at customer-service@informit.com and we will process the deletion of a user's account.

Choice/Opt-out


Users can always make an informed choice as to whether they should proceed with certain services offered by InformIT. If you choose to remove yourself from our mailing list(s) simply visit the following page and uncheck any communication you no longer want to receive: www.informit.com/u.aspx.

Sale of Personal Information


Pearson does not rent or sell personal information in exchange for any payment of money.

While Pearson does not sell personal information, as defined in Nevada law, Nevada residents may email a request for no sale of their personal information to NevadaDesignatedRequest@pearson.com.

Supplemental Privacy Statement for California Residents


California residents should read our Supplemental privacy statement for California residents in conjunction with this Privacy Notice. The Supplemental privacy statement for California residents explains Pearson's commitment to comply with California law and applies to personal information of California residents collected in connection with this site and the Services.

Sharing and Disclosure


Pearson may disclose personal information, as follows:

  • As required by law.
  • With the consent of the individual (or their parent, if the individual is a minor)
  • In response to a subpoena, court order or legal process, to the extent permitted or required by law
  • To protect the security and safety of individuals, data, assets and systems, consistent with applicable law
  • In connection the sale, joint venture or other transfer of some or all of its company or assets, subject to the provisions of this Privacy Notice
  • To investigate or address actual or suspected fraud or other illegal activities
  • To exercise its legal rights, including enforcement of the Terms of Use for this site or another contract
  • To affiliated Pearson companies and other companies and organizations who perform work for Pearson and are obligated to protect the privacy of personal information consistent with this Privacy Notice
  • To a school, organization, company or government agency, where Pearson collects or processes the personal information in a school setting or on behalf of such organization, company or government agency.

Links


This web site contains links to other sites. Please be aware that we are not responsible for the privacy practices of such other sites. We encourage our users to be aware when they leave our site and to read the privacy statements of each and every web site that collects Personal Information. This privacy statement applies solely to information collected by this web site.

Requests and Contact


Please contact us about this Privacy Notice or if you have any requests or questions relating to the privacy of your personal information.

Changes to this Privacy Notice


We may revise this Privacy Notice through an updated posting. We will identify the effective date of the revision in the posting. Often, updates are made to provide greater clarity or to comply with changes in regulatory requirements. If the updates involve material changes to the collection, protection, use or disclosure of Personal Information, Pearson will provide notice of the change through a conspicuous notice on this site or other appropriate way. Continued use of the site after the effective date of a posted revision evidences acceptance. Please contact us if you have questions or concerns about the Privacy Notice or any objection to any revisions.

Last Update: November 17, 2020