vlookup question

and8eye

Board Regular
Joined
Mar 18, 2015
Messages
50
(please dont delete this thread, i cant think of a better title)

hi everyone,

i have strings (each cell contains) like this:

<style type="text/css"><!--td {border: 1px solid #ccc;}br {mso-data-placement:same-cell;}--></style>WW098-ZK-TRXF-PAB-MRX-01
<style type="text/css"></style>BB107-ZK-MRCK-N-SPDB-TRC-01


and i have condition like this:
5651.png


i want to: "if strings between the first - (dash) and the second - (dash) (from left, in this case theyre TRXF and MRCK) matches the condition i had, then print it out"

it should be something like: "if -TRXF- contains TR then 10, or if -MRCK- contains MR then 6"

thank you.
 
Last edited:

Excel Facts

Copy formula down without changing references
If you have =SUM(F2:F49) in F50; type Alt+' in F51 to copy =SUM(F2:F49) to F51, leaving the formula in edit mode. Change SUM to COUNT.
Assuming your list of values WW098-ZK... BB107-ZK... are in Sheet1 Column A and you have your "Conditions" in Sheet2 Column A:B

In Sheet1 Column B Row 2 Enter

Code:
=VLOOKUP(MID(A2,FIND("-",A2,FIND("-",A2)+1)+1,2),Sheet2!$A$1:$B$11,2,FALSE)
 
Upvote 0
Assuming your list of values WW098-ZK... BB107-ZK... are in Sheet1 Column A and you have your "Conditions" in Sheet2 Column A:B

In Sheet1 Column B Row 2 Enter

Code:
=VLOOKUP(MID(A2,FIND("-",A2,FIND("-",A2)+1)+1,2),Sheet2!$A$1:$B$11,2,FALSE)

many thanks

but sometimes the condition which i had contains 3 or 4 words, your code will return #NA

please help
 
Upvote 0
=LOOKUP(9.99999999999999E+307,SEARCH("-"&Symbols,REPLACE($A2,1,FIND("-",$A2),"")),Numbers)

where Symbols are DS, Hy, etc., Numbers 1, 2, etc., and A2 houses a string like WW098-ZK-TRXF-PAB-MRX-01.

Your description is not correct: We have ZK in-between first and second dashes, not TRXF.

Maybe the following fits better what you want:

=LOOKUP(9.99999999999999E+307,SEARCH("-"&Symbols,$A2),Numbers)
 
Upvote 0
Code:
=IFERROR(VLOOKUP(MID(A2,FIND("-",A2,FIND("-",A2)+1)+1,2),Sheet2!$A$1:$B$11,2,FALSE),VLOOKUP(MID(A2,FIND("-",A2,FIND("-",A2,FIND("-",A2)+1)+1)+1,2),Sheet2!$A$1:$B$11,2,FALSE))
 
Upvote 0
=LOOKUP(9.99999999999999E+307,SEARCH("-"&Symbols,REPLACE($A2,1,FIND("-",$A2),"")),Numbers)

where Symbols are DS, Hy, etc., Numbers 1, 2, etc., and A2 houses a string like WW098-ZK-TRXF-PAB-MRX-01.

Your description is not correct: We have ZK in-between first and second dashes, not TRXF.

Maybe the following fits better what you want:

=LOOKUP(9.99999999999999E+307,SEARCH("-"&Symbols,$A2),Numbers)

Aladin your code intrigued me however it only seems to return 10 for both WW098-ZK-TRXF-PAB-MRX-01 and
BB107-ZK-MRCK-N-SPDB-TRC-01

Where it should have returned 10 and 6. Try using this on BB107-ZK-MRCK-N-SPDB-TRC-01 you should get 6 but your formula returns 10? Am I missing something? I created the ranges for Symbols and Numbers.
 
Last edited:
Upvote 0
If it's meant to evaluate the substring between the second "-" and the third "-", then:

=LOOKUP(9.99999999999999E+307,SEARCH("|"&Symbols,"|"&REPLACE(A2,1,FIND("I",SUBSTITUTE($A2,"-","I",2)),"")),Numbers)
 
Upvote 0
Code:
=IFERROR(VLOOKUP(MID(A2,FIND("-",A2,FIND("-",A2)+1)+1,2),Sheet2!$A$1:$B$11,2,FALSE),VLOOKUP(MID(A2,FIND("-",A2,FIND("-",A2,FIND("-",A2)+1)+1)+1,2),Sheet2!$A$1:$B$11,2,FALSE))



To clarify the formula I posted in Post #5 will look at the first 2 letters of the 3rd block and return the value, if it errors because it does not find the match then it will look at the first 2 letters of the 4th block.
This string has 6 blocks we are looking at 3 THEN 4 only.

WW098-ZK-TRXF-PAB-MRX-01
Block1-Block2-
Block3-Block4-Block5-Block6
 
Upvote 0
If it's meant to evaluate the substring between the second "-" and the third "-", then:

=LOOKUP(9.99999999999999E+307,SEARCH("|"&Symbols,"|"&REPLACE(A2,1,FIND("I",SUBSTITUTE($A2,"-","I",2)),"")),Numbers)

That one seems to work but runs in to the same problem my original answer in post #2 faced - revised answer in post #5 and #9

It will error because sometimes he wants to look at the 3rd block and sometimes the 4th block.

Example: Try it with this [TABLE="width: 257"]
<tbody>[TR]
[TD="class: xl65, width: 257"]BB107-ZK-MORE-MRCK-N-SPDB-TRC-01 assuming your trying to return from MRCK in block 4[/TD]
[/TR]
</tbody>[/TABLE]
 
Last edited:
Upvote 0

Forum statistics

Threads
1,224,823
Messages
6,181,181
Members
453,022
Latest member
Mohamed Magdi Tawfiq Emam

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