Starting December 3, join live sessions with database experts and the Microsoft product team to learn just how easy it is to get started
Learn moreGet 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
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 |
111 | 0.1 | Daniel | True | True | Cot |
111 | 0.2 | Eric | True | True | Cot |
111 | 1.0 | Lisa | True | True | Cot |
222 | 1.0 | John | True | True | Cot |
222 | 1.1 | Helena | True | True | Cot |
222 | 1.2 | Soshana | True | True | Cot |
333 | 0.1 | Roben | False | True | Cot |
333 | 2.1 | Stuart | False | True | Cot |
333 | 2.2 | Kiana | False | True | Cot |
444 | 0.2 | Levin | True | False | Cot |
555 | 0.1 | Hanna | True | True | XX |
666 | 1.1 | Daniel | True | True | Cot |
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?
Solved! Go to Solution.
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:
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!
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:
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!
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
)
Starting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.
User | Count |
---|---|
92 | |
86 | |
85 | |
66 | |
49 |
User | Count |
---|---|
140 | |
113 | |
106 | |
64 | |
60 |