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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
Titatovenaar2
Helper III
Helper III

DAX Measure: Show ID's where Column B has multiple values for Column A

Hi,

 

I have a simple table like this:

IDCat1Cat2
1A01
2A02
3B01
4C01
5D01
6D01

 

I want to view the records where Cat1 has multiple values for Cat2.

Which should look like the following, because only for Cat1 A, Cat2 has multiple values.

IDCat1Cat2Measure
1A011
2A021
3B010
4C010
5D010
6D010

 

The following DAX shows the correct COUNT, but when placed in the above table, it shows BLANK values. It does not show 1's or 0's per row. This makes sense, because the measure is on the level of Cat1. How to change the DAX in a way to view 1's and 0's per row on the level of column 'ID'?

 

 

COUNTROWS(
    FILTER(
        ADDCOLUMNS(
            SUMMARIZE(
                'Table'
                ,'Table'[Cat1]
            )
            ,"CNT Cat2",CALCULATE(DISTINCTCOUNT('Table'[Cat2]))
        ),[CNT Cat2] > 1
    )
)

 

I need a measure instead of a calculated column in this model.

 

Does anyone have any suggestion how to tackle this?

Kind regards,

1 ACCEPTED SOLUTION
Jihwan_Kim
Super User
Super User

Hi,

Please check the below picture and the attached pbix file.

 

Jihwan_Kim_0-1671447821349.png

 

 

Expected outcome measure: =
VAR _result =
    COUNTROWS (
        FILTER (
            ADDCOLUMNS (
                DISTINCT ( 'Table'[Cat1] ),
                "@count",
                    CALCULATE (
                        COUNTROWS ( DISTINCT ( 'Table'[Cat2] ) ),
                        ALL ( 'Table'[ID], 'Table'[Cat2] )
                    )
            ),
            [@count] > 1
        )
    ) > 0
RETURN
    IF ( ISINSCOPE ( 'Table'[Cat1] ), DIVIDE ( _result, _result, 0 ) )

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


View solution in original post

2 REPLIES 2
Jihwan_Kim
Super User
Super User

Hi,

Please check the below picture and the attached pbix file.

 

Jihwan_Kim_0-1671447821349.png

 

 

Expected outcome measure: =
VAR _result =
    COUNTROWS (
        FILTER (
            ADDCOLUMNS (
                DISTINCT ( 'Table'[Cat1] ),
                "@count",
                    CALCULATE (
                        COUNTROWS ( DISTINCT ( 'Table'[Cat2] ) ),
                        ALL ( 'Table'[ID], 'Table'[Cat2] )
                    )
            ),
            [@count] > 1
        )
    ) > 0
RETURN
    IF ( ISINSCOPE ( 'Table'[Cat1] ), DIVIDE ( _result, _result, 0 ) )

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


Works like a charm! Nice way of using ISINSCOPE(). Thanks

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

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

April Fabric Community Update

Fabric Community Update - April 2024

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