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
Brad_Vail
Frequent Visitor

Load the latest spreadsheet from a SharePoint folder

My business group will save monthly spreadsheets into a single SharePoint folder. I want the Query editor to open the newest file in the folder regardless of the file name. I have included a portion of the query and you can see that the name of the file that I opened in the first sequence is hard coded in the script. I want to sort the list to place the newest file at the top of the list. The sequence of steps recorded in the Query Editor hard codes the name of the file. When the newest file in the folder does not have the same name, the Query fails. How can I eliminate the steps that hard code the name of the file ?

 

 

Source = SharePoint.Contents("https://DOMAIN.sharepoint.com/sites/BUSINESS FOLDER/", [ApiVersion = 15]),
#"PATH LEVEL 1" = Source{[Name="PATH LEVEL 1"]}[Content],
PATH LEVEL 2 = #"PATH LEVEL 1"{[Name="PATH LEVEL 2"]}[Content],
PATH LEVEL 3 = PATH LEVEL 2{[Name="PATH LEVEL 3"]}[Content],

#"Account Transactions - ACCOU_Sheet" = #"Imported Excel Workbook"{[Item="Sheet 1",Kind="Sheet"]}[Data],
#"SPREADSHEET FILE XLSX" = PATH LEVEL 3{[Name="SPREADSHEET FILE.XLSX"]}[Content],
#"Imported Excel Workbook" = Excel.Workbook(#"SPREADSHEET FILE XLSX"),

#"Promoted Headers" = Table.PromoteHeaders(#"Sheet 1", [PromoteAllScalars=true]),
#"Sorted Rows" = Table.Sort(#"Promoted Headers",{{"Date", Order.Descending}})

1 ACCEPTED SOLUTION
AlexisOlson
Super User
Super User

You should be able to filter [Date modified] equal to the maximal date modified and then take the first (index 0) row from that filtered table.

 

For example, this gives me the most recently modified .xlsx file from the site:

let
    Source = SharePoint.Files("https://DOMAIN.sharepoint.com/sites/SITENAME", [ApiVersion = 15]),
    #"Filtered .xlsx" = Table.SelectRows(Source, each ([Extension] = ".xlsx")),
    #"Filtered last modified" = Table.SelectRows(#"Filtered .xlsx", each ([Date modified] = List.Max(#"Filtered .xlsx"[Date modified]))){0}[Content],
    #"Imported Excel Workbook" = Excel.Workbook(#"Filtered last modified")
in
    #"Imported Excel Workbook"

View solution in original post

1 REPLY 1
AlexisOlson
Super User
Super User

You should be able to filter [Date modified] equal to the maximal date modified and then take the first (index 0) row from that filtered table.

 

For example, this gives me the most recently modified .xlsx file from the site:

let
    Source = SharePoint.Files("https://DOMAIN.sharepoint.com/sites/SITENAME", [ApiVersion = 15]),
    #"Filtered .xlsx" = Table.SelectRows(Source, each ([Extension] = ".xlsx")),
    #"Filtered last modified" = Table.SelectRows(#"Filtered .xlsx", each ([Date modified] = List.Max(#"Filtered .xlsx"[Date modified]))){0}[Content],
    #"Imported Excel Workbook" = Excel.Workbook(#"Filtered last modified")
in
    #"Imported Excel Workbook"

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.