cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
pshah
Regular Visitor

Show Top N and sum up the Others as a value

I created a Rank column and a custom measure. I've filtered on Rank to show less than 11, so basically show me the top 10.

The custom measure is basically saying to show me when rank <= 5, then show Amount else Others.

 

Instead of "Others", is there a way to sum up the Amount value and end up only showing 6 rows. First 5 rows shows the top 5 countries, and then the 6th row sums up the countries that are ranked from 6 to 10.

 

2017-11-28_11-25-53.png

1 ACCEPTED SOLUTION
parry2k
Super User III
Super User III

Here is the solution:

 

1. Goto modelling tab and click new table and add following dax :

 

 

Country with other = UNION(Values('Dim - Country'[Country Name]), ROW("Country Name", "Others"))

it will create a new table with all the countries and addition country "Others"

 

2. Set relationship with this new country with your original table (it will be 1 to many)

 

3. change your country rank measure like this 

 

Ctry Rank = RANKX(ALL('Country with others'[Country Name]), 'Dim - Country'[Total])

4. Add new measure "Total with other" -> This is final measure we need

 

Total with other = 
if([Ctry Rank] <= 10, 'Dim - Country'[Total],
	if(HASONEVALUE('Country with others'[Country Name]), 
		if(values('Country with others'[Country Name]) = "Others", 
			sumx(filter(all('Country with others'[Country Name]), [Ctry Rank ] > 10),  'Dim - Country'[Total])
		)
	)
)

5. Add new table visual , drop country name from "Country with other table" and Total with other measure

 

I expect that you will top 10 countries with their value and rest should be all summed up with "Others"

 

PS - There could be typo in DAX expression, let me know if it doesn't work






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.





View solution in original post

13 REPLIES 13
barrybilewitz
Frequent Visitor

I adapted your formulae for media sales and it worked like a charm - thank you.

@barrybilewitz glad to hear






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.





Phil_Seamark
Microsoft
Microsoft

HI @pshah

 

Is your City Rank a calculated measure or a calculated column?  Can you please share the code you used for this.

 

For the 6th row, what you like to see in the 2nd and 3rd columns?


To learn more about DAX visit : aka.ms/practicalDAX

Proud to be a Datanaut!

Calculated measure -> Ctry Rank = RANKX(ALL('Dim - Country'[Country Name]), 'Dim - Country'[Total])

 

For the 6th row, I'd like to see "Others" in the 2nd and 3rd column, if that makes sense.

pshah
Regular Visitor

For the 4th column, I'd like to show the remaining amount on the 6th row.

 

Based on the screen shot, the math will come out to a little under 50m. So I'd like to show that amount / value in the 4th column and 6th row.

parry2k
Super User III
Super User III

Here is the solution:

 

1. Goto modelling tab and click new table and add following dax :

 

 

Country with other = UNION(Values('Dim - Country'[Country Name]), ROW("Country Name", "Others"))

it will create a new table with all the countries and addition country "Others"

 

2. Set relationship with this new country with your original table (it will be 1 to many)

 

3. change your country rank measure like this 

 

Ctry Rank = RANKX(ALL('Country with others'[Country Name]), 'Dim - Country'[Total])

4. Add new measure "Total with other" -> This is final measure we need

 

Total with other = 
if([Ctry Rank] <= 10, 'Dim - Country'[Total],
	if(HASONEVALUE('Country with others'[Country Name]), 
		if(values('Country with others'[Country Name]) = "Others", 
			sumx(filter(all('Country with others'[Country Name]), [Ctry Rank ] > 10),  'Dim - Country'[Total])
		)
	)
)

5. Add new table visual , drop country name from "Country with other table" and Total with other measure

 

I expect that you will top 10 countries with their value and rest should be all summed up with "Others"

 

PS - There could be typo in DAX expression, let me know if it doesn't work






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.





View solution in original post

Anonymous
Not applicable

Hallo @parry2k ,

your solution almost worked for me as well.

 

But I still don´t get the solution I need.

 

Top10Products.png

I get my Top 10 Products and the Rest (Sonstige), but sum is just the sum of Top 10 Products. But it should be round about 43 Millions.

I just changed the first measure, instead of Values I used Distinct. With Values I get circular dependencies.

 

All other measures like your measures.

 

I am thankfull for every help!

Christian

 

 

Can you please let me know how have got the column in Total with Other Measure after If condition.

if([rank]>10, table[cloumn name].

This is not right syntax right. Can you please correct me.

I Have 2 Columsn Products and sales. I want to get Top 5 rows  Dynamically and rest 5 as sum value in a single row. Can you please help me achive this. I was trying out the Steps but could not get it done.

ProductSales
A3
B4
C1
D5
E7
F8
G12
H9
I2
K10
Anonymous
Not applicable

Hi  Parry2K 

 

 

 

 

 

 

 

 

pshah
Regular Visitor

Thank you!! I'll try this, currently in DirectQuery mode so will have to Import. 

 

Will let you know if it worked or not.

parry2k
Super User III
Super User III

Sounds good. 






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.





pshah
Regular Visitor

Sorry for the very late reply but it worked! Thank you very much for the help!!!!

Helpful resources

Announcements
PBI User Groups

Welcome to the User Group Public Preview

Check out new user group experience and if you are a leader please create your group!

MBAS on Demand

Microsoft Business Applications Summit sessions

On-demand access to all the great content presented by the product teams and community members! #MSBizAppsSummit #CommunityRocks

MBAS Attendee Badge

Claim Your Badge & Digital Swag!

Check out how to claim yours today!

Top Solution Authors
Top Kudoed Authors