Index Match with result coming from 1 of 2 Columns

tancha

New Member
Joined
Sep 17, 2019
Messages
3
Hello.. I am trying to get a formula so that when A1 matches a Product ID in Sheet2,Column B, it will
a) return the data from the relevant row in Column D, if the corresponding row in column Q = No or,
b) return the data from the relevant row in Column R, if the corresponding row in column Q = Yes

I've tried lots of variations like these two but none are working so I'm thinking I must be on the wrong track.
=IF('sheet2'!Q:Q ="No", INDEX('sheet2'!D:D,MATCH(A1,'sheet2'!B:B,0)),INDEX('sheet2'!R:R,MATCH(A1,'sheet2'!B:B,0)))

=IFERROR(INDEX('sheet2'!D:D,MATCH(A1,'sheet2'!B:B,0),MATCH('yesnosheet'!A1,'sheet2'!Q:Q,0)),INDEX('sheet2'!R:R,MATCH(A1,'sheet2'!B:B,0),MATCH('yesnosheet'!A2,'sheet2'!Q:Q, 0)))
 

Excel Facts

Show numbers in thousands?
Use a custom number format of #,##0,K. Each comma after the final 0 will divide the displayed number by another thousand
Can column Q be anything else or will it always be yes or no
 
Upvote 0
How about
=IF(INDEX(Sheet2!Q:Q,MATCH(A1,Sheet2!B:B,0))="No", INDEX(Sheet2!D:D,MATCH(A1, Sheet2!B:B,0)), INDEX(Sheet2!R:R,MATCH(A1, Sheet2!B:B,0)))
 
Upvote 0
You're welcome & thanks for the feedback
 
Upvote 0
What about just
=VLOOKUP(A1,Sheet2!B:R,3+14*(INDEX(Sheet2!Q:Q,MATCH(A1,Sheet2!B:B,0))="Yes"),0)

Or if you want to stick to all index/match
=INDEX(Sheet2!D:R,MATCH(A1,Sheet2!B:B,0),1+14*(INDEX(Sheet2!Q:Q,MATCH(A1,Sheet2!B:B,0))="Yes"))
 
Upvote 0

Forum statistics

Threads
1,213,513
Messages
6,114,072
Members
448,546
Latest member
KH Consulting

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