VBA code to contol Form Control checkboxes

Checkboxes are one of the easiest ways to create interaction with users.  Controlling them with VBA makes them more flexible and more useful in Excel applications.

Here is a collection of the most common code snippets and settings.

Create Check Boxes

The following code will create a checkbox

Sub CreateCheckBoxes()

'Create variable
Dim chkBox As CheckBox

'Create checkbox
Set chkBox = ActiveSheet.CheckBoxes.Add(Top:=0, Height:=1, Width:=1, Left:=0)

End Sub

Loop through all the checkboxes

If you want to apply the same settings or values to all the checkboxes on a worksheet this can be achieved by looping through the checkboxs and applying the settings individually.

Sub LoopThroughCheckboxes()

'Create variable
Dim chkBox As CheckBox

'Loop through each check box on active sheet
For Each chkBox In ActiveSheet.CheckBoxes

    'Do something to each checkbox using chkBox.

Next chkBox

End Sub

Set checkbox to a variable

The macro below will set a checkbox to a variable.

Sub SetCheckboxToVariable()

'Create variable
Dim chkBox As CheckBox

'Set the variable to a specific checkbox
Set chkBox = ActiveSheet.CheckBoxes("CheckBoxName")

End Sub

Common checkbox settings

The settings you are most likely to need to change are included in the macro below.

Sub CommonCheckboxSettings()

'Create variable
Dim chkBox As CheckBox

'Set the variable to a specific checkbox
Set chkBox = ActiveSheet.CheckBoxes("CheckBoxName")

'Set the variable to the name of the Checkbox calling the macro
Set chkBox = ActiveSheet.CheckBoxes(Application.Caller)
'Set the checkbox name
chkBox.Name = "CheckBoxName"

'Set the value of a check box (3 possible values)
chkBox.value = xlOff
chkBox.value = xlOn
chkBox.value = xlMixed

'Set the shading of the can to True or False
chkBox.Display3DShading = True
chkBox.Display3DShading = False

'Set the linked cell
chkBox.LinkedCell = "$E$5"

'Reset the linked cell to nothing
chkBox.LinkedCell = ""

'Set position of the checkbox
With chkBox
    .Top = 20
    .Left = 20
    .Height = 20
    .Width = 20
End With

'Change the checkboxes caption
chkBox.Caption = "check box caption"

'Display the name of the sheet containing the checkbox
MsgBox chkBox.Parent.Name

'Display the address of the cell with the top left pixel
'of the check box
MsgBox chkBox.TopLeftCell.Address

'Display the address of the cell with the bottom right pixel
'of the check box
MsgBox chkBox.BottomRightCell

'Set the macro to be called with clicking the checkbox
chkBox.OnAction = "NameOfMacro"

'Remove the macro being called
chkBox.OnAction = ""

'Is the checkbox enabled? True or False
chkBox.Enabled = False
chkBox.Enabled = True

'Set the checkbox to not move with cells
chkBox.Placement = xlFreeFloating

'Set the checkbox to move with the cells
chkBox.Placement = xlMove

'Set the print option of the checkbox True or False
chkBox.PrintObject = True
chkBox.PrintObject = False

'Delete the checkbox
chkBox.Delete

End Sub

Delete all the checkboxes on the active sheet

Sub DeleteAllCheckBoxes()

ActiveSheet.CheckBoxes.Delete

End Sub

Discover how you can automate your work with our Excel courses and tools.

Excel Academy

Excel Academy
The complete program for saving time by automating Excel.

Excel Automation Secrets

Excel Automation Secrets
Discover the 7-step framework for automating Excel.

Office Scripts Course

Office Scripts: Automate Excel Everywhere
Start using Office Scripts and Power Automate to automate Excel in new ways.

1 thought on “VBA code to contol Form Control checkboxes”

  1. It seems that in VBA macro code for an ActiveX checkbox control you use

    If (ActiveSheet.OLEObjects(“CheckBox1”).Object.Value = True)

    and for a Form checkbox control you use

    If (ActiveSheet.Shapes(“CheckBox1”).OLEFormat.Object.Value = 1)

    Reply

Leave a Comment