Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Get Fabric Certified for FREE during Fabric Data Days. Don't miss your chance! Learn more

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
Fabric Data Days Carousel

Fabric Data Days

Advance your Data & AI career with 50 days of live learning, contests, hands-on challenges, study groups & certifications and more!

October Power BI Update Carousel

Power BI Monthly Update - October 2025

Check out the October 2025 Power BI update to learn about new features.

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.

Top Solution Authors