Yet another Regexp qustion

SReopelle

New Member
Joined
Aug 9, 2018
Messages
5
I've seen the post to find (6 consecutive numbers adjacent to each other in the string) with the solution being:

=LOOKUP(10^6,MID(A1,ROW(INDIRECT("1:"&LEN(A1)-5)),6)+0)

I am trying to find the first 3 digits in a string like this:

text 777 moretext 555.

When I apply the solution above and modify the last section to find 3 digits, it finds the "555". I can't make heads or tails of the expression so I cant' figure out how to modify it to find the first 3 digits.

Can anyone help me with this please?

 

Excel Facts

How to show all formulas in Excel?
Press Ctrl+` to show all formulas. Press it again to toggle back to numbers. The grave accent is often under the tilde on US keyboards.
Assuming your string is in A1 and that the number you want to extract always follows the first space in the string as in your example, in any empty cell enter:
Code:
=TRIM(MID(SUBSTITUTE(A1," ",REPT(" ",100)),100,100))+0
 
Last edited:
Upvote 0
Are the first 3 digits always immediately next to each other? If so, give this a try...

=MID(A1,MIN(FIND({0,1,2,3,4,5,6,7,8,9},A1&"0123456789")),3)
 
Upvote 0
Thanks Rick, you nailed it. The data is not uniform, and in some cases there is a 3 digit number, somethings there are two 3 digit numbers. I just needed the first one. Can the find be modified to find ONLY 3 digit numbers?
 
Upvote 0
Can the find be modified to find ONLY 3 digit numbers?
Since you asked about RegExp, here is a UDF that I think does what you want. Note that by default it searches for exactly 3 digits, but the optional 2nd argument allows you to search for a different number of digits if you want, as shown in C6 below.

Code:
Function FirstN(s As String, Optional Num As Long = 3) As Variant
  Static RX As Object
  
  If RX Is Nothing Then Set RX = CreateObject("VBScript.RegExp")
  RX.Pattern = "(^|\D)(\d{" & Num & "})(\D|$)"
  FirstN = ""
  If RX.Test(s) Then FirstN = Val(RX.Execute(s)(0).SubMatches(1))
End Function

Excel Workbook
ABC
1text 777 moretext 555777
2text 34 das 765das 654765
3365 crde365
4ewtet 55
5
6q 12 wer 3456 te 540 er5403456
7abc 900900
Sheet2
 
Upvote 0
Does this statement mean there could be numbers of more and/or less than 3 digits occurring before a 3 digit number?


In the data, the first set of numbers is 3 digits.

Some added background. I have an application using a regexp, that is searching for 3 digits to identify a location code. If the first 3 digits are incorrect, or do not exist, I am passing the info along so it can be corrected.

There are some fields that are populated like : text 20, what you sent me worked to pull the digits out, I manually scanned the returns to find anomalies and highlight them. At this point, I'm just curious to see how it all works.
 
Upvote 0
Since you asked about RegExp, here is a UDF that I think does what you want. Note that by default it searches for exactly 3 digits, but the optional 2nd argument allows you to search for a different number of digits if you want, as shown in C6 below.

Code:
Function FirstN(s As String, Optional Num As Long = 3) As Variant
  Static RX As Object
  
  If RX Is Nothing Then Set RX = CreateObject("VBScript.RegExp")
  RX.Pattern = "(^|\D)(\d{" & Num & "})(\D|$)"
  FirstN = ""
  If RX.Test(s) Then FirstN = Val(RX.Execute(s)(0).SubMatches(1))
End Function

Sheet2

ABC
text 777 moretext 555
text 34 das 765das 654
365 crde
ewtet 55
q 12 wer 3456 te 540 er
abc 900

<colgroup><col style="font-weight:bold; width:30px; "><col style="width:172px;"><col style="width:53px;"><col style="width:56px;"></colgroup><tbody>
[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=cacaca]#cacaca[/URL] , align: center"]1[/TD]

[TD="align: right"]777[/TD]

[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=cacaca]#cacaca[/URL] , align: center"]2[/TD]

[TD="align: right"]765[/TD]

[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=cacaca]#cacaca[/URL] , align: center"]3[/TD]

[TD="align: right"]365[/TD]

[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=cacaca]#cacaca[/URL] , align: center"]4[/TD]

[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=cacaca]#cacaca[/URL] , align: center"]5[/TD]

[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=cacaca]#cacaca[/URL] , align: center"]6[/TD]

[TD="align: right"]540[/TD]
[TD="align: right"]3456[/TD]

[TD="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=cacaca]#cacaca[/URL] , align: center"]7[/TD]

[TD="align: right"]900[/TD]

</tbody>

Spreadsheet Formulas
CellFormula
B1=FirstN(A1)
C6=FirstN(A6,4)

<tbody>
</tbody>

<tbody>
</tbody>

Thanks so much Peter,
I'm sure this will work dandy, except that I don't know how to enter the VB code into the spreadsheet. :eeek:
 
Upvote 0
Thanks so much Peter,
I'm sure this will work dandy, except that I don't know how to enter the VB code into the spreadsheet. :eeek:
Sorry, since you had mentioned Regexp, I assumed you had used this sort of code before. :)

To implement ..
1. Right click the sheet name tab and choose "View Code".
2. In the Visual Basic window use the menu to Insert|Module
3. Copy and Paste the code into the main right hand pane that opens at step 2.
4. Close the Visual Basic window.
5. Enter the formula as shown in the screen shot and copy down.
6. Your workbook will need to be saved as a macro-enabled workbook (*.xlsm)

BTW, best not to fully quote long posts as it makes the thread harder to read/navigate. If you want to quote, quote small, relevant parts only.
 
Upvote 0
I know you asked for a RegExp function (Peter gave you that in Message #6 ), but I thought you might be interested in seeing a non-RegExp solution (same instructions for use as Peter posted in Message #9 , note I changed the name of the function from his though)...
Code:
Function FirstNNN(s As String) As Variant
  Dim X As Long
  For X = 1 To Len(s) - 2
    If Mid(" " & s & " ", X, 5) Like "[!0-9]###[!0-9]" Then
      FirstNNN = CLng(Mid(s, X, 3))
      Exit Function
    End If
  Next
  FirstNNN = ""
End Function
 
Upvote 0

Forum statistics

Threads
1,223,227
Messages
6,170,849
Members
452,361
Latest member
d3ad3y3

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