cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Frequent Visitor

distinct count of multiple columns

My data contains FName, LName, MName, Gender, Card ID, Health ID, Active Flag and there may be Null in any column for each row i am trying to calculate distinct count  (FName+Card ID+Health ID) and distinct count  (FName+Card ID+Health ID+Where Gender=M)

FNAMELNAMEMNAMEGenderCard IDHealth IDActiveFlag
ABCDXM123456712345Y
BCEFYM981056167891N
ABCDXM123456712345Y
IHPQZM456789034564N
IMPYCF 56789N
   F145647867890N
MEEEBM 78901N
ABCDXM123456712345Y
BCEFYM981056167891N




Please help me with this.

Thanks

1 ACCEPTED SOLUTION

Accepted Solutions
Solution Sage
Solution Sage

Create two measures and try the following Dax

 

Measure1 = COUNTROWS(GROUPBY(User,User[FNAME],User[Card ID],User[Health ID],User[Gender]))
Measure2 = COUNTROWS(FILTER(GROUPBY(User,User[FNAME],User[Card ID],User[Health ID],User[Gender]),User[Gender]="M"))

2018-06-06_9-32-30.png

 

 

 

View solution in original post

6 REPLIES 6
Resident Rockstar
Resident Rockstar

Hi

 

1. Create a new column :   New_Col = 'Table1'[FNAME]&'Table1'[Card ID]&'Table1'[Health ID]

 

2. Then you can create measure to do the count as needed:

 

Dist_cnt = CALCULATE(DISTINCTCOUNT('Table1'[New_Col]))

 

Dist_Male_Cnt=CALCULATE(DISTINCTCOUNT('Table1'[New_Col]),'Table1'[Gender]="M")

 

Hope this helps.

 

Thanks
Raj

 

Solution Sage
Solution Sage

Create two measures and try the following Dax

 

Measure1 = COUNTROWS(GROUPBY(User,User[FNAME],User[Card ID],User[Health ID],User[Gender]))
Measure2 = COUNTROWS(FILTER(GROUPBY(User,User[FNAME],User[Card ID],User[Health ID],User[Gender]),User[Gender]="M"))

2018-06-06_9-32-30.png

 

 

 

View solution in original post

Thanks Jessica the Measures are working.

Resolver II
Resolver II

Hi,

I am wondering which is the best solution in terms of performance?

Concatenate Calculated Column ?
OR
GroupBy Measure ? 

Thank you in advance,

Rob

I think for performance is better calculated column, for datamodel size is better groupBy.

 

Correct me someone, if I am wrong.

Yes, calculated column is better for performance.

The measure will not perform well in that version, it's better to use SUMMARIZE instead of GROUPBY and CALCULATETABLE instead of FILTER, this way you don't have to materialize Gender:

Measure2 = 
CALCULATETABEL (
    COUNTROWS (
        SUMMARIZE ( User, User[FNAME], User[Card ID], User[Health ID] )
    ),
    User[Gender]="M"
)

 

Helpful resources

Announcements
November Update

Check it Out!

Click here to read more about the November 2020 Updates!

Community Conference

Power Platform Community Conference

Check out the on demand sessions that are available now!

secondImage

Power Platform October Community Highlights

Check out the top community contributors across all of the communities

secondImage

Create an end-to-end data and analytics solution

Learn how Power BI works with the latest Azure data and analytics innovations at the digital event with Microsoft CEO Satya Nadella.

Top Solution Authors
Top Kudoed Authors