Check your eligibility for this 50% exam voucher offer and join us for free live learning sessions to get prepared for Exam DP-700.
Get StartedDon't miss out! 2025 Microsoft Fabric Community Conference, March 31 - April 2, Las Vegas, Nevada. Use code MSCUST for a $150 discount. Prices go up February 11th. Register now.
I would want to find the difference in the GenHours for each serialid. Currently this is how my table looks on power BI. I have filtered the latest and 2nd latest date for each serialid.
Now i would want to find the difference between the GenHours that is being diplayed on Power BI after applying filters like removing blanks.
Can someone please help.
@amitchandak @Greg_Deckler @parry2k
Solved! Go to Solution.
Hi @axk180022
According to your statement, I know you want to show absolute Gen Difference. And you will filter your table to show first 2 date for each serialid, you just want show difference in 1st latest date and difference in 2nd latest date will show blank. Here I suggest you build a table visual and create a measure to achieve your goal. Measure could be dynamic.
My Sample:
Rank is a calculated column.
Rank = RANKX(FILTER('Table','Table'[serialid]=EARLIER('Table'[serialid])),'Table'[Dates],,DESC,Dense)
Build a table visual and filter visual by rank column to show items when value is less than or equal to 2.
Measure:
Gen Difference =
VAR _RANK1GenHours =
CALCULATE (
SUM ( 'Table'[GenHours] ),
FILTER (
ALL ( 'Table' ),
'Table'[serialid] = MAX ( 'Table'[serialid] )
&& 'Table'[Rank] = 1
)
)
VAR _RANK2GenHours =
CALCULATE (
SUM ( 'Table'[GenHours] ),
FILTER (
ALL ( 'Table' ),
'Table'[serialid] = MAX ( 'Table'[serialid] )
&& 'Table'[Rank] = 2
)
)
RETURN
IF (
SUM ( 'Table'[Rank] ) = 1,
ABS ( _RANK1GenHours - _RANK2GenHours ),
BLANK ()
)
Result is as below.
Best Regards,
Rico Zhou
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi @axk180022
According to your statement, I know you want to show absolute Gen Difference. And you will filter your table to show first 2 date for each serialid, you just want show difference in 1st latest date and difference in 2nd latest date will show blank. Here I suggest you build a table visual and create a measure to achieve your goal. Measure could be dynamic.
My Sample:
Rank is a calculated column.
Rank = RANKX(FILTER('Table','Table'[serialid]=EARLIER('Table'[serialid])),'Table'[Dates],,DESC,Dense)
Build a table visual and filter visual by rank column to show items when value is less than or equal to 2.
Measure:
Gen Difference =
VAR _RANK1GenHours =
CALCULATE (
SUM ( 'Table'[GenHours] ),
FILTER (
ALL ( 'Table' ),
'Table'[serialid] = MAX ( 'Table'[serialid] )
&& 'Table'[Rank] = 1
)
)
VAR _RANK2GenHours =
CALCULATE (
SUM ( 'Table'[GenHours] ),
FILTER (
ALL ( 'Table' ),
'Table'[serialid] = MAX ( 'Table'[serialid] )
&& 'Table'[Rank] = 2
)
)
RETURN
IF (
SUM ( 'Table'[Rank] ) = 1,
ABS ( _RANK1GenHours - _RANK2GenHours ),
BLANK ()
)
Result is as below.
Best Regards,
Rico Zhou
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
@axk180022 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
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Prices go up Feb. 11th.
Check out the January 2025 Power BI update to learn about new features in Reporting, Modeling, and Data Connectivity.
User | Count |
---|---|
144 | |
80 | |
64 | |
52 | |
49 |
User | Count |
---|---|
211 | |
87 | |
80 | |
69 | |
60 |