+ Reply to Thread
Results 1 to 9 of 9

Exel Rand Between

Hybrid View

  1. #1
    Registered User
    Join Date
    10-07-2017
    Location
    Israel
    MS-Off Ver
    2016
    Posts
    5

    Question Exel Rand Between

    Hey guys,
    I want the rand between funcution will do only unique names and not duplicate.
    My code:
    =INDEX($G$13:$G$21,RANDBETWEEN(1,9))

    Tnx ahead, Daniel.

  2. #2
    Forum Expert tim201110's Avatar
    Join Date
    10-23-2011
    Location
    Russia
    MS-Off Ver
    2016, 2019
    Posts
    2,357

    Re: Exel Rand Between

    C2
    =SMALL(IF(ISNA(MATCH(COLUMN($A$1:INDEX($1:$1,9)),$B2:B2,)),COLUMN($A$1:INDEX($1:$1,9))),RANDBETWEEN(1,9-COUNT($B2:B2))) as array formula, pull right

  3. #3
    Registered User
    Join Date
    10-07-2017
    Location
    Israel
    MS-Off Ver
    2016
    Posts
    5

    Re: Exel Rand Between

    sry didnt understand

  4. #4
    Forum Expert tim201110's Avatar
    Join Date
    10-23-2011
    Location
    Russia
    MS-Off Ver
    2016, 2019
    Posts
    2,357

    Re: Exel Rand Between

    Did not understand what?
    Attached Files Attached Files
    Last edited by tim201110; 10-07-2017 at 06:59 AM.

  5. #5
    Registered User
    Join Date
    10-07-2017
    Location
    Israel
    MS-Off Ver
    2016
    Posts
    5

    Re: Exel Rand Between

    its duplicate man..

  6. #6
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2406
    Posts
    44,662

    Re: Exel Rand Between

    Use an array formula as a helper column, here shown in K13:

    =LARGE(ROW($1:$9)*NOT(COUNTIF($K$12:K12,ROW($1:$9))),RANDBETWEEN(1,10-ROW(A1)))

    Array Formulae are a little different from ordinary formulae in that they MUST be confirmed in the FIRST CELL ONLY by pressing CTRL+SHIFT+ENTER to activate the array, not just ENTER. After that, the array can be dragged down as normal, to cover the desired range.

    You will know the array is active when you see curly brackets { } - or "curly braces" for those of you in the USA, or "flower brackets" for those of you in India - appear around the outside of your formula. If you do not use CTRL+SHIFT+ENTER you will (almost always) get an error message or an incorrect answer. Press F2 on that cell and try again.

    Don't type the curly brackets yourself - it won't work...

    Then use this in L13:

    =INDEX($G$13:$G$21,K13)
    Attached Files Attached Files
    Glenn




    None of us get paid for helping you... we do this for fun. So DON'T FORGET to say "Thank You" to all who have freely given some of their time to help YOU

  7. #7
    Registered User
    Join Date
    10-07-2017
    Location
    Israel
    MS-Off Ver
    2016
    Posts
    5

    Re: Exel Rand Between

    But how i use that without the "Helper" I dont need it..

  8. #8
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2406
    Posts
    44,662

    Re: Exel Rand Between

    You might not want it, but you do need it, I think. It can be hidden, or even be on another sheet... but couldn't think of a simple way of getting rid of it.

  9. #9
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2406
    Posts
    44,662

    Re: Exel Rand Between

    OK. It came to me...

    It's a bit of a monster formula but it works. To make it look a bit simpler (and to ease the typing hassle) I created a Named Range, imaginatively called "List" (CTRL-F3 to view) which covers your input cells. Then use this array formula , here used in I13:

    =INDEX(List,LARGE((ROW(List)-MIN(ROW(List))+1)*(COUNTIF($I$12:I12,List)<>COUNTIF(List,List)),RANDBETWEEN(1,SUM(--(COUNTIF($I$12:I12,List)<>COUNTIF(List,List))))))

    Array Formulae are a little different from ordinary formulae in that they MUST be confirmed in the FIRST CELL ONLY by pressing CTRL+SHIFT+ENTER to activate the array, not just ENTER. After that, the array can be dragged down as normal, to cover the desired range.

    You will know the array is active when you see curly brackets { } - or "curly braces" for those of you in the USA, or "flower brackets" for those of you in India - appear around the outside of your formula. If you do not use CTRL+SHIFT+ENTER you will (almost always) get an error message or an incorrect answer. Press F2 on that cell and try again.

    Don't type the curly brackets yourself - it won't work...
    Attached Files Attached Files

+ 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. Help with RAND (I think...)
    By adamturner in forum Excel Formulas & Functions
    Replies: 2
    Last Post: 12-05-2013, 06:27 AM
  2. Replies: 2
    Last Post: 04-23-2013, 08:59 AM
  3. Rand
    By Sheepkin_Coat in forum Excel General
    Replies: 2
    Last Post: 07-26-2007, 10:15 AM
  4. Rand Help
    By kingsolo in forum Excel General
    Replies: 21
    Last Post: 12-30-2006, 10:33 PM
  5. =rand()....Help?!
    By britishpunk in forum Excel Formulas & Functions
    Replies: 2
    Last Post: 09-13-2006, 07:00 PM
  6. [SOLVED] how do I convert a non exel tabulation to exel
    By dte123 in forum Excel - New Users/Basics
    Replies: 2
    Last Post: 06-29-2006, 09:35 PM
  7. help for RAND
    By jinvictor in forum Excel Formulas & Functions
    Replies: 3
    Last Post: 05-12-2006, 07:20 PM
  8. [SOLVED] Help with Rand
    By Jack in forum Excel General
    Replies: 5
    Last Post: 01-10-2006, 03:30 PM

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