cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
bourne2000
Helper IV
Helper IV

How to calculate new customers and repeated customers?

Hi 

 

I am having below table, which consists of customer ID and date. I calculated week number and weekday.

 

bourne2000_2-1637916808982.png

 

 

I would like to calculate new customer and repeated customers weekly basis. I need to use login date to calculate new customers and repeated customers. I checked other posts but no success

 

Can anyone advise me?

 

Attached is the sample pbix file https://we.tl/t-vF9b2y6IHg

1 ACCEPTED SOLUTION
v-zhangti
Community Support
Community Support

Hi, @bourne2000 

 

I have done the following operations on the basis of your attached pbix file.

Three calculated columns have been added.

 
Count = 
CALCULATE (
    COUNT ( sessions[customer_id] ),
    FILTER (
        sessions,
        [Week Num] <= EARLIER ( sessions[Week Num] )
            && [customer_id] = EARLIER ( sessions[customer_id] )
    )
)
Count = 
CALCULATE (
    COUNT ( sessions[customer_id] ),
    FILTER (
        sessions,
        [Week Num] <= EARLIER ( sessions[Week Num] )
            && [customer_id] = EARLIER ( sessions[customer_id] )
    )
)
New or Old = 
IF ( [Count] = [Min], "New", "Old" )

 

Take customer_id equals 6 as an example, when the Min column equals the Count column, it means he is the first time to appear, so New is output.

vzhangti_0-1638255620671.png

 

Measure:

New = 
CALCULATE (
    DISTINCTCOUNT ( sessions[customer_id] ),
    FILTER (
        sessions,
        [New or Old] = "New"
            && [Week Number] = MAX ( sessions[Week Number] )
    )
)
Old = 
CALCULATE (
    DISTINCTCOUNT ( sessions[customer_id] ),
    FILTER (
        sessions,
        [New or Old] = "Old"
            && [Week Number] = MAX ( sessions[Week Number] )
    )
)

vzhangti_1-1638255808868.png

 

Best Regards,

Community Support Team _Charlotte

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-zhangti
Community Support
Community Support

Hi, @bourne2000 

 

I have done the following operations on the basis of your attached pbix file.

Three calculated columns have been added.

 
Count = 
CALCULATE (
    COUNT ( sessions[customer_id] ),
    FILTER (
        sessions,
        [Week Num] <= EARLIER ( sessions[Week Num] )
            && [customer_id] = EARLIER ( sessions[customer_id] )
    )
)
Count = 
CALCULATE (
    COUNT ( sessions[customer_id] ),
    FILTER (
        sessions,
        [Week Num] <= EARLIER ( sessions[Week Num] )
            && [customer_id] = EARLIER ( sessions[customer_id] )
    )
)
New or Old = 
IF ( [Count] = [Min], "New", "Old" )

 

Take customer_id equals 6 as an example, when the Min column equals the Count column, it means he is the first time to appear, so New is output.

vzhangti_0-1638255620671.png

 

Measure:

New = 
CALCULATE (
    DISTINCTCOUNT ( sessions[customer_id] ),
    FILTER (
        sessions,
        [New or Old] = "New"
            && [Week Number] = MAX ( sessions[Week Number] )
    )
)
Old = 
CALCULATE (
    DISTINCTCOUNT ( sessions[customer_id] ),
    FILTER (
        sessions,
        [New or Old] = "Old"
            && [Week Number] = MAX ( sessions[Week Number] )
    )
)

vzhangti_1-1638255808868.png

 

Best Regards,

Community Support Team _Charlotte

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

amitchandak
Super User
Super User

@bourne2000 , use a date table and create week there with Week rank

 

new columns
Week Start date = 'Date'[Date]+-1*WEEKDAY('Date'[Date],2)+1
Week End date = 'Date'[Date]+ 7-1*WEEKDAY('Date'[Date],2)
Week Rank = RANKX(all('Date'),'Date'[Week Start date],,ASC,Dense)
OR
Week Rank = RANKX(all('Date'),'Date'[Year Week],,ASC,Dense) //YYYYWW format

 

Then have measure like

 

This Week = CALCULATE(sum('Table'[Qty]), FILTER(ALL('Date'),'Date'[Week Rank]=max('Date'[Week Rank])))
Last Week = CALCULATE(sum('Table'[Qty]), FILTER(ALL('Date'),'Date'[Week Rank]=max('Date'[Week Rank])-1))

 

 


New Customer = COUNTX(filter(Customer, ISBLANK([Last Week]) && Not(ISBLANK([This Week]))) , Customer[Name])
Lost Customer = COUNTX(filter(Customer, not(ISBLANK([Last Week])) && (ISBLANK([This Week]))) , Customer[Name])
Retained Customer = COUNTX(filter(Customer, not(ISBLANK([Last Week])) && NOT(ISBLANK([This Week]))) , Customer[Name])

 

 

refer

Customer Retention Part 1:
https://community.powerbi.com/t5/Community-Blog/Customer-Retention-Part-1-Month-on-Month-Retention/b...

Did I answer your question? Mark my post as a solution! Appreciate your Kudos!! !!
Dashboard of My Blogs !! Connect on Linkedin
Want To Learn Power BI
Learn Power BI Beginners !! Advance Power BI Concepts !! Power BI For Tableau User !! Learn Power BI in Hindi !!
Proud to be a Super User!

Helpful resources

Announcements
2022 Release Wave 1 760x460.png

2022 Release Wave 1 Plan

Power Platform release plan for the 2022 release wave 1 describes all new features releasing from April 2022 through September 2022.

Power BI December 2021 Update_carousel 768x460.jpg

Check it Out!

Click here to read more about the December 2021 Updates!

User Group Leader Meeting January 768x460.png

Calling all User Group Leaders!

Don't miss the User Group Leader meetings on January, 24th & 25th, 2022.

Jan 2022 Dev Camp 768x460 copy.png

Power BI Dev Camp- January 27th, 2022

Mark your calendars and join us for our next Power BI Dev Camp!

Top Solution Authors
Top Kudoed Authors