+ Reply to Thread
Results 1 to 6 of 6

How to randomly select from a list with condition

  1. #1
    Registered User
    Join Date
    07-26-2005
    Posts
    3

    How to randomly select from a list with condition

    I have a list of twenty real number in A1 to A20.
    How can I randomly select a number from the list, but not the one with value = 0
    If the selected number is zero, it will automatically select another random number from the list.
    The list is dynamic, so I don't know exactly when and where the ones with zero value show up.
    Thank you.

    Katherine.

  2. #2
    Forum Contributor
    Join Date
    03-12-2004
    Posts
    329
    With 2 helper columns, you can try something like this:

    A3:A20 = your data

    B3 = IF(A3=0,500,ROW()) (Copy down)
    C3 = SMALL(B$3:B$20,ROW()-2) (Copy down)

    D3 = OFFSET(A3,INDIRECT("C"&RANDBETWEEN(ROW(),ROW()+COUNTIF(C3:C20,"<500")-1))-ROW(),0)


    Hope this helps.



    Quote Originally Posted by kathyxyz
    I have a list of twenty real number in A1 to A20.
    How can I randomly select a number from the list, but not the one with value = 0
    If the selected number is zero, it will automatically select another random number from the list.
    The list is dynamic, so I don't know exactly when and where the ones with zero value show up.
    Thank you.

    Katherine.

  3. #3
    Registered User
    Join Date
    07-26-2005
    Posts
    3
    Thanks, Morrigan!

    Katherine

  4. #4
    Forum Expert
    Join Date
    12-24-2004
    Location
    Sweden
    Posts
    1,256
    It can also be calculated in a single cell:

    =INDEX(LARGE(A1:A20,ROW(INDIRECT("1:"&(COUNT(A1:A20)-COUNTIF(A1:A20,0))))),RANDBETWEEN(1,COUNT(A1:A20)-COUNTIF(A1:A20,0)))


    Ola Sandström

  5. #5
    Forum Contributor
    Join Date
    03-12-2004
    Posts
    329
    Just a quick note if you are using Olasa's formula, all data must be positive numbers.


    Quote Originally Posted by olasa
    It can also be calculated in a single cell:

    =INDEX(LARGE(A1:A20,ROW(INDIRECT("1:"&(COUNT(A1:A20)-COUNTIF(A1:A20,0))))),RANDBETWEEN(1,COUNT(A1:A20)-COUNTIF(A1:A20,0)))


    Ola Sandström

  6. #6
    Forum Expert
    Join Date
    12-24-2004
    Location
    Sweden
    Posts
    1,256
    Thanks for spotting that Morrigan.
    This works with both positive and negative number

    =INDEX(LARGE(IF(A1:A20=0,"",A1:A20),ROW(INDIRECT("1:"&(COUNT(A1:A20)-COUNTIF(A1:A20,0))))),RANDBETWEEN(1,COUNT(A1:A20)-COUNTIF(A1:A20,0)))

    However this formula MUST be confirmed by holding down Ctrl and Shift, and then hit Enter.

    Ola Sandström

+ Reply to Thread

Thread Information

Users Browsing this Thread

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

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