March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early bird discount ends December 31.
Register NowBe one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now
Hi all,
I have an awkward slicer/filtering requirement and need advice.
My data looks like this:
Staff | Sales | Country |
Bob | 5 | US |
Fred | 33 | US |
Sue | 85 | US |
Fred | 45 | Mexico |
Sue | 34 | Canada |
Bob | 99 | Spain |
Bob | 21 | Mexico |
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.
Staff | Sales | Country |
Sue | 34 | Canada |
Sue | 85 | Germany |
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!
Solved! Go to 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
@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])))
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
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions.
Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.
User | Count |
---|---|
133 | |
91 | |
88 | |
64 | |
58 |
User | Count |
---|---|
201 | |
137 | |
107 | |
72 | |
68 |