Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Get certified in Microsoft Fabric—for free! For a limited time, get a free DP-600 exam voucher to use by the end of 2024. Register now

Reply
nok
Helper I
Helper I

Distinct ID count based on other columns

Hello,

I have a table that contains an ID column that can be repeated for each step of an approval process. My table follows this structure:

ID      ApprovalStep   ApprovalName   Trigger   Mi      Type    
1110.1DanielTrueTrueCot
1110.2EricTrueTrueCot
1111.0LisaTrueTrueCot
2221.0JohnTrueTrueCot
2221.1HelenaTrueTrueCot
2221.2SoshanaTrueTrueCot
3330.1RobenFalseTrueCot
3332.1StuartFalseTrueCot
3332.2KianaFalseTrueCot
4440.2LevinTrueFalseCot
5550.1HannaTrueTrueXX
6661.1DanielTrueTrueCot


I want to create a measure that counts how many distinct IDs DO NOT have any ApprovalStep that start with "0.", Trigger = "True", Mi = "True" and Type = "Cot".
Based on the table above, the measure should bring the value: 2. Because only IDs 222 and 666 meet all the counting conditions.


How can I create this measure?

1 ACCEPTED SOLUTION
v-huijiey-msft
Community Support
Community Support

Hi @nok ,

 

Thanks for the reply from @AmiraBedh .

 

Please try:

 

Create a measure:

Distinct ID Count = 
VAR _vtable1 =
    FILTER (
        ALLSELECTED ( 'Table' ),
        'Table'[Trigger] = TRUE ()
            && 'Table'[Mi] = TRUE ()
            && 'Table'[Type] = "Cot"
    )
RETURN
    COUNTROWS (
        FILTER (
            SUMMARIZE (
                _vtable1,
                'Table'[ID],
                "minx", MINX ( FILTER ( _vtable1, [ID] = EARLIER ( 'Table'[ID] ) ), [ApprovalStep] )
            ),
            [minx] >= 1
        )
    )

 

The visual effect of the final page is shown below:

vhuijieymsft_0-1719282742977.png

 

If you have any other questions please feel free to contact me.

 

The pbix file is attached.

 

Best Regards,
Yang
Community Support Team

 

If there is any post helps, then please consider Accept it as the solution  to help the other members find it more quickly.
If I misunderstand your needs or you still have problems on it, please feel free to let us know. Thanks a lot!

View solution in original post

2 REPLIES 2
v-huijiey-msft
Community Support
Community Support

Hi @nok ,

 

Thanks for the reply from @AmiraBedh .

 

Please try:

 

Create a measure:

Distinct ID Count = 
VAR _vtable1 =
    FILTER (
        ALLSELECTED ( 'Table' ),
        'Table'[Trigger] = TRUE ()
            && 'Table'[Mi] = TRUE ()
            && 'Table'[Type] = "Cot"
    )
RETURN
    COUNTROWS (
        FILTER (
            SUMMARIZE (
                _vtable1,
                'Table'[ID],
                "minx", MINX ( FILTER ( _vtable1, [ID] = EARLIER ( 'Table'[ID] ) ), [ApprovalStep] )
            ),
            [minx] >= 1
        )
    )

 

The visual effect of the final page is shown below:

vhuijieymsft_0-1719282742977.png

 

If you have any other questions please feel free to contact me.

 

The pbix file is attached.

 

Best Regards,
Yang
Community Support Team

 

If there is any post helps, then please consider Accept it as the solution  to help the other members find it more quickly.
If I misunderstand your needs or you still have problems on it, please feel free to let us know. Thanks a lot!

AmiraBedh
Most Valuable Professional
Most Valuable Professional

First, create a calculated column to identify rows that meet the condition ApprovalStep starts with "0.", Trigger = "True", Mi = "True", and Type = "Cot" :

 

 

IsMatch = 

IF (

    LEFT ( 'Table'[ApprovalStep], 2 ) = "0." && 

    'Table'[Trigger] = TRUE() && 

    'Table'[Mi] = TRUE() && 

    'Table'[Type] = "Cot",

    1,

    0

)

 

Then, create a measure that counts the distinct IDs which do not have any row where IsMatch is 1.

 

DistinctIDCount = 

VAR IDsWithCondition =

    CALCULATETABLE (

        VALUES ( 'Table'[ID] ),

        'Table'[IsMatch] = 1

    )

RETURN

    CALCULATE (

        DISTINCTCOUNT ( 'Table'[ID] ),

        NOT 'Table'[ID] IN IDsWithCondition

    )

 


Proud to be a Power BI Super User !

Microsoft Community : https://docs.microsoft.com/en-us/users/AmiraBedhiafi
Linkedin : https://www.linkedin.com/in/amira-bedhiafi/
StackOverflow : https://stackoverflow.com/users/9517769/amira-bedhiafi
C-Sharp Corner : https://www.c-sharpcorner.com/members/amira-bedhiafi
Power BI Community :https://community.powerbi.com/t5/user/viewprofilepage/user-id/332696

Helpful resources

Announcements
November Carousel

Fabric Community Update - November 2024

Find out what's new and trending in the Fabric Community.

Live Sessions with Fabric DB

Be one of the first to start using Fabric Databases

Starting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.

Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.

Nov PBI Update Carousel

Power BI Monthly Update - November 2024

Check out the November 2024 Power BI update to learn about new features.