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

Distinct count and grouping/filtering

I have the following table in my report:

 

PatientIDNumeratorVisitEndDate
11Jan 1, 2020
11

Feb 1, 2020

10Mar 1, 2020
21Jan 1, 2020
21

Feb 1, 2020

21Mar 1, 2020
31Jan 1, 2020
31

Feb 1, 2020

31Mar 1, 2020

 

I would like to include a measure that brings back the distinct count of patients that have a minimum numerator of 1. In this scenario, the count should be 2 (patientid 2 & 3). How would the expression be written to return this count?

2 ACCEPTED SOLUTIONS
Anonymous
Not applicable

@Anonymous 

 

Try something like this:

 

Measure = 
var Table_unmatch=CALCULATETABLE(VALUES('Table'[PatientID]),FILTER('Table','Table'[Numerator]=0))
Return CALCULATE(DISTINCTCOUNT('Table'[PatientID]),FILTER('Table',NOT([PatientID] in Table_unmatch)))

 

 

Paul Zheng
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

TomMartens
Super User
Super User

Hey @Anonymous ,

 

here is another DAX statement that is very efficient and compact:

tom = 
SUMX(
    VALUES('Table'[PatientID])
    , var _min = CALCULATE(MIN('Table'[Numerator]))
    return
    IF(_min = 1 , 1 , BLANK())
)

It iterates across the distinct PatientID that are available in the current filter context
SUMX(
    VALUES(,,,
determines the minimum Numerator for each PatientID
CALCULATE(MIN(...
checks if the value matches the condition and returns 1 otherwise BLANK()
Finally, all the 1's will be summed by the iterator function SUMX

 

Hopefully, this provides what you are looking for.

 

Regards,
Tom

 



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

Proud to be a Super User!
I accept Kudos 😉
Hamburg, Germany

View solution in original post

4 REPLIES 4
Vera_33
Resident Rockstar
Resident Rockstar

You can groupby PatientID, Calculate Min, then filter the table to the Min = 1, then count rows:

 

Count=
VAR T1 = GROUPBY(Table,[PatientID],"@MIN",MINX(CURRENTGROUP(),[Numerator]))

RETURN

COUNTROWS(FILTER(T1,[@MIN]=1))

TomMartens
Super User
Super User

Hey @Anonymous ,

 

here is another DAX statement that is very efficient and compact:

tom = 
SUMX(
    VALUES('Table'[PatientID])
    , var _min = CALCULATE(MIN('Table'[Numerator]))
    return
    IF(_min = 1 , 1 , BLANK())
)

It iterates across the distinct PatientID that are available in the current filter context
SUMX(
    VALUES(,,,
determines the minimum Numerator for each PatientID
CALCULATE(MIN(...
checks if the value matches the condition and returns 1 otherwise BLANK()
Finally, all the 1's will be summed by the iterator function SUMX

 

Hopefully, this provides what you are looking for.

 

Regards,
Tom

 



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

Proud to be a Super User!
I accept Kudos 😉
Hamburg, Germany
Anonymous
Not applicable

@Anonymous 

 

Try something like this:

 

Measure = 
var Table_unmatch=CALCULATETABLE(VALUES('Table'[PatientID]),FILTER('Table','Table'[Numerator]=0))
Return CALCULATE(DISTINCTCOUNT('Table'[PatientID]),FILTER('Table',NOT([PatientID] in Table_unmatch)))

 

 

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

camargos88
Community Champion
Community Champion

Hi @Anonymous ,

 

Try this code:

 

Measure =

VAR _tbl_0 = SELECTCOLUMNS(CALCULATETABLE('Table'; FILTER(ALL('Table'[Numerator]); 'Table'[Numerator] = 0)); "PatientID"; 'Table'[PatientID])
VAR _tbl_1 = SELECTCOLUMNS(CALCULATETABLE('Table'; FILTER(ALL('Table'[Numerator]); 'Table'[Numerator] >=1)); "PatientID"; 'Table'[PatientID])
VAR _result = EXCEPT(_tbl_1;_tbl_0)

RETURN AVERAGEX(_result; 1)
 
Ricardo


Did I answer your question? Mark my post as a solution!

Proud to be a Super User!



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.

Top Solution Authors
Top Kudoed Authors