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

The ultimate Microsoft Fabric, Power BI, Azure AI & SQL learning event! Join us in Las Vegas from March 26-28, 2024. Use code MSCUST for a $100 discount. Register Now

Reply
chq
Helper II
Helper II

Trying To Build A Slicer With "And"

Hello,

I am trying to get the following dataset to output the number of ID#'s that meet a set of Type critera ... Ideally I would like to be able to toggle how many ID#s purchased "Theatre and Opera" or "Business AND Theatre"

ID#TypeAmount
2Theatre$50
14Theatre$50
14Business$10000
2Opera$65
14Opera$95

 

Desired Outcome:

Slicer: Theatre AND Opera
Distinct Count ID#= 2
Total Spend#= $260

Slicer: Theatre AND Business

Distinct Count ID#= 1

Total Spend#= $10050


It is important that people are able to filter by the Types of their choosing as it will be used for multiple departments. Any ideas?

 

2 ACCEPTED SOLUTIONS
MartynRamsden
Solution Sage
Solution Sage

Hi @chq 

 

Try the following measures:

Count IDs =
VAR SelTypes = VALUES( Table1[Type] )
VAR CountSelTypes = COUNTROWS( SelTypes )
VAR Result =
COUNTROWS(
    FILTER(
        ADDCOLUMNS(
            VALUES( Table1[ID#] ),
            "@TypeCount", CALCULATE( DISTINCTCOUNT( Table1[Type] ), VALUES( Table1[Type] ) )
        ),
        [@TypeCount] = CountSelTypes
    )
)
RETURN Result
Total Value =
VAR SelTypes = VALUES( Table1[Type] )
VAR CountSelTypes = COUNTROWS( SelTypes )
VAR Result =
SUMX(
    FILTER(
        ADDCOLUMNS(
            VALUES( Table1[ID#] ),
            "@TypeCount", CALCULATE( DISTINCTCOUNT( Table1[Type] ), VALUES( Table1[Type] ) ),
            "@Value", CALCULATE( SUM( Table1[Amount] ) )
        ),
        [@TypeCount] = CountSelTypes
    ),
    [@Value]
)
RETURN Result

 

Best regards,
Martyn


If I answered your question, please help others by accepting it as a solution.

View solution in original post

PaulDBrown
Community Champion
Community Champion

@chq 

Here is an alternative solution:

The model:model.JPG

 1) calculate the ditinctcount of types in the data table:

 

Distinctcount Types = DISTINCTCOUNT('DataTable'[Type])

 

2) calculate the Distinctcount based on the slicer selection (AND condition):

 

Distinctcount = 
VAR Ids = COUNTROWS('Type Slicer')

RETURN
CALCULATE(DISTINCTCOUNT('DataTable'[ID#]); 
            FILTER(ALLSELECTED('DataTable'[ID#]);
            Ids = [Distinctcount Types]))

 

3) Calculate the Amount based on the slicer selection (condition AND);

 

Amount for selected Types = CALCULATE([Sum of Amount];
                            FILTER('ID Slicer';
                            [Distinctcount] >0))

 

And you get this (The "ID" filed in the table visual is from the "ID Slicer" table):

results 1.JPG

 

results 2.JPG

 

and here is the PBIX file if you're interested:

Slicer with AND condition 





Did I answer your question? Mark my post as a solution!
In doing so, you are also helping me. Thank you!

Proud to be a Super User!
Paul on Linkedin.






View solution in original post

5 REPLIES 5
PaulDBrown
Community Champion
Community Champion

@chq 

Here is an alternative solution:

The model:model.JPG

 1) calculate the ditinctcount of types in the data table:

 

Distinctcount Types = DISTINCTCOUNT('DataTable'[Type])

 

2) calculate the Distinctcount based on the slicer selection (AND condition):

 

Distinctcount = 
VAR Ids = COUNTROWS('Type Slicer')

RETURN
CALCULATE(DISTINCTCOUNT('DataTable'[ID#]); 
            FILTER(ALLSELECTED('DataTable'[ID#]);
            Ids = [Distinctcount Types]))

 

3) Calculate the Amount based on the slicer selection (condition AND);

 

Amount for selected Types = CALCULATE([Sum of Amount];
                            FILTER('ID Slicer';
                            [Distinctcount] >0))

 

And you get this (The "ID" filed in the table visual is from the "ID Slicer" table):

results 1.JPG

 

results 2.JPG

 

and here is the PBIX file if you're interested:

Slicer with AND condition 





Did I answer your question? Mark my post as a solution!
In doing so, you are also helping me. Thank you!

Proud to be a Super User!
Paul on Linkedin.






MartynRamsden
Solution Sage
Solution Sage

Hi @chq 

 

Try the following measures:

Count IDs =
VAR SelTypes = VALUES( Table1[Type] )
VAR CountSelTypes = COUNTROWS( SelTypes )
VAR Result =
COUNTROWS(
    FILTER(
        ADDCOLUMNS(
            VALUES( Table1[ID#] ),
            "@TypeCount", CALCULATE( DISTINCTCOUNT( Table1[Type] ), VALUES( Table1[Type] ) )
        ),
        [@TypeCount] = CountSelTypes
    )
)
RETURN Result
Total Value =
VAR SelTypes = VALUES( Table1[Type] )
VAR CountSelTypes = COUNTROWS( SelTypes )
VAR Result =
SUMX(
    FILTER(
        ADDCOLUMNS(
            VALUES( Table1[ID#] ),
            "@TypeCount", CALCULATE( DISTINCTCOUNT( Table1[Type] ), VALUES( Table1[Type] ) ),
            "@Value", CALCULATE( SUM( Table1[Amount] ) )
        ),
        [@TypeCount] = CountSelTypes
    ),
    [@Value]
)
RETURN Result

 

Best regards,
Martyn


If I answered your question, please help others by accepting it as a solution.

parry2k
Super User
Super User

@chq something is not clear in your output, in case of 2nd choice, Theatre and Business, isn't the distinct ID count will be 2 instead of 1? 



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.

No as only ID# 14 will meet the AND requirements.

@chq so based on Ids are common in the selected Type ,  dont think it means distinct 



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.

Helpful resources

Announcements
Fabric Community Conference

Microsoft Fabric Community Conference

Join us at our first-ever Microsoft Fabric Community Conference, March 26-28, 2024 in Las Vegas with 100+ sessions by community experts and Microsoft engineering.

February 2024 Update Carousel

Power BI Monthly Update - February 2024

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

Fabric Career Hub

Microsoft Fabric Career Hub

Explore career paths and learn resources in Fabric.

Fabric Partner Community

Microsoft Fabric Partner Community

Engage with the Fabric engineering team, hear of product updates, business opportunities, and resources in the Fabric Partner Community.

Top Solution Authors