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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
kimbtoth
Frequent Visitor

Calculate the difference in a value from two rows

I have a spreadsheet that displays a score for each screening completed by a patient (identified by unique PAT_ID column) over time. NOTE - All screenshots are de-identified.

I am trying to calculate the difference in score (MEAS_VALUE column) for (MaxDate - MinDate) per each PAT_ID.

I was able to group by PAT_ID and limit to rows > 1 and calculate the difference in date duration since I included in on the row. I also was able to use Table-Buffer to sort PAT_ID and  DATE_RECORD Desc) but I can't figure out how to calculate the difference in score (MEAS_VALUE column)  across different rows but only when the PAT_ID is the same.

I tried reviewing previously submitted questions/responses but I'm not getting it.  Thanks for any help!
Screenings Raw DataScreenings Raw DataScreenings GroupedScreenings Grouped

 

 

 

2 REPLIES 2
ronrsnfld
Super User
Super User

You don't show what you want for results, but a simple way of calculating the MEAS_VAL difference between the latest and the earliest dates is within the Table.Group function:

let
    Source = Excel.CurrentWorkbook(){[Name="Table14"]}[Content],
    #"Changed Type" = Table.TransformColumnTypes(Source,{
        {"PAT_ID", type text}, {"SCREENING_NAME", type text}, 
        {"DATE_RECORDED", type date}, {"ENTRY_USER_ID", type text}, 
        {"MEAS_VALUE", Int64.Type}}),
    
    #"Grouped Rows" = Table.Group(#"Changed Type", {"PAT_ID"}, {
        {"Diff" , 
            each 
                Table.Max(_,"DATE_RECORDED")[MEAS_VALUE] - 
                Table.Min(_,"DATE_RECORDED")[MEAS_VALUE], 
                type number}})
in
    #"Grouped Rows"

 

Given this data:

ronrsnfld_0-1699470582409.png

 

The above code produces:

ronrsnfld_1-1699470618784.png

 

 

Greg_Deckler
Super User
Super User

@kimbtoth Not sure of the Power Query solution, maybe @ImkeF can help. Here is a DAX solution as a fall back if you just need to get it done. See my article on Mean Time Between Failure (MTBF) which uses EARLIER: http://community.powerbi.com/t5/Community-Blog/Mean-Time-Between-Failure-MTBF-and-Power-BI/ba-p/3395....
The basic pattern is:
Column = 
  VAR __Current = [Value]
  VAR __PreviousDate = MAXX(FILTER('Table','Table'[Date] < EARLIER('Table'[Date])),[Date])

  VAR __Previous = MAXX(FILTER('Table',[Date]=__PreviousDate),[Value])
RETURN
  __Current - __Previous


@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
The Definitive Guide to Power Query (M)

DAX is easy, CALCULATE makes DAX hard...

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

Find out what's new and trending in the Fabric Community.

Top Solution Authors
Top Kudoed Authors