Join us at FabCon Atlanta from March 16 - 20, 2026, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.
Register now!The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more
Hi all,
i am handling a query that includes information about employees and their working times / shift. There are regulatory requirements that in 7 days the working time is not allowed to be higher than 60 hours. This i want to analyze.
To the query: In total there are over 50 employees from which 20-30 work every day. Hence, per year there are around 10.000-15.000 lines. In the query the working time for every day and every employee is listed. See following (shorted) example:
| Date | Name | Working Time |
| 01.01.2024 | Employee1 | 10,7 |
| 01.01.2024 | Employee2 | 10,7 |
| 01.01.2024 | Employee3 | 10,7 |
| 01.01.2024 | Employee4 | 10,7 |
| 01.01.2024 | Employee9 | 7,5 |
| 02.01.2024 | Employee5 | 10,7 |
| 02.01.2024 | Employee6 | 10,7 |
| 02.01.2024 | Employee1 | 10,7 |
| 02.01.2024 | Employee2 | 10,7 |
| 02.01.2024 | Employee9 | 7,5 |
| 03.01.2024 | Employee7 | 10,7 |
| 03.01.2024 | Employee8 | 10,7 |
| 03.01.2024 | Employee5 | 10,7 |
| 03.01.2024 | Employee6 | 10,7 |
| 03.01.2024 | Employee9 | 7,5 |
| 04.01.2024 | Employee3 | 10,7 |
| 04.01.2024 | Employee4 | 5,35 |
| 04.01.2024 | Employee7 | 10,7 |
| 04.01.2024 | Employee8 | 10,7 |
| 05.01.2024 | Employee1 | 10,7 |
| 05.01.2024 | Employee2 | 10,7 |
| 05.01.2024 | Employee3 | 10,7 |
| 05.01.2024 | Employee4 | 10,7 |
| 06.01.2024 | Employee5 | 10,7 |
| 06.01.2024 | Employee6 | 10,7 |
| 06.01.2024 | Employee1 | 10,7 |
| 06.01.2024 | Employee2 | 10,7 |
| 07.01.2024 | Employee7 | 5,35 |
| 07.01.2024 | Employee8 | 10,7 |
| 07.01.2024 | Employee5 | 10,7 |
| 07.01.2024 | Employee6 | 10,7 |
| 08.01.2024 | Employee3 | 10,7 |
| 08.01.2024 | Employee4 | 10,7 |
| 08.01.2024 | Employee7 | 10,7 |
| 08.01.2024 | Employee8 | 5,35 |
I need to add a column now that calculates the sum of working times of that employee over the last 7 days. Result would look like this:
| Date | Name | Working Time | Sum7Day |
| 07.01.2024 | Employee5 | 10,7 | 42,8 |
| 07.01.2024 | Employee6 | 10,7 | 42,8 |
| 08.01.2024 | Employee3 | 10,7 | 32,1 |
| 08.01.2024 | Employee4 | 10,7 | 26,75 |
| 08.01.2024 | Employee7 | 10,7 | 37,45 |
| 08.01.2024 | Employee8 | 5,35 | 37,45 |
Together with an AI tool i managed to get a working M code. That included an index column (same dates have the same index number):
Sorted = Table.Sort(Source, {{"Name", Order.Ascending}, {"Index", Order.Ascending}}),
7DaySum = Table.AddColumn(Sorted, "Sum7Day", each
let
CurrentIndex = [Index],
CurrentName = [Name],
StartIndex = if CurrentIndex - 6 < 1 then 1 else CurrentIndex - 6,
Last7Rows = Table.SelectRows(Sorted,
each [Name] = CurrentName and [Index] >= StartIndex and [Index] <= CurrentIndex),
Summe = List.Sum(7DaySum[Working Time])
in
Summe)
The code is very computationally intensive and therefore takes a very long time. Hence, i was hoping there was a better method to achieve this calculation.
Thanks in advance,
seppel123
Solved! Go to Solution.
Hi @seppel123 ,
I did the logic using DAX, try to use this DAX code:
Measure =
VAR Nome = SELECTEDVALUE(WorkingTimes[Name])
VAR CurrentDate = MAX(WorkingTimes[Date])
RETURN
CALCULATE(
SUM(WorkingTimes[Working Time]),
WorkingTimes[Name] = Nome,
WorkingTimes[Date] <= CurrentDate &&
WorkingTimes[Date] > CurrentDate - 7
)
You can achieve the same by the M code bellow:
let
Source = YourTable, // Replace "YourTable" with the name of your table
AddedCustom = Table.AddColumn(Source, "Sum7Day", each
let
CurrentName = [Name],
CurrentDate = [Date],
FilteredRows = Table.SelectRows(Source, each
[Name] = CurrentName and
[Date] >= Date.AddDays(CurrentDate, -6) and
[Date] <= CurrentDate
),
RollingSum = List.Sum(FilteredRows[Working Time])
in
RollingSum
)
in
AddedCustom
See the output bellow:
If this help you, please consider to accept as solution and give a kudo.
Thank you
Hi @seppel123 ,
I did the logic using DAX, try to use this DAX code:
Measure =
VAR Nome = SELECTEDVALUE(WorkingTimes[Name])
VAR CurrentDate = MAX(WorkingTimes[Date])
RETURN
CALCULATE(
SUM(WorkingTimes[Working Time]),
WorkingTimes[Name] = Nome,
WorkingTimes[Date] <= CurrentDate &&
WorkingTimes[Date] > CurrentDate - 7
)
You can achieve the same by the M code bellow:
let
Source = YourTable, // Replace "YourTable" with the name of your table
AddedCustom = Table.AddColumn(Source, "Sum7Day", each
let
CurrentName = [Name],
CurrentDate = [Date],
FilteredRows = Table.SelectRows(Source, each
[Name] = CurrentName and
[Date] >= Date.AddDays(CurrentDate, -6) and
[Date] <= CurrentDate
),
RollingSum = List.Sum(FilteredRows[Working Time])
in
RollingSum
)
in
AddedCustom
See the output bellow:
If this help you, please consider to accept as solution and give a kudo.
Thank you
Thank you, that works!
Is it also possible to count how often this measure calculates > 60h for a treemap visulation?
Best regards
seppel123
why for last 7 days ,only contains date 07.01 and 08.01?
Proud to be a Super User!
Hi,
the result is just an example. The shown shorted query has only 8 days, so on day 7 and 8 we can sum over 7 days for sum of the employees. Thats why i shorted it.
Best regards
seppel123
Hi,
thank you for the help! I need the sum for every date, so i could plot it at the end:
Diagram is from the actual data. Each color is a name.
With the measure that did not work. Later on, i also wanted to count how often >60h per 7 days happened and visualize via treemap...
Maybe the real dataset is needed:
Best regards
seppel123
The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!
| User | Count |
|---|---|
| 39 | |
| 38 | |
| 38 | |
| 28 | |
| 27 |
| User | Count |
|---|---|
| 124 | |
| 88 | |
| 73 | |
| 66 | |
| 65 |