cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Highlighted
Anonymous
Not applicable

Get the list of User form the previous month not included in the range.

aka churn in my company.

 

Let say I have a transaction table with timestamp, amount... and userId.
I have a filter context for the time with a slicer and my goal is to count (later having the list of) the number of users who have made a payment in the previous month of the lower date range who isn't present in the list of actual user who paied (is that clear enough?)

I end up writting somethinng like (association == user):

Churn =
VAR previousMinMonth =
    MONTH ( MIN ( 'Date'[Date] ) ) - 1
VAR listOfAssociationIdInRange =
    DISTINCT ( Paiements[id_association] )
VAR ListOfAssociationIdInTargetedMonth =
    CALCULATE (
        DISTINCT ( ALL ( Paiements[id_association] ) ),
        FILTER (
            Paiements,
            Paiements[date] >= previousMinMonth
                && Paiements[date] < MIN ( 'Date'[Date] )
        )
    )
RETURN
    COUNTROWS ( ListOfAssociationIdInTargetedMonth )



I think I'm not that far with this but it's currently not working.

1 ACCEPTED SOLUTION

Accepted Solutions
Highlighted
Anonymous
Not applicable

Re: Get the list of User form the previous month not included in the range.

I finally could have the measure I wanted with :

Churn = 
VAR previousMinMonth =
    PREVIOUSMONTH ( 'Date'[Date] )
VAR listOfAssociationIdInRange =
    DISTINCT( Paiements[id_association])
VAR ListOfAssociationIdInTargetedMonth =
    CALCULATETABLE(
        DISTINCT( Paiements[id_association] ),
        FILTER (
            ALL ( Paiements ),
            Paiements[date] >= STARTOFMONTH ( previousMinMonth ) && Paiements[date] <= ENDOFMONTH( previousMinMonth )
        )
    )
VAR excludedTable =
    EXCEPT ( ListOfAssociationIdInTargetedMonth, listOfAssociationIdInRange )
RETURN
    COUNTROWS(excludedTable)

Thanks @Greg_Deckler for the hints.

View solution in original post

5 REPLIES 5
Highlighted
Super User IV
Super User IV

Re: Get the list of User form the previous month not included in the range.

Nope, not really all that clear. Sample data and expected output would be very helpful. 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.

 

You might check out Not In Common: https://community.powerbi.com/t5/Quick-Measures-Gallery/Not-In-Common/m-p/388273


---------------------------------------

Putting square pegs in round holes since 1972.

I have a NEW book! 
DAX Cookbook from Packt
Over 120 DAX Recipes!




Did I answer your question? Mark my post as a solution!

Proud to be a Super User!




Highlighted
Anonymous
Not applicable

Re: Get the list of User form the previous month not included in the range.

Here a sample of data.

dataTransactionSample.png

I'm targeting "date" as a date of payment and it's the distinct list of "id_association" that I try to get.

The simplified SQL equivalent of what i'm trying to do is :

SELECT DISTINCT 
       a.id, 
       a.nom, 
       aa.[state]
FROM dbo.paiement p
     JOIN dbo.association a ON a.id = p.id_association
     JOIN dbo.association_application aa ON aa.id_association = a.id
WHERE p.statut = 'AUTHORIZED'
      AND CONVERT(DATE, p.date) BETWEEN '2018-01-01' AND '2018-01-31'
      AND NOT EXISTS
(
    SELECT 1
    FROM dbo.paiement p2
    WHERE p2.id_association = p.id_association
          AND p2.statut = 'AUTHORIZED'
          AND CONVERT(DATE, p2.date) BETWEEN '2018-02-01' AND '2019-01-31'
)
ORDER BY 3;

 

Highlighted
Super User IV
Super User IV

Re: Get the list of User form the previous month not included in the range.

OK, I believe a variation of Not In Common is what you are looking for. This makes a few assumptions but something along the lines of:

 

NotInCommon =
VAR __month = MONTH(TODAY())
VAR __year = YEAR(TODAY()) 
VAR __tableA = CALCULATETABLE(DISTINCT(Table[id_association]),FILTER(ALL('Table'),MONTH(MAX([Date])) = __month && YEAR(MAX([Date])) = __year))
VAR __tableB = CALCULATETABLE(DISTINCT(Table[id_association]),FILTER(ALL('Table'),MONTH(MAX([Date])) = __month - 1 && YEAR(MAX([Date])) = __year))
VAR __results = EXCEPT(__tableA,__tableB)
RETURN CONCATENATEX(__results,[id_association],",")

---------------------------------------

Putting square pegs in round holes since 1972.

I have a NEW book! 
DAX Cookbook from Packt
Over 120 DAX Recipes!




Did I answer your question? Mark my post as a solution!

Proud to be a Super User!




Highlighted
Anonymous
Not applicable

Re: Get the list of User form the previous month not included in the range.

That's helping me a lot thanks.

I explore and discover more and more new functions everyday with DAX and I find myself think of new possibilities.

 

Now I have this version of the measure, but I still have an issue in my variable `ListOfAssociationIdInTargetedMonth` :
A table of multiple values was supplied where a single value was expected.

I think it's my All(Paiements) that get triggered but I cannot see how do I have to modify this.

Churn =
VAR previousMinMonth =
    PREVIOUSMONTH ( 'Date'[Date] )
VAR listOfAssociationIdInRange =
    DISTINCT ( Paiements[id_association] )
VAR ListOfAssociationIdInTargetedMonth =
    CALCULATETABLE (
        DISTINCT ( Paiements[id_association] ),
        FILTER (
            ALL ( Paiements ),
            DATESBETWEEN (
                'Date'[Date],
                STARTOFMONTH ( previousMinMonth ),
                ENDOFMONTH ( previousMinMonth )
            )
        )
    )
VAR excludedTable =
    EXCEPT ( ListOfAssociationIdInTargetedMonth, listOfAssociationIdInRange )
RETURN
    COUNTROWS ( ListOfAssociationIdInTargetedMonth )
Highlighted
Anonymous
Not applicable

Re: Get the list of User form the previous month not included in the range.

I finally could have the measure I wanted with :

Churn = 
VAR previousMinMonth =
    PREVIOUSMONTH ( 'Date'[Date] )
VAR listOfAssociationIdInRange =
    DISTINCT( Paiements[id_association])
VAR ListOfAssociationIdInTargetedMonth =
    CALCULATETABLE(
        DISTINCT( Paiements[id_association] ),
        FILTER (
            ALL ( Paiements ),
            Paiements[date] >= STARTOFMONTH ( previousMinMonth ) && Paiements[date] <= ENDOFMONTH( previousMinMonth )
        )
    )
VAR excludedTable =
    EXCEPT ( ListOfAssociationIdInTargetedMonth, listOfAssociationIdInRange )
RETURN
    COUNTROWS(excludedTable)

Thanks @Greg_Deckler for the hints.

View solution in original post

Helpful resources

Announcements
Community Blog

Community Blog

Visit our Community Blog for articles, guides, and information created by fellow community members.

Using the Community

Using the Community

Need help with the Power BI Community? Our 'Using the Community' support articles are a great place to start.

Community Summit North America

Community Summit North America

Innovate, Collaborate, Grow. The top training and networking event across the globe for Microsoft Business Applications

Power Platform 2020 release wave 2 plan

Power Platform 2020 release wave 2 plan

Features releasing from October 2020 through March 2021

Top Solution Authors
Top Kudoed Authors