Join us at FabCon Atlanta from March 16 - 20, 2026, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.
Register now!The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more
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 Date | Candidate ID | Round | Interviewer | Result |
| 1/1/2019 | C1 | Tech1 | KL | Selected |
| 1/2/2019 | C1 | Tech2 | ML | Selected |
| 1/3/2019 | C1 | HR | KJL | Selected |
| 1/4/2019 | C1 | Final | AAA | Hold |
| 1/5/2019 | C1 | Final | AAA | Rejected |
Solved! Go to Solution.
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
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
If (like me) you're still quite intimdated by complex queries and you'd like something more transparent, you could use these steps:
- Right click on your original query and click 'Reference query'
- Name this new query something like "Latest dates"
- Under 'Transform', click 'Group By'
- Group by your participant ID and return a single summary value: The 'max' of the date field.
- You now have a two-column table that contains one row for each participant, and the date of their last data point
- Right click in the empty space under the list of queries on the left, and choose 'Merge queries'
- Use the query merging GUI to perform an outer left join, joining your original table to the two-column table just created
- You now have a table that is filtered to only include the latest data point for each participant.
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
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
The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!
| User | Count |
|---|---|
| 38 | |
| 36 | |
| 33 | |
| 31 | |
| 28 |
| User | Count |
|---|---|
| 129 | |
| 88 | |
| 79 | |
| 68 | |
| 63 |