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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
Krexx
Helper I
Helper I

Filter table based on date slicer, but one fieldname need to show last 3 months too

Hello, i want to show sales of cars based on dateslicer. But for one brand i want to show also the last 3 months. 
My table contains three columns - For example: 

TypeBrandDate
CarBMW01-01-2020
CarMercedes02-03-2020

 

Now i would like to count all the types based on the brand and show it in a barchart. But for BMW they should also display the last 3 months based on the date slicer. When i choose 01/01/2020 - 31/12/2021, then it should display also data for BMW from 01/10/2019. Here is an example what i would like to achieve: 
Test_screen.png

Thanks in advance

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

Hi @Krexx 

I build a  table like yours to have a test.

1.png

Firstly, you need to build a calendar table.

Date = CALENDARAUTO()

Use calendar table to build a Slicer.

Then build a measure to achieve your goal.

Measure = 
VAR _MinDate =
    MINX ( 'Date', 'Date'[Date] )
VAR _MaxDate =
    MAXX ( 'Date', 'Date'[Date] )
VAR _Last3Month =
    EOMONTH ( _MinDate, -4 ) + 1
RETURN
    SUMX (
        'Table',
        IF (
            MAX ( 'Table'[Brand] ) = "BMW"
                && MAX ( 'Table'[Date] ) >= _Last3Month
                && MAX ( 'Table'[Date] ) <= _MaxDate,
            1,
            IF (
                MAX ( 'Table'[Brand] ) = "Mercedes"
                    && MAX ( 'Table'[Date] ) >= _MinDate
                    && MAX ( 'Table'[Date] ) <= _MaxDate,
                1,
                0
            )
        )
    )

Build a Clustered column chart and the result is as below.

Default:

2.png

Change the slicer between 2020/01/01 and 2020/12/31.

3.png

You can download the pbix file from this link: Filter table based on date slicer, but one fieldname need to show last 3 months too

 

Best Regards,

Rico Zhou

 

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

 

View solution in original post

3 REPLIES 3
v-rzhou-msft
Community Support
Community Support

Hi @Krexx 

I build a  table like yours to have a test.

1.png

Firstly, you need to build a calendar table.

Date = CALENDARAUTO()

Use calendar table to build a Slicer.

Then build a measure to achieve your goal.

Measure = 
VAR _MinDate =
    MINX ( 'Date', 'Date'[Date] )
VAR _MaxDate =
    MAXX ( 'Date', 'Date'[Date] )
VAR _Last3Month =
    EOMONTH ( _MinDate, -4 ) + 1
RETURN
    SUMX (
        'Table',
        IF (
            MAX ( 'Table'[Brand] ) = "BMW"
                && MAX ( 'Table'[Date] ) >= _Last3Month
                && MAX ( 'Table'[Date] ) <= _MaxDate,
            1,
            IF (
                MAX ( 'Table'[Brand] ) = "Mercedes"
                    && MAX ( 'Table'[Date] ) >= _MinDate
                    && MAX ( 'Table'[Date] ) <= _MaxDate,
                1,
                0
            )
        )
    )

Build a Clustered column chart and the result is as below.

Default:

2.png

Change the slicer between 2020/01/01 and 2020/12/31.

3.png

You can download the pbix file from this link: Filter table based on date slicer, but one fieldname need to show last 3 months too

 

Best Regards,

Rico Zhou

 

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

 

Greg_Deckler
Super User
Super User

@Krexx - Sorry, having trouble following, can you post sample data as text and expected output?

 

Maybe Complex Selector? https://community.powerbi.com/t5/Quick-Measures-Gallery/The-Complex-Selector/m-p/1116633#M534


Not really enough information to go on, please first check if your issue is a common issue listed here: https://community.powerbi.com/t5/Community-Blog/Before-You-Post-Read-This/ba-p/1116882

Also, please see this post regarding How to Get Your Question Answered Quickly: https://community.powerbi.com/t5/Community-Blog/How-to-Get-Your-Question-Answered-Quickly/ba-p/38490

The most important parts are:
1. Sample data as text, use the table tool in the editing bar
2. Expected output from sample data
3. Explanation in words of how to get from 1. to 2.


@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
The Definitive Guide to Power Query (M)

DAX is easy, CALCULATE makes DAX hard...
amitchandak
Super User
Super User

@Krexx , not very clear

 

You can use rolling 3

Rolling 3 = CALCULATE(sum(Sales[Sales Amount]),DATESINPERIOD('Date'[Date],ENDOFMONTH(Sales[Sales Date]),-3,MONTH))
Rolling 3 = CALCULATE(sum(Sales[Sales Amount]),DATESINPERIOD('Date'[Date ],MAX(Sales[Sales Date]),-3,MONTH))
Rolling 3 = CALCULATE(sum(Sales[Sales Amount]),DATESINPERIOD('Date'[Date ],MAX('Date'[Date ]),-3,MONTH))

 

or this approach

https://www.youtube.com/watch?v=duMSovyosXE

 

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

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