function for Unique values in an array

ankita.sethi

Board Regular
Joined
Apr 27, 2011
Messages
58
Hi,

I have an array called "Universe", which have duplicated values.
I am trying to write a code that gives me an array which have only unique values.

Can anyone help?
 

Excel Facts

How to fill five years of quarters?
Type 1Q-2023 in a cell. Grab the fill handle and drag down or right. After 4Q-2023, Excel will jump to 1Q-2024. Dash can be any character.
Hi

You can use a dictionary object to populate a unique array (it has an Exists method which can check for duplicates):

Code:
Dim cell As Range
Dim dic As Object
Dim myUniqueArray As Variant

Set dic = CreateObject("Scripting.Dictionary")

'use it to load the dictionary with all the unique values in A1:A1000:

For Each cell In Range("A1:A1000")
  If Not dic.Exists(cell.Value) Then _
      dic.Add cell.Value, cell.Value
Next cell


'output to another range:
myUniqueArray = dic.Keys
Range("B1").Resize(UBound(myUniqueArray) - LBound(myUniqueArray) + 1) = Application.Transpose(myUniqueArray)
 
Upvote 0
Thanks for the reply.

If I am understanding correctly, this is taking values from a range in the sheet. However, I have an array defined in the VBA itself and I want the result also as a VBA array. Am i making sense?
 
Upvote 0
You can take the values from the array instead of from the sheet:

Code:
For i = LBound(myArray) to Ubound(myArray)
  If Not dic.Exists(myArray(i)) Then _
     dic.Add myArray(i), myArray(i)
Next i

myUniqueArray = dic.Keys   'you now have your array with no duplicates

Make sense?
 
Upvote 0
@Richard Schollar:

Hi Richard :)

Just curious as to why the IF .Exists test when only taking the keys?

Mark
 
Upvote 0
Thanks a lot!
This works great!
Could you please also tell me how can I see what value an array has at some time in the code like we do for variables either by placing the cursor or in the immediate window?
 
Upvote 0
As long as the array is declared in the procedure running, you can use the Locals window to view variables' values while stepping thru the code.
 
Upvote 0
Hey Mark

Do you mean instead of something like this:

Code:
For i = 1 to 10
  dic.Item(myArray(i)) = 1
Next i

If so, no real reason. I just find the code I originally posted a lot more intuitive at first glance (and thus easier for me to remember! ;))
 
Upvote 0
An overdue Howdy from out west and yes sir, that was what I was wondering.

Thank you,

Mark
 
Upvote 0
Hi,
Thanks a lot again :)
The code works really well. Can you please explain the intuition behind it?What is dictionary object?What does it do?
 
Upvote 0

Forum statistics

Threads
1,213,561
Messages
6,114,317
Members
448,564
Latest member
ED38

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