+ Reply to Thread
Results 1 to 15 of 15

rank question

Hybrid View

  1. #1
    Bill_S
    Guest

    rank question

    I need to rank a number against a separate list. It appears that the RANK
    function in Excel requires your value to actually be "in" the list you're
    ranking it against. Is there a formula I could use to work around this
    limitation of the built-in RANK function.

  2. #2
    William
    Guest

    Re: rank question

    Hi Bill

    Assuming the range of numbers are in A1:A28 and the number you want a
    ranking for is in cell C1 then try...
    {=RANK(MAX(IF(A1:A28<C1,A1:A28)),A1:A28)}
    This is an array formula so enter with Ctrl+Shift+Enter

    -----
    XL2003
    Regards

    William
    willwest22@yahoo.com


    "Bill_S" <BillS@discussions.microsoft.com> wrote in message
    news:DAFF0210-F5AF-4B50-B985-6EA384940345@microsoft.com...
    >I need to rank a number against a separate list. It appears that the RANK
    > function in Excel requires your value to actually be "in" the list you're
    > ranking it against. Is there a formula I could use to work around this
    > limitation of the built-in RANK function.







  3. #3
    Bernd Plumhoff
    Guest

    Re: rank question

    Hi William,

    =RANK(MAX(IF(A1:A28<=B1,A1:A28)),A1:A28) as array formula. Otherwise value
    is one off if value in list.

    Regards,
    Bernd

  4. #4
    Jack Sons
    Guest

    Re: rank question

    Maybe (?)

    {=RANK(MAX(IF(A1:A28<C1,A1:A28)),A1:A28)-1}

    Jack Sons
    The Netherlands


    "William" <willwest22@yahoo.com> schreef in bericht
    news:ObG1sq4RFHA.2664@TK2MSFTNGP15.phx.gbl...
    > Hi Bill
    >
    > Assuming the range of numbers are in A1:A28 and the number you want a
    > ranking for is in cell C1 then try...
    > {=RANK(MAX(IF(A1:A28<C1,A1:A28)),A1:A28)}
    > This is an array formula so enter with Ctrl+Shift+Enter
    >
    > -----
    > XL2003
    > Regards
    >
    > William
    > willwest22@yahoo.com
    >
    >
    > "Bill_S" <BillS@discussions.microsoft.com> wrote in message
    > news:DAFF0210-F5AF-4B50-B985-6EA384940345@microsoft.com...
    >>I need to rank a number against a separate list. It appears that the RANK
    >> function in Excel requires your value to actually be "in" the list you're
    >> ranking it against. Is there a formula I could use to work around this
    >> limitation of the built-in RANK function.

    >
    >
    >
    >
    >




  5. #5
    Bernd Plumhoff
    Guest

    Re: rank question

    Hi Jack,

    No. Put 1, 2 and 3 into your lookup list and rank 2.1 with your formula. It
    returns 1 but should result in 2, I think.

    {=RANK(MAX(IF(A1:A28<=B1,A1:A28)),A1:A28)} is IMHO a possible array formula
    solution.

    =RANK(MATCH(B1,A:A,TRUE),A:A,FALSE) is a (IMHO better) normal solution.

    Regards,
    Bernd


    "Jack Sons" wrote:

    > Maybe (?)
    >
    > {=RANK(MAX(IF(A1:A28<C1,A1:A28)),A1:A28)-1}
    >
    > Jack Sons
    > The Netherlands
    >
    >
    > "William" <willwest22@yahoo.com> schreef in bericht
    > news:ObG1sq4RFHA.2664@TK2MSFTNGP15.phx.gbl...
    > > Hi Bill
    > >
    > > Assuming the range of numbers are in A1:A28 and the number you want a
    > > ranking for is in cell C1 then try...
    > > {=RANK(MAX(IF(A1:A28<C1,A1:A28)),A1:A28)}
    > > This is an array formula so enter with Ctrl+Shift+Enter
    > >
    > > -----
    > > XL2003
    > > Regards
    > >
    > > William
    > > willwest22@yahoo.com
    > >
    > >
    > > "Bill_S" <BillS@discussions.microsoft.com> wrote in message
    > > news:DAFF0210-F5AF-4B50-B985-6EA384940345@microsoft.com...
    > >>I need to rank a number against a separate list. It appears that the RANK
    > >> function in Excel requires your value to actually be "in" the list you're
    > >> ranking it against. Is there a formula I could use to work around this
    > >> limitation of the built-in RANK function.

    > >
    > >
    > >
    > >
    > >

    >
    >
    >


  6. #6
    Domenic
    Guest

    Re: rank question

    Hi guys!

    Consider the following list...

    10
    20
    30

    If we try to rank 5 against this list, all formulas so far would return
    a #N/A error value, when in fact the ranking should be 4, if I'm not
    mistaken.

    Maybe...

    =RANK(MAX(IF(A1:A3<=B1,A1:A3,MIN(A1:A3))),A1:A3)+(B1<MIN(A1:A3))

    ....confirmed with CONTROL+SHIFT+ENTER.

    Hope this helps!

    In article <6D43035E-9110-49EA-9AFD-6E66DD61E77F@microsoft.com>,
    "Bernd Plumhoff" <BerndPlumhoff@discussions.microsoft.com> wrote:

    > Hi Jack,
    >
    > No. Put 1, 2 and 3 into your lookup list and rank 2.1 with your formula. It
    > returns 1 but should result in 2, I think.
    >
    > {=RANK(MAX(IF(A1:A28<=B1,A1:A28)),A1:A28)} is IMHO a possible array formula
    > solution.
    >
    > =RANK(MATCH(B1,A:A,TRUE),A:A,FALSE) is a (IMHO better) normal solution.
    >
    > Regards,
    > Bernd
    >
    >
    > "Jack Sons" wrote:
    >
    > > Maybe (?)
    > >
    > > {=RANK(MAX(IF(A1:A28<C1,A1:A28)),A1:A28)-1}
    > >
    > > Jack Sons
    > > The Netherlands
    > >
    > >
    > > "William" <willwest22@yahoo.com> schreef in bericht
    > > news:ObG1sq4RFHA.2664@TK2MSFTNGP15.phx.gbl...
    > > > Hi Bill
    > > >
    > > > Assuming the range of numbers are in A1:A28 and the number you want a
    > > > ranking for is in cell C1 then try...
    > > > {=RANK(MAX(IF(A1:A28<C1,A1:A28)),A1:A28)}
    > > > This is an array formula so enter with Ctrl+Shift+Enter
    > > >
    > > > -----
    > > > XL2003
    > > > Regards
    > > >
    > > > William
    > > > willwest22@yahoo.com
    > > >
    > > >
    > > > "Bill_S" <BillS@discussions.microsoft.com> wrote in message
    > > > news:DAFF0210-F5AF-4B50-B985-6EA384940345@microsoft.com...
    > > >>I need to rank a number against a separate list. It appears that the RANK
    > > >> function in Excel requires your value to actually be "in" the list you're
    > > >> ranking it against. Is there a formula I could use to work around this
    > > >> limitation of the built-in RANK function.
    > > >
    > > >
    > > >
    > > >
    > > >

    > >
    > >
    > >


  7. #7
    Bernd Plumhoff
    Guest

    Re: rank question

    Hi Domenic,

    Right. Insert a dummy cell into the lookup list which refers to your ranked
    cell.

    Regards,
    Bernd

  8. #8
    Bernd Plumhoff
    Guest

    RE: rank question

    Hello,

    If column A shows your list and cell B1 your value to be ranked, then

    =RANK(MATCH(B1,A:A,TRUE),A:A,FALSE)

    will give you the rank (1 if biggest number...).

    HTH,
    Bernd

+ 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