cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Frequent Visitor

Converting JSON data into PowerBI table

Hello,

 

I got some data from IOT table storage including a column with JSON data, as below.

 

1.PNG

 

I want to extract the data of the fourth column and started with expanding the content and then parsed JSON.

 

2.PNG3.PNG

 

What I got is, as you can see, a column of lists. I can now add every single list as a new query and get the format (visuable data) I want:

 

4.PNG

 

However, my goal is to convert the whole column of lists at once as it is pretty time consuming to extract the values row by row

(by adding the lists as new queries and finally appending the aggregated queries to a new table).

 

5.PNG

 

My question: is there any simple step/code (advanced editor) I do not know, because I will have to deal with a lot more rows as only 18 in this example.

 

Any help will be highly appreciated, 

best regards,

Till

1 ACCEPTED SOLUTION
Microsoft
Microsoft

Hi @tilldunk,

I try to test bu getting date from a json file. I import the data and right click the record column->To table as follows.

1.PNG

Then click expanded columns, get the list column, then click "Expand to New Rows"-> expanded column, I get expected result.

3.png

Here is my Query statement.

let
    Source = Json.Document(File.Contents("C:\Users\v-huizhn\Downloads\generated.json")),
    #"Converted to Table" = Table.FromList(Source, Splitter.SplitByNothing(), null, null, ExtraValues.Error),
    #"Expanded Column1" = Table.ExpandRecordColumn(#"Converted to Table", "Column1", {"UserId", "id", "tipSecurableSet"}, {"Column1.UserId", "Column1.id", "Column1.tipSecurableSet"}),
    #"Expanded Column1.tipSecurableSet" = Table.ExpandRecordColumn(#"Expanded Column1", "Column1.tipSecurableSet", {"id", "Clients"}, {"Column1.tipSecurableSet.id", "Column1.tipSecurableSet.Clients"}),
    #"Expanded Column1.tipSecurableSet.Clients" = Table.ExpandListColumn(#"Expanded Column1.tipSecurableSet", "Column1.tipSecurableSet.Clients"),
    #"Expanded Column1.tipSecurableSet.Clients1" = Table.ExpandRecordColumn(#"Expanded Column1.tipSecurableSet.Clients", "Column1.tipSecurableSet.Clients", {"@odata.type", "typeId", "Entityids", "Clientid"}, {"Column1.tipSecurableSet.Clients.@odata.type", "Column1.tipSecurableSet.Clients.typeId", "Column1.tipSecurableSet.Clients.Entityids", "Column1.tipSecurableSet.Clients.Clientid"})
in
    #"Expanded Column1.tipSecurableSet.Clients1"


For your scenario, I can't reproduce it. Do you mind share the sample table for further analysis?

Best Regards,
Angelia

View solution in original post

6 REPLIES 6
Frequent Visitor

Hello!!!
Only 7 Steps for GET JSON:
let
Source = SharePoint.Files("https://Mysharepoint", [ApiVersion = 15]),
Step01 = Table.SelectRows(Source, each Text.StartsWith([Folder Path], "https://Mysharepoint_SearchFolder/")),
Step02 = Table.SelectColumns(Step01, {"Content", "Name", "Extension", "Folder Path"}),
Step03 = Table.SelectRows(Step02, each [Extension] = ".json"),
Step04 = Table.SelectColumns(Step03, {"Content"}),
Step05 = Table.AddColumn(Step04, "Json", each Json.Document([Content], 65001)),
Step06 = Table.SelectColumns(Step05, {"Json"}),
Step07 = Table.ExpandListColumn(Step06, "Json")
in
Step07

Microsoft
Microsoft

Hi @tilldunk,

I try to test bu getting date from a json file. I import the data and right click the record column->To table as follows.

1.PNG

Then click expanded columns, get the list column, then click "Expand to New Rows"-> expanded column, I get expected result.

3.png

Here is my Query statement.

let
    Source = Json.Document(File.Contents("C:\Users\v-huizhn\Downloads\generated.json")),
    #"Converted to Table" = Table.FromList(Source, Splitter.SplitByNothing(), null, null, ExtraValues.Error),
    #"Expanded Column1" = Table.ExpandRecordColumn(#"Converted to Table", "Column1", {"UserId", "id", "tipSecurableSet"}, {"Column1.UserId", "Column1.id", "Column1.tipSecurableSet"}),
    #"Expanded Column1.tipSecurableSet" = Table.ExpandRecordColumn(#"Expanded Column1", "Column1.tipSecurableSet", {"id", "Clients"}, {"Column1.tipSecurableSet.id", "Column1.tipSecurableSet.Clients"}),
    #"Expanded Column1.tipSecurableSet.Clients" = Table.ExpandListColumn(#"Expanded Column1.tipSecurableSet", "Column1.tipSecurableSet.Clients"),
    #"Expanded Column1.tipSecurableSet.Clients1" = Table.ExpandRecordColumn(#"Expanded Column1.tipSecurableSet.Clients", "Column1.tipSecurableSet.Clients", {"@odata.type", "typeId", "Entityids", "Clientid"}, {"Column1.tipSecurableSet.Clients.@odata.type", "Column1.tipSecurableSet.Clients.typeId", "Column1.tipSecurableSet.Clients.Entityids", "Column1.tipSecurableSet.Clients.Clientid"})
in
    #"Expanded Column1.tipSecurableSet.Clients1"


For your scenario, I can't reproduce it. Do you mind share the sample table for further analysis?

Best Regards,
Angelia

View solution in original post

Super User II
Super User II

Hi Till,

did you try to click on the expand-buttons?:

 

PBI_ExpandJsron2.jpg

 

Imke Feldmann (The BIccountant)

If you liked my solution, please give it a thumbs up. And if I did answer your question, please mark this post as a solution. Thanks!

How to integrate M-code into your solution -- How to get your questions answered quickly -- How to provide sample data -- Check out more PBI- learning resources here -- Performance Tipps for M-queries

Yes, I did. It will give me this table:

 

6.PNG

Well, I got my fault. There is this "Test message" row which is  messing everything up. Deleted the row, expanded the column and got my wanted results. 

Thanks a lot for your help, Till

Oh, I see: Normally you would see another pair of expand-arrows (if all rows would have the record in them).

This is the workaround: http://www.thebiccountant.com/2017/07/25/how-to-expand-a-column-that-cannot-be-expanded-in-power-bi-...

 

Imke Feldmann (The BIccountant)

If you liked my solution, please give it a thumbs up. And if I did answer your question, please mark this post as a solution. Thanks!

How to integrate M-code into your solution -- How to get your questions answered quickly -- How to provide sample data -- Check out more PBI- learning resources here -- Performance Tipps for M-queries

Helpful resources

Announcements
secondImage

Happy New Year from Power BI

This is a must watch for a message from Power BI!

December Update

Check it Out!

Click here to read more about the December 2020 Updates!

Community Blog

Check it Out!

Click here to read the latest blog and learn more about contributing to the Power BI blog!

Get Ready for Power BI Dev Camp

Get Ready for Power BI Dev Camp

Mark your calendars and join us for our next Power BI Dev Camp!.

Top Solution Authors
Top Kudoed Authors