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
Joao_Marto
New Member

Trying to create a Measure by counting distinct rows of a table variable

Hi Community,
I ask your help in something that seems pretty simple, but I´m unable to find an answer. 
I want to calculate, in a card visualization, the nº of different values that exist on a particular column in my dataset.
The particularity of this column ("Column1") is that accepts multiple values, separated by a comma. For example, consider the simple table below.

 

In this particular case, the result should be 11. i want to do it without having to create a new table or modify my current one.
I´m itrying to combine the following steps, without success:
1º create a table variable with only 1 column and contains only the different values of Column1 (Addcolumns+Summarize)
2º in the new table, add new rows for each different value on each row (Generateseries?)
3º count the distinct number of rows

Im very confused right now and I dont know how to use the column of my new table variable inthe distinctcount
Please help
thank you in advance

 

54
 
216,549
992,97,769,1125,1127
823
96
 
823
93
1 ACCEPTED SOLUTION

Hi Sahir,
thank you for your help!
It didnt quite return the correct values in my original dataset.  Is there any limitation in the number of characters a row can have? because the returned value is lower than the correct one which make me think that probably is not able to cover all characters.

It also returned a minor error: "Function "addcolumns" cannot add column [Value] since it already exists".
I made a small change that was accepted:

VAR ResulTable =
    ADDCOLUMNS(
        ExpandedTable,
        "TimmedValue",
        TRIM(MID(SUBSTITUTE('Atividades DPR'[Empresa(s) Adjudicada(s)_id],separator,REPT(" ", 100)),([Value]-1)*100+1,100)))
Return
    Countrows(
        DISTINCT(
            SELECTCOLUMNS(
                ResulTable,
                "TrimmedValue",[Value])))

 

View solution in original post

2 REPLIES 2
Sahir_Maharaj
Super User
Super User

Hello @Joao_Marto,

 

Can you please try this DAX:

Distinct Value Count = 
VAR Separator = ","
VAR ExpandedTable = 
    GENERATE(
        ALL('YourTableName'), 
        VAR CurrentValues = [Column1]
        VAR ValueList = UNICHAR(10) & SUBSTITUTE(CurrentValues, Separator, UNICHAR(10)) & UNICHAR(10)
        RETURN
            GENERATESERIES(1, LEN(ValueList) - LEN(SUBSTITUTE(ValueList, UNICHAR(10), "")), 1)
    )
VAR ResultTable = 
    ADDCOLUMNS(
        ExpandedTable,
        "Value", 
        TRIM(MID(SUBSTITUTE([Column1], Separator, REPT(" ", 100)), ([Value] - 1) * 100 + 1, 100))
    )
RETURN
    COUNTROWS(
        DISTINCT(
            SELECTCOLUMNS(
                ResultTable,
                "TrimmedValue", [Value]
            )
        )
    )

Did I answer your question? Mark my post as a solution, this will help others!

If my response(s) assisted you in any way, don't forget to drop me a "Kudos" 🙂

Kind Regards,
Sahir Maharaj
Data Scientist | Data Engineer | Data Analyst | AI Engineer
P.S. Want me to build your Power BI solution?
➤ Lets connect on LinkedIn: Join my network of 13K+ professionals
➤ Join my free newsletter: Data Driven: From 0 to 100
➤ Website: https://sahirmaharaj.com
➤ Email: sahir@sahirmaharaj.com
➤ Want me to build your Power BI solution? Lets chat about how I can assist!
➤ Join my Medium community of 30K readers! Sharing my knowledge about data science and artificial intelligence
➤ Explore my latest project (350K+ views): Wordlit.net
➤ 100+ FREE Power BI Themes: Download Now
LinkedIn Top Voice in Artificial Intelligence, Data Science and Machine Learning

Hi Sahir,
thank you for your help!
It didnt quite return the correct values in my original dataset.  Is there any limitation in the number of characters a row can have? because the returned value is lower than the correct one which make me think that probably is not able to cover all characters.

It also returned a minor error: "Function "addcolumns" cannot add column [Value] since it already exists".
I made a small change that was accepted:

VAR ResulTable =
    ADDCOLUMNS(
        ExpandedTable,
        "TimmedValue",
        TRIM(MID(SUBSTITUTE('Atividades DPR'[Empresa(s) Adjudicada(s)_id],separator,REPT(" ", 100)),([Value]-1)*100+1,100)))
Return
    Countrows(
        DISTINCT(
            SELECTCOLUMNS(
                ResulTable,
                "TrimmedValue",[Value])))

 

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.

Top Solution Authors