cancel
Showing results for 
Search instead for 
Did you mean: 

Fabric is Generally Available. Browse Fabric Presentations. Work towards your Fabric certification with the Cloud Skills Challenge.

Reply
SFeldmann
Frequent Visitor

Filtering the last valid record dynamically

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

2019-08-09_11h55_19.png

 

Table Workscheme

2019-08-09_11h56_46.png

 

What would I expect?

Example 1:

Date Filter (of slicer): February 2019

2019-08-09_12h01_21.png

 

2019-08-09_12h01_53.png

 

Example 2:

Date Filter (of slicer): May 2019

2019-08-09_12h06_38.png

 

2019-08-09_12h06_58.png

 

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

 

1 ACCEPTED SOLUTION
v-eachen-msft
Community Support
Community Support

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.4-1.PNG

 

Best Regards,

Eads

 

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Community Support Team _ Eads
If this post helps, then please consider Accept it as the solution to help the other members find it.

View solution in original post

2 REPLIES 2
v-eachen-msft
Community Support
Community Support

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.4-1.PNG

 

Best Regards,

Eads

 

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Community Support Team _ Eads
If this post helps, then please consider Accept it as the solution to help the other members find it.

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

Helpful resources

Announcements
PBI November 2023 Update Carousel

Power BI Monthly Update - November 2023

Check out the November 2023 Power BI update to learn about new features.

Community News

Fabric Community News unified experience

Read the latest Fabric Community announcements, including updates on Power BI, Synapse, Data Factory and Data Activator.

Dashboard in a day with date

Exclusive opportunity for Women!

Join us for a free, hands-on Microsoft workshop led by women trainers for women where you will learn how to build a Dashboard in a Day!

Power BI Fabric Summit Carousel

The largest Power BI and Fabric virtual conference

130+ sessions, 130+ speakers, Product managers, MVPs, and experts. All about Power BI and Fabric. Attend online or watch the recordings.

Top Solution Authors
Top Kudoed Authors