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
Anonymous
Not applicable

Generate running time based on stoppages recorded

Dear community,

 

Quite new to the PowerBI land & this community.. I have posted same message today but I foolishly deleted.

 

I kindly ask for your support/help or any suggestion/idea is highly appreciated.

I am trying to generate a table or rows in same table for the actual running time of a machine based on the following information I have:

  • running on a daily basis (except weekends: Saturday & Sundays) from 7h00 am to 15h00 am
  • total stoppages (due to breakdowns/maintenance or whatever the reason) recorded as below screen shot:info available.PNG 

 

 

 

 

 

 

 

 

 

What I want to generate looks like below:

desired info.PNG

 

 

 

 

 

 

Thank you so much in advance for your kindly support! 

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

Hi @Anonymous ,

 

With what I have learned, I tried my best to finish.

 

1.Create two calculated columns in sample data table.

DATE DEBUT DATE = DATE(YEAR([DATE DEBUT]),MONTH([DATE DEBUT]),DAY([DATE DEBUT]))
NEW RANK =
VAR _RANK =
    RANKX (
        FILTER ( 'Table', [DATE DEBUT DATE] = EARLIER ( 'Table'[DATE DEBUT DATE] ) ),
        [DATE DEBUT],
        ,
        ASC,
        DENSE
    )
RETURN
    SWITCH (
        [DATE DEBUT DATE],
        DATE ( 2020, 9, 1 ), "A" & _RANK,
        DATE ( 2020, 9, 2 ), "B" & _RANK,
        DATE ( 2020, 9, 3 ), "C" & _RANK
    )

1.png

 

2.Create a calculated table and create calculated columns in it.

Table1 =
ADDCOLUMNS (
    UNION (
        SELECTCOLUMNS (
            'Table',
            "DATE DEBUT", [DATE FIN],
            "DATE FIN", [DATE DEBUT],
            "RANK", [NEW RANK]
        ),
        ROW ( "DATE DEBUT", "2020-9-1 7:00", "DATE FIN", BLANK (), "INDEX", "A0" ),
        ROW ( "DATE DEBUT", "2020-9-2 7:00", "DATE FIN", BLANK (), "INDEX", "B0" ),
        ROW ( "DATE DEBUT", "2020-9-3 7:00", "DATE FIN", BLANK (), "INDEX", "C0" ),
        ROW ( "DATE DEBUT", BLANK (), "DATE FIN", "2020-9-1 15:00", "INDEX", "A4" ),
        ROW ( "DATE DEBUT", BLANK (), "DATE FIN", "2020-9-2 15:00", "INDEX", "B3" ),
        ROW ( "DATE DEBUT", BLANK (), "DATE FIN", "2020-9-3 15:00", "INDEX", "C6" )
    ),
    "SUB", LEFT ( [RANK], 1 )
)
NEW DATE DEBUT = CALCULATE(MAX('Table1'[DATE DEBUT]),FILTER(ALLEXCEPT('Table1','Table1'[SUB]),[RANK]<EARLIER('Table1'[RANK])))
DURATION = [DATE FIN]-[NEW DATE DEBUT]

2.png

 

3.Create another calculated table which is the result. 

Table2 = 
ADDCOLUMNS (
    FILTER (
        SELECTCOLUMNS (
            'Table1',
            "DATE DEBUT", [NEW DATE DEBUT],
            "DATE FIN", [DATE FIN],
            "DURATION", [DURATION]
        ),
        NOT ( ISBLANK ( [DATE DEBUT] ) )
    ),
    "RUNNING TIME", "RUNNING TIME"
)

 3.png

 

You can check more details from here.

 

 

Best Regards,

Stephen Tao

 

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

1 REPLY 1
v-stephen-msft
Community Support
Community Support

Hi @Anonymous ,

 

With what I have learned, I tried my best to finish.

 

1.Create two calculated columns in sample data table.

DATE DEBUT DATE = DATE(YEAR([DATE DEBUT]),MONTH([DATE DEBUT]),DAY([DATE DEBUT]))
NEW RANK =
VAR _RANK =
    RANKX (
        FILTER ( 'Table', [DATE DEBUT DATE] = EARLIER ( 'Table'[DATE DEBUT DATE] ) ),
        [DATE DEBUT],
        ,
        ASC,
        DENSE
    )
RETURN
    SWITCH (
        [DATE DEBUT DATE],
        DATE ( 2020, 9, 1 ), "A" & _RANK,
        DATE ( 2020, 9, 2 ), "B" & _RANK,
        DATE ( 2020, 9, 3 ), "C" & _RANK
    )

1.png

 

2.Create a calculated table and create calculated columns in it.

Table1 =
ADDCOLUMNS (
    UNION (
        SELECTCOLUMNS (
            'Table',
            "DATE DEBUT", [DATE FIN],
            "DATE FIN", [DATE DEBUT],
            "RANK", [NEW RANK]
        ),
        ROW ( "DATE DEBUT", "2020-9-1 7:00", "DATE FIN", BLANK (), "INDEX", "A0" ),
        ROW ( "DATE DEBUT", "2020-9-2 7:00", "DATE FIN", BLANK (), "INDEX", "B0" ),
        ROW ( "DATE DEBUT", "2020-9-3 7:00", "DATE FIN", BLANK (), "INDEX", "C0" ),
        ROW ( "DATE DEBUT", BLANK (), "DATE FIN", "2020-9-1 15:00", "INDEX", "A4" ),
        ROW ( "DATE DEBUT", BLANK (), "DATE FIN", "2020-9-2 15:00", "INDEX", "B3" ),
        ROW ( "DATE DEBUT", BLANK (), "DATE FIN", "2020-9-3 15:00", "INDEX", "C6" )
    ),
    "SUB", LEFT ( [RANK], 1 )
)
NEW DATE DEBUT = CALCULATE(MAX('Table1'[DATE DEBUT]),FILTER(ALLEXCEPT('Table1','Table1'[SUB]),[RANK]<EARLIER('Table1'[RANK])))
DURATION = [DATE FIN]-[NEW DATE DEBUT]

2.png

 

3.Create another calculated table which is the result. 

Table2 = 
ADDCOLUMNS (
    FILTER (
        SELECTCOLUMNS (
            'Table1',
            "DATE DEBUT", [NEW DATE DEBUT],
            "DATE FIN", [DATE FIN],
            "DURATION", [DURATION]
        ),
        NOT ( ISBLANK ( [DATE DEBUT] ) )
    ),
    "RUNNING TIME", "RUNNING TIME"
)

 3.png

 

You can check more details from here.

 

 

Best Regards,

Stephen Tao

 

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

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.