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
I have two tables, a table of orders and a table of parts associated with those orders, with a many-to-one relationship; there can be many parts associated with a single order. Here is a sample set of data:
Orders
| OrderNum |
| 1 |
| 2 |
| 3 |
Parts
| OrderNum | PartNum | Seq | ExpectedDate |
| 1 | ABC | 1 | 10/10/2021 |
| 1 | DEF | 2 | 10/16/2021 |
| 1 | GHI | 3 | 10/13/2021 |
| 2 | XYZ | 1 | 10/17/2021 |
| 2 | AAA | 2 | 10/11/2021 |
| 3 | BBB | 1 | 10/10/2021 |
| 3 | JKL | 2 | 10/12/2021 |
| 3 | ZZZ | 3 | 10/12/2021 |
I have an measure like Max Expected Date = MAX('Parts'[ExpectedDate]) to determine the latest expected date for each order, which returns a table like:
| OrderNum | Max Expected Date |
| 1 | 10/16/2021 |
| 2 | 10/17/2021 |
| 3 | 10/12/2021 |
Now I would like to return the part number associated with that max expected date. If there are multiple parts with the same max expected date for a single order, then I want to return the part number with the lowest Seq value. For example, for order 3 there are 2 parts with an expected date equal to the max expected date, so I would need to return part JKL because of those two parts it has the lowest Seq value.
The desired output would be:
| OrderNum | Max Expected Date | Max Expected Date Part Number |
| 1 | 10/16/2021 | DEF |
| 2 | 10/17/2021 | XYZ |
| 3 | 10/12/2021 | JKL |
Thank you in advance.
Solved! Go to Solution.
@Anonymous here is the measure:
Latest Part =
VAR __LatestExpectedDate = MAX ( Parts[ExpectedDate] )
VAR __EarliestSequence = CALCULATE ( MIN ( Parts[Seq] ), Parts[ExpectedDate] = __LatestExpectedDate )
RETURN
CALCULATE (
MAX ( Parts[PartNum] ),
Parts[ExpectedDate] = __LatestExpectedDate,
Parts[Seq] = __EarliestSequence
)
output
✨ Follow us on LinkedIn
Check my latest blog post The Power of Using Calculation Groups with Inactive Relationships (Part 1) (perytus.com) I would ❤ Kudos if my solution helped. 👉 If you can spend time posting the question, you can also make efforts to give Kudos to whoever helped to solve your problem. It is a token of appreciation!
⚡ Visit us at https://perytus.com, your one-stop-shop for Power BI-related projects/training/consultancy.⚡
Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!
Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo
If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤
Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.
There are quite a number of ways to do this.
https://stackoverflow.com/questions/52525377/return-top-value-ordered-by-another-column
I'm not sure what version is considered "best practice".
@Anonymous here is the measure:
Latest Part =
VAR __LatestExpectedDate = MAX ( Parts[ExpectedDate] )
VAR __EarliestSequence = CALCULATE ( MIN ( Parts[Seq] ), Parts[ExpectedDate] = __LatestExpectedDate )
RETURN
CALCULATE (
MAX ( Parts[PartNum] ),
Parts[ExpectedDate] = __LatestExpectedDate,
Parts[Seq] = __EarliestSequence
)
output
✨ Follow us on LinkedIn
Check my latest blog post The Power of Using Calculation Groups with Inactive Relationships (Part 1) (perytus.com) I would ❤ Kudos if my solution helped. 👉 If you can spend time posting the question, you can also make efforts to give Kudos to whoever helped to solve your problem. It is a token of appreciation!
⚡ Visit us at https://perytus.com, your one-stop-shop for Power BI-related projects/training/consultancy.⚡
Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!
Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo
If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤
Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.
@Anonymous for order #3, why you will have JLK, not ZZZ, both orders have the latest date? What is the logic to pick one over another?
Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!
Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo
If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤
Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.
@parry2k I only want to return a single part. Logic in this case would be to select the part with the lowest Seq value. Part JKL and ZZZ both have a max expected date of 10/12/2021, so I would return JKL because it has the lower Seq value (2) compared to the Seq value for ZZZ (3).
The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!
| User | Count |
|---|---|
| 38 | |
| 38 | |
| 37 | |
| 28 | |
| 28 |
| User | Count |
|---|---|
| 124 | |
| 89 | |
| 73 | |
| 66 | |
| 65 |