March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early bird discount ends December 31.
Register NowBe one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now
Hello,
Problem Statement:
We have this JSON file that comes from an external vendor that generates these files where we would like to convert MOST of the data fields to Excel columns and then leave the last column have the remaining json content.
The format of the JSON file looks something like this:
[
{
"field1": "blah 1",
"field2": "blah 2",
...(etc)...
"rules": [
{
"anotherfield1": "blah 3",
"anotherfield2": "blah 4",
...(etc)...
"Pattern": {
"a": "blah 5",
"b": "blah 6",
...(etc)...
}
},
{
"anotherfield1": "blah 7",
"anotherfield2": "blah 8",
...(etc)...
"Pattern": {
"a": "blah 9,
"b": "blah 10"
...(etc)...
}
}
]
},
...(etc)...
]
Essentially I know how to convert "field1" and "field2" into separate columns using POWER Query, but what I would like to do is for "rules", put the content of everything under it into a single cell as part of that row. So, the output would look something like this for a single row in Excel:
field1 | field2 | rules
-----------------------------------
blah 1 | blah 2 | <json data in pretty (not single line) format>
My experience:
I'm fairly new to the Power Query capabilities within Excel and doing various searches I see all kinds of blog/video examples for parsing ALL of the JSON data into columns, but not my scenario.
Solved! Go to Solution.
let
Source = Json.Document("
[
{
""field1"": ""blah 1"",
""field2"": ""blah 2"",
""rules"": [
{
""anotherfield1"": ""blah 3"",
""anotherfield2"": ""blah 4"",
""Pattern"": {
""a"": ""blah 5"",
""b"": ""blah 6""
}
},
{
""anotherfield1"": ""blah 7"",
""anotherfield2"": ""blah 8"",
""Pattern"": {
""a"": ""blah 9"",
""b"": ""blah 10""
}
}
]
}
]
"),
#"Converted to Table" = Table.FromList(Source, Splitter.SplitByNothing(), null, null, ExtraValues.Error),
#"Expanded Column1" = Table.ExpandRecordColumn(#"Converted to Table", "Column1", {"field1", "field2", "rules"}, {"field1", "field2", "rules"}),
#"Replaced Value" = Table.ReplaceValue(#"Expanded Column1",each [rules],each Text.FromBinary(Json.FromValue([rules])),Replacer.ReplaceValue,{"rules"})
in
#"Replaced Value"
How to use this code: Create a new Blank Query. Click on "Advanced Editor". Replace the code in the window with the code provided here. Click "Done". Once you examined the code, replace the Source step with your own source.
Please provide meaningful sample data (at a minimum a functioning JSON) and indicate the expected result from that sample data.
- You can put whatever meaningful sample data is desired. I changed it as is sensitive and not needed to address the question.
- I had given an example of what the json structure generally looks like, but looks like I left out a " and , that broke it in the process. This is a functioning example that also excludes the ...(etc)... parts to indicate additional data fields/records are actually present:
[
{
"field1": "blah 1",
"field2": "blah 2",
"rules": [
{
"anotherfield1": "blah 3",
"anotherfield2": "blah 4",
"Pattern": {
"a": "blah 5",
"b": "blah 6"
}
},
{
"anotherfield1": "blah 7",
"anotherfield2": "blah 8",
"Pattern": {
"a": "blah 9",
"b": "blah 10"
}
}
]
}
]
- I had already given the expected output. If you weren't sure what the rules column is supposed to look like, then this is what it would look like:
let
Source = Json.Document("
[
{
""field1"": ""blah 1"",
""field2"": ""blah 2"",
""rules"": [
{
""anotherfield1"": ""blah 3"",
""anotherfield2"": ""blah 4"",
""Pattern"": {
""a"": ""blah 5"",
""b"": ""blah 6""
}
},
{
""anotherfield1"": ""blah 7"",
""anotherfield2"": ""blah 8"",
""Pattern"": {
""a"": ""blah 9"",
""b"": ""blah 10""
}
}
]
}
]
"),
#"Converted to Table" = Table.FromList(Source, Splitter.SplitByNothing(), null, null, ExtraValues.Error),
#"Expanded Column1" = Table.ExpandRecordColumn(#"Converted to Table", "Column1", {"field1", "field2", "rules"}, {"field1", "field2", "rules"}),
#"Replaced Value" = Table.ReplaceValue(#"Expanded Column1",each [rules],each Text.FromBinary(Json.FromValue([rules])),Replacer.ReplaceValue,{"rules"})
in
#"Replaced Value"
How to use this code: Create a new Blank Query. Click on "Advanced Editor". Replace the code in the window with the code provided here. Click "Done". Once you examined the code, replace the Source step with your own source.
Looks like this is the part that I didn't know how to do before:
= Table.ReplaceValue(#"Expanded Column1",each [rules],each Text.FromBinary(Json.FromValue([rules])),Replacer.ReplaceValue,{"rules"})
This is great for extracting the json content at that data field. Is there any additional syntax available for the cell output to show 'pretty' json and not condensed like my example output?
You could go cute on it and inject line feeds but that's a bit much, no?
Sounds like the answer is 'no' for an Excel built-in function that already does that additional json text formatting. At this point it is more of a 'nice to have' and just makes it easier to see the data if so required. That said, we can always copy its cell contents into some other editor that has this format option if needed (which may not come up that often).
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.