Power BI is turning 10! Tune in for a special live episode on July 24 with behind-the-scenes stories, product evolution highlights, and a sneak peek at what’s in store for the future.
Save the dateEnhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends August 31st. Request your voucher.
Hi, I need to have the the latest date and the corresponding Fee of a Customer table having many different customers and many rows for the same Customer. This can be done easily in SQL Server with ROW_NUMBER and then ordering It by the Latest Date.
Input:
Customer | Date | Fee |
A | 13/01/2020 | 10 |
A | 25/01/2020 | 15 |
B | 26/01/2020 | 12 |
B | 16/01/2020 | 7 |
B | 17/01/2020 | 13 |
C | 05/01/2020 | 20 |
C | 02/01/2020 | 25 |
C | 20/02/2020 | 15 |
Temporal
Customer | Date | Fee | Row Number |
A | 13/01/2020 | 10 | 2 |
A | 25/01/2020 | 15 | 1 |
B | 26/01/2020 | 12 | 1 |
B | 16/01/2020 | 7 | 3 |
B | 17/01/2020 | 13 | 2 |
C | 05/01/2020 | 20 | 2 |
C | 02/01/2020 | 25 | 3 |
C | 20/02/2020 | 15 | 1 |
Output:
Customer | Date | Fee |
A | 25/01/2020 | 15 |
B | 26/01/2020 | 12 |
C | 20/02/2020 | 15 |
Thanks in advance
Solved! Go to Solution.
Hi @Ricardofaster ,
The code @CNENFRNL provided works well.
If you don't want to change the code manually, just try this:
Best Regards,
Icey
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi @Ricardofaster ,
The code @CNENFRNL provided works well.
If you don't want to change the code manually, just try this:
Best Regards,
Icey
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi, @Ricardofaster , it's as easy as in SQL to process in PQ given there's in PQ an equivalent of Grougp By clause in SQL.
let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("Tc7BDcAgDAPAXfJGwjFKebcdA7H/GgUqgX/xJbLSmt2WzEuGZ4KYAdbT7wz1WP5Mv9S53dXr4arnZfk7Rmg9cZzqsZ3IYyXv9A8=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Customer = _t, Date = _t, Fee = _t]),
#"Changed Type" = Table.TransformColumns(Source,{{"Date", each Date.FromText(_, "fr")}, {"Fee", Number.From}}),
#"Grouped Rows" = Table.Group(#"Changed Type", {"Customer"}, {{"temporal", each Table.Sort(_, {"Date", Order.Descending}){0}}}),
#"Expanded temporal" = Table.ExpandRecordColumn(#"Grouped Rows", "temporal", {"Date", "Fee"}, {"Latest Date", "Fee"})
in
#"Expanded temporal"
Thanks to the great efforts by MS engineers to simplify syntax of DAX! Most beginners are SUCCESSFULLY MISLED to think that they could easily master DAX; but it turns out that the intricacy of the most frequently used RANKX() is still way beyond their comprehension! |
DAX is simple, but NOT EASY! |
Hi @CNENFRNL ,
Thanks for your response but with your solution I will only get the sum of the Fees by Employee. What I need is the unic value of the Fee corresponding with the latest date by Customer.
Hi, @Ricardofaster , I've amended the code in line with your requirement. Pls try it again.
Thanks to the great efforts by MS engineers to simplify syntax of DAX! Most beginners are SUCCESSFULLY MISLED to think that they could easily master DAX; but it turns out that the intricacy of the most frequently used RANKX() is still way beyond their comprehension! |
DAX is simple, but NOT EASY! |
Check out the July 2025 Power BI update to learn about new features.
This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.
User | Count |
---|---|
10 | |
7 | |
7 | |
6 | |
6 |