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 a bunch of rows that contain Assessment Dates and Scores.
I want to create a calculated table that pulls the MIN Date and score, and MAX Date and score for each client.
I created a caclulated table that gets the MIN and MAX Dates, but not sure how to pull the associated scores in too.
Here's the table calc bringing in the dates:
Solved! Go to Solution.
Table =
ADDCOLUMNS(
SUMMARIZECOLUMNS(
GAD_PHQ[Client_ID],
"Start Date", MIN( GAD_PHQ[Assess_Date] ),
"End Date", MAX( GAD_PHQ[Assess_Date] )
),
"Start Score",
CALCULATE(
AVERAGE( GAD_PHQ[Assess_Score] ),
GAD_PHQ[Assess_Date] = EARLIER( [Start Date] )
),
"End Score",
CALCULATE(
AVERAGE( GAD_PHQ[Assess_Score] ),
GAD_PHQ[Assess_Date] = EARLIER( [End Date] )
)
)
| 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! |
Table =
ADDCOLUMNS(
SUMMARIZECOLUMNS(
GAD_PHQ[Client_ID],
"Start Date", MIN( GAD_PHQ[Assess_Date] ),
"End Date", MAX( GAD_PHQ[Assess_Date] )
),
"Start Score",
CALCULATE(
AVERAGE( GAD_PHQ[Assess_Score] ),
GAD_PHQ[Assess_Date] = EARLIER( [Start Date] )
),
"End Score",
CALCULATE(
AVERAGE( GAD_PHQ[Assess_Score] ),
GAD_PHQ[Assess_Date] = EARLIER( [End Date] )
)
)
| 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! |
Is there a way to add an additional filter so the results show Start Date and Score, End Date and Score, per Client ID AND Assessment Type? Right now, it's pulling Start and End per Client ID only.
Hi @pbrainard ,
How about this one:
CalculatedTable = SUMMARIZE ( 'GAD_PHQ', 'GAD_PHQ'[Client_ID], 'GAD_PHQ'[Full_Name], "Start Date", MIN ( 'GAD_PHQ'[Assess_Date] ), "Start Date Score", CALCULATE ( MAX ( 'GAD_PHQ'[Score] ), FILTER ( 'GAD_PHQ', 'GAD_PHQ'[Assess_Date] = MIN ( 'GAD_PHQ'[Assess_Date] ) ) ), "End Date", MAX ( 'GAD_PHQ'[Assess_Date] ), "End Date Score", CALCULATE ( MAX ( 'GAD_PHQ'[Score] ), FILTER ( 'GAD_PHQ', 'GAD_PHQ'[Assess_Date] = MAX ( 'GAD_PHQ'[Assess_Date] ) ) ) )
Does this work for you? 🙂
/Tom
https://www.tackytech.blog/
https://www.instagram.com/tackytechtom/
| Did I answer your question❓➡️ Please, mark my post as a solution ✔️ |
| Also happily accepting Kudos 🙂 |
| Feel free to connect with me on LinkedIn! | |
| #proudtobeasuperuser | |
The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!
Check out the November 2025 Power BI update to learn about new features.
| User | Count |
|---|---|
| 62 | |
| 46 | |
| 42 | |
| 24 | |
| 18 |
| User | Count |
|---|---|
| 193 | |
| 124 | |
| 101 | |
| 67 | |
| 49 |