Uncheck multiple checkboxes (form) on a row

Jeremic

New Member
Joined
Jan 21, 2015
Messages
4
Im working on a project checklist. When creating new projects, I would like to insert a new row on row 10. Copy the checkboxes from row 11 below, link and set the checkbox functions to work seperatly...so far so good.
However, now I would like to reset all the "newly" created checkboxes to unchecked or "xloff" for all checkboxes on row 10. The range where checkboxes are located is L10:Y10.

As I will constantly create new checkboxes on row 10, I suppose I need class, event, msform?? Im just guessing after a few days of research....Im not really getting anywhere and I feel clueless :confused:
Appreciate all your help.
My code so far looks like below.
Code:
Option Explicit
Sub LinkCheckBoxes()
Dim chk As CheckBox
Dim lCol As Long
lCol = 62 'number of columns to the right for link
For Each chk In ActiveSheet.CheckBoxes
   With chk
      .LinkedCell = _
         .TopLeftCell.Offset(0, lCol).Address
  End With
Next chk
End Sub
Sub CheckBoxDate()
Dim ws As Worksheet
Dim chk As CheckBox
Dim lColD As Long
Dim lColChk As Long
Dim lRow As Long
Dim rngD As Range
lColD = 84 'number of columns to the right for date
Set ws = ActiveSheet
Set chk = ws.CheckBoxes(Application.Caller)
lRow = chk.TopLeftCell.Row
lColChk = chk.TopLeftCell.Column
Set rngD = ws.Cells(lRow, lColChk + lColD)
Select Case chk.Value
       Case 1   'box is checked
      rngD.Value = Date
   Case Else   'box is not checked
      rngD.ClearContents
End Select
End Sub
Sub CheckBoxDate()
Dim ws As Worksheet
Dim chk As CheckBox
Dim lColD As Long
Dim lColChk As Long
Dim lRow As Long
Dim rngD As Range
lColD = 84 'number of columns to the right for date
Set ws = ActiveSheet
Set chk = ws.CheckBoxes(Application.Caller)
lRow = chk.TopLeftCell.Row
lColChk = chk.TopLeftCell.Column
Set rngD = ws.Cells(lRow, lColChk + lColD)
Select Case chk.Value
       Case 1   'box is checked
      rngD.Value = Date
   Case Else   'box is not checked
      rngD.ClearContents
End Select
End Sub

Sub SetCheckBoxesMacro()
Dim chk As CheckBox
For Each chk In ActiveSheet.CheckBoxes
   chk.OnAction = "CheckBoxDate"
Next chk
End Sub
 

Excel Facts

Best way to learn Power Query?
Read M is for (Data) Monkey book by Ken Puls and Miguel Escobar. It is the complete guide to Power Query.
Welcome to MrExcel.

Does this work for you?

Code:
Sub Test()
    Dim chk As CheckBox
    For Each chk In ActiveSheet.CheckBoxes
        With chk
            If .Top = Rows(10).Top Then
                .Value = xlOff
            End If
        End With
    Next chk
End Sub
 
Upvote 0
Hi Andrew,
Sorry but it does not seem to work. Im using form control and not activeX, if it matters?
BR/ Jeremic
 
Upvote 0
How are the CheckBoxes positioned within the cell? The code assumes that the top coincides with the top of the cell. If that's not the case try:

Rich (BB code):
Sub Test()
    Dim chk As CheckBox
    For Each chk In ActiveSheet.CheckBoxes
        With chk
            If Not Application.Intersect(.TopLeftCell, Rows(10)) Is Nothing Then
                .Value = xlOff
            End If
        End With
    Next chk
End Sub
 
Upvote 0
You´re a genius! Works perfectly :)
Im not sure how the checkboxes are positioned, but we can assume its not with the top of the cell :)
Thanks so much for the help!
 
Upvote 0
This is super..can the same or similar code be used to reset the checkboxes in any active range of cells? Thanks!
 
Upvote 0
Thank you. Yes, any range that I choose to "paint" by holding down the left mouse button or selecting discontiguos cells on the same worksheet using the CTRL key.

Thank you for your help.
 
Last edited:
Upvote 0

Forum statistics

Threads
1,214,431
Messages
6,119,462
Members
448,899
Latest member
maplemeadows

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