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 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 Data
Screenings Grouped
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:
The above code produces:
@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
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.