Using VLOOKUP to find a String Text

iggyowner82

New Member
Joined
Feb 19, 2010
Messages
16
Column A

Quarterly Dividend</SPAN>
Bonus Dividend</SPAN>
Annual Dividend</SPAN>

<TBODY>
</TBODY><COLGROUP><COL></COLGROUP>

Column B (list is longer but for example)

CLIFFS NATURAL RESOURCES - Quarterly Dividend 2011 - Ex Date</SPAN>
CONAGRA FOODS INC - Quarterly Dividend 2011 - Ex Date</SPAN>
PINNACLE WEST CAPITAL CORP - Quarterly Dividend 2011 - Ex Date</SPAN>
DIAMOND OFFSHORE DRILLING INC - Quarterly Dividend 2011 - Ex Date</SPAN>
DIAMOND OFFSHORE DRILLING INC - Bonus Dividend 2011 - Ex Date</SPAN>
MEADWESTVACO CORP - Quarterly Dividend 2011 - Ex Date</SPAN>
SEAGATE TECHNOLOGY PLC - Interim Dividend 2011 - Ex Date</SPAN>

<TBODY>
</TBODY><COLGROUP><COL></COLGROUP>

Basically, I am trying to use a VLOOKUP to lookup column B against column A. If the word in column B has within the string "Quarterly Dividend" (As per the lookup in column A), I want the the lookup formula in columns C to say Quarterly Dividend. I am using the below formula but I cannot get the result I am looking for. Any tips would be appreciated: -

=VLOOKUP("*"&B2&"*",$A$2:$A$4,1,TRUE)
 

Excel Facts

Format cells as date
Select range and press Ctrl+Shift+3 to format cells as date. (Shift 3 is the # sign which sort of looks like a small calendar).
Column A
Quarterly Dividend
Bonus Dividend
Annual Dividend

<tbody>
</tbody>

Column B (list is longer but for example)

CLIFFS NATURAL RESOURCES - Quarterly Dividend 2011 - Ex Date
CONAGRA FOODS INC - Quarterly Dividend 2011 - Ex Date
PINNACLE WEST CAPITAL CORP - Quarterly Dividend 2011 - Ex Date
DIAMOND OFFSHORE DRILLING INC - Quarterly Dividend 2011 - Ex Date
DIAMOND OFFSHORE DRILLING INC - Bonus Dividend 2011 - Ex Date
MEADWESTVACO CORP - Quarterly Dividend 2011 - Ex Date
SEAGATE TECHNOLOGY PLC - Interim Dividend 2011 - Ex Date

<tbody>
</tbody>

Basically, I am trying to use a VLOOKUP to lookup column B against column A. If the word in column B has within the string "Quarterly Dividend" (As per the lookup in column A), I want the the lookup formula in columns C to say Quarterly Dividend. I am using the below formula but I cannot get the result I am looking for. Any tips would be appreciated: -

=VLOOKUP("*"&B2&"*",$A$2:$A$4,1,TRUE)

C2, copy down:

=LOOKUP(9.99999999999999E+307,SEARCH(" "&$A$2:$A$4&" "," "&$B2&" "),$A$2:$A$4)
 
Upvote 0
Wow!! That works....but not sure how it works lol. What does the "9.99999999999999E+307" do in the formula?

LOOKUP using that big number as look up value correlates the last numeric value coming from the FIND expression with the results range. Here is a step by step review:

1) Space chars are used in order to isolate an entry from its look-alikes: "iggyowner82" and "iggyowner824" are not the same. If not isolated/protected with spaces around, a SEARCH or FIND would see a match between "iggyowner82" and "iggyowner824" while either one of these functions would not report a match between " iggyowner82 " and " iggyowner824 ".

2) The formula works/evaluates like this:
Rich (BB code):
=LOOKUP(9.99999999999999E+307,
  SEARCH(" "&$A$2:$A$4&" "," "&$B2&" "),$A$2:$A$4)
The SEARCH bit is looking for every item (string) in A2:A4 in B2, appropriately surrounded with space chars. This yields:
Rich (BB code):
=LOOKUP(9.99999999999999E+307,{28;#VALUE!;#VALUE!},$A$2:$A$4)
LOOKUP correlates the position of the last numeric value in:
Rich (BB code):
{28;#VALUE!;#VALUE!}
which is 1 with the value in A2:A4 at that position:
Rich (BB code):
=LOOKUP(9.99999999999999E+307,
  {28;#VALUE!;#VALUE!},
  {"Quarterly Dividend";"Bonus Dividend";"Annual Dividend"})
The result is of course Quarterly Dividend. Note that LOOKUP ignores the error values if it can. The following links detail why such a big number as look up value and the workings:

http://www.mrexcel.com/forum/excel-questions/102091-9-9999999-a.html
http://www.mrexcel.com/forum/excel-questions/310278-vlookup-multiple-matches-match-returned.html (post #7)
 
Upvote 0

Forum statistics

Threads
1,214,914
Messages
6,122,211
Members
449,074
Latest member
cancansova

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