Seperate text and number to different cells

  • Thread starter Thread starter Seperate text and number
  • Start date Start date
S

Seperate text and number

Hi,

I have some data in cell (A1) which is alpha numeric, from this data I want
number and text in seperate cells (B1) and (C1) respectively per the below
example.

A B C
Raw Data Numbers Text
asho344555k123 344555123 ashok
123ab47 12347 ab
1affu123 1123 affu


Thanks
Afroz
 
The following User Defined Function will return the numerals in a mixed cell:

Public Function ReturnNumerals(rng As Range) As String
Dim sStr As String, i As Long, sStr1 As String
Dim sChar As String
sStr = rng.Value
For i = 1 To Len(sStr)
sChar = Mid(sStr, i, 1)
If sChar Like "[0-9]" Then
sStr1 = sStr1 & sChar
End If
Next
ReturnNumerals = sStr1
End Function

This UDF will return the non-numerals in a mexed cell:

Public Function ReturnAlphas(rng As Range) As String
Dim sStr As String, i As Long, sStr1 As String
Dim sChar As String
sStr = rng.Value
For i = 1 To Len(sStr)
sChar = Mid(sStr, i, 1)
If Not sChar Like "[0-9]" Then
sStr1 = sStr1 & sChar
End If
Next
ReturnAlphas = sStr1
End Function

User Defined Functions (UDFs) are very easy to install and use:

1. ALT-F11 brings up the VBE window
2. ALT-I
ALT-M opens a fresh module
3. paste the stuff in and close the VBE window

If you save the workbook, the UDF will be saved with it.

To remove the UDF:

1. bring up the VBE window as above
2. clear the code out
3. close the VBE window

To use the UDF from Excel:

=myfunction(A1)

To learn more about macros in general, see:

http://www.mvps.org/dmcritchie/excel/getstarted.htm

or

http://www.cpearson.com/excel/WritingFunctionsInVBA.aspx
for specifics on UDFs
 
On Fri, 21 May 2010 04:00:01 -0700, Seperate text and number <Seperate text and
Hi,

I have some data in cell (A1) which is alpha numeric, from this data I want
number and text in seperate cells (B1) and (C1) respectively per the below
example.

A B C
Raw Data Numbers Text
asho344555k123 344555123 ashok
123ab47 12347 ab
1affu123 1123 affu


Thanks
Afroz

Here is a macro that will do that.

To enter this Macro (Sub), <alt-F11> opens the Visual Basic Editor.
Ensure your project is highlighted in the Project Explorer window.
Then, from the top menu, select Insert/Module and
paste the code below into the window that opens.

To use this Macro (Sub), first select the range you wish to parse.
Then <alt-F8> opens the macro dialog box. Select the macro by name, and <RUN>.

==============================================
Option Explicit
Sub SplitNumsText()
Dim c As Range, rg As Range
Dim re As Object, mc As Object

Set rg = Selection
Set re = CreateObject("vbscript.regexp")
re.Global = True

For Each c In rg
'format set to text to prevent Excel from using Scientific
'notation, dropping leading zero's, or rounding numbers
'with more than 15 digits
Range(c.Offset(0, 1), c.Offset(0, 2)).NumberFormat = "@"
re.Pattern = "\d" 'remove all digits
c.Offset(0, 1).Value = re.Replace(c.Text, "")
re.Pattern = "\D" 'remove all non-digits
c.Offset(0, 2).Value = re.Replace(c.Text, "")
Next c
End Sub
===============================
--ron
 
For Numbers:

B2:
=LOOKUP(10^10,--MID(A2,MIN(FIND({0,1,2,3,4,5,6,7,8,9},A2&"0123456789")),ROW(INDIRECT("1:"&LEN(A2)))))&LOOKUP(10^10,--RIGHT(A2,ROW($1:$99)))

For Text:

C2:
=LEFT(SUBSTITUTE(A2,LOOKUP(10^10,--MID(A2,MIN(FIND({0,1,2,3,4,5,6,7,8,9},A2&"0123456789")),ROW(INDIRECT("1:"&LEN(A2))))),"")&LOOKUP(10^10,--RIGHT(A2,ROW($1:$99))),LEN(A2)-LEN(B2))

copy B2 and C2 down as far as needed
 
Back
Top