+ Reply to Thread
Results 1 to 9 of 9

Selecting the smallest negative number

  1. #1
    Forum Contributor
    Join Date
    10-11-2008
    Location
    Portugal
    MS-Off Ver
    Excel 2010
    Posts
    111

    Selecting the smallest negative number

    Hi,

    Given a fixed matrix of values, i need a way to calculate the value in that matrix that is closest to a specified number, but always higher than this one.

    I hope the excel file will clear things up!

    Thanks
    Attached Files Attached Files

  2. #2
    Forum Guru DonkeyOte's Avatar
    Join Date
    10-22-2008
    Location
    Northumberland, UK
    MS-Off Ver
    O365
    Posts
    21,531

    Re: Selecting the smallest negative number

    Use SMALL with COUNTIF

    =IF(MAX($K$5:$N$11)<=$F$6;"No Values";SMALL($K$5:$N$11;1+COUNTIF($K$5:$N$11;"<="&$F$6)))

  3. #3
    Forum Moderator zbor's Avatar
    Join Date
    02-10-2009
    Location
    Croatia
    MS-Off Ver
    365 ProPlus
    Posts
    15,627

    Re: Selecting the smallest negative number

    Try this comfirmed with ctrl+shift+enter

    =F6/MAX(IF(F6/K5:N11<1;F6/K5:N11))

    Edit: I'm late Great solution DO!
    Last edited by zbor; 09-04-2010 at 10:43 AM.

  4. #4
    Forum Contributor
    Join Date
    10-11-2008
    Location
    Portugal
    MS-Off Ver
    Excel 2010
    Posts
    111

    Re: Selecting the smallest negative number

    thank you very much both of you

  5. #5
    Forum Contributor
    Join Date
    10-11-2008
    Location
    Portugal
    MS-Off Ver
    Excel 2010
    Posts
    111

    Re: Selecting the smallest negative number

    i'm sorry...just one more thing...how can I determine the relative position of the value found? I tried hlookup and vlookup but they're not working
    Attached Files Attached Files

  6. #6
    Forum Moderator zbor's Avatar
    Join Date
    02-10-2009
    Location
    Croatia
    MS-Off Ver
    365 ProPlus
    Posts
    15,627

    Re: Selecting the smallest negative number

    I'm not sure that this is best way... but working for now...
    Attached Files Attached Files

  7. #7
    Forum Guru DonkeyOte's Avatar
    Join Date
    10-22-2008
    Location
    Northumberland, UK
    MS-Off Ver
    O365
    Posts
    21,531

    Re: Selecting the smallest negative number

    I generally look to return the "co-ordinates" in a single cell and then if nec. create an Address from the co-ordinates rather than dupe what is in reality an expensive approach

    F9:
    =MIN(IF(K5:N11=F8,J5:J11+((COLUMN(K5:N5)-COLUMN(K5)+1)/1000000)))
    confirmed with CTRL + SHIFT + ENTER

    which would return 4.000002

    F10:
    =INT(F9)&INDEX(K4:N4,ROUND(MOD(F9,1)*1000000,0))

    which would return 4B

  8. #8
    Forum Guru DonkeyOte's Avatar
    Join Date
    10-22-2008
    Location
    Northumberland, UK
    MS-Off Ver
    O365
    Posts
    21,531

    Re: Selecting the smallest negative number

    coaster, note I posted with incorrect delimiters for you - modify the , to ; as required.

    I also took advantage of J5:J11 holding 1 to 7 ... if that were not the case eg A:G and you wanted to return DB rather than 4B then you would use:

    Please Login or Register  to view this content.

  9. #9
    Forum Contributor
    Join Date
    10-11-2008
    Location
    Portugal
    MS-Off Ver
    Excel 2010
    Posts
    111

    Re: Selecting the smallest negative number

    that's perfect! thank you very very much

+ 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