Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Get Fabric Certified for FREE during Fabric Data Days. Don't miss your chance! Learn more

Reply
Anonymous
Not applicable

Excel power query - Tranform JSON data correctly

I have the issue that I do not know how to transform the data correctly to get it in a table. The data is coming from an API in JSON. I can transform the data into a table, but I get for each name a column.

 

What I did:

 

First I have the records in a column

 
 

1.png

Then I expand it into a table. Thats okay so far. I tried to group then the data, but that lead to the issue that I got the number 2 in the value column for each entry, instead of the acutal data.2.png

So I tried to tranform the the data:

 

3.png

Switched lines with columns,

4.png

The first line is the descripiton.

Unfortunately, Power Query does not recognize that the data in the same named columns should go into that.

 

I expect to have a result like this in Power Query:

5.png

How can I do this?

1 ACCEPTED SOLUTION
Anonymous
Not applicable

in this way (almost) all done by GUI

 

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSUUpUitWJVjICspLALGMgKxnMMgGyUsAsQySFSCqRlELVxgIA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [value = _t, name = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"value", Int64.Type}, {"name", type text}}),
    grp = Table.Group(#"Changed Type", {"name"}, {{"grp", each _[value]}}),
    #"Extracted Values" = Table.TransformColumns(grp, {"grp", each Text.Combine(List.Transform(_, Text.From), ","), type text}),
    #"Split Column by Delimiter" = Table.SplitColumn(#"Extracted Values", "grp", Splitter.SplitTextByDelimiter(",", QuoteStyle.Csv), {"grp.1", "grp.2"}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Split Column by Delimiter",{{"grp.1", Int64.Type}, {"grp.2", Int64.Type}}),
    #"Transposed Table" = Table.Transpose(#"Changed Type1"),
    #"Promoted Headers" = Table.PromoteHeaders(#"Transposed Table", [PromoteAllScalars=true]),
    #"Changed Type2" = Table.TransformColumnTypes(#"Promoted Headers",{{"a", Int64.Type}, {"b", Int64.Type}, {"c", Int64.Type}, {"d", Int64.Type}})
in
    #"Changed Type2"

 

 

 

View solution in original post

4 REPLIES 4
Icey
Community Support
Community Support

Hi @Anonymous ,

 

Is this problem solved?

 

If it is solved, please always accept the replies making sense as solution to your question so that people who may have the same question can get the solution directly.

 

If not, please let me know.

 

 

Best Regards,

Icey

Anonymous
Not applicable

try this scheme:

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSUUpUitWJVjICspLALGMgKxnMMgGyUsAsQySFSCqRlELVxgIA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [value = _t, name = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"value", Int64.Type}, {"name", type text}}),
    grp = Table.Group(#"Changed Type", {"name"}, {{"grp", each _[value]}}),
    tfc=Table.FromColumns(grp[grp],grp[name])
in
    tfc

 

if you have problem to adapt the code, post your table in a way that is easy to copy and some one will do it for you.

 

Anonymous
Not applicable

in this way (almost) all done by GUI

 

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSUUpUitWJVjICspLALGMgKxnMMgGyUsAsQySFSCqRlELVxgIA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [value = _t, name = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"value", Int64.Type}, {"name", type text}}),
    grp = Table.Group(#"Changed Type", {"name"}, {{"grp", each _[value]}}),
    #"Extracted Values" = Table.TransformColumns(grp, {"grp", each Text.Combine(List.Transform(_, Text.From), ","), type text}),
    #"Split Column by Delimiter" = Table.SplitColumn(#"Extracted Values", "grp", Splitter.SplitTextByDelimiter(",", QuoteStyle.Csv), {"grp.1", "grp.2"}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Split Column by Delimiter",{{"grp.1", Int64.Type}, {"grp.2", Int64.Type}}),
    #"Transposed Table" = Table.Transpose(#"Changed Type1"),
    #"Promoted Headers" = Table.PromoteHeaders(#"Transposed Table", [PromoteAllScalars=true]),
    #"Changed Type2" = Table.TransformColumnTypes(#"Promoted Headers",{{"a", Int64.Type}, {"b", Int64.Type}, {"c", Int64.Type}, {"d", Int64.Type}})
in
    #"Changed Type2"

 

 

 

Jimmy801
Community Champion
Community Champion

Hello @Anonymous 

 

try to add a new step after your step of ExpandedList (first screenshot) like this:

Table.FromRecords(YourStepOfExpandedList[Column1) 

 

Hope it helps

 

Jimmy

Helpful resources

Announcements
Fabric Data Days Carousel

Fabric Data Days

Advance your Data & AI career with 50 days of live learning, contests, hands-on challenges, study groups & certifications and more!

October Power BI Update Carousel

Power BI Monthly Update - October 2025

Check out the October 2025 Power BI update to learn about new features.

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.