Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Earn a 50% discount on the DP-600 certification exam by completing the Fabric 30 Days to Learn It challenge.

Reply
pbrainard
Helper III
Helper III

MIN and MAX Dates (and Scores) in Calculated Table

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:

 

Table =
SUMMARIZE (
'GAD_PHQ',
GAD_PHQ[Client_ID],
GAD_PHQ[Full_Name],
"Start Date", MIN ( GAD_PHQ[Assess_Date] ),
"End Date", MAX ( GAD_PHQ[Assess_Date] )
1 ACCEPTED SOLUTION
CNENFRNL
Community Champion
Community Champion

 

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!

View solution in original post

3 REPLIES 3
CNENFRNL
Community Champion
Community Champion

 

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.

tackytechtom
Super User
Super User

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! linkedIn

#proudtobeasuperuser 

Helpful resources

Announcements
RTI Forums Carousel3

New forum boards available in Real-Time Intelligence.

Ask questions in Eventhouse and KQL, Eventstream, and Reflex.

MayPowerBICarousel

Fabric Monthly Update - May 2024

Check out the May 2024 Fabric update to learn about new features.

LearnSurvey

Fabric certifications survey

Certification feedback opportunity for the community.