Pull out numbers from a text field

erock24

Well-known Member
Joined
Oct 26, 2006
Messages
1,163
I've got a real mess here.
I'm looking for a formula that can pull out numbers from a text field.
In Some of the text fields the numbers are preceeded by a "#" sign. In others they are not. The numbers are all different lengths and can be at the begining, middle, or end.
example of "#" sign one is "Pkg Lot/Bldg #1215"
example of no sign one is "Pkg Lot/bldg 1215"
 

Excel Facts

Quick Sum
Select a range of cells. The total appears in bottom right of Excel screen. Right-click total to add Max, Min, Count, Average.
Try this UDF:

Code:
Public Function getNums(r As String)
Dim temp
With CreateObject("vbscript.regexp")
    .Pattern = "\D"
    .Global = True
    temp = .Replace(r, "")
End With
If IsNumeric(temp) Then temp = Val(temp)
getNums = temp
End Function

Usage is like this:
=getNums(A1)

To put this in:
Copy the code above.
Right click on one of your sheet tabs.
Click on View Code.
From the menu on top, click on Insert, then Module.
Paste into white area.
Hit Alt-q
When you save your workbook, this code will be saved with it.
Book2
ABCD
1Pkg Lot/Bldg #12151215
2Bldg 7 Lot B7
3A 
Sheet1
 
Upvote 0
If your "text/numbers" are all in column A this will pull numbers into column B:
Code:
Sub ExtractNumbers()
Dim rRng As Range, rCell As Range, oMatches As Object, i As Integer
Set rRng = Range("A1:A" & Range("A" & Rows.Count).End(xlUp).Row)
    With CreateObject("vbscript.regexp")
        .Pattern = "\d+"
        .Global = True
        For Each rCell In rRng
            Set oMatches = .Execute(rCell.Value)
            For i = 0 To oMatches.Count - 1
            rCell.Offset(, i + 1) = oMatches(i).Value
            Next i
        Next rCell
    End With
End Sub
 
Upvote 0
Or another (but sloppier) UDF

Code:
Function unmess(r As Range)
Dim  i As Integer, mess As String, ipos As Integer
mess = r.Value
For i = 1 To Len(mess)
    If IsNumeric(Mid(mess, i, 1)) Then
        ipos = i
        Exit For
    End If
Next i
unmess = Val(Mid(mess, ipos, Len(mess) - ipos + 1))
End Function

Try =unmess(A1)

Edit: removed unnecessary Dim.
 
Upvote 0
Wow!! very very very cool.
Thank you both so much for such a fast response to a seemingly tough question.

Both ways work perfectly.
I am actually utilizing both methods. Each one has strengths I like.
Hottpepper,
yours is nice because I can use it anywhere.
DatsMart,
yours is great because if more than one number is present it separates them out.

VogII,
I just saw your post, Thank you very much for the reply.
 
Upvote 0

Forum statistics

Threads
1,215,011
Messages
6,122,680
Members
449,091
Latest member
peppernaut

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