Extracting A Set Number Sequence From A String

Avg_Excel

New Member
Joined
Oct 20, 2018
Messages
1
Hi guys

I am trying to extract a set sequence of 12 numbers from various Ebay URL's.

Here are a few working examples:

https://www.ebay.com.au/itm/Flexibl...PsZfhjpPK35tiFmiaWAg:rk:2:pf:1&frcectupt=true

https://www.ebay.com.au/itm/20-50m-...J9ihREeAyL05NQTaMjkQ:rk:4:pf:1&frcectupt=true

https://www.ebay.com.au/itm/Greenfi...Water-Hose-Reel-Spray-Gun-Rewind/391918478456

The rule of thumb is that it is always a sequence of 12 numbers and there are no other sequences of 12 numbers in the URL's (although there are other irrelevant numbers in the strings as you will see above).

Could somebody please help me with a formula to pull just the 12 numbers out of each string?

Thank you
Will
 

Excel Facts

VLOOKUP to Left?
Use =VLOOKUP(A2,CHOOSE({1,2},$Z$1:$Z$99,$Y$1:$Y$99),2,False) to lookup Y values to left of Z values.
Here is a UDF that will do what you want...
Code:
Function Get12Digits(S As String) As String
  Dim x As Long
  For x = 1 To Len(S)
    If Mid(S, x, 12) Like "############" Then
      Get12Digits = Mid(S, x, 12)
      Exit Function
    End If
  Next
End Function

HOW TO INSTALL UDFs
------------------------------------
If you are new to UDFs, they are easy to install and use. To install it, simply press ALT+F11 to go into the VB editor and, once there, click Insert/Module on its menu bar, then copy/paste the above code into the code window that just opened up. That's it.... you are done. You can now use Get12Digits just like it was a built-in Excel function. For example,

=Get12Digits(A1)

If you are using XL2007 or above, make sure you save your file as an "Excel Macro-Enabled Workbook (*.xlsm) and answer the "do you want to enable macros" question as "yes" or "OK" (depending on the button label for your version of Excel) the next time you open your workbook
 
Upvote 0
Some comments, and another udf, that you could consider.

- You say that there are no other 12-digit numbers in the url. You don't say if it is possible that as well as the 12-digit number you want there could also be, say, a 15-digit number. If that is possible both Rick's udf and mine would need modification as they return the first sequence of 12 digits found.

- Both functions return the results as a string, not a number (so that any leading 0's are retained)

- My function returns (deliberately) an error if there is not a 12 digit number found (though I note you say that will not happen for you), including if the formula is copied down past a blank cell.

- In case you may want to use it elsewhere, my function allows for the searching for a group of digits other than 12 by using the optional 2nd argument. eg To search for a group of 14 digits =GetDigits(D2,14)

Code:
Function GetDigits(S As String, Optional Num As Long = 12) As String
  With CreateObject("VBScript.Regexp")
    .Pattern = "\d{" & Num & "}"
    GetDigits = .Execute(S)(0)
  End With
End Function
 
Upvote 0
- You say that there are no other 12-digit numbers in the url. You don't say if it is possible that as well as the 12-digit number you want there could also be, say, a 15-digit number. If that is possible both Rick's udf and mine would need modification as they return the first sequence of 12 digits found.

- My function returns (deliberately) an error if there is not a 12 digit number found (though I note you say that will not happen for you), including if the formula is copied down past a blank cell.

- In case you may want to use it elsewhere, my function allows for the searching for a group of digits other than 12 by using the optional 2nd argument. eg To search for a group of 14 digits =GetDigits(D2,14)
I modified my code to add the optional Num argument (defaulted to 12 but allowing search for a different number of digits if desired). I did not change it to error out if a number with the specified number of digits is not found... my personal preference is to return the empty text string if such a number cannot be found (one can always test for that need be and I think is looks "cleaner" overall). I also modified my code to only find numbers with the specified number of digits (assuming that such a number would be surrounded with non-digits in order to set if off from the rest of the text (this handles the case when, say, a 15-digit number appears before the requested 12-digit number).
Code:
[table="width: 500"]
[tr]
	[td]Function GetDigits(ByVal S As String, Optional Num As Long = 12) As String
  Dim x As Long
  S = " " & S & " "
  For x = 1 To Len(S)
    If Mid(S, x, Num + 2) Like "[!0-9]" & String(Num, "#") & "[!0-9]" Then
      GetDigits = Mid(S, x + 1, Num)
      Exit Function
    End If
  Next
End Function[/td]
[/tr]
[/table]
 
Upvote 0
I also modified my code to only find numbers with the specified number of digits (assuming that such a number would be surrounded with non-digits in order to set if off from the rest of the text (this handles the case when, say, a 15-digit number appears before the requested 12-digit number).
The equivalent modification for my code would be
Code:
Function GetDigits(S As String, Optional Num As Long = 12) As String
  With CreateObject("VBScript.Regexp")
    .Pattern = "(^|\D)(\d{" & Num & "})(\D|$)"
    GetDigits = .Execute(S)(0).SubMatches(1)
  End With
End Function
 
Upvote 0

Forum statistics

Threads
1,223,888
Messages
6,175,213
Members
452,618
Latest member
Tam84

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