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
Naresh91
Employee
Employee

How to Count the Lost Customers as per the his Latest status

Hi,

I have the below table

 

Cust-IDCust-StatusDate
1In1/2/2020
2Lost1/5/2020
3In1/3/2020
1Lost1/4/2020
4Lost1/2/2020
2In1/6/2020

 

Want to count the "Cust-ID"s who have "Cust-Status" as both "In" ,"Lost" and Latest "Cust-Status" is "Lost".

 

Output of the above table should be 1 as only "Cust-ID" =1 is having the "Cust-Status" as Both "In and Lost" and  Latest "Cust-Status" is "Lost".

2 REPLIES 2
jameszhang0805
Resolver IV
Resolver IV

Calculate Measure Version:

#LostCus = 
VAR _CusWithNumStatus =
    GROUPBY (
        'Table',
        'Table'[Cust-ID],
        "@NumOfStatus", SUMX ( CURRENTGROUP (), 1 )
    )
VAR _Customer =
    ADDCOLUMNS (
        _CusWithNumStatus,
        "@Status",
            CALCULATE (
                MAX ( 'Table'[Cust-Status] ),
                GENERATE (
                    KEEPFILTERS( VALUES ( 'Table'[Cust-ID] ) ),
                    CALCULATETABLE( TOPN ( 1, VALUES ( 'Table'[Date] ), 'Table'[Date] ) )
                )
            )
    )
VAR _LostCus = FILTER ( _Customer, [@Status] = "Lost")
VAR _LostCus2Status = FILTER(_LostCus , [@NumOfStatus] = 2 )
RETURN
    COUNTROWS( _LostCus2Status )
CNENFRNL
Community Champion
Community Champion

@Naresh91 , Power Query, DAX and Excel formula, all of them do the trick with ease.

 

Power Query solution,

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlTSUfLMAxJGBkYGugaGugZGSrE60UpGQCGf/OISZBlTsIwxhg5jsLghFh0mYBkTLDIIW1DNMlOKjQUA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Cust-ID" = _t, #"Cust-Status" = _t, Date = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Cust-ID", Int64.Type}, {"Cust-Status", type text}, {"Date", type date}}),
    #"Grouped Rows" = Table.Group(#"Changed Type", {"Cust-ID"}, {{"Chk", each Table.Sort(_, {"Date", Order.Ascending})}}),
    #"Lost Customer" = Table.TransformColumns(
        #"Grouped Rows", 
        {
            "Chk", 
            each let column = [#"Cust-Status"] 
                in if List.Last(column)="Lost" and List.ContainsAll(column, {"In","Lost"}) then "Lost Customer" else ""
        }
    )
in
    #"Lost Customer"

Screenshot 2021-03-10 042903.png

 

DAX calculated column,

Screenshot 2021-03-10 044745.png

 

Excel array formula, our oldie but goodie, also my favorite,

=IF((SUM(--(IF([Cust-ID]=[@[Cust-ID]],[Cust-Status])={"In","Lost"}))=2)*(INDEX([Cust-Status],MATCH(99999,[Date]/([Cust-ID]=[@[Cust-ID]])))="Lost"),"Lost Customer","")

Screenshot 2021-03-10 045042.png


Thanks to the great efforts by MS engineers to simplify syntax of DAX! Most beginners are SUCCESSFULLY MISLED to think that they could easily master DAX; but it turns out that the intricacy of the most frequently used RANKX() is still way beyond their comprehension!

DAX is simple, but NOT EASY!

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.

Top Solution Authors