Referencing script-created checkboxes with class module?

gravanoc

Active Member
Joined
Oct 20, 2015
Messages
351
Office Version
  1. 365
Platform
  1. Windows
  2. Mobile
I would like to dynamically create some checkboxes and then associate events with them. They will be in a collection.

I have a class module named cCheckBoxHandler with this code:
VBA Code:
Public WithEvents chkBox As MSForms.CheckBox

Private Sub chkBox_Click()

End Sub

I'll add the specifics for the event once I get the rest working. This class is referenced in another script. The problem occurs when trying to assign the newly created checkbox's variable to the class instance's variable.
That line of code is below in bold & comments. There is a type mismatch error, but I'm not sure what I should be using as the common type.

VBA Code:
Dim collChecks As Collection

Sub CreateCheckBoxes()

'Declare variables
Dim c As Range
Dim chkBox As Control
Dim ansBoxDefault As Long
Dim chkBoxRange As Range
Dim chkBoxDefault As Boolean
Dim mSht As Worksheet
Dim cBoxH As cCheckBoxHandler

Set collChecks = New Collection
Set mSht = Sheets("Master")

On Error Resume Next

Set chkBoxRange = Application.InputBox(Prompt:="Select cell range", _
    Title:="Create checkboxes", Type:=8)

If Err.Number <> 0 Then Exit Sub

ansBoxDefault = MsgBox("Should the boxes be checked?", vbYesNoCancel, _
    "Create checkboxes")
If ansBoxDefault = vbYes Then chkBoxDefault = True
If ansBoxDefault = vbNo Then chkBoxDefault = False
If ansBoxDefault = vbCancel Then Exit Sub

On Error GoTo 0

For Each c In chkBoxRange

    Set chkBox = chkBoxRange.Parent.Checkboxes.Add(0, 1, 1, 0)
    Set cBoxH = New cCheckBoxHandler
' ------ ERROR OCCURS BELOW---------'
   [B] Set cBoxH.chkBox = chkBox[/B]
'-------ERROR OCCURS ABOVE--------'
    collChecks.Add cBoxH
    
    With chkBox

        .Top = c.Top + c.Height / 2 - chkBox.Height / 2
        .Left = c.Left + c.Width / 2 - chkBox.Width / 2
        .Name = c.Address
        .LinkedCell = c.offset(0, 0).Address(external:=True)
        .Locked = False
        .Caption = ""
         
    End With

    c.Value = chkBoxDefault
    c.NumberFormat = ";;;"

Next c

End Sub
 

Excel Facts

Highlight Duplicates
Home, Conditional Formatting, Highlight Cells, Duplicate records, OK to add pink formatting to any duplicates in selected range.
My guess is you're getting a type mismatch error on that. If that's the case, you're mixing the two kinds of check boxes. Excel provides Form controls and ActiveX controls, the latter through the MSForms.DLL library. According to your code, you're adding a Form control check box to your worksheet. Unlike ActiveX controls, Form controls do not support automation events, so an attempt to implement your own event handler class will always fail.
 
Upvote 0
Thanks, I figured out by experimenting around to use the Object property of the OLEObject checkboxes, and indeed had to use ActiveX instead of the Form controls. Not ideal, but it is working now.
 
Upvote 0

Forum statistics

Threads
1,223,888
Messages
6,175,217
Members
452,619
Latest member
Shiv1198

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
Back
Top