Get our FREE VBA eBook of the 30 most useful Excel VBA macros.

Automate Excel so that you can save time and stop doing the jobs a trained monkey could do.

Claim your free eBook


VBA code to contol Form Control checkboxes

VBA Code Snippets

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

Headshot Round

About the author

Hey, I’m Mark, and I run Excel Off The Grid.

My parents tell me that at the age of 7 I declared I was going to become a qualified accountant. I was either psychic or had no imagination, as that is exactly what happened. However, it wasn't until I was 35 that my journey really began.

In 2015, I started a new job, for which I was regularly working after 10pm. As a result, I rarely saw my children during the week. So, I started searching for the secrets to automating Excel. I discovered that by building a small number of simple tools, I could combine them together in different ways to automate nearly all my regular tasks. This meant I could work less hours (and I got pay raises!). Today, I teach these techniques to other professionals in our training program so they too can spend less time at work (and more time with their children and doing the things they love).


Do you need help adapting this post to your needs?

I'm guessing the examples in this post don't exactly match your situation. We all use Excel differently, so it's impossible to write a post that will meet everybody's needs. By taking the time to understand the techniques and principles in this post (and elsewhere on this site), you should be able to adapt it to your needs.

But, if you're still struggling you should:

  1. Read other blogs, or watch YouTube videos on the same topic. You will benefit much more by discovering your own solutions.
  2. Ask the 'Excel Ninja' in your office. It's amazing what things other people know.
  3. Ask a question in a forum like Mr Excel, or the Microsoft Answers Community. Remember, the people on these forums are generally giving their time for free. So take care to craft your question, make sure it's clear and concise.  List all the things you've tried, and provide screenshots, code segments and example workbooks.
  4. Use Excel Rescue, who are my consultancy partner. They help by providing solutions to smaller Excel problems.

What next?
Don't go yet, there is plenty more to learn on Excel Off The Grid.  Check out the latest posts:

One thought on “VBA code to contol Form Control checkboxes

  1. Allan Ford says:

    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)

Leave a Reply

Your email address will not be published.