Advance your Data & AI career with 50 days of live learning, dataviz contests, hands-on challenges, study groups & certifications and more!
Get registeredGet Fabric Certified for FREE during Fabric Data Days. Don't miss your chance! Learn more
Good afternoon,
I'm hoping I can get some clarification on an issue I've run into.
For each piece of equipment that I track, I also track the hours that were accrued on that S/N. For certain types of equipment, it can be taken out of service when it fails, repaired, and then put back into service. What I am wanting to do is calculate the hours of service between failures. Equipment of type 2 typically will see multiple failures over it's servicable life, where equipment of type 1 typically DOES NOT see multiple failures, but has the potential to. I am most interested in capturing the life between failures in type 2 equipment. The failure data is housed in the Failures table which is a fact table and the inventory of equipment lives in the Inventory table (Dimension table). I have tried solving my issue using variables with no luck, though I am sure I am doing something incorrectly. I had also thought about assigning indexes to the hours column, one starting at 1 and one starting at 0, but the data is SQL server based and it's typically best practice at my company to do this in that environment, which isn't possible at this time.
Below is a snap shot of a sample data model, and what data in the tables may look like.
 
 
Here is an example of what I would like the measure to output
Any help is greatly appreciated.
Solved! Go to Solution.
Hi @Ncf5031 ,
I created a sample pbix file(see attachment) for you, please check whether that is what you want. You can create a measure as below:
Hrs Diff = 
VAR _selsn =
    SELECTEDVALUE ( 'Failures'[S/N] )
VAR _curdate =
    SELECTEDVALUE ( 'Failures'[date] )
VAR _predate =
    CALCULATE (
        MAX ( 'Failures'[date] ),
        FILTER ( ALLSELECTED ( 'Failures' ), 'Failures'[date] < _curdate )
    )
VAR _prehours =
    CALCULATE (
        SUM ( 'Failures'[Hours] ),
        FILTER ( ALLSELECTED ( 'Failures' ), 'Failures'[date] = _predate )
    )
RETURN
    IF ( ISBLANK ( _prehours ), BLANK (), SUM ( 'Failures'[Hours] ) - _prehours )
If the above one can't help you get the desired result, please provide some sample data in your tables (exclude sensitive data) with Text format and your expected result with backend logic and special examples. It is better if you can share a simplified pbix file. Thank you.
How to upload PBI in Community
Best Regards
Thank you all for your help! I ended up using techniques from the suggestions of both @amitchandak and @Anonymous.
Below is the code snippet that results in a ~mostly~ correct solution. I say mostly because Ideally I would eliminate the hours for the first failure, but it's not the end of the world if they show up. Perhaps this could be solved by using EVALUATE and START AT
Time Between Failures = 
VAR SerialNumber = 'FAILURES'[SERIAL_NUM]
VAR DT = 'FAILURES'[DATET]
VAR LAST_HOURS = 'FAILURES'[HRS]
RETURN
LAST_HOURS - (CALCULATE(MAX('FAILURES'[HRS]), TOPN(1,FILTER('FAILURES', 'FAILURES'[SERIAL_NUM] = SerialNumber && 'FAILURES'[DATE] < DT), 'FAILURES'[DATE], DESC)))
Hi @Ncf5031 ,
I created a sample pbix file(see attachment) for you, please check whether that is what you want. You can create a measure as below:
Hrs Diff = 
VAR _selsn =
    SELECTEDVALUE ( 'Failures'[S/N] )
VAR _curdate =
    SELECTEDVALUE ( 'Failures'[date] )
VAR _predate =
    CALCULATE (
        MAX ( 'Failures'[date] ),
        FILTER ( ALLSELECTED ( 'Failures' ), 'Failures'[date] < _curdate )
    )
VAR _prehours =
    CALCULATE (
        SUM ( 'Failures'[Hours] ),
        FILTER ( ALLSELECTED ( 'Failures' ), 'Failures'[date] = _predate )
    )
RETURN
    IF ( ISBLANK ( _prehours ), BLANK (), SUM ( 'Failures'[Hours] ) - _prehours )
If the above one can't help you get the desired result, please provide some sample data in your tables (exclude sensitive data) with Text format and your expected result with backend logic and special examples. It is better if you can share a simplified pbix file. Thank you.
How to upload PBI in Community
Best Regards
Thank you all for your help! I ended up using techniques from the suggestions of both @amitchandak and @Anonymous.
Below is the code snippet that results in a ~mostly~ correct solution. I say mostly because Ideally I would eliminate the hours for the first failure, but it's not the end of the world if they show up. Perhaps this could be solved by using EVALUATE and START AT
Time Between Failures = 
VAR SerialNumber = 'FAILURES'[SERIAL_NUM]
VAR DT = 'FAILURES'[DATET]
VAR LAST_HOURS = 'FAILURES'[HRS]
RETURN
LAST_HOURS - (CALCULATE(MAX('FAILURES'[HRS]), TOPN(1,FILTER('FAILURES', 'FAILURES'[SERIAL_NUM] = SerialNumber && 'FAILURES'[DATE] < DT), 'FAILURES'[DATE], DESC)))
@Anonymous if I would want to exclude the very first instance of a serial number (i.e.-the first failure) in order to see only the hours between failures, how could I go about that?
Hi @Ncf5031 ,
Since the [Time Between Failures] you created is a calculated column, you can do a filter on this calculated column in the table with the condition that the value of [Time Between Failures] is not blank. This way the rest is all data with hour diff...
Best Regards
Hi @Ncf5031 ,
If your problem has been resolved, could you please mark your post as Answered? It will help the others in the community find the solution easily if they face the same problem as yours. Thank you.
Best Regards
@Anonymous thank you for reminding me.
I ended up marking my post as the solution, though I mentioned I came to this conclusion based off of the assisatnace of you and @amitchandak. I wish I could mark more than one post as a solution, but unfortunately I can't.
@Ncf5031 , with help from a date table
example
Last Day Month Continuous = CALCULATE([sales],filter(ALL('Date'), eomonth('Date'[Date],0) = eomonth(MAXX(FILTER(ALLSELECTED('Date'),'Date'[Date]<max('Date'[Date])),'Date'[Date]),0)))
Last Day Month Continuous = CALCULATE([sales],filter(ALL('Date'), eomonth('Date'[Date],0) = eomonth(Calculate(max(Table[Date]), FILTER(ALL('Date'),'Date'[Date]<max('Date'[Date]))),0)))
if you want use same table then also add in filter
&& Table[SN] = max(Table[SN])
Advance your Data & AI career with 50 days of live learning, contests, hands-on challenges, study groups & certifications and more!
Check out the October 2025 Power BI update to learn about new features.