Fabric is Generally Available. Browse Fabric Presentations. Work towards your Fabric certification with the Cloud Skills Challenge.
04-08-2018 12:54 PM - last edited 09-10-2018 06:38 AM
In the healthcare field, it is often desireable to identify a cohort of patients with similar, multiple diagnoses. This quick measure returns a comma-delimited list of patients that have all been identified with the same diagnoses. The tricky part here is that this allows the user to select from a slicer the diagnoses for which the user is interested in obtaining a cohort. Identified patients have had diagnoses that meet all of the selected criteria. In other words, all patients have had diagnoses for all of the selected diagnoses in the slicer. Essentially creates an AND for the slicer as opposed to the normal OR.
Cohort =
VAR tmpTable1 = GENERATE(VALUES(Diagnosis[Patient]),
EXCEPT(
VALUES(Diagnosis[Diagnosis]),
CALCULATETABLE(VALUES(Diagnosis[Diagnosis]))))
VAR tmpTable2 = SUMMARIZE(tmpTable1,Diagnosis[Patient])
VAR tmpTable3 = EXCEPT(VALUES(Diagnosis[Patient]),tmpTable2)
RETURN CONCATENATEX(tmpTable3,[Patient],",")
This quick measure would take two inputs, the column for the ID to return (Patient) and the column for the slicer selection (Diagnosis)
Also included is the trivial variation, Count of Cohort:
Count of Cohort = VAR tmpTable1 = GENERATE(VALUES(Diagnosis[Patient]), EXCEPT( VALUES(Diagnosis[Diagnosis]), CALCULATETABLE(VALUES(Diagnosis[Diagnosis])))) VAR tmpTable2 = SUMMARIZE(tmpTable1,Diagnosis[Patient]) VAR tmpTable3 = EXCEPT(VALUES(Diagnosis[Patient]),tmpTable2) RETURN COUNTROWS(tmpTable3)
eyJrIjoiZWYwNzZlNzctOTc5NC00ZWU1LWI2OWMtYTZjYTI0MjIzMjEzIiwidCI6IjRhMDQyNzQzLTM3M2EtNDNkMi04MjdiLTAwM2Y0YzdiYTFlNSIsImMiOjN9
@Greg_Deckler How could this be amended so that the patient was in a table format?
@lherbert501 Just drop the CONCATENATEX and return tmpTable3 or use the CONCATENATEX with UNICHAR(10) & (UNICHAR(13) as the delimeter.
You may want to try a measure with better performance
Measure =
VAR __cnt = COUNTROWS( ALLSELECTED( Diagnosis[Diagnosis] ) )
RETURN
CONCATENATEX(
FILTER(
VALUES( Diagnosis[Patient] ),
CALCULATE( DISTINCTCOUNT( Diagnosis[Diagnosis] ) ) = __cnt
),
Diagnosis[Patient],
","
)
Thanks to the great efforts by MS engineers to simplify syntax of DAX! Most beginners are SUCCESSFULLY MISLED to think that they could easily master DAX; but it turns out that the intricacy of the most frequently used RANKX() is still way beyond their comprehension! |
DAX is simple, but NOT EASY! |
@CNENFRNL I'm missing something...