Get rightmost non date value in a row

SingularitysPoint

New Member
Joined
Nov 20, 2015
Messages
17
Office Version
  1. 365
Platform
  1. Windows
We have numerous sheets of thickness readings. They take the form of something similar to:

ITEMPOSBASE THKBASE DATETHICKNESSDATETHICKNESSDATETHICKNESSDATE
001A5.111/06/154.913/06/2353625/09/195.111/06/15
002B7.625/09/198.2513/06/237.625/09/19N11/06/15
003C5.211/06/155.113/06/235.325/09/195.211/06/15

The number of columns after the Item and Position can vary, depending on how many readings we have but, if there isn't a reading one year, the survey date is still entered and an 'N' (for No Reading) is entered.

What I need to get (in the BASETHK and BASEDATE cells) is the rightmost thickness reading for one, and the respective date for the other. The colouring above is purely to show where the results in the BASE columns are coming from.

Is this possible? I've Google lots, and tried LOOKUP, INDEX/MATCH and so on, but without real success.
 

Excel Facts

Can you sort left to right?
To sort left-to-right, use the Sort dialog box. Click Options. Choose "Sort left to right"
Apology accepted. Just remember to provide any cross-post links on both/all forums in the future. :)
It is also worth considering whether posting on multiple forums actually makes things faster. There are numerous helpers in all forums that will just pass over your thread if it is cross-posted because they do not want to bother trying to monitor multiple forums to see if an answer &/or additional information has been provided elsewhere. So you may have two forums in play, but less potential helpers in each one.
 
Upvote 1
For the setup below:
1686732553724.png

C2:
Excel Formula:
=INDEX($E2:$J2,IFERROR(MATCH("N",$E2:$J2,0),COUNTA($E2:$J2)+1)-(COLUMN()-1))
 
Upvote 0
I suggest that you update your Account details (or click your user name at the top right of the forum) so helpers always know what Excel version(s) & platform(s) you are using as the best solution often varies by version. (Don’t forget to scroll down & ‘Save’)
 
Upvote 0
Thank you. T
For the setup below:
View attachment 93533
C2:
Excel Formula:
=INDEX($E2:$J2,IFERROR(MATCH("N",$E2:$J2,0),COUNTA($E2:$J2)+1)-(COLUMN()-1))
Thank you so much. That's excellent and works great for the thicknesses. How do I get it to show the respective date (which is the one to the right or the selected figure)?

I've notced, if there's more than one N, or an N in the middle of the result range, it doesn't quite work. I'm uploading a better example.

BASELINE FORMULA TEST.xlsx
ABCDEFGHIJKLMN
1ITEMPOSBASE THKBASE DATETHICKNESSDATETHICKNESSDATETHICKNESSDATETHICKNESSDATETHICKNESSDATE
2001A5.618/09/20075.113/03/20235.425/09/20195.611/06/20155.522/02/20115.618/09/2007
3002B7.918/09/20078.213/03/20237.625/09/20197.711/06/2015822/02/20117.918/09/2007
4003C7.822/02/20117.613/03/20237.725/09/20197.711/06/20157.822/02/2011N18/09/2007
5004D7.518/09/20077.313/03/20237.125/09/20197.211/06/20157.422/02/20117.518/09/2007
6005E4.318/09/20073.913/03/2023N25/09/20194.211/06/20154.222/02/20114.318/09/2007
7006F3.518/09/20073.713/03/20233.225/09/20193.411/06/20153.322/02/20113.518/09/2007
8007G3.722/02/20113.813/03/20233.125/09/2019N11/06/20153.722/02/2011N18/09/2007
9008H8.411/06/20158.113/03/20238.225/09/20198.411/06/2015N22/02/2011N18/09/2007
10009I8.518/09/20078.113/03/20238.225/09/20198.211/06/20158.422/02/20118.518/09/2007
11010J5.818/09/20075.413/03/20235.325/09/20195.411/06/20155.722/02/20115.818/09/2007
Sheet1
Cell Formulas
RangeFormula
C2:D3,C5:D7,C10:D11C2=M2
C4:D4,C8:D8C4=K4
C9:D9C9=I9
 
Upvote 0
Thanks. I've now done that.
Cheers. Thanks for that. (y)

Try these

23 06 14.xlsm
CDEFGHIJKLMN
1BASE THKBASE DATETHICKNESSDATETHICKNESSDATETHICKNESSDATETHICKNESSDATETHICKNESSDATE
25.618/09/20075.113/03/20235.425/09/20195.611/06/20155.522/02/20115.618/09/2007
37.918/09/20078.213/03/20237.625/09/20197.711/06/2015822/02/20117.918/09/2007
47.822/02/20117.613/03/20237.725/09/20197.711/06/20157.822/02/2011N18/09/2007
57.518/09/20077.313/03/20237.125/09/20197.211/06/20157.422/02/20117.518/09/2007
64.318/09/20073.913/03/2023N25/09/20194.211/06/20154.222/02/20114.318/09/2007
73.518/09/20073.713/03/20233.225/09/20193.411/06/20153.322/02/20113.518/09/2007
83.722/02/20113.813/03/20233.125/09/2019N11/06/20153.722/02/2011N18/09/2007
98.411/06/20158.113/03/20238.225/09/20198.411/06/2015N22/02/2011N18/09/2007
108.518/09/20078.113/03/20238.225/09/20198.211/06/20158.422/02/20118.518/09/2007
115.818/09/20075.413/03/20235.325/09/20195.411/06/20155.722/02/20115.818/09/2007
Sheet5
Cell Formulas
RangeFormula
C2:C11C2=LET(f,FILTER(E2:N2,(E$1:N$1="THICKNESS")*(E2:N2<>"N")),INDEX(f,COUNT(f)))
D2:D11D2=XLOOKUP(C2,E2:M2,F2:N2,,,-1)
 
Upvote 0
Here is another option with a shorter formula for thickness.

23 06 14.xlsm
CDEFGHIJKLMN
1BASE THKBASE DATETHICKNESSDATETHICKNESSDATETHICKNESSDATETHICKNESSDATETHICKNESSDATE
25.618/09/20075.113/03/20235.425/09/20195.611/06/20155.522/02/20115.618/09/2007
37.918/09/20078.213/03/20237.625/09/20197.711/06/2015822/02/20117.918/09/2007
47.822/02/20117.613/03/20237.725/09/20197.711/06/20157.822/02/2011N18/09/2007
57.518/09/20077.313/03/20237.125/09/20197.211/06/20157.422/02/20117.518/09/2007
64.318/09/20073.913/03/2023N25/09/20194.211/06/20154.222/02/20114.318/09/2007
73.518/09/20073.713/03/20233.225/09/20193.411/06/20153.322/02/20113.518/09/2007
83.722/02/20113.813/03/20233.125/09/2019N11/06/20153.722/02/2011N18/09/2007
98.411/06/20158.113/03/20238.225/09/20198.411/06/2015N22/02/2011N18/09/2007
108.518/09/20078.113/03/20238.225/09/20198.211/06/20158.422/02/20118.518/09/2007
115.818/09/20075.413/03/20235.325/09/20195.411/06/20155.722/02/20115.818/09/2007
Sheet5
Cell Formulas
RangeFormula
C2:C11C2=LOOKUP(9^9,FILTER(E2:N2,E$1:N$1="THICKNESS"))
D2:D11D2=XLOOKUP(C2,E2:M2,F2:N2,,,-1)
 
Upvote 0
Solution
Here is another option with a shorter formula for thickness.

23 06 14.xlsm
CDEFGHIJKLMN
1BASE THKBASE DATETHICKNESSDATETHICKNESSDATETHICKNESSDATETHICKNESSDATETHICKNESSDATE
25.618/09/20075.113/03/20235.425/09/20195.611/06/20155.522/02/20115.618/09/2007
37.918/09/20078.213/03/20237.625/09/20197.711/06/2015822/02/20117.918/09/2007
47.822/02/20117.613/03/20237.725/09/20197.711/06/20157.822/02/2011N18/09/2007
57.518/09/20077.313/03/20237.125/09/20197.211/06/20157.422/02/20117.518/09/2007
64.318/09/20073.913/03/2023N25/09/20194.211/06/20154.222/02/20114.318/09/2007
73.518/09/20073.713/03/20233.225/09/20193.411/06/20153.322/02/20113.518/09/2007
83.722/02/20113.813/03/20233.125/09/2019N11/06/20153.722/02/2011N18/09/2007
98.411/06/20158.113/03/20238.225/09/20198.411/06/2015N22/02/2011N18/09/2007
108.518/09/20078.113/03/20238.225/09/20198.211/06/20158.422/02/20118.518/09/2007
115.818/09/20075.413/03/20235.325/09/20195.411/06/20155.722/02/20115.818/09/2007
Sheet5
Cell Formulas
RangeFormula
C2:C11C2=LOOKUP(9^9,FILTER(E2:N2,E$1:N$1="THICKNESS"))
D2:D11D2=XLOOKUP(C2,E2:M2,F2:N2,,,-1)
That works perfectly! Thank you SO much Peter.
 
Upvote 0

Forum statistics

Threads
1,215,614
Messages
6,125,848
Members
449,266
Latest member
davinroach

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top