
DAX offers powerful way to analyze “new” vs. “returning” customers. In this article learn easy and simple DAX measure patterns to count number of new customers and number of returning customers from your data.
What is a Returning Customer?

A returning customer is someone who comes back to our business and does another transaction. For example, in the above illustration, CUST-001 and CUST-004 are repeat or returning customers.
What is a NEW customer?
A new customer is someone who is doing their first transaction with us. In the above example data, all other customers (except CUST-001 & CUST-004) are technically NEW CUSTOMERS.
Note: A new customer today might be a returning customer in future.
DAX measures for calculating new vs. returning customer counts
All the measures in this example are based on a simple “Data” table with 4 columns – Customer ID, Date, Order Qty and Product Name.

Customer Count Measure
=Customer Count = DISTINCTCOUNT(data[Customer ID])This is a simple distinct count measure that tells us how many distinct customers transacted with us. When used with a the context of a date or product we will get the number of customers per each.
Returning Customer Count Measure
Returning Customer Count =
var custs = DISTINCT(data[Customer ID])
var curr_date = LASTDATE(data[Date])
return
sumX(custs, CALCULATE([Customer Count], data[Date]<curr_date))This measure tells us how many returning customers are there for the context of current “time-period”.
How this returning customer count works?
Imagine the below output and let’s focus on the second row.

- For the date context of 6-January
- We create custs variable which gives us all the 92 customer IDs.
- The curr_date variable tells us the latest date – i.e. 6-January.
- We then iterate for each of the customers in custs table and calculate the [Customer Count] prior to the curr_date. This would be 1 if the customer has previously transacted with us and 0 otherwise.
- The SUMX adds up all these values (ie all 1s) and tells us 33, which is the number of returning customers.
New Customers Measure
New Customers = [Customer Count] - [Returning Customer Count]If you already have both the total [customer count] and [returning customer count], you can easily subtract one from another to get the [new customers] count.
But if you don’t have the [returning customer count] or just want to directly calculate the [new customers], you can use below DAX measure.
New Customer Count - direct =
var custs = DISTINCT(data[Customer ID])
var curr_date = LASTDATE(data[Date])
return
SUMX(custs, IF(CALCULATE([Customer Count], data[Date] < curr_date)=0,1,0))The above measure uses the same approach as [Returning Customer Count] but flips the logic inside SUMX by using the IF function to negate the CALCULATE result.
Returning Customers in Last 4 Weeks or similar

While the above [Returning Customer Count] works flawlessly, it may not be realistic to consider a customer to be returning if they rarely transact. So a more realistic calculation would be to consider a customer to be returning if they did some business in the last 4 weeks (or x periods). Here is the DAX pattern for that.
Returning Customers in Last 4 Weeks =
var custs = DISTINCT(data[Customer ID])
var curr_date = LASTDATE(data[Date])
var start_date = DATEADD(curr_date,-28,DAY)
return
SUMX(custs, CALCULATE([Customer Count], data[Date]<curr_date && data[Date]>=start_date))In this case, we simply calculate the “start_date” for our calculation window as well. Here I have used 28 days as an example, but you can easily change this to any window size.
Then we apply the same SUMX logic but modify the filter context in the CALCULATE to check both boundaries of the dates.
Why not do this analysis in SQL or somewhere upstream?

When I mentioned about this approach to my wife Jo, she said, why not do this in SQL directly and tag each customer as “new” or “returning”?
Here is why I prefer to do this with DAX:
- Business Rule Flexibility: With DAX based approach, we can easily change the business rule surrounding who is a returning customer. For example, we can use the 4 week window like above easily.
- Interactivity: We can add a product slicer (see below) to analyze which customers returned to purchase the same product. This is incredibly helpful to understand customer loyalty and campaign effectiveness.
Of course, there are advantages with SQL approach too. Mainly,
- SQL tagging is faster: Unlike DAX calculations which run in real-time & client-side, SQL calculations are done once and at server side. When you have millions or billions of records, doing SUMX in real-time is going to be slow.
- Consistency: Applying customer tagging at server side in the data layer means the business rule & logic is consistently applied for every report.
Sample Power BI Workbook:
If you want to play with these measures and understand the calculation better, check out the sample PBIX file here.
In conclusion
New vs. Returning Customer analysis is a must-have for customer analytics. The DAX required for this is easy to implement and works beautifully. Try this analysis to understand the effectiveness of marketing campaigns (lead gen, customer capture) and loyalty programs (reward points, notifications). Using a time-window based calculations (ex: 4 weeks) is a great way to understand customer behavior and purchasing patterns.














11 Responses to “Fix Incorrect Percentages with this Paste-Special Trick”
I've just taught yesterday to a colleague of mine how to convert amounts in local currency into another by pasting special the ROE.
great thing to know !!!
Chandoo - this is such a great trick and helps save time. If you don't use this shortcut, you have to take can create a formula where =(ref cell /100), copy that all the way down, covert it to a percentage and then copy/paste values to the original column. This does it all much faster. Nice job!
I was just asking peers yesterday if anyone know if an easy way to do this, I've been editing each cell and adding a % manually vs setting the cell to Percentage for months and just finally reached my wits end. What perfect timing! Thanks, great tip!
If it's just appearance you care about, another alternative is to use this custom number format:
0"%"
By adding the percent sign in quotes, it gets treated as text and won't do what you warned about here: "You can not just format the cells to % format either, excel shows 23 as 2300% then."
Dear Jon S. You are the reason I love the internet. 3 year old comments making my life easier.
Thank you.
Here is a quicker protocol.
Enter 10000% into the extra cell, copy this cell, select the range you need to convert to percentages, and use paste special > divide. Since the Paste > All option is selected, it not only divides by 10000% (i.e. 100), it also applies the % format to the cells being pasted on.
@Martin: That is another very good use of Divide / Multiply operations.
@Tony, @Jody: Thank you 🙂
@Jon S: Good one...
@Jon... now why didnt I think of that.. Excellent
Thank You so much. it is really helped me.
Big help...Thanks
Thanks. That really saved me a lot of time!
Is Show Formulas is turned on in the Formula Ribbon, it will stay in decimal form until that is turned off. Drove me batty for an hour until I just figured it out.