Macro or Formula to extract certain text from a cell?

xsil

New Member
Joined
Dec 7, 2005
Messages
25
Riddle me this.

I would like to extract just the two-letter state code from a string of text in a cell. Note that the two letter state codes do not always appear exactly at the end, so the solution will require something more complex than, say "Right(A1,2)".

For example, in each of the strings of text listed below, I'd be looking for "NY", "AZ", or "CA" to be returned:

Dunkirk NY 013
E Aurora NY
Yuma AZ
Woodland Hills CA (SMATV)


What is the best approach here? I do not believe there is a built in formula for this, so perhaps some VBA code that would recognize the two letter state codes from a separate list.... and then...?

Help!

Thanks very much.
 

Excel Facts

Round to nearest half hour?
Use =MROUND(A2,"0:30") to round to nearest half hour. Use =CEILING(A2,"0:30") to round to next half hour.
I put you sample date in A1:A4. In A6:A8 I made a list of states (only the ones in your sample, but it could be longer). In B1 I typed:

=INDEX($A$6:$A$8,MATCH(TRUE,ISNUMBER(SEARCH(" "&$A$6:$A$8&" ",A1)),FALSE))

and pressed Ctrl+Shift+Enter, not just Enter. If correctly entered Excel will surround this array formula with curly braces {}.

Then I copied the formula to B2:B4.

The results looked right.
 
Upvote 0

Forum statistics

Threads
1,214,415
Messages
6,119,381
Members
448,888
Latest member
Arle8907

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