Google Groups no longer supports new Usenet posts or subscriptions. Historical content remains viewable.
Dismiss

Copying Combo Boxes

1 view
Skip to first unread message

RickGreg

unread,
Aug 28, 2007, 11:35:01 AM8/28/07
to
I am using a series of combo boxes as an input control in a worksheet. Each
combo box toggles between yes/no to control the input on a given row. There
will be close to 100 combo boxes in the sheet (one each in rows 1-100). The
input range will be the same for all combo boxes. However, the Cell Link
will coincide with the row the box sits in.

For example, combo box in Row 9 will determine value of cell D9. Combo box
in Row 10 will control cell D10, and so on.

My question: When I copy/paste the combo boxes, the input range and cell
link entries remain the same. I then have to manually change the Cell Link
for each box.

Is there a way to automate this, or make cell references relative to the
location of the combo box? Looking to save some time and typing! (I create
sheets like this often, so this would save me time now and in the future.)

Thanks in advance.

Excel 11.3.7 (070727)
OS 10.4.10

JE McGimpsey

unread,
Aug 28, 2007, 11:54:49 AM8/28/07
to
In article <C2F9B8E5.1A9EA%rgre...@NOSPAMPLEASEfoxandcompany.com>,
RickGreg <rgre...@NOSPAMPLEASEfoxandcompany.com> wrote:

> My question: When I copy/paste the combo boxes, the input range and cell
> link entries remain the same. I then have to manually change the Cell Link
> for each box.
>
> Is there a way to automate this, or make cell references relative to the
> location of the combo box? Looking to save some time and typing! (I create
> sheets like this often, so this would save me time now and in the future.)

one way:

Public Sub SetDropDownLinks()
Dim dd As DropDown
For Each dd In ActiveSheet.DropDowns
With dd
.LinkedCell = .Parent.Cells(.TopLeftCell.Row, "C").Address
End With
Next dd
End Sub

RickGreg

unread,
Aug 28, 2007, 12:32:45 PM8/28/07
to
in article jemcgimpsey-3151...@msnews.microsoft.com, JE
McGimpsey at jemcg...@mvps.org wrote on 8/28/07 11:54 AM:


Thanks for the quick response. Two follow-ups if I may:

> What do I do with your code? Create a new macro and paste it? (I'm a VBA
novice!)

> Is there a way to adapt your code so it only applies to Selected dropdowns in
a sheet (vs. All dd in sheet)?? I have a few other DD's in this sheet that do
not link to the same column.

All the relevant DDs are in the same column if that helps.

Thanks again!

RickGreg

unread,
Aug 28, 2007, 12:37:18 PM8/28/07
to
in article jemcgimpsey-3151...@msnews.microsoft.com, JE
McGimpsey at jemcg...@mvps.org wrote on 8/28/07 11:54 AM:

> In article <C2F9B8E5.1A9EA%rgre...@NOSPAMPLEASEfoxandcompany.com>,

I answered my first question with a quick test creating a macro and pasting
the code. Works for all DDs. Hopefully you can help me refine for selected
DDs.... (E.g., if I pre-select the DDs I want to change..) THX!

JE McGimpsey

unread,
Aug 28, 2007, 12:47:50 PM8/28/07
to
In article <C2F9C77E.1A9F9%rgre...@NOSPAMPLEASEfoxandcompany.com>,
RickGreg <rgre...@NOSPAMPLEASEfoxandcompany.com> wrote:

> I answered my first question with a quick test creating a macro and pasting
> the code. Works for all DDs. Hopefully you can help me refine for selected
> DDs.... (E.g., if I pre-select the DDs I want to change..) THX!

One way:

Public Sub SetSelectedDropDownLinks()
Dim dd As Object
If TypeOf Selection Is DrawingObjects Then
For Each dd In Selection
If TypeOf dd Is DropDown Then
With dd
.LinkedCell = .Parent.Cells( _
.TopLeftCell.Row, "C").Address
End With
End If
Next dd
End If
End Sub

RickGreg

unread,
Aug 28, 2007, 12:55:27 PM8/28/07
to
in article jemcgimpsey-12BC...@msnews.microsoft.com, JE
McGimpsey at jemcg...@mvps.org wrote on 8/28/07 12:47 PM:

> Public Sub SetSelectedDropDownLinks()
> Dim dd As Object
> If TypeOf Selection Is DrawingObjects Then
> For Each dd In Selection
> If TypeOf dd Is DropDown Then
> With dd
> .LinkedCell = .Parent.Cells( _
> .TopLeftCell.Row, "C").Address
> End With
> End If
> Next dd
> End If
> End Sub


Works perfectly. You have saved untold hours. Thank you! -Rick G

0 new messages