limit range to unique values

M

Michael

I am looking for a way to limit a named range to unique values. So
that if a value is entered that already exists in the range the value
that already exists would become empty and the new location would hold
the unique value.

I got something sort of working with the selection change event but it
took too long to cycle through each cell in the range to make sure it
did not equal the target value. was not pretty. The range is only
like 50 cells.

I am looking for advise on how to make it work.

Thanks
 
D

Don Guillett

Include your efforts to date
If desired, send your file to my address below. I will only look if:
1. You send a copy of this message on an inserted sheet
2. You give me the newsgroup and the subject line
3. You send a clear explanation of what you want
4. You send before/after examples and expected results.
 
P

p45cal

To get the ball rolling you could adapt something along these lines:


VBA Code:
--------------------


Private Sub Worksheet_Change(ByVal Target As Range)
Dim theRange As Range
If Not Intersect(Target, Range("$B$4:$E$14")) Is Nothing And Not IsEmpty(Target) Then
Set theRange = Range("$B$4:$E$14")
If Application.CountIf(theRange, Target.Value) > 1 Then
Set c = Target
Do
Set c = theRange.Find(Target.Value, c)
If c.Address <> Target.Address Then c.ClearContents
Loop Until c.Address = Target.Address
End If
End If
End Sub
--------------------






I am looking for a way to limit a named range to unique values. So
 
T

Tom Hutchins

Try this Worksheet_Change event code. I named the range which should have no
duplicate values UniqRng in this example.

Private Sub Worksheet_Change(ByVal Target As Range)
Dim tgt As Range, xx As Range
For Each tgt In Target
If (Not Intersect(tgt, ActiveSheet.Range("UniqRng")) Is Nothing) And _
(Len(tgt.Value) > 0) Then
For Each xx In ActiveSheet.Range("UniqRng")
If xx.Address <> tgt.Address Then
If xx.Value = tgt.Value Then
xx.Value = vbNullString
End If
End If
Next xx
End If
Next tgt
End Sub


This code should be placed on the code page of the worksheet where you want
this to work.

Hope this helps,

Hutch
 
B

Bob Umlas, Excel MVP

No VBA required. Suppose it's column B which yuo want to limit to unique
values. Select the whole column, use Data/Validation, select Custom from the
"Allow" dropdown, enter this formula:
=COUNTIF(B:B,B1)=1
and perhaps click the Error Alert tab to supply a message when a duplicate
value is entered.
 
P

p45cal

No VBA required.


I suspect it might be, Bob. How otherwise would "if a value is entere
that already exists in the range, the value that already exists woul
become empty and the new location would hold the unique value" be don
without it?

No VBA required. Suppose it's column B which yuo want to limit t
unique
 
M

Michael

Try this Worksheet_Change event code. I named the range which should haveno
duplicate values UniqRng in this example.

Private Sub Worksheet_Change(ByVal Target As Range)
Dim tgt As Range, xx As Range
For Each tgt In Target
    If (Not Intersect(tgt, ActiveSheet.Range("UniqRng")) Is Nothing) And _
        (Len(tgt.Value) > 0) Then
        For Each xx In ActiveSheet.Range("UniqRng")
            If xx.Address <> tgt.Address Then
                If xx.Value = tgt.Value Then
                    xx.Value = vbNullString
                End If
            End If
        Next xx
    End If
Next tgt
End Sub

This code should be placed on the code page of the worksheet where you want
this to work.

Hope this helps,

Hutch

This worked perfectly. Thank you very much.!
 

Ask a Question

Want to reply to this thread or ask your own question?

You'll need to choose a username for the site, which only take a couple of moments. After that, you can post your question and our members will help you out.

Ask a Question

Top