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
Anonymous
Not applicable

How to count the number of different values from many columns

Hi everyone,

 

I have a small request about a project I'm doing on PBI Desktop :

I have, in the same table, 3 columns for which I want to count the number of each value.

I don't have access to Query, thus I can't transpose or unpivot the columns.

For instance :

Table 1

       Col 1  |  Col 2  |  Col 3

          A           A           B

          B           B           C

          B           A           B

          A           A           A

 

For this case, the indicator I want to highlight the most common value : A with a count of 6.

How may I perform that ?

 

 

Thanks in advance !

1 ACCEPTED SOLUTION

@Anonymous

Having such a data set, you can create a measure without having to interfere with the data (you wrote that you do not have this possibility).

lkalawski_0-1598880758997.png

 

This measure will give you the most common value in all columns:

The Most Common Category =
VAR _table =
    UNION (
        SELECTCOLUMNS ( 'Table', "Columnas1", 'Table'[Column1] ),
        SELECTCOLUMNS ( 'Table', "Columnas1", 'Table'[Column2] ),
        SELECTCOLUMNS ( 'Table', "Columnas1", 'Table'[Column3] )
    )
VAR _summarize =
    SUMMARIZE (
        _table,
        [Columnas1],
        "Cnt", COUNTX ( FILTER ( _table, [Columnas1] = EARLIER ( [Columnas1] ) ), [Columnas1] )
    )
RETURN
    MAXX ( TOPN ( 1, _summarize, [Cnt] ), [Columnas1] )

 



_______________
If I helped, please accept the solution and give kudos! 😀


 

View solution in original post

8 REPLIES 8
v-eqin-msft
Community Support
Community Support

Hi @Anonymous ,

According to my understanding, you want to calculate the count of per Category from multiple columns, right?

In my opinion, it is the easiest way to use Slicer to dynamically display the count.

 

You could use the following formula:

 

1.Create a new table for slicer

8.28.5.1.png

2.Calculate each columns count:

countPerCategory =
VAR _sele =
    SELECTEDVALUE ( 'forSlicer'[Category] )
RETURN
    CALCULATE (
        COUNT ( CountTable[Col1] ),
        FILTER ( CountTable, CountTable[Col1] = _sele )
    )
        + CALCULATE (
            COUNT ( CountTable[Col2] ),
            FILTER ( CountTable, CountTable[Col2] = _sele )
        )
        + CALCULATE (
            COUNT ( CountTable[Col3] ),
            FILTER ( CountTable, CountTable[Col3] = _sele )
        )

My visualization looks like this:

8.28.5.2.png

Is the result what you want? If you have any questions, please upload some data samples and expected output.

Please do mask sensitive data before uploading.

 

Best Regards,

Eyelyn Qin

Anonymous
Not applicable

Hi @v-eqin-msft 

 

Thanks for your answer, what I want is not to select what category fo which I want the count but directly showing the category having the most frequency.

 

Thanks !

@Anonymous

Having such a data set, you can create a measure without having to interfere with the data (you wrote that you do not have this possibility).

lkalawski_0-1598880758997.png

 

This measure will give you the most common value in all columns:

The Most Common Category =
VAR _table =
    UNION (
        SELECTCOLUMNS ( 'Table', "Columnas1", 'Table'[Column1] ),
        SELECTCOLUMNS ( 'Table', "Columnas1", 'Table'[Column2] ),
        SELECTCOLUMNS ( 'Table', "Columnas1", 'Table'[Column3] )
    )
VAR _summarize =
    SUMMARIZE (
        _table,
        [Columnas1],
        "Cnt", COUNTX ( FILTER ( _table, [Columnas1] = EARLIER ( [Columnas1] ) ), [Columnas1] )
    )
RETURN
    MAXX ( TOPN ( 1, _summarize, [Cnt] ), [Columnas1] )

 



_______________
If I helped, please accept the solution and give kudos! 😀


 

Anonymous
Not applicable

@lkalawski 

Thank you very much ! You helped me a lot with that !!

pranit828
Community Champion
Community Champion

HI @Anonymous 

 

DISTINCTCOUNT(
SELECTCOLUMNS(Table1,"Col1",[Col1],"col2",[Col2],"col3",[Col3])
)




PBI_SuperUser_Rank@1x.png


Hope it resolves your issue? 
Did I answer your question? Mark my post as a solution!

Appreciate your Kudos, Press the thumbs up button!!
Linkedin Profile
Anonymous
Not applicable

Hi @pranit828 ,

 

This solution doesn't work because the function DISTINCTCOUNT only take as arguments columns and not tables.

 

Thanks for your attention

amitchandak
Super User
Super User
Anonymous
Not applicable

Hi @amitchandak !

Thanks for your reply. Unpivoting table is performed with PBQ which I can't use now because  I work with imported data on PBI Desktop. 

 

That's why I was asking for some insights about an other way of doing that, maybe a pure DAX way with a more or less complex measure ?

 

 

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.