Randomly select a set of values from a different column with no duplicates

curtpoz

New Member
Joined
Mar 7, 2018
Messages
3
I am trying to randomly select a set of values from another column without duplicates. The formula I am using below works for randomly selecting values from the table in Column A, but it often returns duplicate values. Is there any way to use this without doing the whole extra "helper" =RAND() column route?


ABC
1Location
Random Location Lookup
2AS104=INDEX(Table1[Locn],RANDBETWEEN(1,COUNTA(Table1[Locn])),1)
3AS113
4CR215
5DP102

<tbody>
</tbody>
 

Excel Facts

Why are there 1,048,576 rows in Excel?
The Excel team increased the size of the grid in 2007. There are 2^20 rows and 2^14 columns for a total of 17 billion cells.
With formulas only, I think it will be rather tough. Of course, one could write dedicated UDF (User Defined Function in VBA) either to return whole array of results at once or to draw random value except these which were drawn before.

But Easy and reliable solution with helper column filled with RAND function is really easy and reasonably elegant solution in my opinion.

Anyway, if you are interested in UDF, here is example one (copy this code to standard module):

Code:
Function random_draw(r_from As Range, r_except As Range) As Variant
Dim source_arr, exceptions_arr, i As Long, counter As Long
source_arr = r_from.Value
counter = UBound(source_arr)
exceptions_arr = r_except.Value
With New Collection
  For i = 1 To UBound(source_arr)
    .Add source_arr(i, 1), CStr(source_arr(i, 1))
  Next i
  On Error Resume Next
  For i = 1 To UBound(exceptions_arr)
    .Remove CStr(exceptions_arr(i, 1))
  Next i
  On Error GoTo 0
  random_draw = .Item(WorksheetFunction.RandBetween(1, .Count))
End With
End Function

and in your worksheet use it in cell C2 as:
Code:
=random_draw(A$2:A$5,C$1:C1)
and copy down
 
Upvote 0

Forum statistics

Threads
1,215,482
Messages
6,125,060
Members
449,206
Latest member
Healthydogs

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