+ Reply to Thread
Results 1 to 7 of 7

Find nearest number

  1. #1
    Valued Forum Contributor
    Join Date
    03-03-2009
    Location
    UK
    MS-Off Ver
    MS365 Subscription Excel for Mac
    Posts
    1,017

    Find nearest number

    In cell A1 I have a number. I want a formula that looks at that number and then looks at row C on sheet2 where there are rows and rows of numbers. I want the formula to return the nearest match to the number in cell A1.

  2. #2
    Forum Guru AlKey's Avatar
    Join Date
    07-20-2009
    Location
    Lakeland, FL USA
    MS-Off Ver
    Microsoft Office 2010/ Office 365
    Posts
    8,903

    Re: Find nearest number

    Hi ScabbyDog,

    I suggest that you upload a sample spreadsheet with about 10-15 rows of data so we could figure our a solution for you.
    If you like my answer please click on * Add Reputation
    Don't forget to mark threads as "Solved" if your problem has been resolved

    "Nothing is so firmly believed as what we least know."
    --Michel de Montaigne

  3. #3
    Valued Forum Contributor
    Join Date
    03-03-2009
    Location
    UK
    MS-Off Ver
    MS365 Subscription Excel for Mac
    Posts
    1,017

    Re: Find nearest number

    I thought it would be a simple enough index match forumla which I'm not very good at. The number in cell A1 would be for eg, 4.22 and in sheet 2 there would be the numbers 4, 4.5, 5 etc. So in this case I'd want the number 4 returned.

  4. #4
    Valued Forum Contributor
    Join Date
    03-03-2009
    Location
    UK
    MS-Off Ver
    MS365 Subscription Excel for Mac
    Posts
    1,017

    Re: Find nearest number

    Attached is a sample workbook.

    Thanks!SAMPLE1.xlsx

  5. #5
    Forum Guru AlKey's Avatar
    Join Date
    07-20-2009
    Location
    Lakeland, FL USA
    MS-Off Ver
    Microsoft Office 2010/ Office 365
    Posts
    8,903

    Re: Find nearest number

    Try this

    =LOOKUP(A1,Sheet2!$A$1:$A$40)

  6. #6
    Forum Expert XOR LX's Avatar
    Join Date
    04-18-2013
    Location
    Turin, Italy
    MS-Off Ver
    Office 365
    Posts
    7,742

    Re: Find nearest number

    Hi,

    Two options:

    Array**:

    =INDEX(Sheet2!$A$1:$A$40,MATCH(TRUE,ABS(Sheet2!$A$1:$A$40-A1)=MIN(ABS(Sheet2!$A$1:$A$40-A1)),0))

    Non-array:

    =INDEX(Sheet2!$A$1:$A$40,LOOKUP(16^16,1/(INDEX(ABS(Sheet2!$A$1:$A$40-A1),,)=MIN(INDEX(ABS(Sheet2!$A$1:$A$40-A1),,)))*(ROW(Sheet2!$A$1:$A$40)-MIN(ROW(Sheet2!$A$1:$A$40))+1)))

    Regards


    **Array formulas are not entered in the same way as 'standard' formulas. Instead of pressing just ENTER, you first hold down CTRL and SHIFT, and only then press ENTER. If you've done it correctly, you'll notice Excel puts curly brackets {} around the formula (though do not attempt to manually insert these yourself).
    Last edited by XOR LX; 12-11-2013 at 10:39 AM.
    Click * below if this answer helped

    Advanced Excel Techniques: http://excelxor.com/

  7. #7
    Valued Forum Contributor adyteo's Avatar
    Join Date
    01-10-2013
    Location
    Calgary
    MS-Off Ver
    Excel 2010
    Posts
    540

    Re: Find nearest number

    Please Login or Register  to view this content.
    you need to have two columns (A and C) in Sheet2: same numbers, column A sorted ascending, column C sorted descending.
    In your example, using the above formula, you get 4.25 (4.25 is closed to 4.22 than 4)

+ 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. [SOLVED] To find nearest biggest number
    By gan_xl in forum Excel Formulas & Functions
    Replies: 6
    Last Post: 10-10-2013, 07:43 AM
  2. To find nearest biggest number
    By gan_xl in forum Excel Programming / VBA / Macros
    Replies: 0
    Last Post: 10-10-2013, 06:49 AM
  3. [SOLVED] Rounding the number produced by an evaluated expression to the nearest number in CF
    By orly_sm in forum Excel Formulas & Functions
    Replies: 4
    Last Post: 05-29-2013, 09:16 AM
  4. [SOLVED] Never pastes in right line. Nearest number to number in a given cell.
    By Wales MB in forum Excel Programming / VBA / Macros
    Replies: 14
    Last Post: 11-29-2012, 01:45 PM
  5. find nearest help
    By nobbyknownowt in forum Excel Formulas & Functions
    Replies: 6
    Last Post: 04-21-2006, 08:40 AM

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