March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early bird discount ends December 31.
Register NowBe one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now
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)
FNAME | LNAME | MNAME | Gender | Card ID | Health ID | ActiveFlag |
AB | CD | X | M | 1234567 | 12345 | Y |
BC | EF | Y | M | 9810561 | 67891 | N |
AB | CD | X | M | 1234567 | 12345 | Y |
IH | PQ | Z | M | 4567890 | 34564 | N |
IM | PY | C | F | 56789 | N | |
F | 1456478 | 67890 | N | |||
ME | EE | B | M | 78901 | N | |
AB | CD | X | M | 1234567 | 12345 | Y |
BC | EF | Y | M | 9810561 | 67891 | N |
Please help me with this.
Thanks
Solved! Go to Solution.
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"))
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"
)
Maestro!
Just a quick precision:
Measure2 =
CALCULATE (
COUNTROWS (
SUMMARIZE ( User, User[FNAME], User[Card ID], User[Health ID] )
),
User[Gender]="M"
)
Change the CALCULATETABLE to simple CALCULATE.
Have a great day!
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"))
Worked for me too.
Thumbs up
Thanks Jessica the Measures are working.
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
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.
User | Count |
---|---|
115 | |
76 | |
57 | |
52 | |
44 |
User | Count |
---|---|
164 | |
116 | |
63 | |
57 | |
50 |