seperating text and numbers

sandie713

New Member
Joined
Feb 19, 2002
Messages
1
I have a cell that has numbers and text in it. I need to seperate the numbers from the text and put this in a seperate cell. I have tried an if statement with the isnumber function, but even when it is a number it thinks it is text. any suggestions?
 

Excel Facts

What is =ROMAN(40) in Excel?
The Roman numeral for 40 is XL. Bill "MrExcel" Jelen's 40th book was called MrExcel XL.
Sandie,
What kind of format is your data in, are the numbers mixed with the letters or on one side or the other. Are the the same about of characters/numbers in each row?.
If you could post a few examples it would help.


On 2002-02-20 18:16, sandie713 wrote:
I have a cell that has numbers and text in it. I need to seperate the numbers from the text and put this in a seperate cell. I have tried an if statement with the isnumber function, but even when it is a number it thinks it is text. any suggestions?
 
Upvote 0
Hi Sandie
You can separate them by formula if there is a space or a constant between text and number.
If not, you can use this macro to remove all numbers from any cells in your sheet, leaving the text behind. If the numbers include a decimal stop you will need to add a new line to code to remove this.

WARNING!!! Only use this macro on a copy of your work as it is likely to remove all numbers from the active sheet.


Sub RemoveNumbers()
'
' RemoveNumbers Macro
'
With Selection
Cells.Replace What:="1", Replacement:="", LookAt:=xlPart, SearchOrder:= _
xlByRows, MatchCase:=False
Cells.Replace What:="2", Replacement:="", LookAt:=xlPart, SearchOrder:= _
xlByRows, MatchCase:=False
Cells.Replace What:="3", Replacement:="", LookAt:=xlPart, SearchOrder:= _
xlByRows, MatchCase:=False
Cells.Replace What:="4", Replacement:="", LookAt:=xlPart, SearchOrder:= _
xlByRows, MatchCase:=False
Cells.Replace What:="5", Replacement:="", LookAt:=xlPart, SearchOrder:= _
xlByRows, MatchCase:=False
Cells.Replace What:="6", Replacement:="", LookAt:=xlPart, SearchOrder:= _
xlByRows, MatchCase:=False
Cells.Replace What:="7", Replacement:="", LookAt:=xlPart, SearchOrder:= _
xlByRows, MatchCase:=False
Cells.Replace What:="8", Replacement:="", LookAt:=xlPart, SearchOrder:= _
xlByRows, MatchCase:=False
Cells.Replace What:="9", Replacement:="", LookAt:=xlPart, SearchOrder:= _
xlByRows, MatchCase:=False
Cells.Replace What:="0", Replacement:="", LookAt:=xlPart, SearchOrder:= _
xlByRows, MatchCase:=False
End With
End Sub

Hope this is of use
Derek
This message was edited by Derek on 2002-02-20 19:52
This message was edited by Derek on 2002-02-20 20:44
 
Upvote 0
On 2002-02-20 18:16, sandie713 wrote:
I have a cell that has numbers and text in it. I need to seperate the numbers from the text and put this in a seperate cell. I have tried an if statement with the isnumber function, but even when it is a number it thinks it is text. any suggestions?

Since you didn't give examples that would inform us what kind of regularity your alphanumeric entries might have, I'll consider in what follows a few possibilities:

1) xza 126 [ the alpha and num parts are separated by a space or a comma or by another delimiter ]

Use the option Data|Text To columns where you check what the delimiter is.

2) 126 xza [ the same as above ]

Again use the option Data|Text To Columns.

3) xza126, can3452, etc. [ That is, the alpha and num parts are together and the num parts is always after the alpha part ]

In B1 enter:

=SUBSTITUTE(A1,RIGHT(A1,SUMPRODUCT((LEN(A1)-LEN(SUBSTITUTE(A1,{0,1,2,3,4,5,6,7,8,9},""))))),"")

where A1 houses a target entry.

In C1 enter:

=SUBSTITUTE(A1,B1,"")+0

4) 126xza, 3452can, etc. [ That is, the alpha and num parts are together and the num parts is always before the alpha part ]

In B1 enter:

=SUBSTITUTE(A1,LEFT(A1,SUMPRODUCT((LEN(A1)-LEN(SUBSTITUTE(A1,{0,1,2,3,4,5,6,7,8,9},""))))),"")

where A1 houses a target entry.

In C1 enter:

=SUBSTITUTE(A1,B1,"")+0

5) zx67a45sad, dax765x78,etc. [ That is, alphanumeric characters are all interspersed ]

Interpreting narrowly, "I need to seperate the numbers from the text and put this in a seperate cell," as meaning delete the digits from the target entry leaving only digit-free rest behind.

Activate Insert|Name|Define;
Enter RemZeroToSeven as name in the Names in workbook box;
Enter in the Refers to box as formula:

=SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(Sheet1!A1,0,""),1,""),2,""),3,""),4,""),5,""),6,""),7,"")

Click OK.

Now in B1 enter:

=SUBSTITUTE(SUBSTITUTE(RemZeroToSeven,8,""),9,"")

Note. I devised the last one, the occasion being an off-line question by msvec. As might be noticed, this can also be used in cases 4 and 5!

If the entries contain numbers with decimals, the formulas above can be adapted to take care of that too.

Aladin
 
Upvote 0

Forum statistics

Threads
1,213,556
Messages
6,114,284
Members
448,562
Latest member
Flashbond

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