Results 1 to 6 of 6

Thread: Formula - return bottom non-blank value in a range

  1. #1
    Board Regular
    Join Date
    Nov 2015
    Location
    UK
    Posts
    263
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default Formula - return bottom non-blank value in a range

    Hi there,

    I have a column which holds a running total of hours taken. So, for example, the user enters a number of hours in cell L50, then the formula below, which sits in N50, deducts that number from a running total above in column N.

    =IF(L50<>"",IF(SUM($N$27:$N49)>0,SMALL($N$27:$N49,1)-IF($M50<>"",$M50,0),$F$22-M50),"")

    The issue is that this formula was built on the assumption that hours taken would always be positive numbers and therefore the figure would always be reducing. The problem is that I sometimes need to enter negative figures to balance things out, and so the SMALL part of the formula below is causing problems, as it's looking for the smallest figure in the cells above it, whereas I need it to find the bottom-most non-blank value.

    So, for example, with 50 hours remaining, I enter -5 in column L to add a few hours back on, taking it to 55. I then enter -10 in the cell below, but it now picks the original 50 up as the smallest figure in the above range, resulting in 60 where it should be 65.

    I hope this makes sense. Basically, I need to replace the SMALL component with something that finds the lowest (position, not value) non-blank cell in the range $N$27:$N49. I can't use the most recent, as not all values have dates attached.


    Thanks in advance for your help
    Last edited by MisterProzilla; Jun 13th, 2018 at 10:34 AM.

  2. #2
    MrExcel MVP Jonmo1's Avatar
    Join Date
    Oct 2006
    Location
    Bryan, TX
    Posts
    44,061
    Post Thanks / Like
    Mentioned
    19 Post(s)
    Tagged
    0 Thread(s)

    Default Re: Formula - return bottom non-blank value in a range

    Finding the furthest down 'numeric' value, try

    LOOKUP(9.99999999999999E+307,$N$27:$N49)
    Use the MrExcel HTML Maker to post nicely formatted tables in your forum posts.
    Find a link in post number 31

    The more we learn, and the better we get at our trade, the easier it becomes to overlook the obvious.

    Life moves pretty fast. If you don't stop and look around once in a while, you could miss it.
    Ferris Bueller A.K.A. John Hughes, 1986

  3. #3
    Board Regular
    Join Date
    Nov 2015
    Location
    UK
    Posts
    263
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default Re: Formula - return bottom non-blank value in a range

    Perfect, thanks very much

    How does that even work, just out of curiosity?

  4. #4
    MrExcel MVP Jonmo1's Avatar
    Join Date
    Oct 2006
    Location
    Bryan, TX
    Posts
    44,061
    Post Thanks / Like
    Mentioned
    19 Post(s)
    Tagged
    0 Thread(s)

    Default Re: Formula - return bottom non-blank value in a range

    You're welcome..
    9.99999999999999E+307 is just the scientific notation for the largest number allowed in a cell, also called Bignum.

    Lookup assumes your data is sorted in ascending order (it doesn't verify if it actually is or not, it just proceeds as if it is).
    Lookup is looking for the largest value that is less than or equal to the lookup value.
    The BigNum guarantees that there will be no numbers larger than the lookup value.
    So it must look at all the numbers because it doesn't know if the next number is greater or not. So it has to check them all.
    It doesn't really look at all of them, because it's assumed to be sorted ascending, it does a Binary search where it cuts the ranges in half and looks at the last one. It then proceeds with a process of elimination.
    When it looks at the last number in the range, it will NOT be greater than the lookup value.
    So it assumes the last value IS the largest number (because it assumes the data is sorted ascending).
    Use the MrExcel HTML Maker to post nicely formatted tables in your forum posts.
    Find a link in post number 31

    The more we learn, and the better we get at our trade, the easier it becomes to overlook the obvious.

    Life moves pretty fast. If you don't stop and look around once in a while, you could miss it.
    Ferris Bueller A.K.A. John Hughes, 1986

  5. #5
    Board Regular
    Join Date
    Nov 2015
    Location
    UK
    Posts
    263
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default Re: Formula - return bottom non-blank value in a range

    Aha, and computers think they're so smart

    I think I got most of that, apart from the bit about cutting the ranges in half


    Thanks again

  6. #6
    MrExcel MVP Jonmo1's Avatar
    Join Date
    Oct 2006
    Location
    Bryan, TX
    Posts
    44,061
    Post Thanks / Like
    Mentioned
    19 Post(s)
    Tagged
    0 Thread(s)

    Default Re: Formula - return bottom non-blank value in a range

    Cutting ranges in half...

    original list of numbers
    1 2 3 4 5 6 7 8 9 10

    Lookup cuts it in half, and looks at the last number of each half..
    1 2 3 4 5 (Is 5 greater than the lookup value?)
    If No, then it looks at 6 7 8 9 10 (is 10 greater....
    If Yes, then it looks at 6 7 8 (is 8 greater...
    etc..
    Use the MrExcel HTML Maker to post nicely formatted tables in your forum posts.
    Find a link in post number 31

    The more we learn, and the better we get at our trade, the easier it becomes to overlook the obvious.

    Life moves pretty fast. If you don't stop and look around once in a while, you could miss it.
    Ferris Bueller A.K.A. John Hughes, 1986

Some videos you may like

User Tag List

Tags for this Thread

Like this thread? Share it with others

Like this thread? Share it with others

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •