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
Anonymous
Not applicable

load latest date record

Hi all,

 

I have data like below table, I want to load only latest record based on Candidate ID &  Round

 

Ex: I want to remove 4th record C1 --> Final --> Hold while loading into power bi. 

 

Interview DateCandidate IDRoundInterviewerResult
1/1/2019C1Tech1KLSelected
1/2/2019C1Tech2MLSelected
1/3/2019C1HRKJLSelected
1/4/2019C1FinalAAAHold
1/5/2019C1FinalAAARejected
1 ACCEPTED SOLUTION
v-yulgu-msft
Employee
Employee

Hi @Anonymous,

 

What is your data source? For some databases like SQL Server, you can add customized SQL Query to "SQL statement" when creating data connection to filter latest date records within group and only load those records into desktop.

 

However, for some other data source types like Excel, above method doesn't work. You may have to load all data records into desktop first, then apply data transformation via Power Query to specify how many rows you would like to keep from the original dataset. Reference: Grouping in Power Query; Getting The Last Item in Each Group

1.PNG2.PNG

let
    Source = Excel.Workbook(File.Contents("C:\Users\xxxx\Desktop\Sample Data.xlsx"), null, true),
    Sheet4_Sheet = Source{[Item="Sheet4",Kind="Sheet"]}[Data],
    #"Promoted Headers" = Table.PromoteHeaders(Sheet4_Sheet, [PromoteAllScalars=true]),
    #"Changed Type" = Table.TransformColumnTypes(#"Promoted Headers",{{"Interview Date", type date}, {"Candidate ID", type text}, {"Round", type text}, {"Interviewer", type text}, {"Result", type text}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"Candidate ID", "Round"}, {{"all data", each _, type table}, {"Latest date", each List.Max([Interview Date]), type date}}),
    #"Expanded all data" = Table.ExpandTableColumn(#"Grouped Rows", "all data", {"Interview Date", "Interviewer", "Result"}, {"all data.Interview Date", "all data.Interviewer", "all data.Result"}),
    #"Filtered Rows" = Table.SelectRows(#"Expanded all data", each [all data.Interview Date] = [Latest date]),
    #"Renamed Columns" = Table.RenameColumns(#"Filtered Rows",{{"all data.Interview Date", "Interview Date"}, {"all data.Interviewer", "Interviewer"}, {"all data.Result", "Result"}}),
    #"Removed Columns" = Table.RemoveColumns(#"Renamed Columns",{"Latest date"})
in
    #"Removed Columns"

Best regards,

Yuliana Gu

Community Support Team _ Yuliana Gu
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

1 REPLY 1
v-yulgu-msft
Employee
Employee

Hi @Anonymous,

 

What is your data source? For some databases like SQL Server, you can add customized SQL Query to "SQL statement" when creating data connection to filter latest date records within group and only load those records into desktop.

 

However, for some other data source types like Excel, above method doesn't work. You may have to load all data records into desktop first, then apply data transformation via Power Query to specify how many rows you would like to keep from the original dataset. Reference: Grouping in Power Query; Getting The Last Item in Each Group

1.PNG2.PNG

let
    Source = Excel.Workbook(File.Contents("C:\Users\xxxx\Desktop\Sample Data.xlsx"), null, true),
    Sheet4_Sheet = Source{[Item="Sheet4",Kind="Sheet"]}[Data],
    #"Promoted Headers" = Table.PromoteHeaders(Sheet4_Sheet, [PromoteAllScalars=true]),
    #"Changed Type" = Table.TransformColumnTypes(#"Promoted Headers",{{"Interview Date", type date}, {"Candidate ID", type text}, {"Round", type text}, {"Interviewer", type text}, {"Result", type text}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"Candidate ID", "Round"}, {{"all data", each _, type table}, {"Latest date", each List.Max([Interview Date]), type date}}),
    #"Expanded all data" = Table.ExpandTableColumn(#"Grouped Rows", "all data", {"Interview Date", "Interviewer", "Result"}, {"all data.Interview Date", "all data.Interviewer", "all data.Result"}),
    #"Filtered Rows" = Table.SelectRows(#"Expanded all data", each [all data.Interview Date] = [Latest date]),
    #"Renamed Columns" = Table.RenameColumns(#"Filtered Rows",{{"all data.Interview Date", "Interview Date"}, {"all data.Interviewer", "Interviewer"}, {"all data.Result", "Result"}}),
    #"Removed Columns" = Table.RemoveColumns(#"Renamed Columns",{"Latest date"})
in
    #"Removed Columns"

Best regards,

Yuliana Gu

Community Support Team _ Yuliana Gu
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

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.