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
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
Icey
Community Support
Community Support

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
Icey
Community Support
Community Support

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.

Thank You So much.It was a Great Help.

Greg_Deckler
Super User
Super User

Well, in general you will use DATEDIFF with HOUR

Sample data posted as text would be great.

@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
The Definitive Guide to Power Query (M)

DAX is easy, CALCULATE makes DAX hard...

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


@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
The Definitive Guide to Power Query (M)

DAX is easy, CALCULATE makes DAX hard...

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.