Fetching list of Files in a folder is easy with Power Query, it is one of the built-in source types. However fetching list of folders is not a built-in function. In this post I’ll show you how to fetch list of files, and also fetch only list of folders. The method explained in a way that you can customize the code and apply any conditions as you want later on. Conditions such as File or folder name masking to fetch only names that contains special character strings.
Fetch All Files in a Folder
For fetching all files in a folder you can simply use the GUI Get Data, and under File, choose Folder
Browse for Folder
and then simply you will see list of all files.
As you see in the above table extracted, there is a column named Content, which has the content of the file. you can click on that to see content of the file if you want.
What is the M Code Written Behind the Scenes
The code behind the scenes for this transformation used Folder.Files function
let Source = Folder.Files("C:\Users\Reza\Dropbox\Speaking") in Source
Fetch All Files and Folders
There is another M function to fetch all files and folders listed under a folder, named Folder.Contents. This function returns the Content column with data type of the record and content of it. for Files data type usually is Binary, and for Folders it is table. So it can be easily distinguished and separated. Here is list of all files and folders fetched:
let Source = Folder.Contents("C:\Users\Reza\Dropbox\Speaking") in Source
Result set contains both files and folders
As you see the Content column shows the data type of the value. To check if a record is Folder or not, we have to compare its data type to Table. We can add a column to the table to check data type of the content column in each record. data type can be checked with Value.Is function.
let Source = Folder.Contents("C:\Users\Reza\Dropbox\Speaking"), TypeAdded=Table.AddColumn(Source,"Type",each Value.Is([Content],type table)) in TypeAdded
And the result set shows if the record is folder or not
To fetch only folders, we can filter the data set with Table.SelectRows function. I’ve sorted the result set descending by creating date of the folder. Here is the code:
let Source = Folder.Contents("C:\Users\Reza\Dropbox\Speaking"), TypeAdded=Table.AddColumn(Source,"Type",each Value.Is([Content],type table)), Folders=Table.SelectRows(TypeAdded, each [Type]=true), Sorted=Table.Sort(Folders,{"Date created", Order.Descending}) in Sorted
And the result:
Fetch Files and Folders with Masking
Now that you’ve got through the M code, it would be really easy to apply any masking option to this. Here are couple of examples:
1- Fetch Only Folders Created after Specific Date
let Source = Folder.Contents("C:\Users\Reza\Dropbox\Speaking"), TypeAdded=Table.AddColumn(Source,"Type",each Value.Is([Content],type table)), Folders=Table.SelectRows(TypeAdded, each [Type]=true), Sorted=Table.Sort(Folders,{"Date created", Order.Descending}), Filtered=Table.SelectRows(Sorted, each [Date created]>DateTime.FromText("2015-1-1")) in Filtered
Result
2- Fetch Only Files with .txt extension and name similar to “amp”
let Source = Folder.Files("C:\Users\Reza\Dropbox\Speaking"), Sorted=Table.Sort(Source ,{"Date created", Order.Descending}), Filtered=Table.SelectRows(Sorted, each [Extension]=".txt" and Text.Contains([Name],"amp")) in Filtered
Result:
Awesome Post ! Power Query is an amazing tool !
I am looking to fetch workbooks from a folder within another folder. So say I have folder X which contains 100 other folders. In each folder is another folder called Y where my work book is. Do you know of a way to have power query reference a main folder (X) then for each folder within (X) find the folder that contains my workbook to query?
Cheers!
Hi Stefan,
Thanks for your kind feedback.
It is easy to do such thing in Power Query. start with Get Data from the main folder. Choose Folder as the source. and all files under any sub folders will be showed as a table output. then filter name of the file you want.
Cheers,
Reza
So good! Is there a way I can return only files where I am the author or last modified by?
Hi Karen
When you get data from folder, you get some attributes of the file, and then you can filter by those attributes.
Hi,
I have a scenario. I have a files in multiple folders under parent folder. While importing into the analysis service, I have to append the data from all the folders to a single table.
Could you please help me how to achieve this scenario.
Eg:
Folder A:
Subfolder A -> file.csv
Subfolder B -> file.csv
Subfolder C -> file.csv
after invoking these three files, all the data has to get append to a single table
Thanks,
Sathya
Hi Sathya
is your question about how to append data from files in multiple subfolders? or how to create a string format of “Subfolder A -> file.csv”?
because if it is the first, then you just need to click on combine files after getting list of all files. If it is the second question, then you need to do some text-based transformation from the path column
Cheers
Reza