Sort / XLookUp running slow - any way to speed up calculations?

dropkickweasel

Board Regular
Joined
Feb 2, 2014
Messages
70
I have an array of around 2000 text strings.
I want to randomise the order of them on the click of a button.

My current solution is:

Column B; The original array Given the Named Range "Original_List"
Column C: A random value between 1 and 10000 generated with the following VBA code:
Code:
Sub RandomiseWordList()

Dim rng As Range
Set rng = Sheets("Working").Range("C2:C2001")

For Each Cell In rng
    Cell.Value = WorksheetFunction.RandBetween(1, 1000000)
    Next

End Sub
Column D: =SORT($C$2:$C$2001) Given the named range "Random_Number"

Column E: =XLOOKUP(D2,random_number,original_list)

All of this works fine, it just takes a little while to completely populate the newly ordered list in Column E.
Using INDEX-MATCH seems to be nominally quicker (~18s instead of ~20s).

Is there anything I can do to reduce the time taken for column E to populate when the macro is run?

Additionally, is there anything I can add to the macro to ensure that each number generated is unique?
If there is a way to do this, I could limit the range to 1 - 2315 if that makes any difference to the speed? (I arbitrarily picked 1000000 to attempt to reduce the number of duplicates).

Many thanks in advance.
 

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
How use this
VBA Code:
Sub RandomiseWordList()
   Sheets("Working").Range("C2:C2001").Value = Application.RandArray(2000)
End Sub
and then use sortby, rather than xlookup
 
Upvote 0
Or another option, get rid of the formulas & just use
VBA Code:
Sub RandomiseWordList()
  With Application
      Sheets("Working").Range("C2:C2001").Value = .SortBy(Range("original_list"), .RandArray(2000))
  End With
End Sub
 
Upvote 0
Solution
Or another option, get rid of the formulas & just use
VBA Code:
Sub RandomiseWordList()
  With Application
      Sheets("Working").Range("C2:C2001").Value = .SortBy(Range("original_list"), .RandArray(2000))
  End With
End Sub

That's so much more efficient than what I was doing, thank you so much!
 
Upvote 0
You're welcome & thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,214,818
Messages
6,121,725
Members
449,049
Latest member
MiguekHeka

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