Fetch Files and/or Folders with Filtering and Masking: Power Query

4

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

1

Browse for Folder

2

and then simply you will see list of all files.

3

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

4

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

5

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:

6

 

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

7

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:

8

 

Reza Rad on FacebookReza Rad on LinkedinReza Rad on TwitterReza Rad on Youtube
Reza Rad
Trainer, Consultant, Mentor
Reza Rad is a Microsoft Regional Director, an Author, Trainer, Speaker and Consultant. He has a BSc in Computer engineering; he has more than 20 years’ experience in data analysis, BI, databases, programming, and development mostly on Microsoft technologies. He is a Microsoft Data Platform MVP for 12 continuous years (from 2011 till now) for his dedication in Microsoft BI. Reza is an active blogger and co-founder of RADACAD. Reza is also co-founder and co-organizer of Difinity conference in New Zealand, Power BI Summit, and Data Insight Summit.
Reza is author of more than 14 books on Microsoft Business Intelligence, most of these books are published under Power BI category. Among these are books such as Power BI DAX Simplified, Pro Power BI Architecture, Power BI from Rookie to Rock Star, Power Query books series, Row-Level Security in Power BI and etc.
He is an International Speaker in Microsoft Ignite, Microsoft Business Applications Summit, Data Insight Summit, PASS Summit, SQL Saturday and SQL user groups. And He is a Microsoft Certified Trainer.
Reza’s passion is to help you find the best data solution, he is Data enthusiast.
His articles on different aspects of technologies, especially on MS BI, can be found on his blog: https://radacad.com/blog.

6 thoughts on “Fetch Files and/or Folders with Filtering and Masking: Power Query

  • 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

  • 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

Leave a Reply