cancel
Showing results for 
Search instead for 
Did you mean: 
Reply

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

Accepted Solutions
v-yulgu-msft Super Contributor
Super Contributor

Re: load latest date record

Hi @vengadeshpalani,

 

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 Super Contributor
Super Contributor

Re: load latest date record

Hi @vengadeshpalani,

 

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

Helpful resources

Announcements
October 2019 Community Highlights

October 2019 Community Highlights

October was a busy month in the community. Read the recap article to learn about some of the events and content.

New Solution Badges

New Solution Badges

Two waves of brand new solution badges are coming! Read the article for more information on our new community badges.

Ask Amir Anything

Exclusive LIVE Community Event No. 2 – Ask Amir Anything

Next in our Triple A series: Ask Amir Netz questions about the latest updates, features and future.

Analytics in Azure virtual event

Analytics in Azure virtual event

Experience a limitless analytics service built to ingest, prep, manage, and serve data for immediate use in Power BI.

Users Online
Currently online: 332 members 3,461 guests
Please welcome our newest community members: