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
ROCKYBI12
Frequent Visitor

New/Lost/Returning/Loyal Customers

New/Lost/Returning/Loyal Customers
 

Hi!

 

I'm struggling to find a solution to catergorize new/returning/loyal customer over the years... I've tried different approaches posted on the community (script and expression), but the answers only give me the counts. I am thinking it might work using an IF formula in a created column . I need it on expression! I'll neded to select years on a filter, use it on graphs...

 

Definitions:

 

New - clients that never bought, and bought on the selected year.

Returning - clients that have bought in any year before, didn't bought the previous year, but bought the selected year.

Loyal - clients that bought previous year, and the selected year.

Important: The previous year is always compared to the selected year, not the actual year, like today...

 

The data (simplified):

CLIENTID

FISCAL YEAR

SALES DATE

SALES AMOUNT

 

Thank you!

(I cant share data file)

1 ACCEPTED SOLUTION
Icey
Community Support
Community Support

Hi @ROCKYBI12 ,

 

Please check if this is what you want:

Icey_0-1644401133866.png

Fiscal Year = 
IF (
    [Purchase Date] <= DATE ( YEAR ( [Purchase Date] ), 12, 21 ),
    RIGHT ( YEAR ( [Purchase Date] ) - 1, 2 ) & "-"
        & RIGHT ( YEAR ( [Purchase Date] ), 2 ),
    RIGHT ( YEAR ( [Purchase Date] ), 2 ) & "-"
        & RIGHT ( YEAR ( [Purchase Date] ) + 1, 2 )
)
Status = 
VAR CurCustomer = [Customer]
VAR CurFY = [Fiscal Year]
VAR PreFY =
    VALUE ( LEFT ( CurFY, 2 ) ) - 1 & "-"
        & VALUE ( RIGHT ( CurFY, 2 ) ) - 1
VAR PrePreFY =
    VALUE ( LEFT ( PreFY, 2 ) ) - 1 & "-"
        & VALUE ( RIGHT ( PreFY, 2 ) ) - 1
VAR Count_CurFY =
    DISTINCT (
        SUMMARIZE (
            FILTER ( Sheet1, [Fiscal Year] = CurFY && [Customer] = CurCustomer ),
            [Customer]
        )
    )
VAR Count_PreFY =
    DISTINCT (
        SUMMARIZE (
            FILTER ( Sheet1, [Fiscal Year] = PreFY && [Customer] = CurCustomer ),
            [Customer]
        )
    )
VAR Count_PrePreFY =
    DISTINCT (
        SUMMARIZE (
            FILTER ( Sheet1, [Fiscal Year] <= PrePreFY && [Customer] = CurCustomer ),
            [Customer]
        )
    )
RETURN
    SWITCH (
        TRUE (),
        Count_CurFY > 0
            && Count_PreFY = 0
            && Count_PrePreFY = 0, "New",
        Count_CurFY > 0
            && Count_PreFY > 0, "Renewed",
        Count_CurFY > 0
            && Count_PreFY = 0
            && Count_PrePreFY > 0, "Re-activated"
    )

Icey_1-1644401187521.png

 

 

Best Regards,

Icey

 

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

4 REPLIES 4
Icey
Community Support
Community Support

Hi @ROCKYBI12 ,

 

I can't find your requirements. It just shows blank. Could you show me your requirements again?

Icey_0-1644207642885.png

 

 

Best Regards,

Icey

  • need to categorize each customer to have a status for each fiscal year. I need to calculate new customer, renewed customer and reactivated customer.

 

New customer: First ever purchase in corresponding fiscal year.

Renewed Customer: Customer purchased in corresponding fiscal year and has made atleast one purchase in the year previous.

Re-activated Customer: Customer purchased in corresponding fiscal year and has made at least one purchase anytime before but not in the fiscal year pirior. 

 

Most solutions online only take into account using either previous month or # of days since last purchase. I have yet to find a solution that will work using FY (FYI FY is from my Date calender that I have added). I am open to any and all soultions. Thinking an IF formula could work. Thanks 

 

I cant share the data set but I have gave some examples below with the expected results (Status):

Fiscal YearDateCustomerStatus
20-2112/21/2021AReactivated
17-1812/21/2018AReactivated
15-1612/21/2016ANew
    
20-2112/21/2021BRenewed
19-2012/21/2020BReactivated
15-1612/21/2016BNew
Icey
Community Support
Community Support

Hi @ROCKYBI12 ,

 

Please check if this is what you want:

Icey_0-1644401133866.png

Fiscal Year = 
IF (
    [Purchase Date] <= DATE ( YEAR ( [Purchase Date] ), 12, 21 ),
    RIGHT ( YEAR ( [Purchase Date] ) - 1, 2 ) & "-"
        & RIGHT ( YEAR ( [Purchase Date] ), 2 ),
    RIGHT ( YEAR ( [Purchase Date] ), 2 ) & "-"
        & RIGHT ( YEAR ( [Purchase Date] ) + 1, 2 )
)
Status = 
VAR CurCustomer = [Customer]
VAR CurFY = [Fiscal Year]
VAR PreFY =
    VALUE ( LEFT ( CurFY, 2 ) ) - 1 & "-"
        & VALUE ( RIGHT ( CurFY, 2 ) ) - 1
VAR PrePreFY =
    VALUE ( LEFT ( PreFY, 2 ) ) - 1 & "-"
        & VALUE ( RIGHT ( PreFY, 2 ) ) - 1
VAR Count_CurFY =
    DISTINCT (
        SUMMARIZE (
            FILTER ( Sheet1, [Fiscal Year] = CurFY && [Customer] = CurCustomer ),
            [Customer]
        )
    )
VAR Count_PreFY =
    DISTINCT (
        SUMMARIZE (
            FILTER ( Sheet1, [Fiscal Year] = PreFY && [Customer] = CurCustomer ),
            [Customer]
        )
    )
VAR Count_PrePreFY =
    DISTINCT (
        SUMMARIZE (
            FILTER ( Sheet1, [Fiscal Year] <= PrePreFY && [Customer] = CurCustomer ),
            [Customer]
        )
    )
RETURN
    SWITCH (
        TRUE (),
        Count_CurFY > 0
            && Count_PreFY = 0
            && Count_PrePreFY = 0, "New",
        Count_CurFY > 0
            && Count_PreFY > 0, "Renewed",
        Count_CurFY > 0
            && Count_PreFY = 0
            && Count_PrePreFY > 0, "Re-activated"
    )

Icey_1-1644401187521.png

 

 

Best Regards,

Icey

 

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

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.