Deny duplicates in dropdown lists using VBA

Moe12345

New Member
Joined
Jul 14, 2021
Messages
8
Office Version
  1. 2016
Platform
  1. Windows
Hi, I am currently experiencing problems with duplicates in dependent dropdown lists. I have sheet with 6 lists, the second list is dependent on the first
and the remaining lists are all dependent on the entry of the second list. These lists are all suppose to reset and does show "Please select..." when a new entry is made in the second
and first list. The problem arises when I use a code the disallows duplicates. Then the reset functionality is not working. Could anyone please help me with this to make all of it work,
ie both the reset function and denying duplicates?

This is the code:

VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)


  If Target.Address = "$E$4" Then
   
   
Range("E6").Value = "Please Select..."
End If


  If Target.Address = "$E$6" Then
 
Range("C11:C20").Value = "Please Select..."
Application.EnableEvents = True

End If



If Target.Address = "$E$6" Then
Range("C26:c30").Value = "Please Select..."

End If

If Target.Address = "$E$6" Then
Range("C35:c37").Value = "Please Select..."
 
 End If
 
 
If Target.Address = "$E$6" Then
Range("C43").Value = "Please Select..."

End If

If Intersect(Target, Range("C10:c43")) Is Nothing Then Exit Sub
If Target.Cells.Count > 1 Then Exit Sub
If WorksheetFunction.CountIf(Range("C10:C43"), Target) > 1 Then
Application.EnableEvents = False
Application.Undo                           'This part gives an error
If Application.EnableEvents = True Then
MsgBox "Item already selected, please try again."
End If
 
Last edited by a moderator:

Excel Facts

How to find 2nd largest value in a column?
MAX finds the largest value. =LARGE(A:A,2) will find the second largest. =SMALL(A:A,3) will find the third smallest
@Moe12345 I obviously don't fully appreciate your need but, does this help?

VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)

If Target.Address = "$E$4" Then
    Range("E6").Value = "Please Select..."
End If


If Target.Address = "$E$6" Then
    Application.EnableEvents = False
    Range("C11:C20, C26:c30, C43").Value = "Please Select..."
    Application.EnableEvents = True
End If


If Intersect(Target, Range("C10:c43")) Is Nothing Then Exit Sub
    If Target.Cells.Count > 1 Then Exit Sub
    If WorksheetFunction.CountIf(Range("C10:C43"), Target) > 1 Then
        Prev = Target
        Application.EnableEvents = False
        If Application.EnableEvents = False Then
        MsgBox Prev & " already selected, please try again."
        Application.Undo
    End If
End If
Application.EnableEvents = True
End Sub
 
Upvote 0
Solution
Thank you for the reply, i've tested the code and it seems to be working perfectly. A huge thank you from me!
 
Upvote 0

Forum statistics

Threads
1,214,644
Messages
6,120,709
Members
448,983
Latest member
Joaquim_Baptista

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