CELL EQUALS LAST NONBLANK CELL IN A COLUMN

V

Vicky

Can someone give me a function to use so that the cell at the bottom of a
column equals the last nonblank cell above in that column?
 
T

T. Valko

The best solution to this depends on many conditions. Among those are:

What type of data is in the range, is it text or numeric, or can it be both?
Are there any empty/blanks cells *within* the range?
Are there any formulas in the range that might return formula blanks?

As a starting point you can try something like this. Assumes no empty/blank
cells within the range:

=IF(COUNTA(A1:A10),INDEX(A1:A10,COUNTA(A1:A10)),"")
 
V

Vicky

There are formulas in the cells above. The formulas results in a number
based upon the "If" condition in the formulas, else it returns a blank value
in the cell. Here is a sample of one of the formulas in a cell in the column
above...

=IF(AND(W16<>"",(COUNTA($W$3:W15)>0)-(COUNTBLANK($W$3:W15)),(COUNTA($W17:W$22)=0)-COUNTBLANK($W17:W$22)),$F16,"")
 
T

T. Valko

This will return the *last numeric value* in the range:

=IF(COUNT(A1:A10),LOOKUP(1E100,A1:A10),"")
 
V

Vicky

Thank you so much! This worked. I have yet to understand how LOOKUP works.
Maybe in time I will. :)
 
T

T. Valko

You're welcome. Thanks for the feedback!

How LOOKUP works:

The way that LOOKUP works is if the lookup_value is greater than all the
values in the lookup_vector it will match the *last* value in the
lookup_vector that is less than the lookup_value.

To ensure that the lookup_value is greater than all the values in the
lookup_vector we use an arbitrary number that is guaranteed to meet this
condition. In this case the lookup_value is 1E100, 1 followed by 100 zeros.
There's a pretty good chance that no number in your range will be greater
than that so the formula returns the *last numeric* value in the range.
 

Ask a Question

Want to reply to this thread or ask your own question?

You'll need to choose a username for the site, which only take a couple of moments. After that, you can post your question and our members will help you out.

Ask a Question

Top