Extract single IP address from a string

IanPC

New Member
Joined
Jul 3, 2018
Messages
3
Hello - I have a spreadsheet of URLs, some of which contain IP addresses and some don't. I'm struggling to write an excel formula that will identify the URLs with IP addresses in them, and extract that IP address into another cell. What formula would I paste down column B to achieve this?


URL (column A)Desired output (column B)
http://sample.domain/the/eed/dhgg.html[#Error of some kind]
http://10.22.88.11/eid/tedld/ed.html10.22.88.11
http://242.25.23.7/ede/vkjd/tt.html242.25.23.7
etc

<tbody>
</tbody>

Any help gratefully received. Many thanks.
 
Are they really your expected results for IP addresses? :unsure:
For example:
3172.26.56.104
903172.16.106.29
000008239.240.0.182
 
Upvote 0

Excel Facts

Select a hidden cell
Somehide hide payroll data in column G? Press F5. Type G1. Enter. Look in formula bar while you arrow down through G.
I will make it simpler now.
Apologize for the confusion.

sourceFirst IPSecond IP
Gwinnett (3a)_VIPR 172.26.56.104172.26.56.104
Harmonic - 172.24.100.46 255.255.255.0172.24.100.46255.255.255.0
Imagine BMS 107.8.2.116107.8.2.116
Imagine Encoder – 50.113.193.10950.113.193.109
IMAGINE ENCODER - IMG-DLLATX-ENC04 - 24.174.45.21524.174.45.215
Imagine Encoder TWC-MW-05 107.8.3.109107.8.3.109
IMG_c7-01 (107.8.2.116)107.8.2.116
IN-PS9K_03 172.16.106.29 0.0.0.255172.16.106.290.0.0.255
IN-PS9K_05_SLDCMO 172.28.52.73172.28.52.73
ION Encoder 172.21.34.13172.21.34.13
ION-4 Encoder - 107.9.92.70107.9.92.70
IVMS 184.152.127.53184.152.127.53
IVMS 69.76.65.6769.76.65.67
 
Upvote 0
I will make it simpler now.
Apologize for the confusion.
Thanks, that is clearer. :)

I see that you have Excel 365 and am assuming that you have the new dynamic array functions (eg UNIQUE) that automatically 'spill' into required ranges. If that is so, this udf copied down a single column should produce the required results as the function in each row should spill any multiple IPs across that row.

VBA Code:
Function IPs(s As String) As Variant
  Dim itm As Variant
  Dim tmp As String
  
  IPs = ""
  With CreateObject("VBScript.RegExp")
    .Global = True
    .Pattern = "((\d{1,3}\.){2,3}\d{1,3})"
    For Each itm In .Execute(s)
      tmp = tmp & " " & itm
    Next itm
  End With
  If Len(tmp) > 0 Then IPs = Split(Mid(tmp, 2))
End Function

Is it correct that you want nothing returned in the second last row here?

billtadz.xlsm
ABCD
1sourceFirst IPSecond IP
2Gwinnett (3a)_VIPR 172.26.56.104172.26.56.104
3Harmonic - 172.24.100.46 255.255.255.0172.24.100.46255.255.255.0
4Imagine BMS 107.8.2.116107.8.2.116
5Imagine Encoder – 50.113.193.10950.113.193.109
6IMAGINE ENCODER - IMG-DLLATX-ENC04 - 24.174.45.21524.174.45.215
7Imagine Encoder TWC-MW-05 107.8.3.109107.8.3.109
8IMG_c7-01 (107.8.2.116)107.8.2.116
9 
10No IPs here 
11IN-PS9K_03 172.16.106.29 0.0.0.255172.16.106.290.0.0.255
12IN-PS9K_05_SLDCMO 172.28.52.73172.28.52.73
13ION Encoder 172.21.34.13172.21.34.13
14ION-4 Encoder - 107.9.92.70107.9.92.70
15IVMS 184.152.127.53184.152.127.53
16IVMS 69.76.65.6769.76.65.67
17IN-PS9K_03 172.16.106.29 0.0.0.255 ABC 125.125.125.125172.16.106.290.0.0.255125.125.125.125
18ION-4 Encoder - 46.9 
19ION-4 Encoder - 46.9.246.9.2
Sheet1
Cell Formulas
RangeFormula
B2,B4:B10,B12:B16,B18:B19,B17:D17,B11:C11,B3:C3B2=IPs(A2)
 
Upvote 0
Sorry, Im using 2016
OK, I see you have changed that in your profile now. :)

So, would you be looking for a user-defined function that gets copied down and across several columns or a straight macro that just populates the required cells?
 
Upvote 0
A straight macro is favourable.
Try this with a copy of your data.
VBA Code:
Sub Get_IPs()
  Dim RX As Object
  Dim a As Variant, b As Variant, itm As Variant
  Dim i As Long
  
  a = Range("A2", Range("A" & Rows.Count).End(xlUp)).Value
  ReDim b(1 To UBound(a), 1 To 1)
  Set RX = CreateObject("VBScript.RegExp")
  RX.Global = True
  RX.Pattern = "((\d{1,3}\.){2,3}\d{1,3})"
  For i = 1 To UBound(a)
    For Each itm In RX.Execute(a(i, 1))
      b(i, 1) = b(i, 1) & " " & itm
    Next itm
  Next i
  With Range("B2").Resize(UBound(b))
    .Value = b
    .TextToColumns DataType:=xlDelimited, Space:=True, Other:=False, FieldInfo:=Array(1, 9)
  End With
End Sub
 
Upvote 0

Forum statistics

Threads
1,215,043
Messages
6,122,816
Members
449,095
Latest member
m_smith_solihull

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