“Classes struggle, some classes triumph, others are eliminated. Such is history” – Chairman Mao
Contents
- 1 A Quick Guide to the VBA Class Module
- 2 The Webinar
- 3 Introduction
- 4 Download the Source Code
- 5 Why Do We Use Objects
- 6 Advantages of Using Objects
- 7 Disadvantages of Using Objects
- 8 Creating a Simple Class Module
- 9 VBA Class Modules Versus VBA Normal Modules
- 10 The Parts of a Class Module
- 11 Class Module Events
- 12 Class Module Example 1
- 13 Class Module Example 2
- 14 Conclusion
- 15 What’s Next?
A Quick Guide to the VBA Class Module
Item | Explanation |
---|---|
Class Module | Allows the user to create their own objects. |
Method | A public function or sub in the class module. |
Member variable | A variable declared in the class module. |
Property | Special function/subs that behave like variables when used |
Property types | Get, Set and Let. |
Event - Initialize | Sub that automatically runs when the class module object is created. |
Event - Terminate | Sub that automatically runs when the class module object is deleted. |
Declaring and Creating - Static | Dim o As New Class1 |
Declaring and Creating - Dynamic | Dim o As Class1 Set o = New Class1 |
Calling a class module sub | o.WriteValues Total |
Calling a class module function | Amount = o.Calculate() |
Using a class module property | o.Amount = 1 Total = o.Amount |
The Webinar
Members of the Webinar Archives can access the webinar for this article by clicking on the image below.
(Note: Archive members have access to the webinar archive.)
Introduction
VBA Class Modules allow the user to create their own objects. If you are not familiar with objects then I would highly recommend that you first check out my previous post VBA Objects – The Ultimate Guide.
In languages such as C# and Java, classes are used to create objects. Class Modules are the VBA equivalent of these classes. The major difference is that VBA Class Modules have a very limited type of Inheritance* compared to classes in the other languages. In VBA, Inheritance works in a similar way to Interfaces** in C#\Java.
In VBA we have built-in objects such as the Collection, Workbook, Worksheet and so on. The purpose of VBA Class Modules is to allow us to custom build our own objects.
Let’s start this post by looking at why we use objects in the first place.
*Inheritance is using an existing class to build a new class.
**Interfaces are a form of Inheritance that forces a class to implement specifics procedures or properties.
Download the Source Code
Why Do We Use Objects
Using objects allows us to build our applications like we are using building blocks.
The idea is that the code of each object is self-contained. It is completely independent of any other code in our application.
This is similar to how things are built using Lego® bricks. There are many different types of Lego® components used. For example, a block, steering wheel, and laser are different items. They behave completely independently of each other. The wheel spins, the laser rotates etc. Yet we can connect them together to create a building, vehicle, space station and so on.
If you are still not clear about this then don’t worry. We’ll be breaking it all down into simple terms in the rest of this post.
Advantages of Using Objects
Treating parts of our code as blocks provide us with a lot of great advantages
- It allows us to build an application one block at a time.
- It is much easier to test individual parts of an application.
- Updating code won’t cause problems in other parts of the application.
- It is easy to add objects between applications.
Disadvantages of Using Objects
With most things in life there are pros and cons. Using VBA class modules is no different. The following are the disadvantages of using class module to create objects
- It takes more time initially to build applications*.
- It is not always easy to clearly define what an object is.
- People new to classes and objects can find them difficult to understand at first.
*If you create an application using objects it will take longer to create it initially as you have to spend more time planning and designing it. However, in the long run it will save you a huge amount of time. Your code will be easier to manage, update and reuse.
Creating a Simple Class Module
If you would like to see working examples of this code you can download the source code from the top of this post.
Let’s look at a very simple example of creating a class module and using it in our code.
To create a class module we right-click in the Project window and then select Insert and Class Module
Our new class is called Class1. We can change the name in the Properties window as the following screenshot shows:
Let’s change the name of the class module to clsCustomer. Then we will add a variable to the class module like this:
Public Name As String
We can now use this class module in any module(standard or class) in our workbook. For example
' Create the object from the class module Dim oCustomer As New clsCustomer ' Set the customer name oCustomer.Name = "John" ' Print the name to the Immediate Window(Ctrl + G) Debug.Print oCustomer.Name
Class Module versus Objects
People who are new to using classes and VBA class modules, often get confused between what is a class and what is an object.
Let’s look at a real world example. Think of a mass produced item like a coffee mug. A design of the mug is created first. Then, thousands of coffee mugs are created from this design.
This is similar to how class modules and objects work.
The class module can be thought of as the design.
The object can be thought of as the item that is created from the design.
The New keyword in VBA is what we use to create an object from a class module. For example:
' Creating objects using new Dim oItem As New Class1 Dim oCustomer1 As New clsCustomer Dim coll As New Collection
Note: We don’t use New with items such as Workbooks and Worksheets. See When New is not required for more information.
VBA Class Modules Versus VBA Normal Modules
Writing code in a class module is almost the same as writing code in a normal module. We can use the same code we use in normal modules. It’s how this code is used which is very different.
Let’s look at the two main differences between the class and the normal module. These often cause confusion among new users.
Difference 1 – How the modules are used
If you want to use a sub/function etc. from a class module you must create the object first.
For example, imagine we have two identical PrintCustomer subs. One is in a class module and one is in a normal module…
' CLASS MODULE CODE - clsCustomer Public Sub PrintCustomer() Debug.Print "Sample Output" End Sub
' NORMAL MODULE CODE Public Sub PrintCustomer() Debug.Print "Sample Output" End Sub
You will notice the code for both is exactly the same.
To use the PrintCustomer sub from the class module, you must first create an object of that type
' Other Module ' https://excelmacromastery.com/ Sub UseCustomer() Dim oCust As New clsCustomer oCust.PrintCustomer End Sub
To use PrintCustomer from the normal module you can call it directly
' Other Module ' https://excelmacromastery.com/ Sub UseCustomer() PrintCustomer End Sub
Difference 2 – Number of copies
When you create a variable in a normal module there is only one copy of it. For a class module, there is one copy of the variable for each object you create.
For example, imagine we create a variable StudentName in both a class and normal module:
' NORMAL MODULE Public StudentName As String
' CLASS MODULE called clsStudent Public StudentName As String
For the normal module variable there will only be one copy of this variable in our application.
StudentName = "John"
For the class module, a new copy of the variable StudentName is created each time a new object is created.
Dim student1 As New clsStudent Dim student2 As New clsStudent student1.StudentName = "Bill" student2.StudentName = "Ted"
When you fully understand VBA class modules, these differences will seem obvious.
The Parts of a Class Module
There are four different items in a class module. These are
- Methods – functions/subs.
- Member variables – variables.
- Properties– types of functions/subs that behave like variables.
- Events – subs that are triggered by an event.
You can see they are all either functions, subs or variables.
Let’s have a quick look at class that has examples of each of these:
' CLASS MODULE CODE from clsAccount ' https://excelmacromastery.com/vba-class-modules/ ' Member variable Private m_balance As Double ' Properties Property Get Balance() As Double Balance = m_balance End Property Property Let Balance(value As Double) m_balance = value End Property ' Event - triggered when class created Private Sub Class_Initialize() m_balance = 100 End Sub ' Methods Public Sub Withdraw(amount As Double) m_balance = m_balance - amount End Sub Public Sub Deposit(amount As Double) m_balance = m_balance + amount End Sub
The following code demonstrates how this class could be used:
' This sub uses the clsAccount class ' The results are printed to the Immediate Window(Ctrl + G) ' https://excelmacromastery.com/vba-class-modules/ Sub Demo_clsAccount() Dim oAccount As New clsAccount ' Print the balance Debug.Print "Starting balance is: " & oAccount.Balance ' Deposit money oAccount.Deposit 25 ' Print the balance Debug.Print "Balance after deposit is: " & oAccount.Balance ' Withdraw Money oAccount.Withdraw 100 ' Print the balance Debug.Print "Balance after withdrawl is: " & oAccount.Balance End Sub
If we run the code we will get the following:
Starting balance is: 100
Balance after deposit is: 125
Balance after withdrawl is: 25
Now that we have seen examples, let’s take a look at each of these in turn.
Class Module Methods
Methods refer to the procedures of the class. In VBA procedures are subs and functions. Like member variables they can be Public or Private.
Let’s look at an example:
' CLASS MODULE CODE for clsExample ' https://excelmacromastery.com/vba-class-modules/ ' Public procedures can be called from outside the object Public Sub PrintText(text As String) Debug.Print text End Sub Public Function Calculate(amount As Double) As Double Calculate = amount - GetDeduction End Function ' private procedures can only be called from within the Class Module Private Function GetDeduction() As Double GetDeduction = 2.78 End Function
We can use the clsExample class module like this:
' Sub used to demonstrate Class clsExample ' https://excelmacromastery.com/vba-class-modules/ Public Sub ClassMembers() Dim oSimple As New clsExample oSimple.PrintText "Hello" Dim total As Double total = oSimple.Calculate(22.44) Debug.Print total End Sub
Class Module Member Variables
The member variable is very similar to the normal variable we use in VBA. The difference is we use Public or Private instead of Dim.
' CLASS MODULE CODE Private Balance As Double Public AccountID As String
Note: Dim and Private do exactly the same thing but the convention is to use Dim in sub/functions and to use Private outside sub/functions.
The Public keyword means the variable can be accessed from outside the class module. For example:
' This code will give an ERROR!! Sub Demo_BankAccount() Dim oAccount As New clsBankAccount ' Valid - AccountID is public oAccount.AccountID = "499789" ' ERROR - Balance is private oAccount.Balance = 678.9 End Sub
In the above example, we cannot access Balance because it is declared as Private. We can only use a Private variable within the class module. We can use in a function/sub in the class module e.g.
' CLASS MODULE CODE ' https://excelmacromastery.com/ Private Balance As Double Public Sub SetBalance() Balance = 100 Debug.Print Balance End Sub
It is considered poor practice to have public member variables. This is because you are allowing code outside the object to interfere with how the class works. The purpose of the using classes is so that we hide what is happening from the caller.
To avoid the user directly talking to our member variables we use Properties.
Class Module Properties
- Get – returns an object or value from the class
- Let – sets a value in the class
- Set – sets an object in the class
Format of VBA Property
The normal format for the properties are as follows:
Public Property Get () As Type End Property Public Property Let (varname As Type ) End Property Public Property Set (varname As Type ) End Property
We have seen already that the Property is simply a type of sub. The purpose of the Property is to allow the caller to get and set values.
Why we use Properties
Why can’t we just make the variables Public and use them directly?
Let’s explain with some examples. Imagine we have a class that maintains a list of Countries. We could store the list as an array
' Use array to store countries ' https://excelmacromastery.com/ Public arrCountries As Variant ' Set size of array when class is initialized ' https://excelmacromastery.com/ Private Sub Class_Initialize() ReDim arrCountries(1 To 1000) End Sub
When the user wants to get the number of countries in the list they could do this:
' NORMAL MODULE CODE Dim oCountry As New clsCountry ' Get the number of items NumCountries = UBound(oCountry.arrCountries) - LBound(oCountry.arrCountries) + 1
There are two major problems with the above code:
- To get the number of countries you need to know how the list is stored e.g. Array.
- If we change the Array to a Collection, we need to change all code that reference the array directly.
To solve these problems we can create a function to return the number of countries
' CLASS MODULE CODE - clsCountryList ' Array Private arrCountries() As String Public Function Count() As Long Count = UBound(arrCountries) + 1 End Function
We then use it like this:
' MODULE CODE Dim oCountries As New clsCountries Debug.Print "Number of countries is " & oCountries.Count
This code solves the two problems we listed above. We can change our Array to a Collection and the caller code will still work e.g.
' CLASS MODULE CODE ' Collection ' https://excelmacromastery.com/ Private collCountries() As Collection Public Function Count() As Long Count = collCountries.Count End Function
The caller is oblivious to how the countries are stored. All the caller needs to know is that the Count function will return the number of countries.
As we have just seen, a sub or function provides a solution to the above problems. However, using a Property can provide a more elegant solution.
Using a Property instead of a Function/Sub
Instead of the creating a Count Function we can create a Count Property. As you can see below they are very similar:
' Replace this Public Function Count() As Long Count = UBound(m_countries) - LBound(m_countries) + 1 End Function ' With this Property Get Count() As Long Count = UBound(m_countries) - LBound(m_countries) + 1 End Property
In this scenario, there is not a lot of difference between using the Property and using a function. However, there are differences. We normally create a Get and Let property like this:
' https://excelmacromastery.com/vba-class-modules/ Private m_totalCost As Double Property Get totalCost() As Long totalCost = m_totalCost End Property Property Let totalCost(value As Long) m_totalCost = value End Property
Using Let allows us to treat the property like a variable. So we can do this
oAccount.TotalCost = 6
The second difference is that using Let and Get allows us to use the same name when referencing the Get or Let property. So we can use the property like a variable. This is the purpose of using Properties over a sub and function.
oAccount.TotalCost = 6 value = oAccount.TotalCost
If we used a function and a sub then we cannot get the behaviour of a variable. Instead we have to call two different procedures e.g.
oAccount.SetTotalCost 6 value = oAccount.GetTotalCost
You can also see that when we used Let we can assign the value like a variable. When we use SetTotalCost , we had to pass it as a parameter.
The Property in a Nutshell
- The Property hides the details of the implementation from the caller.
- The Property allows us to provide the same behaviour as a variable.
Types of VBA Property
There are three types of Properties. We have seen Get and Let already. The one we haven’t looked at is Set.
Set is similar to Let but it is used for an object(see Assigning VBA Objects for more detail about this).
Originally in Visual Basic, the Let keyword was used to assign a variable. In fact, we can still use it if we like.
' These line are equivalent Let a = 7 a = 7
So we use Let to assign a value to a variable and we use Set to assign an object to an object variable.
' Using Let Dim a As Long Let a = 7 ' Using Set Dim coll1 As Collection, coll2 As Collection Set coll1 = New Collection Set coll2 = coll1
- Let is used to assign a value to a basic variable type.
- Set is used to assign an object to an object variable.
In the following example, we use Get and Let properties for a string variable:
' CLASS MODULE CODE for clsPerson ' https://excelmacromastery.com/vba-class-modules/ ' SET/LET PROPERTIES for a variable Private m_name As String ' Get/Let Properties Property Get name() As String name = m_name End Property Property Let name(name As String) m_name = name End Property
We can then use the name properties like this:
' Testing Let and Set for the clsPerson Class ' https://excelmacromastery.com/vba-class-modules/ Sub TestLetSet() Dim name As String Dim oPerson As New clsPerson ' Let Property oPerson.name = "Bill" ' Get Property name = oPerson.name End Sub
In the next example, we use Get and Set properties for an object variable:
' CLASS MODULE CODE for clsCurrency ' https://excelmacromastery.com/vba-class-modules/ Private m_Prices As Collection ' Get/Set Properties Property Get Prices() As Collection Set Prices = m_Prices End Property Property Set Prices(newPrices As Collection) Set m_Prices = newPrices End Property
We can then use the properties like this:
' The code below demonstrates how to use the Let\Set properties with a class. ' ' 1. The sub creates a collection and adds value. ' 2. We then add it to the clsCurrency class object using the Set Property. ' 3. We then read it from the class object usiing the Get property. ' ' https://excelmacromastery.com/vba-class-modules/ Sub TestLetSet() ' Create a collection and add prices Dim Prices As New Collection Prices.Add 21.23 Prices.Add 22.12 Prices.Add 20.12 Dim oCurrency As New clsCurrency ' Uses the Set property of clsCurrency to ' add the collection to the class Set oCurrency.Prices = Prices Dim PricesCopy As Collection ' Uses the Get property of clsCurrency ' to read the collection from the class Set PricesCopy = oCurrency.Prices ' Print the results to the Immediate Window(Ctrl + G) PrintCollection Prices, "Prices" PrintCollection PricesCopy, "Copy" End Sub ' Print the contents of a Collection to the Immediate Window(Ctrl + G) Sub PrintCollection(c As Collection, name As String) Debug.Print vbNewLine & "Printing " & name & ":" Dim item As Variant For Each item In c Debug.Print item Next item End Sub
We use the Get property to return the values for both items. Notice that even though we use the Get Property to return the Collection, we still need to use the Set keyword to assign it.
One very important thing to understand is that when we use Set we are still referencing the same collection. Set is not creating a copy of the collection. You can read more about this here
Class Module Events
If you to see working examples of this code you can download the source code from the top of this post.
A class module has two events
- Initialize – occurs when a new object of the class is created.
- Terminate – occurrs when the class object is deleted.
In Object-Oriented languages like C++, these events are referred to as the Constructor and the Destructor. In most languages, you can pass parameters to a constructor but in VBA you cannot. We can use a Class Factory to get around this issue as we will see below.
Initialize
Let’s create a very simple class module called clsSimple with Initialize and Terminate events:
' CLASS MODULE CODE ' https://excelmacromastery.com/ Private Sub Class_Initialize() MsgBox "Class is being initialized" End Sub Private Sub Class_Terminate() MsgBox "Class is being terminated" End Sub Public Sub PrintHello() Debug.Print "Hello" End Sub
In the following example, we use Dim and New to create the object.
In this case, oSimple is not created until we reference it for the first time e.g.
' https://excelmacromastery.com/ Sub ClassEventsInit2() Dim oSimple As New clsSimple ' Initialize occurs here oSimple.PrintHello End Sub
When we use Set and New together the behaviour is different. In this case the object is created when Set is used e.g.
' https://excelmacromastery.com/ Sub ClassEventsInit() Dim oSimple As clsSimple ' Initialize occurs here Set oSimple = New clsSimple oSimple.PrintHello End Sub
Note: For more information about the different between using New with Dim and using New with Set see Subtle Differences of Dim Versus Set
As I said earlier, you cannot pass a parameter to Initialize. If you need to do this you need a function to create the object first
' CLASS MODULE - clsSimple ' https://excelmacromastery.com/ Public Sub Init(Price As Double) End Sub ' NORMAL MODULE Public Sub Test() ' Use CreateSimpleObject function Dim oSimple As clsSimple Set oSimple = CreateSimpleObject(199.99) End Sub Public Function CreateSimpleObject(Price As Double) As clsSimple Dim oSimple As New clsSimple oSimple.Init Price Set CreateSimpleObject = oSimple End Function
We will expand on this CreateSimpleObject in Example 2 to create a Class Factory.
Terminate
The Terminate event occurs when the class is deleted. This happens when we set it to Nothing
' https://excelmacromastery.com/ Sub ClassEventsTerm() Dim oSimple As clsSimple Set oSimple = New clsSimple ' Terminate occurs here Set oSimple = Nothing End Sub
If we don’t set the object to Nothing then VBA will automatically delete it when it goes out of scope.
What this means is that if we create an object in a procedure, when that procedure ends VBA will delete any objects that were created.
' https://excelmacromastery.com/ Sub ClassEventsTerm2() Dim oSimple As New clsSimple ' Initialize occurs here oSimple.PrintHello ' oSimple is deleted when we exit this Sub calling Terminate End Sub
Class Module Example 1
In this example, we are going to look at a very common use of a Class module.
Imagine we have the following data
We want to read the Albums based on a range of years and then create various reports.
We could use a 2D Array for this or a Collection of collections e.g.
' https://excelmacromastery.com/ For i = 2 To rg.Rows.Count Year = rg.Cells(i, 3) If startYear <= Year And endYear >= Year Then ' Create a new collection for each row Set rowColl = New Collect ' Add artist rowColl.Add rg.Cells(i, 1).Value ' Add Title rowColl.Add rg.Cells(i, 2).Value ' and so on ' Add row collection to main collection coll.Add rowColl End If Next i
As you can imagine this code would get messy very quickly.
Lucky for us we have VBA class modules to make our life easier. We can create a class module to store the items.
' clsAlbum class module Private m_sArtist As String Private m_sTitle As String Private m_sYear As String Private m_sGenre As String Private m_sSales As String ' Properties ' https://excelmacromastery.com/ Public Property Get Artist() As String Artist = m_sArtist End Property Public Property Let Artist(ByVal sArtist As String) m_sArtist = sArtist End Property ' etc
Each time we want to add a record we can do it as follows:
' Declare the Variable Dim oAlbum As clsAlbum ' Create new album Set oAlbum = New clsAlbum ' Add the details oAlbum.Artist = rg.Cells(i, 1) oAlbum.Title = rg.Cells(i, 2) oAlbum.Year = rg.Cells(i, 3) oAlbum.Genre = rg.Cells(i, 4) oAlbum.Sales = rg.Cells(i, 5) ' Add the album object to the collection coll.Add oAlbum
You can see that this makes our code much more readable. It is clear what Artist, Title etc. are being used for.
We can then easily use this data to create reports, write to files etc.
' https://excelmacromastery.com/ Sub PrintAlbum(coll As Collection) Dim oAlbum As clsAlbum For Each oAlbum In coll ' Print out the title and artist for each album Debug.Print oAlbum.Title, oAlbum.Artist Next End Sub
Below is the full code for this example:
' https://excelmacromastery.com/ Sub CreateReport() Dim coll As Collection ' read the data Set coll = ReadAlbums(1990, 2001) ' Print the album details PrintAlbum coll ' Print the total sales PrintTotalSales coll End Sub Function ReadAlbums(startYear As Long, endYear As Long) _ As Collection Dim rg As Range Set rg = Sheet1.Range("A1").CurrentRegion ' Create a collection to store the albums Dim coll As New Collection Dim oAlbum As clsAlbum Dim i As Long, Year As Long For i = 2 To rg.Rows.Count Year = rg.Cells(i, 3) If startYear <= Year And endYear >= Year Then ' Create new album Set oAlbum = New clsAlbum ' Add the details oAlbum.Artist = rg.Cells(i, 1) oAlbum.Title = rg.Cells(i, 2) oAlbum.Year = Year oAlbum.Genre = rg.Cells(i, 4) oAlbum.sales = rg.Cells(i, 5) ' Add the album objecdt to the collection coll.Add oAlbum End If Next i Set ReadAlbums = coll End Function Sub PrintAlbum(coll As Collection) Dim oAlbum As clsAlbum For Each oAlbum In coll Debug.Print oAlbum.Title, oAlbum.Artist Next End Sub Sub PrintTotalSales(coll As Collection) Dim oAlbum As clsAlbum, sales As Double For Each oAlbum In coll sales = sales + oAlbum.sales Next Debug.Print "Total number sales is " & sales End Sub
Class Module Example 2
In this example, we’re going to take things a bit further. We’re going to look at some neat tricks when using objects.
Imagine you have a list of products like in the image below.
The products have different fields so we need to use a different class module for each product type. One type for a Book row, one type for a Film row.
We’ll create our class modules first. As you can imagine the are very similar for both product types
' CLASS MODULE - clsBook ' https://excelmacromastery.com/ ' Member variables Private m_Title As String Private m_Year As Long ' Properties Property Get ItemType() As String ItemType = "Book" End Property Property Get Title() As String Title = m_Title End Property Property Get Year() As Long Year = m_Year End Property ' Methods Public Sub Init(rg As Range) m_Title = rg.Cells(1, 2) m_Year = CLng(rg.Cells(1, 4)) End Sub Public Sub PrintToImmediate() Debug.Print ItemType, m_Title, m_Year End Sub
' CLASS MODULE - clsFilm ' https://excelmacromastery.com/ ' Member variables Private m_Title As String Private m_Year As Long ' Properties Property Get ItemType() As String ItemType = "Film" End Property Property Get Title() As String Title = m_Title End Property Property Get Year() As Long Year = m_Year End Property ' Methods Sub Init(rg As Range) m_Title = rg.Cells(1, 2) m_Year = CLng(rg.Cells(1, 5)) End Sub Public Sub PrintToImmediate() Debug.Print ItemType, m_Title, m_Year End Sub
As you can see, the only real difference is the Init sub.
When we read each record we need to determine if it is a Book or Film. Then we create the appropriate object. You would imagine we would have to create a variable for each type e.g.
' One variable required for each type Dim oBook As clsBook Dim oFilm As clsFilm ' If book do this Set oBook = New clsBook ' Else If film do this Set oFilm = New clsFilm
If we had lots of different types this would get very messy indeed. The good news is we only need to use one variable!
In VBA we can declare a variable as a Variant. When we use a Variant we are essentially saying “We will decide the type of variable when the code is running”.
This is very useful when dealing with objects and allows us to get away with using one variable e.g.
' Only one variable required Dim oItem As Variant ' If book set type to clsBook Set oItem = New clsBook ' Else If film set type to clsFilm Set oItem = New clsFilm
This is really useful as we only need one variable no matter how many objects we have.
A second advantage of using a Variant is this. If each Class Module has a sub/function with the same name and parameters, we can use the same variable to call it
So imagine clsBook has a function called InitBook and clsFilm has a function called InitFilm. We would need to do this:
' If clsBook If Type = "Book" Then oItem.InitBook ElseIf Type = "Film" Then oItem.InitFilm
However, if they have the same name, e.g. Init, we can replace the If\ElseIf lines of code with one line:
' this will call the Init sub of whatever type oItem is set to
oItem.Init
We can now create a function to create the appropriate object. In Object Oriented Programming, we have what is called a Class Factory. This is simply a function that creates an object based on a given type.
We saw earlier that the Initialize event does not take parameters. We can call Init in the Class Factory to get around this issue.
The full code for the ClassFactory function is here:
' https://excelmacromastery.com/ Function ClassFactory(rg As Range) As Variant ' Get product type Dim sType As String sType = rg.Cells(1, 1) ' Create an object based on the type Dim oItem As Variant Select Case sType Case "Book": Set oItem = New clsBook Case "Film": Set oItem = New clsFilm Case Else MsgBox "Invalid type" End Select ' Parse the fields to the correct class variables oItem.Init rg ' Return the product object Set ClassFactory = oItem End Function
This following is our starting sub. In this sub, we read through the worksheet and pass the range to ClassFactory.
It creates the object, passes the range to the object Parse method. Then it returns the object which we add to our Collection.
' https://excelmacromastery.com/ Sub ReadProducts() ' Create the collection Dim coll As New Collection Dim product As Variant Dim rg As Range ' Read products from the worksheet Dim i As Long For i = 1 To 2 Set rg = Sheet1.Range("A" & i & ":E" & i) Set product = ClassFactory(rg) coll.Add product Next ' Print the product details to the Immediate Window(Ctrl + G) PrintCollection coll End Sub
We can also use the variant object to print the items. As long as both objects have a sub with the same name and parameters(e.g PrintToImmediate) we can call it using a Variant type.
' https://excelmacromastery.com/ Public Sub PrintCollection(ByRef coll As Collection) Dim v As Variant For Each v In coll ' Print items v.PrintToImmediate Next End Sub
The source code for this post also includes this example using Inheritance(i.e. class interfaces). You can download the code here:
Conclusion
That concludes my post on the VBA Class Modules. In this post, we have looked at the parts of the VBA Class Module and two example cases where you would use them.
It’s important to understand that Classes and Objects is a vast topic. There are countless types of objects you can create and ways you can use them.
If you plan to use Class Modules then my advice is to start simple and get familiar with how to create a simple one. Once you have mastered the basics it will be much easier to move onto more challenging scenarios.
What’s Next?
Free VBA Tutorial If you are new to VBA or you want to sharpen your existing VBA skills then why not try out the The Ultimate VBA Tutorial.
Related Training: Get full access to the Excel VBA training webinars and all the tutorials.
(NOTE: Planning to build or manage a VBA Application? Learn how to build 10 Excel VBA applications from scratch.)
Assuming in column A I have SEDOL in cell A1, then these values:
a
a
b
b
c
d
e
f
g
Without classes, I can write:
Sub NoClass()
Dim DataArray() As Variant
DataArray() = Sheet1.Cells(1, 1).CurrentRegion.Value
Dim Counter As Integer
Dim Ticker As Integer
For Counter = LBound(DataArray(), 1) To UBound(DataArray(), 1) – 1
If DataArray(Counter, 1) DataArray(Counter + 1, 1) Then Ticker = Ticker + 1
Next Counter
End Sub
Using a class, what can I replace the ??? with?
Sub WithClass()
Dim DataArray() As Variant
DataArray() = Sheet1.Cells(1, 1).CurrentRegion.Value
Dim Counter As Integer
Dim Ticker As Integer
Dim MyClass As Class1
For Counter = LBound(DataArray(), 1) To UBound(DataArray(), 1) – 1
Set MyClass = New Class1
MyClass.SEDOL = Sheet1.Cells(Counter, 1)
If MyClass.SEDOL “1” Then Ticker = Ticker + 1
Next Counter
End Sub
‘ CLASS1
Option Explicit
Private pSEDOL As String
Public Property Get SEDOL() As String
SEDOL = pSEDOL
End Property
Public Property Let SEDOL(ByVal s As String)
pSEDOL = s
End Property
Thanks
Sorry, I meant:
Sub WithClass()
Dim DataArray() As Variant
DataArray() = Sheet1.Cells(1, 1).CurrentRegion.Value
Dim Counter As Integer
Dim Ticker As Integer
Dim MyClass As Class1
For Counter = LBound(DataArray(), 1) To UBound(DataArray(), 1) – 1
Set MyClass = New Class1
MyClass.SEDOL = Sheet1.Cells(Counter, 1)
If MyClass.SEDOL ??? Then Ticker = Ticker + 1
Next Counter
End Sub
Sorry, instead of:
If MyClass.SEDOL “1”
I meant:
If MyClass.SEDOL ???
I meant:
If MyClass.SEDOL ???
How can I use classes to represent DataArray(Counter + 1, 1)
Would this be a possible solution?
Sub WithClass()
Dim DataArray() As Variant
DataArray() = Sheet1.Cells(1, 1).CurrentRegion.Value
Dim Counter As Integer
Dim Ticker As Integer
Dim MyClass As Class1
Dim MyClass1 As Class1
For Counter = LBound(DataArray(), 1) To UBound(DataArray(), 1) – 1
Set MyClass = New Class1
Set MyClass1 = New Class1
MyClass.SEDOL = Sheet1.Cells(Counter, 1)
MyClass1.SEDOL = Sheet1.Cells(Counter + 1, 1)
If MyClass.SEDOL MyClass1.SEDOL Then Ticker = Ticker + 1
Next Counter
End Sub
Hi Doug,
If really depends on the overall design. If you use a class then the calculations take place inside. The code below is an example of how you would use a class.
Paul
Thanks!
I understand what you have done but this line:
If arr(i, 1) = arr(i + 1, 1)
makes it hard to understand what’s going on, as per your first class module example, where you state:
“As you can imagine this code would get messy very quickly.”
Instead if you used class modules, you can easily identify what arr(i, 1) would be, etc.
How would you incorporate that instead of writing:
If arr(i, 1) = arr(i + 1, 1)
Thanks
Whatever way you use the class it will still be necessary to use this code arr(i, 1) = arr(i + 1, 1). It is simply assigning the next row value to the current row.
thanks
Thanks Paul, I don’t think this is correct, no matter what it will not run. I’ve placed this into a class module named clsAccount and it will not run locally; testing the scope of variables in class modules.
‘ CLASS MODULE CODE
Private Balance As Double
Private Sub SetBalance()
Balance = 100
Debug.Print Balance
End Sub
Hi Dal,
SetBalance can only be called from inside the Class Module because it is private. Change it to be Public and it will run fine. I have updated this in the post.
Paul
Thanks for your rapid response Paul and the article.
Yes I managed to run it outside the class module using Public however the tutorial insinuates it can run inside the class module itself; but this isn’t the case.
I’ve put the code in exactly as the tutorial and tried running directly from the class module but it will not run, thanks again.
Regards
Dal
What do you mean it doesn’t work. Can you post the code you used and the error that you got?
Hi Paul,
Thanks for your response, apologies for the slander, I read it a thousand times “In the above example we cannot access Balance because it is declared as Private. We can only use a Private variable within the class module. We can use in a function/sub in the class module e.g.”.
I know you are illustrating the scope of variables here as the primary lesson. “We can use in a function/sub in the class module” I took this to mean that you could run class modules independently like normal modules, but of course I was mistaken. The class is applied to an item/ object; much like html and css.
Apologies again and thank you greatly for taking the time out of your day to help us simple folk learn; for free!
Regards
Darren
No problem Darren.
Hello Professor Paul!
Is it possible to create a class module where a call can have “subcalls”?
I mean, instead of this:
Dim MyDuties as New ThingsToDo
MyDuties.PrintAllFiles
MyDuties.PrintOnlyFirstFile
I would like to do this:
Dim MyDuties as New ThingsToDo
MyDuties.Print.AllFiles
MyDuties.Print.OnlyFirstFile
Is this possible? Thank you very much in advance!
Hi Sergio.
Yes. You could have a class called clsPrint and you could have this as a member of the ThingsTodo class. Then you could use it like you’ve shown.
MyDuties.MyPrint.AllFiles
Note: You cannot use Print as a variable name as it is a reserved word.
Paul
Thank you Sir! I would like to say that your tutorials are the most complete on the net and very well explained. That would be great if you Sir consider to make a second part of this tutorial where you Sir could talk about more advanced class concepts, like interface and the implements statement of VBA. Because the internet lack such a great tutorial about those concepts.
Paul,
In the code below, is it a good way to use class modules? If not, what would be the best way to achieve the same result?
‘ Standard Module
Option Explicit
Sub Test()
Dim DataArray() As Variant
DataArray = Sheet1.Cells(1, 1).CurrentRegion.Value
Dim DataArrayRows As Long
DataArrayRows = UBound(DataArray(), 1)
Dim FruitArray() As Variant
ReDim FruitArray(1 To DataArrayRows, 1 To 1) As Variant
Dim Counter As Long
Dim MyData As ClsData
Dim MyColl As Collection
Set MyColl = New Collection
For Counter = 2 To DataArrayRows
Set MyData = New ClsData
MyData.DayOfWeek = DataArray(Counter, 1)
Select Case MyData.DayOfWeek
Case “Monday”
MyData.Fruit = “Orange”
Case “Tuesday”
MyData.Fruit = “Apple”
Case Else
MyData.Fruit = “Banana”
End Select
MyColl.Add MyData
Next Counter
Dim c As ClsData
Dim i As Long
For Each MyData In MyColl
i = i + 1
FruitArray(i, 1) = MyData.Fruit
Next MyData
Sheet1.Cells(2, 2).Resize(DataArrayRows, 1).Value = FruitArray()
End Sub
‘ ClsData
Option Explicit
Private pDayOfWeek As String
Private pFruit As String
Public Property Get DayOfWeek() As String
DayOfWeek = pDayOfWeek
End Property
Public Property Let DayOfWeek(ByVal D As String)
pDayOfWeek = D
End Property
Public Property Get Fruit() As String
Fruit = pFruit
End Property
Public Property Let Fruit(ByVal F As String)
pFruit = F
Using the class module to store records is fine.
Thanks
Paul,
I have properties of my class named AOC1,AOC2….AOC7 and in my application for each of seven rows, I am seeking to match with the corresponding property like this:
If row 1VAR=odata.AOC1 then matched is true
Now using a variable for row: VAR=ROW()
rowVAR=oData.”AOC”&VAR
However, VBA does not recognise ” .”AOC”&VAR” as a member of this class.
Is there a way to iterate the matching through the 7 properties?
Paul,
I found the CallbyName function, thanks.
If CallByName(oDatm, AOCref, VbGet) = “OPT” Then
Brendan
Thanks Paul for this wonderful introduction to VBA class modules.
You’re welcome David.
In era where every “ultimate guide” only sratches the surface and has 20 subpages this one just blowed me away.
I’m super thankful for referencing to other languages. That made it so easy to get used to VBA “grammar” ;p
100/10 Paul + the site looks very clean. So glad I found you ^^
Thanks – glad you like it.
Paul, your tutorials are works of art. I’ve had decent success using the Excel object model, but one thing about custom classes is very confusing to me – the SET statement can change an object variable containing a discrete instance of the class to a reference to another instance. Wouldn’t it make more sense to be able to declare a variable as either an instance or a reference, and for VBA to enforce that usage?
And one other question on the behavior of chained references, e.g. if I1 and I2 are actual instances,
SET R1 = I1
SET R2 = R1
SET R1 = I2 or SET R1 = Nothing
R2 will continue pointing to I1 regardless of any change to R1?
Thanks…
Hi Chris,
If you look at VBA Objects in Memory it explains how the object variables work.
Each object variable stores the address of the object. When you use “Set R1 = L1” you are essentially copying the address in L1 to R1. They are now both referencing the same object.
R2 isn’t pointing to L2. It’s pointing to the object that was at L2 when set was used.
Paul
I wanted to limit the scope of some object properties defined in a class module and have made them private. I eventually realized that in this way they would not be available for other regular modules. Do variables defined in the class module need to be public to be accessible from other modules?
Yes. If variables are private they are only accessible within the class module.
It is better to use properties instead of making variables public.
However, if the class is a list of variables and nothing else then making them public is fine.
Hello Paul,
thank you for this nice introduction. I had one question though:
Is it possible to define Properties “on-the-fly”?
I am thinking about the **kwargs approach in Python. Because I do not necessarily know what/how many properties I will be adding to my object but I would love it if I didn’t have to add a property every time a new one is specified.
I believe you hinted that there is now way around it with this code snippet:
‘ clsAlbum class module
Private m_sArtist As String
Private m_sTitle As String
‘etc
‘ Properties
Public Property Get Artist() As String
Artist = m_sArtist
End Property
Public Property Let Artist(ByVal sArtist As String)
m_sArtist = sArtist
End Property
‘ etc
Many thanks for your reply in advance.
Hi Amr,
You mean like Reflection that’s available in C#\Java. It’s not possible in VBA.
I’m not sure whether this is what you want but I had to do this in a project and used an approach much like the way that values were stored in .INI files. I implemented the creation of the new properties as a method LetProperty (PropertyName AS String, Value AS String) and getting the value of a property as a function GetProperty(PropertyName as String) AS String. I was happy that the values were all stored and return as Strings but you can get round this if that doesn’t suit you.
The Class used a dictionary to store the names and values of properties. LetProperty checked to see if a property with the specified name already existed, creating one if there wasn’t, then stored or updated the value. GetProperty just retrieves the value, raising an error if there is no property with the specified name.
Hope this helps,
Mike
Paul, I am trying to use VBA classes to define shapes in an Excel-based visual process-modeling application.
I want to build and manage complex group shapes that define different types of visible model shapes. The shapes will have many common properties, but some unique ones also. Same with methods of course!
I am not sure how I can use a VBA Class module to define an object that is based on an Excel shape / group shape. I am currently using “template” shape objects that I programmatically copy and paste to create new shapes. I think that is a good strategy for managing and evolving visual shape designs, but maybe not for OO design?
You see, I’m an experienced VBA programmer, but with…”no class”, so I don’t even know what questions to ask!
Hi Dave, If you google OO Design Shapes you will see lots of examples of using shapes in Object Oriented programming.
You create a base class of shape and then derive from this using the Implements keyword. Keep in mind that VBA OO is limited compared to other languages.
Paul
Thanks Paul, I think that got me started in the right direction!
Further to shapes, can you recommend a good resource for mastering the programmatic use of Microsoft Office shapes? Might be a book, library, tutorial, etc. My idea is to build a process modeling tool capable of simulation on the Excel platform. But the VBA resources I have seen don’t give me enough information about how to construct custom shapes, define connection points, control connection behavior, etc.(again all programmatically with VBA). Or am I perhaps trying to do too much with Office/VBA, and should switch to Visual Studio/JavaScript, or some other platform? I want to base it on Excel as the nearly universal technical tool that all my potential users would have mastered, so I can potentially allow them to extend it.
Hi Dave,
I don’t know of a good resource on Shapes. It is one of the areas of Excel VBA that doesn’t have a lot of coverage.
There is stuff here but it maybe a bit basic. What you are trying to do should be possible in Excel. I would start with a simple application and see how far you can get with it.
Paul
Thanks very much
Hello Paul,
I want to ask you about memory handling in Class Module Example 1:
Inside the function ReadAlbums, a collection is created and at the end of the function, it is written “Set ReadAlbums = coll”. After that program returns to “Sub CreateReport” where it is written “Set coll = ReadAlbums(1990, 2001)”. My question is whether “coll” in sub “CreateReport” is an object with its own memory allocation and values in it OR in fact it points to memory that is now free for use again. I mean, is there the possibility for the “coll” to point to data that after a while will be overwritten? I ask this because the use of “Set” confuses me.
Thanks in advance for your reply.
Olá Paul,
Excelente material de aprendizagem.
Tive alguns problemas com FUNCTIONS que tinham que retornar CLASSES e só consegui resolver através de suas explicações.
Mais uma vez, PARABÉNS pelo material.!!
Abraços,
Paulo.
Thanks for a great article!
One question/error:
If we write
ReDim arrCountries(1 To 1000)
then the number of countries can be retrieved by
NumCountries = UBound(oCountry.arrCountries)
In the code above, it’s
NumCountries = UBound(oCountry.arrCountries) + 1
which gives “1001”.
Thanks Frank.
It should actually be:
UBound(oCountry.arrCountries) – LBound(oCountry.arrCountries) + 1
because the lower bound may not always be 1.
How to use or init class module which is inside of another addin in our vba project or in excel interface ? Suppose i have one class called myName inside some other addin abc.xlam and i want to use that myName class in my another VBA project. How to use it like we use other modules/proc/sub ?
Even after reference to that addin, i didn’t found while declaring dim statement.
Anything different method to use it when it is under AddIn than that class is inside our VBA ?
Hi!
I’m not really sure about this is the best article to ask this question. Could you give me advice about how to differ ranges and variables that are used on at least two worksheets? I mean for example: I have rngSKU range on two worksheets. If I declare two range variables denoted with the worksheet name is a bit disturbing for me, like rngSKU_wsOne and rngSKU_wsTwo. Therefore I created two classes for the worksheets, one with the name wsOne, and one with the name wsTwo and declare the rngSKU public variable at each classes. And I reference the variable in module for example: o_wsOne.rngSKU. Is it proper method? I think it’s more transparent method. But what is the solution if I have two workbooks with same named worksheets? So It would be a class in class method. Could you give me an example how to manage variables and worksheets in complex projects with more workbooks and worksheets? Thank You!
Hi Paul,
Thanks for the class lesson. I have tried several times to download the vba module for this.
I have used my personal and my work emails with no luck.
Has the code been locked or am I doing something wrong?
Thanks
Jeff
What problem are you having with the download? The email was send to you. I checked the email and I was able to download the code. I have resent the email again.
Hi Jeff,
I checked my email service provider and it shows that you got the email. This is not always 100% accurate. Send me an email(Paul and website name) and I will send you the file.
Paul
Hi Paul I have had the same problem as Jeff over the last few days. Web site says email has been sent but it does not appear in my inbox or spam. Great website by the way and enjoying your VBA Handbook course. Regards Peter Turner
Hi Peter,
Glad you are enjoying the course. I have checked this and it appears to be working fine. Please email me and I will send on the correct file.
-Paul
is it possible to pass multi dimensional array between sub function and class modules?
Yes it is. Use a sub or property of the class to do it.
Hi, I think there’s a typo under Using a Property instead of a Function/Sub in the blue box. I think the last llne should be End Property instead of End Function.
Thanks for pointing that out. I have updated it.
Hello Paul
As always you are very thorough, and I find it difficult to make any of my own full notes better than your clear Blogs.
I think I just about understand all that you have covered now.
But I have come to a conclusion, which many experts seem very split on whether they agree or disagree with me. So I would very much welcome your opinion.
I believe the following to be at least approximately correct
The Custom Class module which we are able to add in the VB Editor could approximately be compared with some Class module which we don’t have access to ( and can never see ) from which the ThisWorkbook code module that we can see is made.
Similarly, the Custom Class module which we are able to add in the VB Editor could approximately be compared with some Class module which we don’t have access to ( and can never see ) from which the Worksheet code modules that we can see is made. ( I would further suggest that for each of the worksheet code modules there could be considered a separate Class module, although they might be very similar )
( I fully agree and understand that the Class modules are like a blue print to be used to make an object )
When we instantiate, ( make an object ), from our Custom Class, we effectively have an object , which we might consider could have a code module comparable to the ThisWorkbook and worksheets code modules, but which we can’t see. This code module, if we could see it, has a copy of all the coding in the Class module. That actual copy of the coding, which we don’t have direct access to, is effectively the coding that runs. ( Microsoft does allow us to take the option of taking the F8 Debug Steps through the Class module, but this I suggest is just for convenience, and is somewhat misleading because we cannot step through the blue print. It may appear that way to us for convenience , but actually we are stepping through the invisible instantiated object coding.)
The main conclusion I have is that we can consider our Custom Class module as approximately a level up form the ThisWorkbook and worksheets code modules. Possibly we should consider the ThisWorkbook and worksheets code modules as object code modules.
Some people seem to agree fully with me on this. A few go off in some angry rage quoting theoretical explanations that they claim to prove that the ThisWorkbook and worksheets code modules and the Custom Class module that we can add and see are directly equivalent Class modules.
What’s your opinion?
Alan
Hi, Paul.
Your 3rd screenshot is incorrect. After you insert the Class, the panel properties will display Class Module and not Module. You might have published the incorrect screenshot.
Regards,
Tom
Hi Tom,
Well spotted. I have updated the screenshot.
-Paul
Thanks Paul for a comprehensive and interesting step by step tutorial of Class Modules and Class Interfaces.
It has certainly given me a solid foundation and understanding about the topic (the same also applies to many other of your great tutorials which I have gratefully studied).
I have now gone through this Class Module tutorial (all the code, including the one showing the Inheritance/Class interface approach). I have also gone through your separate tutorial on class Interfaces in Excel VBA (https://www.youtube.com/watch?v=3bO50gHRndA&ab_channel=ExcelMacroMastery).
I have done some reflections and would much appreciate if you had an opportunity to take a look the questions below.
What are the pros and cons of using Class Module Interfaces vs instead using the second technique where a Variant variable instead is used to reference any Class?
When Should I use the “InterFace” approach vs the approach where the Classes are referenced by using a Variant variable?
Thanks a lot for sharing your incredible knowledge!
The main reason is that Interfaces enforce setting the Type. In other words if you made a mistake like using the wrong class then the compiler will pick it up.
If you use a Variant the error may not be discovered until the code runs.
That explains it! Thanks Paul!