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!Calling all Data Engineers! Fabric Data Engineer (Exam DP-700) live sessions are back! Starting October 16th. Sign up.
I have table as shown below. For each Reference, there may be multiple rows at different dates. I want to be able to create a calculated column that will evaluate, for each Reference, the value of the Count field where the Date is the maximum for that Reference (ie not just the maximum date in the table as a whole) Is this possible?
Reference | Count | Date |
A | 106 | 01/10/2020 |
A | 81 | 01/10/2021 |
B | 3 | 01/11/2022 |
B | 17 | 01/11/2020 |
B | 18 | 01/11/2023 |
B | 15 | 01/11/2021 |
C | 19 | 10/07/2023 |
C | 19 | 01/11/2022 |
D | 51 | 01/06/2021 |
D | 58 | 01/06/2023 |
E | 2 | 01/04/2021 |
E | 2 | 01/04/2022 |
E | 23 | 01/07/2021 |
What I am aiming for is:
Reference | Result |
A | 81 |
B | 18 |
C | 19 |
D | 58 |
E | 2 |
Many thanks for any help for this !
Solved! Go to Solution.
Hi @MatthewUK ,
You can achieve this by using:-
Result =
VAR MaxDate = CALCULATE(MAX('YourTable'[Date]), ALLEXCEPT('YourTable', 'YourTable'[Reference]))
RETURN
CALCULATE(MAX('YourTable'[Count]), 'YourTable'[Date] = MaxDate)
Hope this will help you.
Thank you
thank you so much - I'd tried loads of answers from similar questions and failed but this has worked a treat!
Hi @MatthewUK ,
You can achieve this by using:-
Result =
VAR MaxDate = CALCULATE(MAX('YourTable'[Date]), ALLEXCEPT('YourTable', 'YourTable'[Reference]))
RETURN
CALCULATE(MAX('YourTable'[Count]), 'YourTable'[Date] = MaxDate)
Hope this will help you.
Thank you
Join the Fabric FabCon Global Hackathon—running virtually through Nov 3. Open to all skill levels. $10,000 in prizes!
Check out the October 2025 Power BI update to learn about new features.