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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
rosh
Regular Visitor

Show top 10 customers age groups based on sales

Hi

 

I have the following dimension table:

 

CustomerIDAge bucketGender
130M
240F
340M
430M
520F
660M

 

And the following sales table: 

SalesIDCustomerIDSaleDate
115001/06/2021
215002/03/2021
322005/03/2021
4310002/04/2021
535025/05/2021
635011/03/2021
741014/03/2021
854002/01/2021
9615015/04/2021
10610002/02/2021

 

I want to be able to create a top N list by customer sales (top n is based on a slicer and sales data is filtered by a slicer). 

But then return those top N customers age bands in a histogram. 

 

Example: Top N = 2

Top customers:

CustomerIDTotal sales
3200
6250
1100

 

Age distribution of Top N
Count:Age
230
160

 

So far I can rank the total customer sales, but then if I try and count the ages, the count equals the total sales items instead of grouping by customer ID. 

5 REPLIES 5
parry2k
Super User
Super User

@rosh although you already have great solutions, some of them will not show the Total Sales of TopN correctly. Here is my solution and all the measures required to make it work:

 

Total = SUM( SALES[Sale] )

Top n Customers = 
CALCULATE ( 
    [TOTAL], 
    KEEPFILTERS ( 
        TOPN ( 
            [Parameter Value], 
            ALLSELECTED ( CUSTOMER ), 
            [Total Sales], 
            DESC 
        ) 
    ) 
)

Top n count = 
VAR __table = 
ADDCOLUMNS ( 
    ALLSELECTED ( CUSTOMER[CustomerID] ), 
    "@TopN", [Top n Customers] 
)
RETURN  
COUNTX ( __table, [@TopN] )

 

Check my latest blog post Comparing Selected Client With Other Top N Clients | PeryTUS  I would ❤ Kudos if my solution helped. 👉 If you can spend time posting the question, you can also make efforts to give Kudos to whoever helped to solve your problem. It is a token of appreciation!

Visit us at https://perytus.com, your one-stop-shop for Power BI-related projects/training/consultancy.

 

 



Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!

Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo

If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤


Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.

CNENFRNL
Community Champion
Community Champion

Screenshot 2021-06-26 201357.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!

Thanks, this almost works, but the problem is that my sales detail has more than one sales row per customer. So the above solution counts the age band of the same customer more than once. 

 

Any advice?

CNENFRNL
Community Champion
Community Champion

I didn't get your point; I used the above mockup dataset, which also containes more than one row for each customer.


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!

Jihwan_Kim
Super User
Super User

 

Picture1.png

 

Sales Total =
SUM(Sales[Sale])
 
Customers Count in the Age bucket =
VAR topNselect =
SELECTEDVALUE ( 'topN'[topN], 1 )
VAR _topNtablebyagebucket =
TOPN ( topNselect, ALL ( Customers[Age bucket] ), [Sales Total] )
RETURN
CALCULATE ( COUNTROWS ( Customers ), KEEPFILTERS ( _topNtablebyagebucket ) )
 
 
 

If this post helps, then please consider accepting it as the solution to help other members find it faster, and give a big thumbs up.


Go to My LinkedIn Page


Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

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