how to extract a string of numbers from a cell containing text and numbers

AwesomeSteph

Board Regular
Joined
Aug 18, 2017
Messages
80
I have an excel list of over 5 thousand cells in a column. All in column A.
Each cell is unique with different information in a different order.
I need to extract from each of these cells the numbers proceeding "RE" in each cell. however they are not all in the same place in the cell some are the beginning some are at the end and some in the middle. is there an easy formula that I can apply to column B that will find all "RE"'s that have numbers after it and produce just those numbers?

thank you so much for any help with this!
 

Excel Facts

Excel motto
Not everything I do at work revolves around Excel. Only the fun parts.
Here is a VBA solution

Code:
Option Explicit


Sub FindRE()
    Dim lr As Long, i As Long
    lr = Range("A" & Rows.Count).End(xlUp).Row
    Application.ScreenUpdating = False
    For i = 1 To lr
        If InStr(Range("A" & i), "RE") > 0 Then
            Range("B" & i) = Range("A" & i)
        End If
    Next i


    For i = 1 To lr
        If Range("B" & i) <> "" Then
            Range("B" & i) = Replace(Range("B" & i), "RE", "")
        End If
    Next i
    Application.ScreenUpdating = True
    MsgBox "complete"
End Sub

Standard Module
How to install your new code
Copy the Excel VBA code
Select the workbook in which you want to store the Excel VBA code
Press Alt+F11 to open the Visual Basic Editor
Choose Insert > Module
Edit > Paste the macro into the module that appeared
Close the VBEditor
Save your workbook (Excel 2007+ select a macro-enabled file format, like *.xlsm)


To run the Excel VBA code:
Press Alt-F8 to open the macro list
Select a macro in the list
Click the Run button
 
Upvote 0
HI,
it would be good if you can provide some examples of how the string is in your column and what outcome you like to have.

but something down this line could do what you are after

Code:
Function REout(ByVal strText As String) As String
    Dim intPos As Integer
    
    intPos = InStr(strText, "RE")
    
    REout = Mid(strText, intPos + 3)
    
End Function

HTH
 
Upvote 0
this macro just deleted the "RE". there is a lot of other information in each cell in column A. the result needs to just be RE##### but I need everything after the RE until there is a space.
so for an example Cell A1 contains "Blah, words SA 0.020.01 RE18019 blah 0 -0.01-0.02 Blah blah blah" and what I need to be in cell B1 would be just "RE18019"
 
Upvote 0
Here's a formula solution:
=TRIM(LEFT(SUBSTITUTE(MID(A1,FIND("RE",A1&"RE"),255)," ",REPT(" ",255)),255))


Excel 2010
AB
1Blah, words SA 0.020.01 RE18019 blah 0 -0.01-0.02 Blah blah blahRE18019
Sheet1
Cell Formulas
RangeFormula
B1=TRIM(LEFT(SUBSTITUTE(MID(A1,FIND("RE",A1&"RE"),255)," ",REPT(" ",255)),255))
 
Upvote 0
Code:
Sub test()    
    With CreateObject("VBScript.RegExp")
        .Pattern = "RE[\d]+"
        For Each huc In Range("A1:A" & Cells(Rows.Count, 1).End(3).Row)
            If .test(huc) Then
                huc.Offset(, 1).Value = .Execute(huc.Value)(0)
            End If
        Next
    End With
End Sub
 
Upvote 0
Here's a formula solution:
=TRIM(LEFT(SUBSTITUTE(MID(A1,FIND("RE",A1&"RE"),255)," ",REPT(" ",255)),255))

Excel 2010
AB
1Blah, words SA 0.020.01 RE18019 blah 0 -0.01-0.02 Blah blah blahRE18019

<colgroup><col style="width: 25pxpx"><col><col></colgroup><thead>
</thead><tbody>
</tbody>
Sheet1

Worksheet Formulas
CellFormula
B1=TRIM(LEFT(SUBSTITUTE(MID(A1,FIND("RE",A1&"RE"),255)," ",REPT(" ",255)),255))

<thead>
</thead><tbody>
</tbody>

<tbody>
</tbody>
Thank you SO much!!! This is exactly what I needed!!
 
Upvote 0

Forum statistics

Threads
1,214,412
Messages
6,119,365
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