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
FilipVDR
Helper I
Helper I

How to calculate new faults, existing faults, ... , Is PowerBI the right place for this data problem

Hello,

 

I'm reading a table of fault id's which has start and ending dates.

AssetIDFaultIDStartClose
10111/08/20234/08/2023
10221/08/20231/08/2023
10331/08/2023 

 

Business wants to see graphs where they can see how many new, existing and closed faults they have open for each day/week/month.

 

So i guess I should end up with someting like this? For now i have about 40.000 faultID's but this could become 4million rows.

Is there a way to do this with PowerBI? I tried some dax measures but i already ran out of memory on my Laptop.

 

Or is there a better way in PowerQuery?

DateAssetIDFaultIDNewFaultExistingFaultClosedFault
1/08/20231011100
2/08/20231011010
3/08/20231011010
4/08/20231011001
1/08/20231022101
1/08/20231033100
2/08/20231033010
3/08/20231033010
4/08/20231033010

 

1 ACCEPTED SOLUTION
v-yueyunzh-msft
Community Support
Community Support

Hi , @FilipVDR 

Thanks for your sample data first. Here are the steps you can refer to . My test data is the same as yours.My Table name is 'Table'.

(1)We can create a blank query in Power Query Editor:
And then we can put this M code in the "Advanced Editor":

let
    Source = Table,
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"AssetID", Int64.Type}, {"FaultID", Int64.Type}, {"Start", type date}, {"Close", type date}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "Custom", each try  List.Dates([Start], Duration.Days( [Close] -[Start])+1   ,#duration(1,0,0,0))   otherwise
List.Dates([Start], Duration.Days(List.Max(Table[Close])  -[Start])+1   ,#duration(1,0,0,0)   )),
    #"Removed Columns" = Table.RemoveColumns(#"Added Custom",{"Start", "Close"}),
    #"Expanded Custom" = Table.ExpandListColumn(#"Removed Columns", "Custom"),
    #"Renamed Columns" = Table.RenameColumns(#"Expanded Custom",{{"Custom", "Date"}}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Renamed Columns",{{"Date", type date}})
in
    #"Changed Type1"

 

Then we can get the table like this:

vyueyunzhmsft_0-1691372590792.png

Then we can apply the data to Desktop and then we can click "New Column " to create some calculated columns in Power BI Desktop:

NewFault = IF( CALCULATE( MAX('Table'[Start]) , 'Table'[AssetID]=EARLIER('Table2'[AssetID]) , 'Table'[FaultID]=EARLIER('Table2'[FaultID])) = [Date] ,1,0)
ExistingFault = var _close_date =  CALCULATE( MAX('Table'[Close]) , 'Table'[AssetID]=EARLIER('Table2'[AssetID]) , 'Table'[FaultID] =EARLIER('Table2'[FaultID]))

return
IF( [NewFault] =1, 0 , IF(_close_date=BLANK() ,1,  IF([Date] <_close_date,1,0)  ))
ClosedFault = var _close_date =  CALCULATE( MAX('Table'[Close]) , 'Table'[AssetID]=EARLIER('Table2'[AssetID]) , 'Table'[FaultID] =EARLIER('Table2'[FaultID]))

return
IF([Date] = _close_date ,1,0)

 

Then we can get the table you want to get :

vyueyunzhmsft_1-1691372661641.png

 

 

 

Thank you for your time and sharing, and thank you for your support and understanding of PowerBI! 

 

Best Regards,

Aniya Zhang

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly

View solution in original post

3 REPLIES 3
v-yueyunzh-msft
Community Support
Community Support

Hi , @FilipVDR 

Thanks for your sample data first. Here are the steps you can refer to . My test data is the same as yours.My Table name is 'Table'.

(1)We can create a blank query in Power Query Editor:
And then we can put this M code in the "Advanced Editor":

let
    Source = Table,
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"AssetID", Int64.Type}, {"FaultID", Int64.Type}, {"Start", type date}, {"Close", type date}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "Custom", each try  List.Dates([Start], Duration.Days( [Close] -[Start])+1   ,#duration(1,0,0,0))   otherwise
List.Dates([Start], Duration.Days(List.Max(Table[Close])  -[Start])+1   ,#duration(1,0,0,0)   )),
    #"Removed Columns" = Table.RemoveColumns(#"Added Custom",{"Start", "Close"}),
    #"Expanded Custom" = Table.ExpandListColumn(#"Removed Columns", "Custom"),
    #"Renamed Columns" = Table.RenameColumns(#"Expanded Custom",{{"Custom", "Date"}}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Renamed Columns",{{"Date", type date}})
in
    #"Changed Type1"

 

Then we can get the table like this:

vyueyunzhmsft_0-1691372590792.png

Then we can apply the data to Desktop and then we can click "New Column " to create some calculated columns in Power BI Desktop:

NewFault = IF( CALCULATE( MAX('Table'[Start]) , 'Table'[AssetID]=EARLIER('Table2'[AssetID]) , 'Table'[FaultID]=EARLIER('Table2'[FaultID])) = [Date] ,1,0)
ExistingFault = var _close_date =  CALCULATE( MAX('Table'[Close]) , 'Table'[AssetID]=EARLIER('Table2'[AssetID]) , 'Table'[FaultID] =EARLIER('Table2'[FaultID]))

return
IF( [NewFault] =1, 0 , IF(_close_date=BLANK() ,1,  IF([Date] <_close_date,1,0)  ))
ClosedFault = var _close_date =  CALCULATE( MAX('Table'[Close]) , 'Table'[AssetID]=EARLIER('Table2'[AssetID]) , 'Table'[FaultID] =EARLIER('Table2'[FaultID]))

return
IF([Date] = _close_date ,1,0)

 

Then we can get the table you want to get :

vyueyunzhmsft_1-1691372661641.png

 

 

 

Thank you for your time and sharing, and thank you for your support and understanding of PowerBI! 

 

Best Regards,

Aniya Zhang

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly

Thanks, your solution works.

I have changed the duration to 7 days to have it week by week, day of day would give me too many records I think. 

amitchandak
Super User
Super User

@FilipVDR , Use this HR blog, but for existing (Active employee), use Strictly > and <

 

Power BI: HR Analytics - Employees as on Date : https://youtu.be/e6Y-l_JtCq4
https://community.powerbi.com/t5/Community-Blog/HR-Analytics-Active-Employee-Hire-and-Termination-tr...

 

 

Or file after signature

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.