skip to main content
Power BI
    • What is Power BI
    • Why Power BI
    • Customer stories
    • Data visuals
    • Security
    • Power BI Desktop
    • Power BI Pro
    • Power BI Premium
    • Power BI Mobile
    • Power BI Embedded
    • Power BI Report Server
  • Pricing
    • Azure + Power BI
    • Microsoft 365 + Power BI
    • Dynamics 365 + Power BI
      • Energy
      • Healthcare
      • Manufacturing
      • Media
      • Retail
    • For analysts
    • For IT
      • Overview
      • Embedded analytics
      • Power BI visuals
      • Automation
      • Documentation
      • Community
    • Partners Overview
    • Solutions Partners
    • BI Specialized Partners
    • Power BI CSOs
    • Fabric Partner Community
    • Training
    • Getting started
      • Overview
      • Self-guided learning
      • Webinars
      • Documentation
      • Roadmap
      • Overview
      • Issues
      • Give feedback
    • Blog
    • Business intelligence topics
    • Overview
    • Forums
    • Galleries
    • Submit ideas
    • Events
    • User groups
    • Community blog
    • Register
    • ·
    • Sign in
    • ·
    • Help
    Go To
    • Power BI forums
    • Updates
    • News & Announcements
    • Get Help with Power BI
    • Desktop
    • Service
    • Report Server
    • Power Query
    • Mobile Apps
    • Developer
    • DAX Commands and Tips
    • Custom Visuals Development Discussion
    • Health and Life Sciences
    • Power BI Spanish forums
    • Translated Spanish Desktop
    • Power Platform Integration - Better Together!
    • Power Platform Integrations
    • Power Platform and Dynamics 365 Integrations
    • Training and Consulting
    • Instructor Led Training
    • Galleries
    • Community Connections & How-To Videos
    • COVID-19 Data Stories Gallery
    • Themes Gallery
    • Data Stories Gallery
    • R Script Showcase
    • Webinars and Video Gallery
    • Quick Measures Gallery
    • 2021 MSBizAppsSummit Gallery
    • 2020 MSBizAppsSummit Gallery
    • 2019 MSBizAppsSummit Gallery
    • Events
    • Ideas
    • Custom Visuals Ideas
    • Issues
    • Issues
    • Events
    • Upcoming Events
    • Community Engagement
    • T-Shirt Design Challenge 2023
    • Community Blog
    • Power BI Community Blog
    • Custom Visuals Community Blog
    • Community Support
    • Community Accounts & Registration
    • Using the Community
    • Community Feedback
    cancel
    Turn on suggestions
    Auto-suggest helps you quickly narrow down your search results by suggesting possible matches as you type.
    Showing results for 
    Search instead for 
    Did you mean: 

    Fabric is Generally Available. Browse Fabric Presentations. Work towards your Fabric certification with the Cloud Skills Challenge.

    • Power BI forums
    • Galleries
    • Quick Measures Gallery
    • Patient Cohort (AND Slicer)

    Patient Cohort (AND Slicer)

    04-08-2018 12:54 PM - last edited 09-10-2018 06:38 AM

    Super User Greg_Deckler
    Super User
    4108 Views
    LinkedIn LinkedIn Facebook Facebook Twitter Twitter
    Greg_Deckler
    Super User Greg_Deckler
    Super User
    • Mark as New
    • Bookmark
    • Subscribe
    • Mute
    • Subscribe to RSS Feed
    • Permalink
    • Print
    • Report Inappropriate Content

    Patient Cohort (AND Slicer)

    ‎04-08-2018 12:54 PM

    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


    @ me in replies or I'll lose your thread!!!
    Instead of a Kudo, please vote for this idea
    Become an expert!: Enterprise DNA
    External Tools: MSHGQM
    YouTube Channel!: Microsoft Hates Greg
    Latest book!:
    Mastering Power BI 2nd Edition

    DAX is easy, CALCULATE makes DAX hard...
    Cohort.pbix
    104 KB
    Labels:
    • Labels:
    • Filters
    • Other
    Message 1 of 5
    4,108 Views
    6
    Reply
    • All forum topics
    • Previous Topic
    • Next Topic
    lherbert501
    lherbert501 Helper V
    Helper V
    • Mark as New
    • Bookmark
    • Subscribe
    • Mute
    • Subscribe to RSS Feed
    • Permalink
    • Print
    • Report Inappropriate Content

    ‎06-14-2023 07:02 AM

    @Greg_Deckler How could this be amended so that the patient was in a table format?

    Message 4 of 5
    362 Views
    0
    Reply
    Greg_Deckler
    Super User Greg_Deckler
    Super User
    In response to lherbert501
    • Mark as New
    • Bookmark
    • Subscribe
    • Mute
    • Subscribe to RSS Feed
    • Permalink
    • Print
    • Report Inappropriate Content

    ‎06-15-2023 06:00 AM

    @lherbert501 Just drop the CONCATENATEX and return tmpTable3 or use the CONCATENATEX with UNICHAR(10) & (UNICHAR(13) as the delimeter.


    @ me in replies or I'll lose your thread!!!
    Instead of a Kudo, please vote for this idea
    Become an expert!: Enterprise DNA
    External Tools: MSHGQM
    YouTube Channel!: Microsoft Hates Greg
    Latest book!:
    Mastering Power BI 2nd Edition

    DAX is easy, CALCULATE makes DAX hard...
    Message 5 of 5
    352 Views
    0
    Reply
    CNENFRNL
    CNENFRNL Community Champion
    Community Champion
    • Mark as New
    • Bookmark
    • Subscribe
    • Mute
    • Subscribe to RSS Feed
    • Permalink
    • Print
    • Report Inappropriate Content

    ‎03-19-2023 12:40 PM

    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!

    Cohort.pbix
    Message 2 of 5
    625 Views
    0
    Reply
    Greg_Deckler
    Super User Greg_Deckler
    Super User
    In response to CNENFRNL
    • Mark as New
    • Bookmark
    • Subscribe
    • Mute
    • Subscribe to RSS Feed
    • Permalink
    • Print
    • Report Inappropriate Content

    ‎03-19-2023 02:19 PM

    @CNENFRNL I'm missing something...

    Greg_Deckler_0-1679260766931.png

     


    @ me in replies or I'll lose your thread!!!
    Instead of a Kudo, please vote for this idea
    Become an expert!: Enterprise DNA
    External Tools: MSHGQM
    YouTube Channel!: Microsoft Hates Greg
    Latest book!:
    Mastering Power BI 2nd Edition

    DAX is easy, CALCULATE makes DAX hard...
    Message 3 of 5
    614 Views
    0
    Reply

    Power Platform

    • Overview
    • Power BI
    • Power Apps
    • Power Pages
    • Power Automate
    • Power Virtual Agents

    • Sign in
    • Sign up

    Browse

    • Solutions
    • Partners
    • Consulting Services

    Downloads

    • Power BI Desktop
    • Power BI Mobile
    • Power BI Report Server
    • See all downloads

    Learn

    • Guided learning
    • Documentation
    • Support
    • Community
    • Give feedback
    • Webinars
    • Developers
    • Blog
    • Newsletter

    © 2023 Microsoft

    Follow Power BI

    • Privacy & cookies
    • Manage cookies
    • Terms of use
    • Trademarks
    Consumer Privacy Act (CCPA) Opt-Out Icon Your Privacy Choices