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

Join the Fabric FabCon Global Hackathon—running virtually through Nov 3. Open to all skill levels. $10,000 in prizes! Register now.

Reply
klontok
New Member

Create new table with percent of respondents for each category

I have an unpivoted table of survey data where respondents could choose more than one of several options.

 

Survey IDInfectionResponse
0001SinusitisSelected
0001SepsisSelected
0002PneumoniaSelected
0003SepsisSelected
0003PneumoniaSelected

 

I would like to create a table that shows the percent of respondents that chose each infection.

Infection% of respondents
Sinusitis33%
Sepsis66%
Pneumonia66%

 

I tried using SUMMARIZE, but I can't seem to get the correct denominator. The COUNTDISTINCT below counts only the distinct Survey IDs within the infection category instead of in the entire table, so I get 100% for every type of infection. Maybe SUMMARIZE is the wrong way to go? Thanks in advance for any help! 

 

Table = SUMMARIZE('Infections Prior to Diagnosis', 'Infections Prior to Diagnosis'[Infections],"Percent of respondents",DIVIDE(COUNT('Infections Prior to Diagnosis'[Response]),COUNTDISTINCT('Infections Prior to Diagnosis'[Survey ID])
)
2 ACCEPTED SOLUTIONS
lbendlin
Super User
Super User

This question is much more complex than you might think, but here is a simplistic approach that takes some liberties.

 

lbendlin_0-1707350488547.png

 

View solution in original post

Anonymous
Not applicable

Hi @klontok ,

 

If you want to create a calculation table, I have made a modification on the formula you provided, refer below:

Table_ = 
SUMMARIZE(
    'Infections Prior to Diagnosis',
    'Infections Prior to Diagnosis'[Infection],
    "Percent of respondents",
    DIVIDE(
        CALCULATE (
            COUNTROWS('Infections Prior to Diagnosis'),
            FILTER(
                ALL('Infections Prior to Diagnosis'),
                'Infections Prior to Diagnosis'[Infection] = VALUES('Infections Prior to Diagnosis'[Infection])
            )
        ),
        CALCULATE(
            DISTINCTCOUNT('Infections Prior to Diagnosis'[Survey ID]),
            ALL('Infections Prior to Diagnosis')
        )
    )
)

vkongfanfmsft_1-1707380411897.png

 

Best Regards,
Adamk Kong

 

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

3 REPLIES 3
Anonymous
Not applicable

Hi @klontok ,

 

If you want to create a calculation table, I have made a modification on the formula you provided, refer below:

Table_ = 
SUMMARIZE(
    'Infections Prior to Diagnosis',
    'Infections Prior to Diagnosis'[Infection],
    "Percent of respondents",
    DIVIDE(
        CALCULATE (
            COUNTROWS('Infections Prior to Diagnosis'),
            FILTER(
                ALL('Infections Prior to Diagnosis'),
                'Infections Prior to Diagnosis'[Infection] = VALUES('Infections Prior to Diagnosis'[Infection])
            )
        ),
        CALCULATE(
            DISTINCTCOUNT('Infections Prior to Diagnosis'[Survey ID]),
            ALL('Infections Prior to Diagnosis')
        )
    )
)

vkongfanfmsft_1-1707380411897.png

 

Best Regards,
Adamk Kong

 

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

lbendlin
Super User
Super User

This question is much more complex than you might think, but here is a simplistic approach that takes some liberties.

 

lbendlin_0-1707350488547.png

 

Thank you so much! I was assuming I had to create another table, but the measure actually works better for my purposes because the slicers filter it. 

Helpful resources

Announcements
September Power BI Update Carousel

Power BI Monthly Update - September 2025

Check out the September 2025 Power BI update to learn about new features.

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.