using class module to avoid public declaration

tiredofit

Well-known Member
Joined
Apr 11, 2013
Messages
1,395
I read on these threads that it is advisable to pass variables via class modules rather than declare publically.

This is stored in Module1:

Code:
Public myarray() As Variant

Sub NoClass()

myarray = Range("A1").CurrentRegion.Value

Dim myarrayrows As Long

myarrayrows = UBound(myarray, 1)

Dim newarray() As Variant

ReDim newarray(1 To myarrayrows, 1 To 1) As Variant

Dim Counter As Long

For Counter= 1 To myarrayrows

    newarray(aCounter1) = myarray(Counter, 1)

Next Counter

Range("E1").Resize(myarrayrows, 1).Value = newarray

End Sub

This is stored in a class module, class1:

Code:
Option Explicit

Private temparray As Variant

Property Get myarray() As Variant

myarray = temparray

End Property

Property Let myarray(passedarray As Variant)

temparray = passedarray

End Property

This is in module2:

Code:
Sub WithClass()

Dim myclass As Class1

Set myclass = New Class1

myclass.myarray = Range("A1").CurrentRegion.Value

Dim myarrayrows As Long

myarrayrows = UBound(myclass.myarray, 1)

Dim newarray() As Variant

ReDim newarray(1 To myarrayrows, 1 To 1) As Variant

Dim CounterAs Long

For Counter= 1 To myarrayrows

    newarray(Counter, 1) = myclass.myarray(Counter, 1)

Next Counter

Range("E1").Resize(myarrayrows, 1).Value = newarray

Set myclass = Nothing

End Sub

Admittedly these programs do literally nothing other than copy what's in column A and pastes it in column E.

To test, fill column A with around 50,000 entries and run Sub NoClass.

Repeat for Sub WithClass.

Sub NoClass takes less than a second to run.

The version with classes is significantly slower. I think it's because it constantly goes to the get property:

Code:
For Counter= 1 To myarrayrows

    newarray(Counter, 1) = myclass.myarray(Counter, 1) ' from here it goes to the class module

Next Counter

Can someone please tell me what have I done wrong?

Surely using classes cannot affect the performance by that much?

So how should I amend it to speed it up?

Thanks
 

Some videos you may like

Excel Facts

Lock one reference in a formula
Need 1 part of a formula to always point to the same range? use $ signs: $V$2:$Z$99 will always point to V2:Z99, even after copying

Andy Pope

Active Member
Joined
Dec 31, 2003
Messages
348
The reason for the delay when using a class is that you are passing the whole array back every time and then in the module, not the class, you are selecting the specific element of the array.

Your code in WithClass routine
Code:
For Counter = 1 To myarrayrows
    newarray(Counter, 1) = myclass.myarray(Counter, 1)
Next Counter

Is actually doing this
Code:
For Counter = 1 To myarrayrows
    newarray(Counter, 1) = myclass.myarray()(Counter, 1)
Next Counter

What you need to do instead is extract the specific item from the array stored in the class.

Code:
Sub WithClassItem()

Dim myclass As Class1
    
Set myclass = New Class1

myclass.myarray = Range("A1").CurrentRegion.Value

Dim myarrayrows As Long

myarrayrows = UBound(myclass.myarray, 1)

Dim newarray() As Variant

ReDim newarray(1 To myarrayrows, 1 To 1) As Variant

Dim Counter As Long

For Counter = 1 To myarrayrows

    newarray(Counter, 1) = myclass.myarrayItem(Counter, 1)

Next Counter

Range("E1").Resize(myarrayrows, 1).Value = newarray

Set myclass = Nothing

End Sub

with this new property in the class object
Code:
Property Get myarrayItem(RowIndex, ColIndex) As Variant

    myarrayItem = temparray(RowIndex, ColIndex)
    
End Property

Timings (seconds) with A1:A50000 populated with row number
No Class 8.74944582137687E-02
With Class 114.13540019235
With Class Item 9.85504419641074E-02
 

Watch MrExcel Video

Forum statistics

Threads
1,123,531
Messages
5,602,209
Members
414,513
Latest member
junbuggle

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Top