Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started
I have a decent sized XML file around 230MB. The file contains several columns that can themselves contain tables. See screenshot below. I regret that I cannot provide even a shortened version of this file.
How do I expand the columns "cves.cve" and "xrefs.xref"?
Here is my existing auto-generated query code.
let Source = Xml.Tables(File.Contents("C:\Users\squiddly\Desktop\plugins.xml")), Table1 = Source{1}[Table], #"Changed Type" = Table.TransformColumnTypes(Table1,{{"filename", type text}, {"script_id", Int64.Type}, {"script_name", type text}, {"script_version", type text}, {"script_copyright", type text}, {"script_family", type text}}), #"Removed Columns" = Table.RemoveColumns(#"Changed Type",{"filename", "script_version", "script_copyright", "bids", "dependencies", "required_keys", "required_ports", "excluded_keys", "preferences", "required_udp_ports"}), #"Expanded attributes" = Table.ExpandTableColumn(#"Removed Columns", "attributes", {"attribute"}, {"attributes.attribute"}), #"Expanded attributes.attribute" = Table.ExpandTableColumn(#"Expanded attributes", "attributes.attribute", {"name", "value"}, {"attributes.attribute.name", "attributes.attribute.value"}), #"Expanded cves" = Table.ExpandTableColumn(#"Expanded attributes.attribute", "cves", {"cve"}, {"cves.cve"}), #"Expanded xrefs" = Table.ExpandTableColumn(#"Expanded cves", "xrefs", {"xref"}, {"xrefs.xref"}) in #"Expanded xrefs"
It appears related to the solution that Marcel gave in this post, I just can't figure it out.
http://community.powerbi.com/t5/Desktop/Expand-value-from-table/td-p/214838
Solved! Go to Solution.
I was able to understand Marcel's solution after sleeping on it a bit. Here's the code I used:
#"Expanded cves" = Table.ExpandTableColumn(#"Removed Columns", "cves", {"cve"}, {"cves.cve"}), #"Lists from cves" = Table.TransformColumns(#"Expanded cves",{{"cves.cve", each if _ is table then Table.ToList(_) else {_}}}), #"Expanded cves.cve" = Table.ExpandListColumn(#"Lists from cves", "cves.cve"),
#"Expanded cves" step expands the 'cves' column down to the 'cve' column. The 'cve' column is the one that contains zero or one or multiple values. If I expand this normally, the column contains values of either null, <single value>, or 'Table'.
#"Lists from cves" performs an if on each value to determine if it's a table. If it's a table, then it puts that value into a list. If it's a normal value, it leaves it alone.
#"Expanded cves.cve" expands the lists such that it duplicates rows for each unique value in any tables found in "cve".
I've been able to repeat this to great success. I'm sorry I can't provide the XML as it's proprietary. I truly appreciate your effort Dale!
Hi,
I need to expand the table in the Query.1 coloumn. Any help on how can i do it will be super helpful
Hi @squiddly,
Can you share a very small sample please? It's hard to build a test data source. If you can't provide a sample, maybe you can modify the file below.
One question: do these "Table" only contain plain values? In other words, they don't nest other tables.
<?xml version="1.0" encoding="UTF-8"?> <root> <element> <attributes.attribute.name>p</attributes.attribute.name> <cves> <cves.cve> <hehe> <element>cca</element> <element>ccb</element> </hehe> </cves.cve> <cves.cve> <hehe> <element>ssa</element> <element>dscb</element> </hehe> </cves.cve> </cves> <script_family>slsc</script_family> <script_id>77913</script_id> <script_name>s1012654</script_name> <xrefs.xref> <xxa> <element>a</element> <element>b</element> </xxa> </xrefs.xref> </element> <element> <attributes.attribute.name>p</attributes.attribute.name> <cves>cca</cves> <script_family>slsc</script_family> <script_id>77913</script_id> <script_name>s1012654</script_name> <xrefs.xref> <xxb> <element>c</element> <element>d</element> </xxb> </xrefs.xref> </element> <element> <attributes.attribute.name>p</attributes.attribute.name> <cves.cve>ccb</cves.cve> <script_family>slsc</script_family> <script_id>77913</script_id> <script_name>s1012654</script_name> <xrefs.xref>xxb</xrefs.xref> </element> <element> <attributes.attribute.name>s</attributes.attribute.name> <cves.cve>dd</cves.cve> <script_family>slsc</script_family> <script_id>77913</script_id> <script_name>s1012654</script_name> <xrefs.xref>ss</xrefs.xref> </element> <element> <attributes.attribute.name>c</attributes.attribute.name> <cves.cve>gg</cves.cve> <script_family>slsc</script_family> <script_id>77913</script_id> <script_name>s1012654</script_name> </element> </root>
Best Regards,
Dale
I was able to understand Marcel's solution after sleeping on it a bit. Here's the code I used:
#"Expanded cves" = Table.ExpandTableColumn(#"Removed Columns", "cves", {"cve"}, {"cves.cve"}), #"Lists from cves" = Table.TransformColumns(#"Expanded cves",{{"cves.cve", each if _ is table then Table.ToList(_) else {_}}}), #"Expanded cves.cve" = Table.ExpandListColumn(#"Lists from cves", "cves.cve"),
#"Expanded cves" step expands the 'cves' column down to the 'cve' column. The 'cve' column is the one that contains zero or one or multiple values. If I expand this normally, the column contains values of either null, <single value>, or 'Table'.
#"Lists from cves" performs an if on each value to determine if it's a table. If it's a table, then it puts that value into a list. If it's a normal value, it leaves it alone.
#"Expanded cves.cve" expands the lists such that it duplicates rows for each unique value in any tables found in "cve".
I've been able to repeat this to great success. I'm sorry I can't provide the XML as it's proprietary. I truly appreciate your effort Dale!
Thanks, worked for me