Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Enhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends August 31st. Request your voucher.

Reply
stephras
Frequent Visitor

Calculating percentiles of measures within a summarize, grouped by one columns values

Hi all,

So I'm very new to Power BI and DAX but doing my best to learn. 

 

I am currently trying to apply an RFM model to a very big set of customer and sales data spanning multiple countries.

So far I've managed just fine to set up measures for "Last Transaction Date", "Recency", "Frequency" and "Monetary".

 

And it works just fine when I do a summary of all customers and get their measures.

stephras_0-1655130163980.png

Also, based on the tutorials I've seen so far, it's easy enough to assign values based on the percentiles for a given measure.

Seen here for the Recency value.

stephras_1-1655130238581.png

 

However, this (of course) compares customers from different countries. As the customers may vary to a great extend I would like to group by country and then do the percentile calculation. 

 

I've tried a bunch of different ways but nothing really works (mostly because I don't really know what I am doing 😅).

My thoughts went something like these examples below, which are clearly not working.

 

Can anybody point me in the right direction? 

 

stephras_2-1655130727546.png

Or something like this, which at least gave a value, but totally wrong.

 

Any and all help would be greatly appreciated 🙂 

stephras_3-1655131168753.png

 

 

1 ACCEPTED SOLUTION
Anonymous
Not applicable

Hi  @stephras ,

Here are the steps you can follow:

1. Create calculated column.

New Recency Score =
SWITCH(
    TRUE(),
'Table'[Recency values]<=PERCENTILEX.INC(FILTER(ALL('Table'),'Table'[country]=EARLIER('Table'[country])),[Recency values],0.25),4,
'Table'[Recency values]<=PERCENTILEX.INC(FILTER(ALL('Table'),'Table'[country]=EARLIER('Table'[country])),[Recency values],0.5),3,
'Table'[Recency values]<=PERCENTILEX.INC(FILTER(ALL('Table'),'Table'[country]=EARLIER('Table'[country])),[Recency values],0.75),2,1)

2. Result:

vyangliumsft_0-1655347955646.png

 

Best Regards,

Liu Yang

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
Anonymous
Not applicable

Hi  @stephras ,

Here are the steps you can follow:

1. Create calculated column.

New Recency Score =
SWITCH(
    TRUE(),
'Table'[Recency values]<=PERCENTILEX.INC(FILTER(ALL('Table'),'Table'[country]=EARLIER('Table'[country])),[Recency values],0.25),4,
'Table'[Recency values]<=PERCENTILEX.INC(FILTER(ALL('Table'),'Table'[country]=EARLIER('Table'[country])),[Recency values],0.5),3,
'Table'[Recency values]<=PERCENTILEX.INC(FILTER(ALL('Table'),'Table'[country]=EARLIER('Table'[country])),[Recency values],0.75),2,1)

2. Result:

vyangliumsft_0-1655347955646.png

 

Best Regards,

Liu Yang

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

Thanks! it worked 🙂

Helpful resources

Announcements
July 2025 community update carousel

Fabric Community Update - July 2025

Find out what's new and trending in the Fabric community.

July PBI25 Carousel

Power BI Monthly Update - July 2025

Check out the July 2025 Power BI update to learn about new features.