Entering changing months with a cell

L

Loadmaster

Cells D1:AJ1 have years 2006:2038. Cells C2:C13 have Jan thru Dec. Cell A4
has the array formula

=LOOKUP(9.999999999999E+307,INDEX(D2:AH13,0,MAX(IF(D2:AH13<>"",COLUMN(D2:AH13)-COLUMN(D2)+1))))

,showing the last figure entered in the table. Note: I had to push
Ctrl+Shift+Enter to execute the formula. How do I enter into cell BC16 the
Month corresponding to the last figure entered in D2:AH13 from column C?
 
M

Mike H

Maybe

=OFFSET(INDIRECT(ADDRESS(SUMPRODUCT(MAX((ROW(D2:AH13)*(D2:AH13<>"")))),SUMPRODUCT(MAX((COLUMN(D2:AH13)*(D2:AH13<>"")))))),0,(SUMPRODUCT(MAX((COLUMN($D$2:$AH$13)*($D$2:$AH$13<>""))))*-1)+3,1,1)

It's a bit long winded and I'm sure there must be an easier way but lets
wait and see. Mind out for the line-wrap it's all one line.

Mike
 
B

Bernard Liengme

Try
=INDEX(C2:C13,MAX(IF(D1:AH12<>"",COLUMN(D1:AH12)-COLUMN(D1)+1)-1))
best wishes
 
L

Loadmaster

The closest I came is when I used the rng D2:AH13, D2 vice D1 and I pushed
Ctrl+Shift+Enter at the end of the formula . it still came up with a month of
Feb "which was wrong" and would not change when I entered another figure
within the table.
 
T

T. Valko

Try this array formula** :

=INDEX(C2:C13,MATCH(1E100,INDEX(D2:AH13,0,MAX(IF(D2:AH13<>"",COLUMN(D2:AH13)-COLUMN(D2)+1)))))

Curious about this:
Cells D1:AJ1 have years 2006:2038.

According to that your table extends to column AJ yet the formula you posted
only covers up to column AH.
 
L

Loadmaster

Thank-you that is the formula I was looking for.

T. Valko said:
Try this array formula** :

=INDEX(C2:C13,MATCH(1E100,INDEX(D2:AH13,0,MAX(IF(D2:AH13<>"",COLUMN(D2:AH13)-COLUMN(D2)+1)))))

Curious about this:


According to that your table extends to column AJ yet the formula you posted
only covers up to column AH.
 

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