Manipulate data in single cell

77winston

New Member
Joined
Sep 11, 2013
Messages
31
Office Version
  1. 2013
Platform
  1. Windows
Hi, Hope someone can assist with this query.

I have an excel sheet with one cell that contains a long string of data. What I need to do is to extract certain values from that string and build a table of data.
The data i want to extract is wrapped in curly brackets. I only want to extract the last value of the string from each of the data wrapped in curly bracktes.

Below is samole data in Column A, rows 2,3 & 4
a:9:{i:0;a:2:{s:3:"key";s:9:"lead-form";s:5:"value";s:4:"2028";}i:1;a:2:{s:3:"key";s:10:"first-name";s:5:"value";s:3:"Mal";}i:2;a:2:{s:3:"key";s:9:"last-name";s:5:"value";s:7:"Spencer";}i:3;a:2:{s:3:"key";s:5:"email";s:5:"value";s:23:"test@gmail.com";}i:4;a:2:{s:3:"key";s:5:"phone";s:5:"value";s:10:"040000000";}i:5;a:2:{s:3:"key";s:5:"state";s:5:"value";s:8:"Victoria";}i:6;a:2:{s:3:"key";s:9:"post-code";s:5:"value";s:4:"3170";}i:7;a:2:{s:3:"key";s:4:"type";s:5:"value";s:11:"Residential";}i:8;a:2:{s:3:"key";s:7:"message";s:5:"value";s:203:"I am interested in purchasing half a dozen solar powered LED spot lights around my homes external walls. Please let me know what my options are and the cost range as I have someone who can install them.";}}
a:8:{i:0;a:2:{s:3:"key";s:9:"lead-form";s:5:"value";s:4:"2026";}i:1;a:2:{s:3:"key";s:10:"first-name";s:5:"value";s:5:"Rafia";}i:2;a:2:{s:3:"key";s:9:"last-name";s:5:"value";s:6:"Sarwar";}i:3;a:2:{s:3:"key";s:5:"email";s:5:"value";s:22:"test975@gmail.com";}i:4;a:2:{s:3:"key";s:5:"phone";s:5:"value";s:10:"3092929499";}i:5;a:2:{s:3:"key";s:5:"state";s:5:"value";s:3:"NSW";}i:6;a:2:{s:3:"key";s:4:"type";s:5:"value";s:11:"Residential";}i:7;a:2:{s:3:"key";s:7:"message";s:5:"value";s:1:"0";}}
a:13:{i:0;a:2:{s:3:"key";s:9:"lead-form";s:5:"value";s:4:"2030";}i:1;a:2:{s:3:"key";s:10:"first-name";s:5:"value";s:4:"Greg";}i:2;a:2:{s:3:"key";s:9:"last-name";s:5:"value";s:7:"Bristow";}i:3;a:2:{s:3:"key";s:5:"email";s:5:"value";s:21:"test123@gmail.com";}i:4;a:2:{s:3:"key";s:5:"phone";s:5:"value";s:10:"0400830017";}i:5;a:2:{s:3:"key";s:7:"address";s:5:"value";s:4:"3090";}i:6;a:2:{s:3:"key";s:10:"downlights";s:5:"value";s:2:"86";}i:7;a:2:{s:3:"key";s:9:"cfl-bulbs";s:5:"value";s:2:"12";}i:8;a:2:{s:3:"key";s:6:"a-bulb";s:5:"value";s:2:"12";}i:9;a:2:{s:3:"key";s:9:"reflector";s:5:"value";s:1:"0";}i:10;a:2:{s:3:"key";s:12:"candle-globe";s:5:"value";s:1:"6";}i:11;a:2:{s:3:"key";s:9:"best-time";s:5:"value";s:7:"Evening";}i:12;a:2:{s:3:"key";s:7:"how-did";s:5:"value";s:13:"Search Engine";}}

Expected Output
Based on row 2
Lead-FormFirst-namelast-nameemailphonestatepost codetypemessage
2028​
MalSpencertest@gmail.com
040000000​
victoria
3170​
ResidentialI am interested in purchasing half a dozen solar powered LED spot lights around my homes external walls. Please let me know what my options are and the cost range as I have someone who can install them.

Can this be achived easily?

Thanking you in advace.
 

Excel Facts

Add Bullets to Range
Select range. Press Ctrl+1. On Number tab, choose Custom. Type Alt+7 then space then @ sign (using 7 on numeric keypad)
Yes. However, the samples have differing fields. You will need to map every possible field or simply leave the cells blank. What I mean by mapping is creating a relationship between one or more fields in your data to one field in your table.

JSON:
lead-form
first-name
last-name
email
phone
state
post-code
type
message
-----------------------------------------------------------
lead-form
first-name
last-name
email
phone
state
type
message
-----------------------------------------------------------
lead-form
first-name
last-name
email
phone
address
downlights
cfl-bulbs
a-bulb
reflector
candle-globe
best-time
how-did
 
Last edited by a moderator:
Upvote 0
See if this is any use, copied across and down.

77winston 1.xlsm
ABCDEFGHIJ
1Lead-FormFirst-namelast-nameemailphonestatepost-codetypemessage
2a:9:{i:0;a:2:{s:3:"key";s:9:"lead-form";s:5:"value";s:4:"2028";}i:1;a:2:{s:3:"key";s:10:"first-name";s:5:"value";s:3:"Mal";}i:2;a:2:{s:3:"key";s:9:"last-name";s:5:"value";s:7:"Spencer";}i:3;a:2:{s:3:"key";s:5:"email";s:5:"value";s:23:"test@gmail.com";}i:4;a:2:{s:3:"key";s:5:"phone";s:5:"value";s:10:"040000000";}i:5;a:2:{s:3:"key";s:5:"state";s:5:"value";s:8:"Victoria";}i:6;a:2:{s:3:"key";s:9:"post-code";s:5:"value";s:4:"3170";}i:7;a:2:{s:3:"key";s:4:"type";s:5:"value";s:11:"Residential";}i:8;a:2:{s:3:"key";s:7:"message";s:5:"value";s:203:"I am interested in purchasing half a dozen solar powered LED spot lights around my homes external walls. Please let me know what my options are and the cost range as I have someone who can install them.";}}2028MalSpencertest@gmail.com040000000Victoria3170ResidentialI am interested in purchasing half a dozen solar powered LED spot lights around my homes external walls. Please let me know what my options are and the cost range as I have someone who can install them.
3a:8:{i:0;a:2:{s:3:"key";s:9:"lead-form";s:5:"value";s:4:"2026";}i:1;a:2:{s:3:"key";s:10:"first-name";s:5:"value";s:5:"Rafia";}i:2;a:2:{s:3:"key";s:9:"last-name";s:5:"value";s:6:"Sarwar";}i:3;a:2:{s:3:"key";s:5:"email";s:5:"value";s:22:"test975@gmail.com";}i:4;a:2:{s:3:"key";s:5:"phone";s:5:"value";s:10:"3092929499";}i:5;a:2:{s:3:"key";s:5:"state";s:5:"value";s:3:"NSW";}i:6;a:2:{s:3:"key";s:4:"type";s:5:"value";s:11:"Residential";}i:7;a:2:{s:3:"key";s:7:"message";s:5:"value";s:1:"0";}}2026RafiaSarwartest975@gmail.com3092929499NSWN/AResidential0
4a:13:{i:0;a:2:{s:3:"key";s:9:"lead-form";s:5:"value";s:4:"2030";}i:1;a:2:{s:3:"key";s:10:"first-name";s:5:"value";s:4:"Greg";}i:2;a:2:{s:3:"key";s:9:"last-name";s:5:"value";s:7:"Bristow";}i:3;a:2:{s:3:"key";s:5:"email";s:5:"value";s:21:"test123@gmail.com";}i:4;a:2:{s:3:"key";s:5:"phone";s:5:"value";s:10:"0400830017";}i:5;a:2:{s:3:"key";s:7:"address";s:5:"value";s:4:"3090";}i:6;a:2:{s:3:"key";s:10:"downlights";s:5:"value";s:2:"86";}i:7;a:2:{s:3:"key";s:9:"cfl-bulbs";s:5:"value";s:2:"12";}i:8;a:2:{s:3:"key";s:6:"a-bulb";s:5:"value";s:2:"12";}i:9;a:2:{s:3:"key";s:9:"reflector";s:5:"value";s:1:"0";}i:10;a:2:{s:3:"key";s:12:"candle-globe";s:5:"value";s:1:"6";}i:11;a:2:{s:3:"key";s:9:"best-time";s:5:"value";s:7:"Evening";}i:12;a:2:{s:3:"key";s:7:"how-did";s:5:"value";s:13:"Search Engine";}}2030GregBristowtest123@gmail.com0400830017N/AN/AN/AN/A
Sheet1
Cell Formulas
RangeFormula
B2:J4B2=IFERROR(TRIM(LEFT(RIGHT(SUBSTITUTE(REPLACE(LEFT($A2,FIND("}",$A2,SEARCH(B$1,$A2))),1,SEARCH(B$1,$A2),""),"""",REPT(" ",1000)),2000),1000)),"N/A")
 
Upvote 0

Forum statistics

Threads
1,213,527
Messages
6,114,148
Members
448,552
Latest member
WORKINGWITHNOLEADER

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