Having trouble executing text to columns on JSON

yits05

Board Regular
Joined
Jul 17, 2020
Messages
56
Office Version
  1. 2016
Platform
  1. Windows
have some VBA code which returns some JSON from an API into a single cell. I would like to be able to run text to columns so that I can split up the JSON into individual columns based on a delimiter, but when I try to do so, all the JSON disappears and just leaves the opening "{".

1613065652710.png


Example of JSON:

JSON:
"{
 ""status"": 200,
 ""likelihood"": 10,
 ""data"": {
 ""id"": ""abcdefg"",
 ""full_name"": ""david smith"",
}"

And I would like it to appear, using the "," as a delimiter:


"status": 200"likelihood": 10"data": {
"id": "abcdefg"

Thanks for the help
 

Excel Facts

How to change case of text in Excel?
Use =UPPER() for upper case, =LOWER() for lower case, and =PROPER() for proper case. PROPER won't capitalize second c in Mccartney
You can use Power Query to Parse JSON.

Book1
EFGHIJKLMNO
17Column1coaddress1address2citycityStatusstatezipStatuszip
18{ "addresses": [ { "co" : "", "address1" : "1231 W 38TH AVE", "address2" : "", "city" : "DENVER", "cityStatus" : "", "state" : "CO", "zipStatus" : "S", "zip" : "80211-2612" }]} 1231 W 38TH AVEDENVERCOS80211-2612
Sheet6


Power Query:
let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    JSON = Table.TransformColumns(Source,{{"Column1", each Json.Document(_)}}),
    ExpandRecord = Table.ExpandRecordColumn(JSON, "Column1", {"addresses"}, {"addresses"}),
    ExpandList = Table.ExpandListColumn(ExpandRecord, "addresses"),
    Extract = Table.ExpandRecordColumn(ExpandList, "addresses", {"co", "address1", "address2", "city", "cityStatus", "state", "zipStatus", "zip"}, {"co", "address1", "address2", "city", "cityStatus", "state", "zipStatus", "zip"})
in
    Extract
 
Upvote 0

Forum statistics

Threads
1,213,551
Messages
6,114,266
Members
448,558
Latest member
aivin

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