Microsoft Fabric Community Conference 2025, March 31 - April 2, Las Vegas, Nevada. Use code FABINSIDER for a $400 discount.
Register nowGet inspired! Check out the entries from the Power BI DataViz World Championships preliminary rounds and give kudos to your favorites. View the vizzies.
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)
Employee | StartDate and Time | End Date And Time |
b | 06-04-2020 09:30:00 | 06-04-2020 18:30:00 |
b | 07-04-2020 19:30:00 | 08-04-2020 04:00:00 |
b | 08-04-2020 09:30:00 | 08-04-2020 18:30:00 |
kindly help me out with dax calculation for the required two calculated columns.
Solved! Go to Solution.
Hi @Dharani_98 ,
I create a Measure, not a Calculated Column. Please check:
1. Create [StartDate] column.
StartDate = DATEVALUE('Table'[StartDate and Time])
2. Create a Calendar table.
Calendar =
CALENDAR (
MINX ( 'Table', DATEVALUE ( 'Table'[StartDate and Time] ) ),
MAXX ( 'Table', DATEVALUE ( 'Table'[End Date And Time] ) )
)
3. Create relationship.
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.
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.
Hi @Dharani_98 ,
I create a Measure, not a Calculated Column. Please check:
1. Create [StartDate] column.
StartDate = DATEVALUE('Table'[StartDate and Time])
2. Create a Calendar table.
Calendar =
CALENDAR (
MINX ( 'Table', DATEVALUE ( 'Table'[StartDate and Time] ) ),
MAXX ( 'Table', DATEVALUE ( 'Table'[End Date And Time] ) )
)
3. Create relationship.
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.
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.
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
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code FABINSIDER for a $400 discount!
Check out the February 2025 Power BI update to learn about new features.
User | Count |
---|---|
86 | |
71 | |
68 | |
50 | |
30 |
User | Count |
---|---|
119 | |
101 | |
73 | |
65 | |
40 |