Power BI is turning 10, and we’re marking the occasion with a special community challenge. Use your creativity to tell a story, uncover trends, or highlight something unexpected.
Get startedJoin us for an expert-led overview of the tools and concepts you'll need to become a Certified Power BI Data Analyst and pass exam PL-300. Register now.
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
This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.
Check out the June 2025 Power BI update to learn about new features.
User | Count |
---|---|
72 | |
68 | |
53 | |
39 | |
33 |
User | Count |
---|---|
71 | |
63 | |
57 | |
49 | |
46 |