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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
HuwThomas
Frequent Visitor

Returning IDs based on a specified MIN value

Good morning,

 

I'm relatively new to Power BI and am having trouble with returning IDs where the Staus is only 5, where IDs appear multiple times in the table. Below is a simplified version of my data, with either a Status of 2 or 5.

 

I wish to return the rows of IDs that only have a 5 status, so do not appear again in the list with a 2 status. I have been trying to do this where MIN = 5 but have been unable to get this to work.

 

Many thanks,

 

Huw

 

IDStatus
12
22
32
25
12
45
52
65
52
1 ACCEPTED SOLUTION

Hi @HuwThomas,

 

You can try creating a calculated column which checks whether the average of Status for each ID is 5. The formula below returns either true or false

 

Status5 = 
CALCULATE(
AVERAGE ( 'Table'[Status] ),
ALLEXCEPT ( 'Table','Table'[ID] )
) = 5









Did I answer your question? Mark my post as a solution!


Proud to be a Super User!









"Tell me and I’ll forget; show me and I may remember; involve me and I’ll understand."
Need Power BI consultation, get in touch with me on LinkedIn or hire me on UpWork.
Learn with me on YouTube @DAXJutsu or follow my page on Facebook @DAXJutsuPBI.

View solution in original post

6 REPLIES 6
v-yuezhe-msft
Employee
Employee

@HuwThomas,

To get the table as request, we can use the DAX function CALCULATETABLE in Power BI desktop.

1. Enter the data accordingly, here we can get the original table named TEST.
2. Create a new table by clicking the New Table icon. After that we are going to use the formula as below to get the data what we need.

 

Status 5 = CALCULATETABLE(TEST,FILTER(TEST, TEST[STATUS] = 5))

1.PNG


Alternatively, we can filter the TEST table directly in Query Editor or using visual level filter .

 2.png3.PNG
For more information, please refer to the pbix as attached.



Regards,
Lydia

Community Support Team _ Lydia Zhang
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

@v-yuezhe-msftThank you for your reply but this isn't quite what I was trying to achieve. I was hoping to return IDs that only have a 5 status, so if they also appear in the list with a 2 status then I do not wish to pull them through. So, in my test data I would want ID 4 and 6 but not ID 2.

 

Apologies, I probably didn't explain this clearly!

 

Regards,

 

Huw

@HuwThomas,

Based on my test, we can take these steps to get the new table as request.

1. First we can create a measure:
Measure := DISTINCTCOUNT(TEST[STATUS])

2. Create a table visual and filter the table, set the Measure value to 1 and status value to  5. 
1.jpg

 

For more information, please check the pbix as attached.



Regards,
Lydia

Community Support Team _ Lydia Zhang
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

@v-yuezhe-msft,

 

That's a great workaround but limits the presentation of this information (forced to have the extra columns and unable to use other visuals). 

 

I've managed my own workaround which is using a new table, summarising the ID and summing the status column. This has worked so far so I will just have to hope that it does not cause any problems down the line!

 

My solution: 

 

Table = SUMMARIZE('Table', 'Table'[ID], "Status" , SUM('Table'[Status]))

 

Many thanks for the help,

 

Huw

 

Hi @HuwThomas,

 

You can try creating a calculated column which checks whether the average of Status for each ID is 5. The formula below returns either true or false

 

Status5 = 
CALCULATE(
AVERAGE ( 'Table'[Status] ),
ALLEXCEPT ( 'Table','Table'[ID] )
) = 5









Did I answer your question? Mark my post as a solution!


Proud to be a Super User!









"Tell me and I’ll forget; show me and I may remember; involve me and I’ll understand."
Need Power BI consultation, get in touch with me on LinkedIn or hire me on UpWork.
Learn with me on YouTube @DAXJutsu or follow my page on Facebook @DAXJutsuPBI.

Hi @danextian,

 

That's great! Exactly what I was trying to do, many thanks!

 

 

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

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

April Fabric Community Update

Fabric Community Update - April 2024

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