Add Deselect VBA Coding for Multiselect Dropdown

SHG0303

New Member
Joined
Dec 6, 2023
Messages
1
Office Version
  1. 365
Platform
  1. Windows
Hello. I am using the following VBA code which created multi select, comma separated in specific columns, however I also want the option to be able to deselect values you have already selected rather than having to delete all the values in the cell and having to start again, can some please help? Thank you so much for any help offered, I'm completely stuck.

VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)
Dim Oldvalue As String
Dim Newvalue As String
Application.EnableEvents = True
On Error GoTo Exitsub
If Not Intersect(Target, Range("I:I,J:J,K:K,L:L,W:W,X:X,AI:AI,AT:AT,AU:AU,AV:AV,AW:AW,BA:BA,BB:BB,BC:BC")) Is Nothing 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
 

Excel Facts

Workdays for a market open Mon, Wed, Friday?
Yes! Use "0101011" for the weekend argument in NETWORKDAYS.INTL or WORKDAY.INTL. The 7 digits start on Monday. 1 means it is a weekend.
Try this code:
VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)

    Dim OldValue As String
    Dim NewValue As String
    Dim p1 As Long, p2 As Long

    If Target.Value = "" Then Exit Sub

    If Not Intersect(Target, Range("I:I,J:J,K:K,L:L,W:W,X:X,AI:AI,AT:AT,AU:AU,AV:AV,AW:AW,BA:BA,BB:BB,BC:BC")) Is Nothing Then
    
        If Not Target.SpecialCells(xlCellTypeAllValidation) Is Nothing Then
    
            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
                    'Append new value
                    Target.Value = OldValue & "," & NewValue
                Else
                    'Remove already selected value
                    p1 = InStr("," & OldValue & ",", "," & NewValue & ",")
                    p2 = p1 + Len("," & NewValue & ",")
                    If p1 = 1 Then
                        'Remove from start
                        OldValue = Mid(OldValue, p2 - 2)
                    ElseIf p1 + Len("," & NewValue & ",") = Len("," & OldValue & ",") + 1 Then
                        'Remove from end
                        OldValue = Left(OldValue, p1 - 3)
                    ElseIf p1 > 1 Then
                        'Remove from middle
                        OldValue = Left(OldValue, p1 - 1) & Mid(OldValue, p2 - 2)
                    End If
                    Target.Value = OldValue
                End If
            End If
            
            Application.EnableEvents = True
            
        End If
    
    End If

End Sub
 
Upvote 0
Try this code:
VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)

    Dim OldValue As String
    Dim NewValue As String
    Dim p1 As Long, p2 As Long

    If Target.Value = "" Then Exit Sub

    If Not Intersect(Target, Range("I:I,J:J,K:K,L:L,W:W,X:X,AI:AI,AT:AT,AU:AU,AV:AV,AW:AW,BA:BA,BB:BB,BC:BC")) Is Nothing Then
   
        If Not Target.SpecialCells(xlCellTypeAllValidation) Is Nothing Then
   
            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
                    'Append new value
                    Target.Value = OldValue & "," & NewValue
                Else
                    'Remove already selected value
                    p1 = InStr("," & OldValue & ",", "," & NewValue & ",")
                    p2 = p1 + Len("," & NewValue & ",")
                    If p1 = 1 Then
                        'Remove from start
                        OldValue = Mid(OldValue, p2 - 2)
                    ElseIf p1 + Len("," & NewValue & ",") = Len("," & OldValue & ",") + 1 Then
                        'Remove from end
                        OldValue = Left(OldValue, p1 - 3)
                    ElseIf p1 > 1 Then
                        'Remove from middle
                        OldValue = Left(OldValue, p1 - 1) & Mid(OldValue, p2 - 2)
                    End If
                    Target.Value = OldValue
                End If
            End If
           
            Application.EnableEvents = True
           
        End If
   
    End If

End Sub

Feels close to what I need. However, if one manually backspaces on the first value, the incorrect info will be shown. Users might manually try to put info/backspace vs using dropdown (user error) - and I’m trying to account for this.
 
Upvote 0

Forum statistics

Threads
1,224,815
Messages
6,181,136
Members
453,021
Latest member
Justyna P

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