Join us for an expert-led overview of the tools and concepts you'll need to pass exam PL-300. The first session starts on June 11th. See you there!
Get registeredPower BI is turning 10! Let’s celebrate together with dataviz contests, interactive sessions, and giveaways. 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
This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.
Check out the June 2025 Power BI update to learn about new features.
User | Count |
---|---|
81 | |
76 | |
61 | |
37 | |
33 |
User | Count |
---|---|
99 | |
56 | |
50 | |
42 | |
40 |