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

Get certified in Microsoft Fabric—for free! For a limited time, get a free DP-600 exam voucher to use by the end of 2024. Register now

Reply
Dan_Sprague
Advocate I
Advocate I

Need advice on a slicing requirement puzzle

Hi all,

I have an awkward slicer/filtering requirement and need advice.  

My data looks like this:

StaffSalesCountry
Bob5US
Fred33US
Sue85US
Fred45Mexico
Sue34Canada
Bob99Spain
Bob21Mexico

 

I need to have a slicer on country.  Now the tricky part is that when a user selects a country, the results need to include the country they selected AND show any other countries where the staff had sales. 

 

For example, with the above data, if the user selected Canada in the slicer, the results should be this below, since Sue was the only one with sales in Canada, and Sue also had sales in Germany. 

 

StaffSalesCountry
Sue34Canada
Sue85Germany

 

If the user selected US, all data should show, (nothing filtered out), since each staff had sales in US.

 

So when a user selects a country, they should see wichever staff had sales in that country, and wherever else the staff had sales.  

 

Any advice is greatly appreciated!

1 ACCEPTED SOLUTION

Hi @Dan_Sprague 

 

Please see the attached file with a solution included, you will need to create a country dimension table for it to work and place a country column in a table visual.

measure = 
VAR __staff = CALCULATETABLE( VALUES( 'Table'[Staff] ), ALLEXCEPT( 'Table', 'Table'[Country] ) ) 
RETURN 
CALCULATE(
    SUM( 'Table'[Sales] ),
    ALL( 'Table'[Country] ),
    KEEPFILTERS( 'Table'[Staff] IN __staff )
)

for reference

image.png

 

Best Regards,
Mariusz

If this post helps, then please consider Accepting it as the solution.

Please feel free to connect with me.
LinkedIn

 

View solution in original post

3 REPLIES 3
amitchandak
Super User
Super User

@Dan_Sprague , try one of the two

measure =
var _staff = distinct(filter(all(Table[Staff]), table[Country] in allselected(table[Country])))
return
calculate(sum(sales),filter(all(Table), Table[Staff] in _staff))


measure =
calculate(sum(sales),filter(all(Table), Table[Staff] in allselected(table[Staff])))

Join us as experts from around the world come together to shape the future of data and AI!
At the Microsoft Analytics Community Conference, global leaders and influential voices are stepping up to share their knowledge and help you master the latest in Microsoft Fabric, Copilot, and Purview.
️ November 12th-14th, 2024
 Online Event
Register Here

Thanks @amitchandak.  Apparently I didn't explain my problem efficiently. 

 

In my PBI report the visual used to show the data is a matrix.  I have a slicer on country.  

When a country is chosen, the matrix needs to show the details of each staff with sales in that country, AND, other rows (for other countries) that each staff had sales in.  

 

I don't need a sum of all sales in all countries, but need to show the details of each country.

Hi @Dan_Sprague 

 

Please see the attached file with a solution included, you will need to create a country dimension table for it to work and place a country column in a table visual.

measure = 
VAR __staff = CALCULATETABLE( VALUES( 'Table'[Staff] ), ALLEXCEPT( 'Table', 'Table'[Country] ) ) 
RETURN 
CALCULATE(
    SUM( 'Table'[Sales] ),
    ALL( 'Table'[Country] ),
    KEEPFILTERS( 'Table'[Staff] IN __staff )
)

for reference

image.png

 

Best Regards,
Mariusz

If this post helps, then please consider Accepting it as the solution.

Please feel free to connect with me.
LinkedIn

 

Helpful resources

Announcements
November Carousel

Fabric Community Update - November 2024

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

Live Sessions with Fabric DB

Be one of the first to start using Fabric Databases

Starting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.

Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.

Nov PBI Update Carousel

Power BI Monthly Update - November 2024

Check out the November 2024 Power BI update to learn about new features.