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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
sse
Regular Visitor

Import multiple XML files

Is it possible to use the import from folder for multiple XML files? I have manged to extract the data I need from a single XML file using "import from XML" but not with the files from folder. Thank you!

1 ACCEPTED SOLUTION
alex-potter
Advocate IV
Advocate IV

The way I usually do it is with 2 queries: a folder query to get the paths/names of the files, and a function query to parse them.  

 

Steps:

  1. Query the folder where your XML files are
  2. Add a column that combines the path and file name to make an absolute path to the XML file and call it [Path]
  3. Create an XML query to one of the XML files in the folder
  4. Open advanced editor and create a parameter by adding (path as text) => at the top
  5. Replace the path specified inside Folder.Files() to path
  6. Close the advanced editor and name the query "getXML"
  7. In the Folder Query, add a custom column and call the getXML function by stating getXML([Path])
  8. Close and Load

    XML Parse Function Query
let
    Source = Folder.Files("C:\XML Files"),
    #"Removed Other Columns" = Table.SelectColumns(Source,{"Name", "Folder Path"}),
    #"Added Custom" = Table.AddColumn(#"Removed Other Columns", "Path", each [Folder Path] & [Name]),
    #"Added Custom1" = Table.AddColumn(#"Added Custom", "XML Data", each getXML([Path])),
    #"Expanded XML Data" = Table.ExpandTableColumn(#"Added Custom1", "XML Data", {"TITLE", "ARTIST", "COUNTRY", "COMPANY", "PRICE", "YEAR"}, {"TITLE", "ARTIST", "COUNTRY", "COMPANY", "PRICE", "YEAR"})
in
    #"Expanded XML Data"

Folder Query

(path as text) =>
let
    Source = Xml.Tables(File.Contents(path)),
    Table0 = Source{0}[Table],
    #"Changed Type" = Table.TransformColumnTypes(Table0,{{"TITLE", type text}, {"ARTIST", type text}, {"COUNTRY", type text}, {"COMPANY", type text}, {"PRICE", type number}, {"YEAR", Int64.Type}})
in
    #"Changed Type"

 

Message me if you would like an example PBIX file that does this

Alex

Alex Potter
Lead Visualization Engineer
Luxoft Inc.

View solution in original post

13 REPLIES 13
alex-potter
Advocate IV
Advocate IV

The way I usually do it is with 2 queries: a folder query to get the paths/names of the files, and a function query to parse them.  

 

Steps:

  1. Query the folder where your XML files are
  2. Add a column that combines the path and file name to make an absolute path to the XML file and call it [Path]
  3. Create an XML query to one of the XML files in the folder
  4. Open advanced editor and create a parameter by adding (path as text) => at the top
  5. Replace the path specified inside Folder.Files() to path
  6. Close the advanced editor and name the query "getXML"
  7. In the Folder Query, add a custom column and call the getXML function by stating getXML([Path])
  8. Close and Load

    XML Parse Function Query
let
    Source = Folder.Files("C:\XML Files"),
    #"Removed Other Columns" = Table.SelectColumns(Source,{"Name", "Folder Path"}),
    #"Added Custom" = Table.AddColumn(#"Removed Other Columns", "Path", each [Folder Path] & [Name]),
    #"Added Custom1" = Table.AddColumn(#"Added Custom", "XML Data", each getXML([Path])),
    #"Expanded XML Data" = Table.ExpandTableColumn(#"Added Custom1", "XML Data", {"TITLE", "ARTIST", "COUNTRY", "COMPANY", "PRICE", "YEAR"}, {"TITLE", "ARTIST", "COUNTRY", "COMPANY", "PRICE", "YEAR"})
in
    #"Expanded XML Data"

Folder Query

(path as text) =>
let
    Source = Xml.Tables(File.Contents(path)),
    Table0 = Source{0}[Table],
    #"Changed Type" = Table.TransformColumnTypes(Table0,{{"TITLE", type text}, {"ARTIST", type text}, {"COUNTRY", type text}, {"COMPANY", type text}, {"PRICE", type number}, {"YEAR", Int64.Type}})
in
    #"Changed Type"

 

Message me if you would like an example PBIX file that does this

Alex

Alex Potter
Lead Visualization Engineer
Luxoft Inc.

Nice clean solution that still works in 2019!

Thank you 🙂

Anonymous
Not applicable

Is there ever likely to be a more solid solution to this? Don't get me wrong I like your solution but its more of a workaround until a proper solution is put in place.

 

Is it likely we will see XML given more attention as its a common format I am hit with and the thought of trying to manage to import it into Power Bi especially when the XML reflects a schema of several tables is just plain hairy.

 

Maybe even just letting powebi hook up to an XML database and create the connection that way would be more optimal.

Anonymous
Not applicable

Hi 

 

what if i need to import from a folder some xlsb files with the same structure but i what to import only one worksheet?

 

Many many thanks!

Hi Alex, could you share the pbix please?

Great, thank you! I got it to work now. Excellent.

 

Edit : Nevermind .. i got it working

 

Can you upload the pbix as example Alex? Thanks

 

 

Hi amien,

 

Below is a link to a zip folder containing the example XML files and a PBIX file.  If you extract the folder to your C drive, everything should work without editing the path in the query.

XML Files Zip Folder

Alex Potter
Lead Visualization Engineer
Luxoft Inc.

Alex, thanks for your reply, it halped me a lot in understanding how BI works. however I have an additional challenge- i have to combine multiple XML files with the same name and schema but from different folders into one datase. I was thinking of creating separate wueries for each file, but the folders are getting added all the time...

 

any advise?

 

thanks so much!

PowerBIGuy
Responsive Resident
Responsive Resident

I just tested this and it worked for me. 

 

Cheers

Business Intelligence Architect / Consultant

The "from XML" and "from folder gives different output and I am not able to nest out the relevant data in "from folder"

 

From XML

 

let
Source = Xml.Tables(File.Contents("C:\337.xml")),
Table0 = Source{0}[Table],
Table1 = Table0{1}[Table],
#"Changed Type" = Table.TransformColumnTypes(Table1,{{"Id", Int64.Type}, {"LglSeqNb", Int64.Type}, {"CreDtTm", type datetime}})
in
#"Changed Type"

 

From Folder

 

    Source = Folder.Files("W:\XML folder")

sse
Regular Visitor

Is it possible to combine Source = Xml.Tables and Source = Folder.Files ?

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

Find out what's new and trending in the Fabric Community.