Adding a checkbox to new row, and checking or unchecking it

mharper90

Board Regular
Joined
May 28, 2013
Messages
117
Office Version
  1. 365
Platform
  1. MacOS
I have UserForm1 that adds a new row of data to ws1 based on the data submitted in the UserForm. In column "E" of this new row, I'm trying to get the UserForm1, CommandButton1 click macro to add a checkbox to the empty cell, center it within the cell, and then use the value of Userform1.Checkbox2 to either check or uncheck the newly inserted checkbox. Greatly appreciate the help! Also, is there a way to control the size of the inserted checkbox via macro to ensure it's scaled proportional to the rest of the worksheet?
 

Excel Facts

Remove leading & trailing spaces
Save as CSV to remove all leading and trailing spaces. It is faster than using TRIM().
Check the 2 options for Form Checkbox or for ActiveX checkbox Control


Code:
Private Sub CommandButton1_Click()
    Dim lastRow As Double
    Dim sh As Worksheet, nombre As String
    
    Set sh = Sheets("Sheet1")
    lastRow = sh.Range("A" & Rows.Count).End(xlUp).Row + 1
    
    With sh.Range("E" & lastRow)


[COLOR=#0000ff]        'Form checkbox[/COLOR]
        sh.CheckBoxes.Add(.Left + 1, .Top + 1, .Width - 1, .Height - 1).Select
        Selection.Value = Me.CheckBox1.Value
        Selection.Caption = ""


    End With


    With sh.Range("F" & lastRow)
        
[COLOR=#0000ff]        'ActiveX checkbox Control[/COLOR]
        sh.OLEObjects.Add(ClassType:="Forms.CheckBox.1", Link:=False, _
            DisplayAsIcon:=False, Left:=.Left + 1, Top:=.Top + 1, Width:=.Width - 1, Height:=.Height - 1).Select
            nombre = Selection.Name
        sh.OLEObjects(nombre).Object.Caption = ""
        sh.OLEObjects(nombre).Object.Value = Me.CheckBox1.Value
        
    End With
    
End Sub
 
Upvote 0
Perhaps
Code:
Private Sub CommandButton1_Click()
    Dim newRow As Range, ECell As Range
    Dim newBox As CheckBox
   
    Set newRow = Sheet1.Cells(Rows.Count, 1).End(xlUp).EntireRow: adjust to match
    
    Set ECell = newRow.Range("E1")
    
    With ECell
        Set newBox = newRow.Parent.CheckBoxes.Add(.Left, .Top, 100, .Height)
    End With
    With newBox
        .Caption = vbNullString
        .Width = 10
        .Left = ECell.Left + (ECell.Width / 2) - (.Width / 4)
        .LinkedCell = ECell.Address
        .Value = Me.CheckBox2.Value
    End With
    Application.ScreenUpdating = True
End Sub
 
Upvote 0
I used the "Form Checkbox" version. Can you explain why I should choose one over the other? It works great, except that it doesn't seem to be "stuck" to the cell I entered it into. By this, I mean that if I hide or delete a row, the checkbox just sits there. Is there a way to treat it the same way a cell with text or something would be treated for those actions?

Check the 2 options for Form Checkbox or for ActiveX checkbox Control


Code:
Private Sub CommandButton1_Click()
    Dim lastRow As Double
    Dim sh As Worksheet, nombre As String
    
    Set sh = Sheets("Sheet1")
    lastRow = sh.Range("A" & Rows.Count).End(xlUp).Row + 1
    
    With sh.Range("E" & lastRow)


[COLOR=#0000ff]        'Form checkbox[/COLOR]
        sh.CheckBoxes.Add(.Left + 1, .Top + 1, .Width - 1, .Height - 1).Select
        Selection.Value = Me.CheckBox1.Value
        Selection.Caption = ""


    End With

End Sub
 
Upvote 0
I used the "Form Checkbox" version. Can you explain why I should choose one over the other?



Each control has different characteristics, however, the ActiveX has more properties than the userform, there is no rule that tells us which one you should choose, you simply choose the one that suits your needs; As you gain experience, you will be able to know which one you need for each occasion.

Is there a way to treat it the same way a cell with text or something would be treated for those actions?

There is no way to treat it like a row, if you delete a row, you will also have to eliminate the control.


However, in the ActiveX, there is the property "Move and change size with cells"



You can perform tests with both and analyze which one is most useful to you.
 
Upvote 0

Forum statistics

Threads
1,223,893
Messages
6,175,240
Members
452,621
Latest member
Laura_PinksBTHFT

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