Fabric is Generally Available. Browse Fabric Presentations. Work towards your Fabric certification with the Cloud Skills Challenge.
Hello,
I have a the following use case:
On the one hand I have employees, where the working hours per week changing from a specific starting date.
On the other hand I have a table, where all changes are posted for each employee with starting date and working hours week.
In my report, I have two single slicers, one for the year ie. 2019, 2020 etc. and one for the months 1 - 12
My challenge now is calculating the active value for working hours per week depending on the Date Filter of the slicers.
Table Employee
Table Workscheme
What would I expect?
Example 1:
Date Filter (of slicer): February 2019
Example 2:
Date Filter (of slicer): May 2019
I tried several approaches with LASTNONBLANK, LASTDATE etc., but none of them worked properly.
Does anybody have an idea how to handle this issue?
Thank you in advance 🙂
Stefan
Solved! Go to Solution.
Hi @SFeldmann ,
Firstly, you need to create a new table to save date.
Date = CALENDAR ( MIN ( 'Table'[Starting Date] ), MAX ( 'Table'[Starting Date] ) )
Then create a column to be compared with Starting date.
YM = VALUE ( 'Date'[Date].[Year] & FORMAT ( 'Date'[Date], "mm" ) )
Now, you can create a new measure “Hours Week”.
Hours Week = VAR selectDate = SELECTEDVALUE ( 'Date'[YM], MIN ( 'Date'[YM] ) ) RETURN CALCULATE ( SELECTEDVALUE ( 'Table'[Working Hours Week] ), FILTER ( 'Table', VALUE ( FORMAT ( 'Table'[Starting Date], "yyyymm" ) ) = VALUE ( FORMAT ( CALCULATE ( MAX ( 'Table'[Starting Date] ), ALLEXCEPT ( 'Table', 'Table'[Employee Code] ), selectDate >= VALUE ( FORMAT ( 'Table'[Starting Date], "yyyymm" ) ) ), "yyyymm" ) ) ) )
At last, you can use slicer to filter your table.
Best Regards,
Eads
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi @SFeldmann ,
Firstly, you need to create a new table to save date.
Date = CALENDAR ( MIN ( 'Table'[Starting Date] ), MAX ( 'Table'[Starting Date] ) )
Then create a column to be compared with Starting date.
YM = VALUE ( 'Date'[Date].[Year] & FORMAT ( 'Date'[Date], "mm" ) )
Now, you can create a new measure “Hours Week”.
Hours Week = VAR selectDate = SELECTEDVALUE ( 'Date'[YM], MIN ( 'Date'[YM] ) ) RETURN CALCULATE ( SELECTEDVALUE ( 'Table'[Working Hours Week] ), FILTER ( 'Table', VALUE ( FORMAT ( 'Table'[Starting Date], "yyyymm" ) ) = VALUE ( FORMAT ( CALCULATE ( MAX ( 'Table'[Starting Date] ), ALLEXCEPT ( 'Table', 'Table'[Employee Code] ), selectDate >= VALUE ( FORMAT ( 'Table'[Starting Date], "yyyymm" ) ) ), "yyyymm" ) ) ) )
At last, you can use slicer to filter your table.
Best Regards,
Eads
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi @v-eachen-msft,
Thank you for your solution, that works totally fine.
One final comment that has to be considered to this solution: They must be no relationship between the Date[Date] and the Workscheme[Starting Date].
Best Regards,
Stefan
Check out the November 2023 Power BI update to learn about new features.
Read the latest Fabric Community announcements, including updates on Power BI, Synapse, Data Factory and Data Activator.