Multiple Select Drop in a Single Cell

scoobydoo

New Member
Joined
Jan 6, 2010
Messages
32
Office Version
  1. 365
Platform
  1. Windows
Hello! I'm attempting to use a drop down list for requests to update a row of data. The drop down list options are in Column A2:A8 in my sample data. I would like to make the multiple select drop down in Column C. There may be more rows of data at any given time. I'm trying to select all types of updates that are needed for each row. I only entered $C$2 in the VBA Code. However, I need it to include Column C. I used VBA Code below but nothing happens when I test it. I would appreciate help to correct this code that I found in a tutorial.

Private Sub Worksheet_Change(ByVal Target As Range)

' Initializing variables
Dim oldVal As String
Dim newVal As String
' Checking for changes in the drop down lists

Application.EnableEvents = True

If Target.Address = "$C$2" Then

If Target.SpecialCells(xlCellTypeAllValidation) Is Nothing Then
Exit Sub
' Adding the multiple selected items to the list
Else
If Target.Value = "" Then
Exit Sub

Else
Application.EnableEvents = False
newVal = Target.Value
Application.Undo
oldVal = Target.Value
If oldVal = "" Then
Target.Value = newVal
Else
If InStr(oldVal, newVal) = 0 Then
Target.Value = oldVal & ", " & newVal '& vbNewLine &
Else
Target.Value = oldVal
End If
End If
End If
End If
End If

Application.EnableEvents = True

End Sub
 
Please see a screenshot of my dataset. I also have same file if needed.

1737007183985.png
 
Upvote 0
Please try the following on a copy of your workbook. Replace your existing code with the following (you will of course need to copy the data validation cell (C2) down column C to as many rows as you think you'll need).

VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)
    Dim Oldvalue As String, Newvalue As String
    Application.EnableEvents = False
    On Error GoTo Exitsub
    If Target.Column = 3 Then
        If Target.SpecialCells(xlCellTypeAllValidation) Is Nothing Then
            GoTo Exitsub
            Else
            If Target.Value = "" Then GoTo Exitsub Else
            Application.EnableEvents = False
            Newvalue = Target.Value
            Application.Undo
            Oldvalue = Target.Value
            If Oldvalue = "" Then
                Target.Value = Newvalue
                Else
                If InStr(1, Oldvalue, Newvalue) = 0 Then
                    Target.Value = Oldvalue & "; " & Newvalue
                Else
                Target.Value = Oldvalue
                End If
            End If
        End If
    End If
Exitsub:
    Application.EnableEvents = True
End Sub
 
Upvote 0
Solution
Private Sub Worksheet_Change(ByVal Target As Range) Dim Oldvalue As String, Newvalue As String Application.EnableEvents = False On Error GoTo Exitsub If Target.Column = 3 Then If Target.SpecialCells(xlCellTypeAllValidation) Is Nothing Then GoTo Exitsub Else If Target.Value = "" Then GoTo Exitsub Else Application.EnableEvents = False Newvalue = Target.Value Application.Undo Oldvalue = Target.Value If Oldvalue = "" Then Target.Value = Newvalue Else If InStr(1, Oldvalue, Newvalue) = 0 Then Target.Value = Oldvalue & "; " & Newvalue Else Target.Value = Oldvalue End If End If End If End If Exitsub: Application.EnableEvents = True End Sub
Hello kevin9999,

Thank you so much for your reply! I followed your instructions and still didn't get it to work. I'm not really sure what I'm doing wrong. I made sure to save it as a macro enabled spreadsheet, enabled macros in the Trust Center and restarted my computer. Any other suggestions?
 
Upvote 0
Are you placing the code in the worksheet module where you want it to apply? Right click the tab (bottom of the screen) of the relevant sheet, select View Code, and put the code in the window that appears on the right side of the screen. If you still can't get it to work, could you share your file via Dropbox, Google Drive or similar file sharing platform?
 
Upvote 0
Are you placing the code in the worksheet module where you want it to apply? Right click the tab (bottom of the screen) of the relevant sheet, select View Code, and put the code in the window that appears on the right side of the screen. If you still can't get it to work, could you share your file via Dropbox, Google Drive or similar file sharing platform?
That worked! :) Thank you so much for your help! Hopefully, it's smooth sailing from here. Make it a great day!
 
Upvote 0
That worked! :) Thank you so much for your help! Hopefully, it's smooth sailing from here. Make it a great day!
Are you placing the code in the worksheet module where you want it to apply? Right click the tab (bottom of the screen) of the relevant sheet, select View Code, and put the code in the window that appears on the right side of the screen. If you still can't get it to work, could you share your file via Dropbox, Google Drive or similar file sharing platform?
One more question... the column heading is affected by this code. How do I exclude the column heading which is in Cell D3?
 
Upvote 0
One more question... the column heading is affected by this code. How do I exclude the column heading which is in Cell D3?
If cell D3 is being affected then your file must be different from the image you provided in post #2. You could add another condition to your code (AND Target.Row > 3) to only affect your sheet from row 4 and below.
 
Upvote 0
One more question... the column heading is affected by this code. How do I exclude the column heading which is in C

If cell D3 is being affected then your file must be different from the image you provided in post #2. You could add another condition to your code (AND Target.Row > 3) to only affect your sheet from row 4 and below.
I was able to revise the code you sent initially, adding the Target.Row > 3 to make it work. I really appreciate all of your help!
 
Upvote 0

Forum statistics

Threads
1,226,771
Messages
6,192,919
Members
453,767
Latest member
922aloose

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