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

Don't miss out! 2025 Microsoft Fabric Community Conference, March 31 - April 2, Las Vegas, Nevada. Use code MSCUST for a $150 discount. Prices go up February 11th. Register now.

Reply
pmetaliya
Frequent Visitor

Calculate distinct count total at a group level

Hi, 

I'm trying to create a measure to get the "Other" count for each ethnicity but having trouble calculating total distinct count group by Ethnicity. There is 1:M relationship between Person(Ethnicity) and Behavior(Incident ID). 5,928 is a distinct count without ethnicity group and 6,297 is the total (sum of #Incident for each ethnicity) I'm looking for to determine Other. Ex: #Incident for Asian = 103, Other = 6297-103 = 6194. 

 

pmetaliya_1-1628700464093.png

Expected result for #Incident Other

Ethnicity# Incident# Incident OtherTotalAll-WrongDesired Total
American Indian or Alaska Native10628759286297
Asian103619459286297
Black or African American3531276659286297
Hispanic/Latino1464483359286297
Native Hawaiian or Other Pacific Islander9628859286297
White1180511759286297

 

 

TotalAll-Wrong = CALCULATE(DISTINCTCOUNT('Behavior'[DISCIPLINE_INCIDENT_ID]), ALL(Person[Ethnicity]))

 

I was able to get 6297 as a total with these formulas but not when the ethnicity filter context was applied. 

 

# Incident All 1 = 
SUMX(
    VALUES(Person[Ethnicity Cd]),
    CALCULATE(DISTINCTCOUNT('Behavior'[DISCIPLINE_INCIDENT_ID])))
# Incident All 2 = 
VAR TotalGrpbyEthn = 
SUMMARIZE(
    'Person',
    Person[Ethnicity],
    "EthnDistinct", DISTINCTCOUNT ('Behavior'[DISCIPLINE_INCIDENT_ID] )
)
RETURN SUMX(TotalGrpbyEthn, [EthnDistinct])
# Incident All 4 = 
VAR TotalGrpbyEthn = 
SUMMARIZE(
    'Person',
    Person[Ethnicity],
    "EthnDistinct", DISTINCTCOUNT ('Behavior'[DISCIPLINE_INCIDENT_ID] )
)
RETURN CALCULATE((SUMX(TotalGrpbyEthn, [EthnDistinct])), ALLEXCEPT(Person, Person[Ethnicity]))

 

Relationship

pmetaliya_2-1628700685781.png

 

I need this to be dynamic to work across multiple other slicers from School and Person tables on the report page. Could you please point me in the right direction? 

pbix file with sample data 

1 ACCEPTED SOLUTION
wdx223_Daniel
Super User
Super User

# Incident = CALCULATE(DISTINCTCOUNT('Behavior'[DISCIPLINE_INCIDENT_ID]))

# Incident All 1 = 
SUMX(
    VALUES('Person'[Ethnicity]),
    [# Incident])

# Incident Other 1 = VAR _all=CALCULATE([# Incident All 1],ALL(Person[Ethnicity])) RETURN IF([# Incident All 1],_all-[# Incident All 1])

wdx223_Daniel_0-1628728387826.png

 

View solution in original post

2 REPLIES 2
wdx223_Daniel
Super User
Super User

# Incident = CALCULATE(DISTINCTCOUNT('Behavior'[DISCIPLINE_INCIDENT_ID]))

# Incident All 1 = 
SUMX(
    VALUES('Person'[Ethnicity]),
    [# Incident])

# Incident Other 1 = VAR _all=CALCULATE([# Incident All 1],ALL(Person[Ethnicity])) RETURN IF([# Incident All 1],_all-[# Incident All 1])

wdx223_Daniel_0-1628728387826.png

 

Wow. Thanks, Daniel. Your measures are working as expected. 

Helpful resources

Announcements
Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!

Jan25PBI_Carousel

Power BI Monthly Update - January 2025

Check out the January 2025 Power BI update to learn about new features in Reporting, Modeling, and Data Connectivity.

Jan NL Carousel

Fabric Community Update - January 2025

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