return text after 2nd occurrence of an equal sign (=)

andymalan

Board Regular
Joined
Feb 22, 2017
Messages
128
Office Version
  1. 365
  2. 2007
Platform
  1. Windows
Hello
i have to extract numbers from a string in Col G (varying rows) the data looks like this

Width = 760, Depth = 350
Width = 1610, Height = 50, Depth = 16
Width = 1610, Depth = 350

my formula in col H

<colgroup><col></colgroup><tbody>
</tbody>

<colgroup><col></colgroup><tbody>
</tbody>

MID(LEFT(G80,FIND(",",G80)-1),FIND("=",G80)+1,LEN(G80)) returns the first part i.e. 760; 1610; 1610

what formula can I use to return (in Col I) the second occurrence i.e. 350; 50; 350

your help will really be appreciated.
 

Excel Facts

Copy a format multiple times
Select a formatted range. Double-click the Format Painter (left side of Home tab). You can paste formatting multiple times. Esc to stop
I put the various numbers in H through Nth column (n = however many numbers are in the string(s) in G)

Code:
Sub ExtractNums()
Dim strg() As String, i As Integer, j As Integer, w As Long, k As Long, LR As Long
LR = Cells(Rows.Count, "G").End(xlUp).Row
For i = 1 To LR
k = 8
strg = Split(Range("G" & i), ",")
 For j = 0 To UBound(strg)
 w = WorksheetFunction.Find("=", strg(j))
 Cells(i, k) = 1 * Right(strg(j), Len(strg(j)) - w)
 k = k + 1
 Next j
Next i
End Sub
 
Last edited:
Upvote 0
With a formula.
Excel Workbook
GHI
1Width = 760, Depth = 350350
2Width = 1610, Height = 50, Depth = 1650
3Width = 1610, Depth = 350350
Sheet
 
Upvote 0
Hi,

If, according to your description, you don't care for the Order of the data (i.e. Width, Depth, Height), you Just want the 1st, 2nd, and 3rd numeric values extracted, use this in Column H, copied down and across to Column J, results are converted to Real numbers:


Book1
GHIJ
1Width = 760, Depth = 350760350
2Width = 1610, Height = 50, Depth = 1616105016
3Width = 1610, Depth = 3501610350
Sheet702
Cell Formulas
RangeFormula
H1=IFERROR(MID(SUBSTITUTE(SUBSTITUTE($G1,"=",REPT(" ",100)),",",REPT(" ",100)),(COLUMNS($H1:H1)*2-1)*100,100)+0,"")


PS, formula can be copied across to as many Columns as you need if there are more than 3 numbers in the original text string.
 
Last edited:
Upvote 0
With your example of Cell G80

Column H:
=VALUE(MID(LEFT(G80,FIND(",",G80)-1),FIND("=",G80)+1,LEN(G80)))

Column I:
=VALUE(MID(G80,FIND("=",SUBSTITUTE(G80,"="," ",1))+1,LEN(G80)))
 
Upvote 0
Another way

<table border="1" cellspacing="0" style="font-family:Calibri,Arial; font-size:11pt; background-color:#ffffff; "> <colgroup><col style="font-weight:bold; width:30px; " /><col style="width:225.27px;" /><col style="width:155.88px;" /></colgroup><tr style="background-color:#cacaca; text-align:center; font-weight:bold; font-size:8pt; "><td > </td><td >G</td><td >H</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >1</td><td >Width = 760, Depth = 350</td><td style="text-align:right; ">350</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >2</td><td >Width = 1610, Height = 50, Depth = 16</td><td style="text-align:right; ">50</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >3</td><td >Width = 1610, Depth = 350</td><td style="text-align:right; ">350</td></tr></table><br /><table style="font-family:Arial; font-size:10pt; border-style: groove ;border-color:#00ff00;background-color:#fffcf9; color:#000000; "><tr><td ><b></b></td></tr><tr><td ><table border = "1" cellspacing="0" cellpadding="2" style="font-family:Arial; font-size:9pt;"><tr style="background-color:#cacaca; font-size:10pt;"><td ></td><td ></td></tr><tr><td >H1</td><td >=MID(SUBSTITUTE(SUBSTITUTE(G1,",",REPT(" ",99),2),"=",REPT(" ",99),2),99,50)+0</td></tr></table></td></tr></table>
 
Upvote 0

Forum statistics

Threads
1,213,515
Messages
6,114,080
Members
448,548
Latest member
harryls

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