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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
Anonymous
Not applicable

filter for values for all years after starting year

dear all,

I have an ID that has an starting date and ending date. I would like to have a year filter on my report which filters all the values that are between (or equal <= and >=).

How can i do this?

best

1 ACCEPTED SOLUTION

HI @Anonymous ,

I'd like to suggest you to add a calendar table(no relationship to current table) as source of slicer and write a measure formula to filter and concatenate and display all matched years.

Measure =
VAR selected =
    MAX ( 'calendar'[Date] )
VAR _calendar =
    CALCULATETABLE (
        CALENDAR (
            MIN ( 'Table'[Start] ),
            IF (
                MAX ( 'Table'[End] ) <> BLANK (),
                MAX ( 'Table'[End] ),
                MAXX ( ALLSELECTED ( 'Table'[End] ), [End] )
            )
        ),
        VALUES ( 'Table'[ID] )
    )
RETURN
    CONCATENATEX (
        DISTINCT (
            SELECTCOLUMNS (
                FILTER ( _calendar, [Date] >= selected ),
                "Year", YEAR ( [Date] )
            )
        ),
        [Year],
        ","
    )

71.gif

Regards,

Xiaoxin Sheng

Community Support Team _ Xiaoxin
If this post helps, please consider accept as solution to help other members find it more quickly.

View solution in original post

2 REPLIES 2
Anonymous
Not applicable

To further extend my explanation, i hereby have an example of what my data looks like:

IDStartEnd
A1-1-201531-12-2018
B1-6-2017null
C31-7-20198-2-2022

 

and how i would like to show it:

So in a year filter with all the years (or relevant years) from my datetable:

IDTo appear in year filter
A2015, 2016, 2017, 2018
B2017… (and all years in datetable)
C2019, 2020, 2021, 2022

HI @Anonymous ,

I'd like to suggest you to add a calendar table(no relationship to current table) as source of slicer and write a measure formula to filter and concatenate and display all matched years.

Measure =
VAR selected =
    MAX ( 'calendar'[Date] )
VAR _calendar =
    CALCULATETABLE (
        CALENDAR (
            MIN ( 'Table'[Start] ),
            IF (
                MAX ( 'Table'[End] ) <> BLANK (),
                MAX ( 'Table'[End] ),
                MAXX ( ALLSELECTED ( 'Table'[End] ), [End] )
            )
        ),
        VALUES ( 'Table'[ID] )
    )
RETURN
    CONCATENATEX (
        DISTINCT (
            SELECTCOLUMNS (
                FILTER ( _calendar, [Date] >= selected ),
                "Year", YEAR ( [Date] )
            )
        ),
        [Year],
        ","
    )

71.gif

Regards,

Xiaoxin Sheng

Community Support Team _ Xiaoxin
If this post helps, please consider accept as solution to help other members find it more quickly.

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

Find out what's new and trending in the Fabric Community.