insanalyst

New Member
Joined
Dec 2, 2011
Messages
4
I have a WB where column A contains stocks and stock symbols. The stock symbols represent the last 1-4 letters in each cell. Because each stock name (and symbol) is of different length and may or may not have multiple spaces, the traditional means of "reverse contatenation" aren't helping (e.g. text to columns, =RIGHT(text,FIND(" ",text)), etc.) any ideas? WB is several thousand rows long so a clean solution is preferred. perhaps a way to make the FIND function return the last space in the text?
 

Excel Facts

Lock one reference in a formula
Need 1 part of a formula to always point to the same range? use $ signs: $V$2:$Z$99 will always point to V2:Z99, even after copying
Are you trying to extract the last 4 characters, but not include the spaces?
Could you provide an example of your data and the expected outcome.
 
Upvote 0
I am trying to extract the stock symbol. It could be anywhere from 1-4 letters long depending on the symbol. I can trim spaces if necessary. here is an example:
<TABLE style="WIDTH: 213pt; BORDER-COLLAPSE: collapse" border=0 cellSpacing=0 cellPadding=0 width=284><COLGROUP><COL style="WIDTH: 213pt; mso-width-source: userset; mso-width-alt: 10386" width=284><TBODY><TR style="HEIGHT: 15pt" height=20><TD style="BORDER-BOTTOM: #ece9d8; BORDER-LEFT: #ece9d8; BACKGROUND-COLOR: transparent; WIDTH: 213pt; HEIGHT: 15pt; BORDER-TOP: #ece9d8; BORDER-RIGHT: #ece9d8" id=td_post_251209 height=20 width=284><TABLE style="WIDTH: 213pt; BORDER-COLLAPSE: collapse" border=0 cellSpacing=0 cellPadding=0 width=284><COLGROUP><COL style="WIDTH: 213pt; mso-width-source: userset; mso-width-alt: 10386" width=284><TBODY><TR style="HEIGHT: 15pt" height=20><TD style="BORDER-BOTTOM: #ece9d8; BORDER-LEFT: #ece9d8; BACKGROUND-COLOR: transparent; WIDTH: 213pt; HEIGHT: 15pt; BORDER-TOP: #ece9d8; BORDER-RIGHT: #ece9d8" id=td_post_251209 height=20 width=284>AGILENT TECHNOLOGIES IN A</TD></TR></TBODY></TABLE>
ALLSCRIPTS HEALTHCARE MDRX
</TD></TR><TR style="HEIGHT: 15pt" height=20><TD style="BORDER-BOTTOM: #ece9d8; BORDER-LEFT: #ece9d8; BACKGROUND-COLOR: transparent; HEIGHT: 15pt; BORDER-TOP: #ece9d8; BORDER-RIGHT: #ece9d8" height=20>ALPHA NATURAL RESOURCES ANR</TD></TR><TR style="HEIGHT: 15pt" height=20><TD style="BORDER-BOTTOM: #ece9d8; BORDER-LEFT: #ece9d8; BACKGROUND-COLOR: transparent; HEIGHT: 15pt; BORDER-TOP: #ece9d8; BORDER-RIGHT: #ece9d8" height=20>ALTERA CORP ALTR</TD></TR><TR style="HEIGHT: 15pt" height=20><TD style="BORDER-BOTTOM: #ece9d8; BORDER-LEFT: #ece9d8; BACKGROUND-COLOR: transparent; HEIGHT: 15pt; BORDER-TOP: #ece9d8; BORDER-RIGHT: #ece9d8" height=20>ALTRIA GROUP INC MO</TD></TR><TR style="HEIGHT: 15pt" height=20><TD style="BORDER-BOTTOM: #ece9d8; BORDER-LEFT: #ece9d8; BACKGROUND-COLOR: transparent; HEIGHT: 15pt; BORDER-TOP: #ece9d8; BORDER-RIGHT: #ece9d8" height=20>AMAZON COM INC AMZN</TD></TR></TBODY></TABLE>

In all cases the characters after the last space represent the stock symbol
 
Upvote 0
you can use this formula:

=RIGHT(A1,LEN(A1)-FIND("*",SUBSTITUTE(A1," ","*",LEN(A1)-LEN(SUBSTITUTE(A1," ","")))))

or this function:

Code:
Public Function getLastWord(ByVal str As String, _
                            Optional tst As Boolean) As String

Dim funcTst As Boolean, lenStr As Long, ndx As Long
tst = False
On Error GoTo exitFunc

str = RTrim$(str)
lenStr = Len(str)
ndx = InStrRev(str, Chr(32))

getLastWord = Mid$(str, ndx + 1, lenStr - ndx)
tst = True
exitFunc:
End Function
 
Upvote 0
Chirp, this worked like a charm, thankyou. Just familiarizing myself with LEN. This worked so smoothly
 
Upvote 0

Forum statistics

Threads
1,213,506
Messages
6,114,027
Members
448,543
Latest member
MartinLarkin

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