Random sample generator

discopapa

New Member
Joined
Nov 16, 2022
Messages
1
Office Version
  1. 365
Platform
  1. Windows
  2. Web
Hi,

My excel sheet is 10.000+ rows and 4 columns.

A: Provider
B: Brand
C: Product
D: URL

My job is to every day randomly go through each provider and click on one Product URL for each Brand.

I like to automize the selection with a script so I get my excel sheet reduced to 7 Providers * 40 Brands = 280 rows.

It is important that the sample selection gets random every day.

Is this doable?
 

Excel Facts

Can you AutoAverage in Excel?
There is a drop-down next to the AutoSum symbol. Open the drop-down to choose AVERAGE, COUNT, MAX, or MIN
Hi and welcome to MrExcel!

Your data in sheet1, header in row 1, your data start in row 2.
The results in the "random" sheet, you must create the sheet.

If you want to change the random number, change the 40 in this line:
num = 40 'random numbers
I guess each provider has more than 40 brands

Try:
VBA Code:
Sub RandomSampleGenerator()
  Dim dic As Object
  Dim a As Variant, arr As Variant, ky As Variant
  Dim i As Long, j As Long, k As Long, lr As Long, n As Long, u As Long, v As Long, x As Long, y As Long
  Dim num As Long
  
  num = 40      'random numbers
  
  Set dic = CreateObject("Scripting.Dictionary")
  With Sheets("Sheet1")
    lr = .Range("A" & Rows.Count).End(3).Row
    a = .Range("A1:D" & lr).Value
    u = Evaluate(Replace("=MAX(COUNTIF(@,@))", "@", .Name & "!A2:A" & lr))  'max unique value
    v = Evaluate(Replace("=SUMPRODUCT((@<>"""")/COUNTIF(@,@&""""))", "@", .Name & "!A2:A" & lr)) 'unique provider
  End With

  ReDim b(1 To v, 1 To u)
  ReDim c(1 To v * num, 1 To 4)
  
  For i = 2 To UBound(a, 1)
    If Not dic.exists(a(i, 1)) Then
      n = n + 1     'fila de b | columna de b
      k = 1
      dic(a(i, 1)) = n & "|" & k
    End If
    j = Split(dic(a(i, 1)), "|")(0)
    k = Split(dic(a(i, 1)), "|")(1)
    b(j, k) = i
    k = k + 1
    dic(a(i, 1)) = j & "|" & k
  Next
  
  arr = Evaluate("ROW(1:" & u & ")")
  Randomize
  For i = 1 To num
    x = Int(Rnd * u + i)
    y = arr(i, 1)
    arr(i, 1) = arr(x, 1)
    arr(x, 1) = y
    u = u - 1
  Next i
  
  j = 0
  For Each ky In dic.keys
    For i = 1 To num
      n = Split(dic(ky), "|")(0)
      k = arr(i, 1)
      j = j + 1
      c(j, 1) = a(b(n, k), 1)
      c(j, 2) = a(b(n, k), 2)
      c(j, 3) = a(b(n, k), 3)
      c(j, 4) = a(b(n, k), 4)
    Next
  Next
  
  Sheets("random").Range("A2").Resize(UBound(c, 1), UBound(c, 2)).Value = c
End Sub

HOW TO INSTALL MACROs
------------------------------------
If you are new to macros, they are easy to install and use. To install it, simply press ALT+F11 to go into the VB editor and, once there, click Insert/Module on its menu bar, then copy/paste the above code into the code window that just opened up. That's it.... you are done. To use the macro, go back to the worksheet with your data on it and press ALT+F8, select the macro name (RandomSampleGenerator) from the list that appears and click the Run button.
The macro will execute and perform the action(s) you asked for. If you will need to do this again in this same workbook, and if you are using XL2007 or above, make sure you save your file as an "Excel Macro-Enabled Workbook (*.xlsm) and answer the "do you want to enable macros" question as "Yes" or "OK" (depending on the button label for your version of Excel) the next time you open your workbook.
 
Upvote 0

Forum statistics

Threads
1,215,343
Messages
6,124,402
Members
449,156
Latest member
LSchleppi

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