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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
Boja
Advocate II
Advocate II

Import the newest excel file from SharePoint

Hello,

 

I would need an assistance with M code.

 

Namely, excel files are stored on the sharedrive and Power Bi only needs the newest file from the folder (the file with the latest date created). The file names are standardized except the date part: SI Dashboard Data - FY17 - 2017-05-22

The report has set sceduled refresh and each time Power BI should replace the old file with the newest.

I put filters to extract file by SI Dashboard name and by the latest date created. 

 

Here is the M code but it doesn't work when the new file is saved on the drive. I guess some variable for latest date should be introduced but i have no idea how.

 

Could you please shed a light on this? Highly appreciated.

 

 

 

let
Source = SharePoint.Files("https://dimensiondata-my.sharepoint.com/personal/bojana_sokica_dimensiondata_com/", [ApiVersion = 15]),
#"Filtered by xlsx" = Table.SelectRows(Source, each ([Extension] = ".xlsx")),
#"Filtered by FileName" = Table.SelectRows(#"Filtered by xlsx", each Text.StartsWith([Name], "SI Dashboard")),
#"Filtered by Newest Date" = Table.SelectRows(#"Filtered by FileName", let latest = List.Max(#"Filtered by FileName"[Date created]) in each [Date created] = latest),
#"SI Dashboard - SLA Performance - FY17 - 2017-05-22-07-20-04 xlsx_https://dimensiondata-my sharepoint com/personal/bojana_sokica_dimensiondata_com/Documents/data/" = #"Filtered by Newest Date"{[Name="SI Dashboard - SLA Performance - FY17 - 2017-05-22-07-20-04.xlsx",#"Folder Path"="https://dimensiondata-my.sharepoint.com/personal/bojana_sokica_dimensiondata_com/Documents/data/"]}[...],
#"Imported Excel" = Excel.Workbook(#"SI Dashboard - SLA Performance - FY17 - 2017-05-22-07-20-04 xlsx_https://dimensiondata-my sharepoint com/personal/bojana_sokica_dimensiondata_com/Documents/data/"),
Detail_Sheet = #"Imported Excel"{[Item="Detail",Kind="Sheet"]}[Data]
in
Detail_Sheet

1 ACCEPTED SOLUTION
v-ljerr-msft
Employee
Employee

Hi @Boja,

 

Based on my test, The M code below should work in this scenario. 

let
    Source = SharePoint.Files("https://mytenant.sharepoint.com/teams/abc", [ApiVersion = 15]),
    #"Sorted Rows" = Table.Sort(Source,{{"Name", Order.Descending}}),
    #"Kept First Rows" = Table.FirstN(#"Sorted Rows",1),
    #"Invoke Custom Function1" = Table.AddColumn(#"Kept First Rows", "Transform File from Query1", each #"Transform File from Query1"([Content])),
    #"Renamed Columns1" = Table.RenameColumns(#"Invoke Custom Function1", {"Name", "Source.Name"}),
    #"Removed Other Columns1" = Table.SelectColumns(#"Renamed Columns1", {"Source.Name", "Transform File from Query1"}),
    #"Expanded Table Column1" = Table.ExpandTableColumn(#"Removed Other Columns1", "Transform File from Query1", Table.ColumnNames(#"Transform File from Query1"(#"Sample File"))),
    #"Changed Type" = Table.TransformColumnTypes(#"Expanded Table Column1",{{"Source.Name", type text}, {"Product", type text}, {"Category", type text}, {"Segment", type text}, {"ManufacturerID", Int64.Type}, {"Manufacturer", type text}})
in
    #"Changed Type"

In addition, here is a good article about loading the newest excel file from a Folder which is similar to loading from SharePoint Folder for your reference. Smiley Happy 

 

Regards

View solution in original post

3 REPLIES 3
v-ljerr-msft
Employee
Employee

Hi @Boja,

 

Based on my test, The M code below should work in this scenario. 

let
    Source = SharePoint.Files("https://mytenant.sharepoint.com/teams/abc", [ApiVersion = 15]),
    #"Sorted Rows" = Table.Sort(Source,{{"Name", Order.Descending}}),
    #"Kept First Rows" = Table.FirstN(#"Sorted Rows",1),
    #"Invoke Custom Function1" = Table.AddColumn(#"Kept First Rows", "Transform File from Query1", each #"Transform File from Query1"([Content])),
    #"Renamed Columns1" = Table.RenameColumns(#"Invoke Custom Function1", {"Name", "Source.Name"}),
    #"Removed Other Columns1" = Table.SelectColumns(#"Renamed Columns1", {"Source.Name", "Transform File from Query1"}),
    #"Expanded Table Column1" = Table.ExpandTableColumn(#"Removed Other Columns1", "Transform File from Query1", Table.ColumnNames(#"Transform File from Query1"(#"Sample File"))),
    #"Changed Type" = Table.TransformColumnTypes(#"Expanded Table Column1",{{"Source.Name", type text}, {"Product", type text}, {"Category", type text}, {"Segment", type text}, {"ManufacturerID", Int64.Type}, {"Manufacturer", type text}})
in
    #"Changed Type"

In addition, here is a good article about loading the newest excel file from a Folder which is similar to loading from SharePoint Folder for your reference. Smiley Happy 

 

Regards

Hey, would you mind teliing me if we should save this code as a macro and then run it ?

Thank you  v-ljerr-msft super Contributor, 🙂

This is excatly what I needed.

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

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

Top Solution Authors
Top Kudoed Authors