+ Reply to Thread
Results 1 to 3 of 3

Assign Random Values in a Range

  1. #1
    Registered User
    Join Date
    01-31-2020
    Location
    Spain
    MS-Off Ver
    365
    Posts
    7

    Assign Random Values in a Range

    Hello everybody!

    I am wondering how to solve this problem in Excel (without coding something in JAVA/ VBA)


    I would like to assign each person a queue (q1,q2,q3,q4), but taking into account that each queue has a limit of people in percentage.
    For instance: q1 -> 20%, q2 -> 30%, q3 -> 23%, q4 -> 27%, therefore, if I had 20 people, q1-> 4, q2->6, q3->5, q4->5

    How can I combine random formulas and percentages of people?
    Any ideas would be welcomed!
    Thank you very much

  2. #2
    Forum Expert
    Join Date
    07-06-2004
    Location
    Northern California
    MS-Off Ver
    2K, 2003, 2010, O365
    Posts
    1,490

    Re: Assign Random Values in a Range

    Start with queue names and % in A2:A5, so A2: q1, B2: 20%, etc. People's identifiers (names or IDs) in A11:A30.

    C1: =COUNTA(A11:A30)
    D1: =SUM(D2:D5)
    F1: =C1-SUMPRODUCT(INT(C1*B2:B5))

    C2: 0
    D2: =INT(C$1*B2)+F2
    E3: =MOD(C$1*B2,1)
    F2: =(MATCH(MAX(E$2:E$5),$E$2:$E$5,0)=ROWS(F$2:F2))*F$1

    Select D2:F2 and fill down into D3:D5.

    C3: =C2+D2

    Fill C3 down into C4:C5. This completes the setup for queues.

    Select E11:E30. Type the formula =RAND(), hold down [Ctrl] and press [Enter]. This should fill that range with distinct random values.

    B11: =LOOKUP(COUNTIF(E$11:E$30,">"&E11),C$2:C$5,A$2:A$5)

    Fill B11 down into B12:B30. This gives random queue assignments in B11:B30 to each of the people in A11:A30.

    FWIW, when and if you get the latest Excel with spilled formulas and dynamic arrays, you could use the following alternative formula for B11:B30 and dispense entirely with the E11:E30 formulas.

    B11: =LOOKUP(SORTBY(SEQUENCE(C1,1,0),RANDARRAY(C1,1),1),C$2:C$5,A$2:A$4)
    Last edited by hrlngrv; 01-31-2020 at 06:46 PM. Reason: typo

  3. #3
    Registered User
    Join Date
    01-31-2020
    Location
    Spain
    MS-Off Ver
    365
    Posts
    7

    Re: Assign Random Values in a Range

    Thank you very much for your help!
    Actually it was no an idea, it was a solution!

    Many thanks!

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Similar Threads

  1. Assign values from a range based on a criteria
    By arkaran in forum Excel Programming / VBA / Macros
    Replies: 1
    Last Post: 01-01-2019, 02:05 AM
  2. Replies: 9
    Last Post: 11-28-2017, 09:34 AM
  3. Macro to assign values from one set of range to another
    By zilvinas_s in forum Excel Programming / VBA / Macros
    Replies: 0
    Last Post: 12-16-2014, 10:57 AM
  4. Replies: 2
    Last Post: 11-06-2014, 05:07 PM
  5. How to assign text to a range of values
    By shalani in forum Excel Formulas & Functions
    Replies: 4
    Last Post: 08-25-2011, 05:07 AM
  6. Assign a Dropdown list to a range of cells from values of other range
    By kmlprtsngh in forum Excel Programming / VBA / Macros
    Replies: 1
    Last Post: 01-03-2011, 10:39 AM
  7. [SOLVED] Assign a random selection to a range
    By Tracy D. in forum Excel Programming / VBA / Macros
    Replies: 3
    Last Post: 01-14-2005, 04:06 PM

Tags for this Thread

Bookmarks

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1