cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Highlighted
Dharani_98
Frequent Visitor

Time And Date In Power BI Desktop

I wanted to create a calculated column that returns the total working hours based on the starting Date.The result of my calculated

column should be [9,4:30,13].

i.e B worked for 9 hours on 6-4-2020

                        4:30 hours on 7-4-2020

                        13 hours on 8-4-2020.

 

Another Calculated Column for Salary If working from 8 am to 5pm each hour we pay a different salary (say 100 per hour).

Similarly while working from 5.01 pm to 7:59 am a different amount should be paid for each hour(say 200 per hour). 

Thus the Result of this calculated column should be

on 6-4-2020 it is 1050(from 9:30 am to 5:00 pm it is 750 and from 5:00pm to 6:30 pm it is 300)

on 7-4-2020 it is 900 (from 7:30 pm to 12:00 am it is 900)

on 8-4-2020 it is 1850 (from 12:00 am to 4:00 am it is 800 and again from 9:30 am to 6:30 pm it is 1050)

EmployeeStartDate and TimeEnd Date And Time
b06-04-2020 09:30:0006-04-2020 18:30:00
b07-04-2020 19:30:0008-04-2020 04:00:00
b08-04-2020 09:30:0008-04-2020 18:30:00
   

 

kindly help me out with dax calculation for the required two calculated columns.

1 ACCEPTED SOLUTION

Accepted Solutions
Community Support
Community Support

Re: Time And Date In Power BI Desktop

Hi @Dharani_98 ,

 

I create a Measure, not a Calculated Column. Please check:

 

1. Create [StartDate] column. 

StartDate = DATEVALUE('Table'[StartDate and Time])

startdate.PNG

 

2. Create a Calendar table.

Calendar = 
CALENDAR (
    MINX ( 'Table', DATEVALUE ( 'Table'[StartDate and Time] ) ),
    MAXX ( 'Table', DATEVALUE ( 'Table'[End Date And Time] ) )
)

calendar.PNG

 

3. Create relationship.

relationships.jpg

 

4. Create [Rank_] measure.

Rank_ =
RANKX (
    ALLSELECTED ( 'Table' ),
    CALCULATE ( MAX ( 'Table'[StartDate] ) ),
    ,
    ASC,
    DENSE
)

 

5. Create [Salary Measure].

Salary Measure = 
VAR LastRank = [Rank_] - 1
VAR LastStartDateTime =
    CALCULATE (
        MAX ( 'Table'[StartDate and Time] ),
        FILTER ( ALLSELECTED ( 'Table' ), [Rank_] = LastRank )
    )
VAR LastEndDateTime =
    CALCULATE (
        MAX ( 'Table'[End Date And Time] ),
        FILTER ( ALLSELECTED ( 'Table' ), [Rank_] = LastRank )
    )
VAR LastDateDiff =
    DATEDIFF ( LastStartDateTime, LastEndDateTime, DAY )
VAR ThisDateDiff =
    DATEDIFF (
        MAX ( 'Table'[StartDate and Time] ),
        MAX ( 'Table'[End Date And Time] ),
        DAY
    )
VAR StartDateTime =
    IF (
        LastDateDiff = 1,
        CONVERT (
            DATEVALUE ( MAX ( 'Table'[StartDate and Time] ) ) & " "
                & TIME ( 0, 0, 0 ),
            DATETIME
        ),
        MAX ( 'Table'[StartDate and Time] )
    )
VAR EndDateTime =
    IF (
        ThisDateDiff = 1,
        CONVERT (
            DATEVALUE ( MAX ( 'Table'[End Date And Time] ) ) & " "
                & TIME ( 0, 0, 0 ),
            DATETIME
        ),
        MAX ( 'Table'[End Date And Time] )
    )
VAR SpecifiedStartTime =
    CONVERT (
        DATEVALUE ( MAX ( 'Table'[StartDate and Time] ) ) & " "
            & TIME ( 8, 0, 0 ),
        DATETIME
    )
VAR SpecifiedEndTime =
    CONVERT (
        DATEVALUE ( MAX ( 'Table'[StartDate and Time] ) ) & " "
            & TIME ( 17, 0, 0 ),
        DATETIME
    )
VAR Result =
    IF (
        LastDateDiff = 1,
        IF (
            EndDateTime > SpecifiedStartTime
                && EndDateTime <= SpecifiedEndTime,
            DATEDIFF ( StartDateTime, LastEndDateTime, MINUTE ) / 60 * 200
                + DATEDIFF ( MAX ( 'Table'[StartDate and Time] ), EndDateTime, MINUTE ) / 60 * 100,
            IF (
                EndDateTime > SpecifiedEndTime,
                DATEDIFF ( StartDateTime, LastEndDateTime, MINUTE ) / 60 * 200
                    + DATEDIFF ( MAX ( 'Table'[StartDate and Time] ), SpecifiedEndTime, MINUTE ) / 60 * 100
                    + DATEDIFF ( SpecifiedEndTime, EndDateTime, MINUTE ) / 60 * 200
            )
        ),
        IF (
            LastDateDiff <> 1,
            IF (
                StartDateTime >= SpecifiedStartTime
                    && EndDateTime <= SpecifiedEndTime,
                DATEDIFF ( StartDateTime, EndDateTime, MINUTE ) / 60 * 100,
                IF (
                    StartDateTime >= SpecifiedStartTime
                        && StartDateTime < SpecifiedEndTime
                        && EndDateTime > SpecifiedEndTime,
                    DATEDIFF ( StartDateTime, SpecifiedEndTime, MINUTE ) / 60 * 100
                        + DATEDIFF ( SpecifiedEndTime, EndDateTime, MINUTE ) / 60 * 200,
                    IF (
                        StartDateTime >= SpecifiedEndTime,
                        DATEDIFF ( StartDateTime, EndDateTime, MINUTE ) / 60 * 200
                    )
                )
            )
        )
    )
RETURN
    Result

 

6. Create a table visual.

salary.PNG

 

For more details, please check the attached PBIX file.

 

 

 

Best Regards,

Icey

 

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

4 REPLIES 4
Super User IV
Super User IV

Re: Time And Date In Power BI Desktop

Well, in general you will use DATEDIFF with HOUR

Sample data posted as text would be great.

---------------------------------------

Putting square pegs in round holes since 1972.

I have a NEW book! 
DAX Cookbook from Packt
Over 120 DAX Recipes!
Did I answer your question? Mark my post as a solution!

Proud to be a Datanaut!

Super User IV
Super User IV

Re: Time And Date In Power BI Desktop

Please see this post regarding How to Get Your Question Answered Quickly: https://community.powerbi.com/t5/Community-Blog/How-to-Get-Your-Question-Answered-Quickly/ba-p/38490


---------------------------------------

Putting square pegs in round holes since 1972.

I have a NEW book! 
DAX Cookbook from Packt
Over 120 DAX Recipes!
Did I answer your question? Mark my post as a solution!

Proud to be a Datanaut!

Community Support
Community Support

Re: Time And Date In Power BI Desktop

Hi @Dharani_98 ,

 

I create a Measure, not a Calculated Column. Please check:

 

1. Create [StartDate] column. 

StartDate = DATEVALUE('Table'[StartDate and Time])

startdate.PNG

 

2. Create a Calendar table.

Calendar = 
CALENDAR (
    MINX ( 'Table', DATEVALUE ( 'Table'[StartDate and Time] ) ),
    MAXX ( 'Table', DATEVALUE ( 'Table'[End Date And Time] ) )
)

calendar.PNG

 

3. Create relationship.

relationships.jpg

 

4. Create [Rank_] measure.

Rank_ =
RANKX (
    ALLSELECTED ( 'Table' ),
    CALCULATE ( MAX ( 'Table'[StartDate] ) ),
    ,
    ASC,
    DENSE
)

 

5. Create [Salary Measure].

Salary Measure = 
VAR LastRank = [Rank_] - 1
VAR LastStartDateTime =
    CALCULATE (
        MAX ( 'Table'[StartDate and Time] ),
        FILTER ( ALLSELECTED ( 'Table' ), [Rank_] = LastRank )
    )
VAR LastEndDateTime =
    CALCULATE (
        MAX ( 'Table'[End Date And Time] ),
        FILTER ( ALLSELECTED ( 'Table' ), [Rank_] = LastRank )
    )
VAR LastDateDiff =
    DATEDIFF ( LastStartDateTime, LastEndDateTime, DAY )
VAR ThisDateDiff =
    DATEDIFF (
        MAX ( 'Table'[StartDate and Time] ),
        MAX ( 'Table'[End Date And Time] ),
        DAY
    )
VAR StartDateTime =
    IF (
        LastDateDiff = 1,
        CONVERT (
            DATEVALUE ( MAX ( 'Table'[StartDate and Time] ) ) & " "
                & TIME ( 0, 0, 0 ),
            DATETIME
        ),
        MAX ( 'Table'[StartDate and Time] )
    )
VAR EndDateTime =
    IF (
        ThisDateDiff = 1,
        CONVERT (
            DATEVALUE ( MAX ( 'Table'[End Date And Time] ) ) & " "
                & TIME ( 0, 0, 0 ),
            DATETIME
        ),
        MAX ( 'Table'[End Date And Time] )
    )
VAR SpecifiedStartTime =
    CONVERT (
        DATEVALUE ( MAX ( 'Table'[StartDate and Time] ) ) & " "
            & TIME ( 8, 0, 0 ),
        DATETIME
    )
VAR SpecifiedEndTime =
    CONVERT (
        DATEVALUE ( MAX ( 'Table'[StartDate and Time] ) ) & " "
            & TIME ( 17, 0, 0 ),
        DATETIME
    )
VAR Result =
    IF (
        LastDateDiff = 1,
        IF (
            EndDateTime > SpecifiedStartTime
                && EndDateTime <= SpecifiedEndTime,
            DATEDIFF ( StartDateTime, LastEndDateTime, MINUTE ) / 60 * 200
                + DATEDIFF ( MAX ( 'Table'[StartDate and Time] ), EndDateTime, MINUTE ) / 60 * 100,
            IF (
                EndDateTime > SpecifiedEndTime,
                DATEDIFF ( StartDateTime, LastEndDateTime, MINUTE ) / 60 * 200
                    + DATEDIFF ( MAX ( 'Table'[StartDate and Time] ), SpecifiedEndTime, MINUTE ) / 60 * 100
                    + DATEDIFF ( SpecifiedEndTime, EndDateTime, MINUTE ) / 60 * 200
            )
        ),
        IF (
            LastDateDiff <> 1,
            IF (
                StartDateTime >= SpecifiedStartTime
                    && EndDateTime <= SpecifiedEndTime,
                DATEDIFF ( StartDateTime, EndDateTime, MINUTE ) / 60 * 100,
                IF (
                    StartDateTime >= SpecifiedStartTime
                        && StartDateTime < SpecifiedEndTime
                        && EndDateTime > SpecifiedEndTime,
                    DATEDIFF ( StartDateTime, SpecifiedEndTime, MINUTE ) / 60 * 100
                        + DATEDIFF ( SpecifiedEndTime, EndDateTime, MINUTE ) / 60 * 200,
                    IF (
                        StartDateTime >= SpecifiedEndTime,
                        DATEDIFF ( StartDateTime, EndDateTime, MINUTE ) / 60 * 200
                    )
                )
            )
        )
    )
RETURN
    Result

 

6. Create a table visual.

salary.PNG

 

For more details, please check the attached PBIX file.

 

 

 

Best Regards,

Icey

 

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

Dharani_98
Frequent Visitor

Re: Time And Date In Power BI Desktop

Thank You So much.It was a Great Help.

Helpful resources

Announcements
Announcing the New Spanish Forum

Announcing the New Spanish Forum

Do you need help in Spanish? Check out our new Spanish community section.

MBAS Gallery 2020

MBAS Gallery 2020

Watch Microsoft Business Applications Summit sessions on-demand.

‘Better Together’ Integration Forum Launch

‘Better Together’ Integration Forum Launch

We've launched a how-to forum where you can learn about how Power BI integrates with other Power Platform products.

Top Solution Authors
Top Kudoed Authors