extract multiple values from text string

Cartesian

New Member
Joined
May 3, 2019
Messages
11
Hi,

Can you please help me pull out certain values from a text string?
I would like to use a formula and not code.

The string is very long and is a series of coordinates and is in cell A3 and is in the format below:
points:[{x:416.83624,y:379.13855,status:0},{x:415.50653,y:378.78394,status:2},{x:414.4428,y:379.13855,status:2},{x:413.02448,y:379.84772,status:2},{x:411.07425,y:380.7342,status:2} etc etc etc

I would like to create a 2 column table with the x & y coordinates in order they appear, i.e.
The formulas in each column will need to be dragged down potentially 10000 times to extract all coordinates from the cell.

[TABLE="class: grid, width: 200, align: center"]
<tbody>[TR]
[TD]X[/TD]
[TD]Y[/TD]
[/TR]
[TR]
[TD]416.8362[/TD]
[TD]379.13855[/TD]
[/TR]
[TR]
[TD]415.50653[/TD]
[TD]378.78394[/TD]
[/TR]
[TR]
[TD]414.4428[/TD]
[TD]379.13855[/TD]
[/TR]
[TR]
[TD]413.02448[/TD]
[TD]379.84772[/TD]
[/TR]
[TR]
[TD]411.07425[/TD]
[TD]380.7342[/TD]
[/TR]
</tbody>[/TABLE]

Note: the amount of decimals is not always the same. I am fine with it retrieving the first 3 decimals if that makes it easier (e.g. 416.836)

Thanks!
 

Excel Facts

Does the VLOOKUP table have to be sorted?
No! when you are using an exact match, the VLOOKUP table can be in any order. Best-selling items at the top is actually the best.
Hey, with the string in cell A3 and the X Y table being in A4 & B4 cells try these formulas in cells A5 & B5

A5:
MID(SUBSTITUTE(MID(SUBSTITUTE($A$3,",",REPT(",",LEN($A$3))),(3*ROW()-15)*LEN($A$3)+1,LEN($A$3)),",",""),4,100)
B5:
MID(SUBSTITUTE(MID(SUBSTITUTE($A$3,",",REPT(",",LEN($A$3))),(3*ROW()-14)*LEN($A$3)+1,LEN($A$3)),",",""),3,100)

Drag these down, note that A5 should show up as "nts:[{x:416.83624" but the rest of the rows should be correct, just manually change A5 afterwards to 416.83624! The Y column should be fine.
 
Upvote 0
Hi thanks for the quick reply!
Actually there is a whole bunch of other jargon in the text before these coordinates. Also some other text in the middle and at the end.
Every X has its corresponding Y.

Is there a way to reference "x:" and give the 7 characters following it, and same as "y:" ?
And then have it look up the 2nd set of coordinates, then third, etc?

=MID($A$3,SEARCH("x:",$A$3)+2, 7)
Like this, but then have it move to the next set afterwards.
 
Upvote 0
How about, for x
=MID($A$3,SEARCH("|",SUBSTITUTE($A$3,"x:","|",ROW(A1)))+2,8)
 
Upvote 0
Ahh okay that makes it more difficult then!

Are the coordinates the only characters that are within curly braces? If so then that can be used as some criteria. Tricky to see without the full string!
 
Upvote 0
Slight tweak to the formula in post#4 to convert the value to a number & also the formula for y
With the string in A3


Excel 2013/2016
AB
5416.836379.138
6415.506378.783
7414.442379.138
8413.024379.847
9411.074380.734
Database
Cell Formulas
RangeFormula
A5=MID($A$3,SEARCH("|",SUBSTITUTE($A$3,"x:","|",ROW(A1)))+2,7)*1
B5=MID($A$3,SEARCH("|",SUBSTITUTE($A$3,"y:","|",ROW(A1)))+2,7)*1
 
Last edited:
Upvote 0
Slight tweak to the formula in post#4 to convert the value to a number & also the formula for y
With the string in A3

Excel 2013/2016
AB

<colgroup><col style="width: 25pxpx"><col><col></colgroup><thead>
</thead><tbody>
[TD="align: center"]5[/TD]
[TD="align: right"]416.836[/TD]
[TD="align: right"]379.138[/TD]

[TD="align: center"]6[/TD]
[TD="align: right"]415.506[/TD]
[TD="align: right"]378.783[/TD]

[TD="align: center"]7[/TD]
[TD="align: right"]414.442[/TD]
[TD="align: right"]379.138[/TD]

[TD="align: center"]8[/TD]
[TD="align: right"]413.024[/TD]
[TD="align: right"]379.847[/TD]

[TD="align: center"]9[/TD]
[TD="align: right"]411.074[/TD]
[TD="align: right"]380.734[/TD]

</tbody>
Database

[TABLE="width: 85%"]
<tbody>[TR]
[TD]Worksheet Formulas[TABLE="width: 100%"]
<thead>[TR="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=DAE7F5]#DAE7F5[/URL] "]
[TH="width: 10px"]Cell[/TH]
[TH="align: left"]Formula[/TH]
[/TR]
</thead><tbody>[TR]
[TH="width: 10px, bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=DAE7F5]#DAE7F5[/URL] "]A5[/TH]
[TD="align: left"]=MID($A$3,SEARCH("|",SUBSTITUTE($A$3,"x:","|",ROW(A1)))+2,7)*1[/TD]
[/TR]
[TR]
[TH="width: 10px, bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=DAE7F5]#DAE7F5[/URL] "]B5[/TH]
[TD="align: left"]=MID($A$3,SEARCH("|",SUBSTITUTE($A$3,"y:","|",ROW(A1)))+2,7)*1[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[/TR]
</tbody>[/TABLE]

Heya Fluff, how would I go about returning every nth value instead of every one?
If I put a 'resolution' cell in the sheet i.e. 5
How can I get it to look up the first value, then every 5th value after?
Some kind of offset on the ROW?
 
Upvote 0
With the "Resolution" value in A4, how about
=MID($A$3,SEARCH("|",SUBSTITUTE($A$3,"x:","|",ROW(A1)*$A$4-$A$4+1))+2,7)*1
 
Upvote 0

Forum statistics

Threads
1,224,820
Messages
6,181,159
Members
453,021
Latest member
Justyna P

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