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
AdityaPowerBI
Helper II
Helper II

Filtering based on filtered values

Hi All,

 

I am stuck in a problem. Here are the details. I have a sales data which has sales with customer name and order date fields. I need to count customer which were active 4 months ago but are not active now. Basically I need to find lost values. E.g

If my data set has maximum order date as 30th November then 4 month ago i.e July 1st to July 31 who were the active customer then and out of those how many are active now. The difference is lost customers.
Data
Customer  Date

A              2nd July
B               4th July
C               10th July
D                20th July
A                10th November
B                  20th November
Here A,B,C,D were active 4 months ago but now only A and B are active. Basically we have 2 lost customer. I want to filter based on filtered active customer.        

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

Hi @AdityaPowerBI ,

You can create a calculated column as below:

Active customer = 
VAR _maxorddate =
    CALCULATE ( MAX ( 'Table'[Date] ), ALL ( 'Table' ) )
RETURN
    CALCULATE (
        MAX ( 'Table'[Customer] ),
        FILTER (
            SUMMARIZE (
                'Table',
                'Table'[Customer],
                "ConL", CALCULATE ( MAX ( 'Table'[Date] ), ALLEXCEPT ( 'Table', 'Table'[Customer] ) )
            ),
            DATEDIFF ( [ConL], _maxorddate, MONTH ) < 4
        )
    )

Filtering based on filtered values.JPGIf the above one is not applicable for your scenario, please provide your expected result with more explanation. Thank you.

Best Regards

Community Support Team _ Rena
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

2 REPLIES 2
v-yiruan-msft
Community Support
Community Support

Hi @AdityaPowerBI ,

You can create a calculated column as below:

Active customer = 
VAR _maxorddate =
    CALCULATE ( MAX ( 'Table'[Date] ), ALL ( 'Table' ) )
RETURN
    CALCULATE (
        MAX ( 'Table'[Customer] ),
        FILTER (
            SUMMARIZE (
                'Table',
                'Table'[Customer],
                "ConL", CALCULATE ( MAX ( 'Table'[Date] ), ALLEXCEPT ( 'Table', 'Table'[Customer] ) )
            ),
            DATEDIFF ( [ConL], _maxorddate, MONTH ) < 4
        )
    )

Filtering based on filtered values.JPGIf the above one is not applicable for your scenario, please provide your expected result with more explanation. Thank you.

Best Regards

Community Support Team _ Rena
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
amitchandak
Super User
Super User

@AdityaPowerBI , With the help from date table and time intelligence . Create measures like

 

MTD Sales = CALCULATE(SUM(Sales[Sales Amount]),DATESMTD('Date'[Date]))
last MTD Sales = CALCULATE(SUM(Sales[Sales Amount]),DATESMTD(dateadd('Date'[Date],-4,MONTH)))

 

Not active now = countx(values(Table[Customer]), if(isblank([MTD Sales]) && not(isblank(last MTD Sales)),Table[Customer], blank()))

 

To get the best of the time intelligence function. Make sure you have a date calendar and it has been marked as the date in model view. Also, join it with the date column of your fact/s. Refer :radacad sqlbi My Video Series Appreciate your Kudos.

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.