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

Don't miss out! 2025 Microsoft Fabric Community Conference, March 31 - April 2, Las Vegas, Nevada. Use code MSCUST for a $150 discount. Prices go up February 11th. Register now.

Reply
John_Foord
New Member

Filter table based on duplicated ID and depending if columns contains value

Hello everyone, 

As a beginner, I have a difficulty with a data set and a request that I can resume as such.
I have the following data set and I should retrieve value following these rules:
If Id has a category = "CS" and "MD", return "CS" value (excluding MD value). 
Else if there is no "CS" in category for an Id, return the "MD" value.

Index IdCategoryValue
1ACS5
2AMD10
3BCS6
4Bothers11

5

CMD7

6

Cother12

 

 

I have difficulty to figure out how resolve this problem without creating additional table but i feel like it could be possible, isn'it ?

thank in advance for any help and comment

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

Hi All,
Firstly parry2k thank you for youe solution!
And @John_Foord , I'm glad to tell you that your needs can be realized, we can go through the MEASUREMENT to achieve your needs, when asking for the value, grouped by ID to ensure that he does not value the display in one line, but rather includes the calculation of this one group.

Measure 2 = 
VAR CS_Count = CALCULATE(COUNTROWS('Table'), 'Table'[Category] = "CS", ALLEXCEPT('Table', 'Table'[Id]))
VAR MD_Count = CALCULATE(COUNTROWS('Table'), 'Table'[Category] = "MD", ALLEXCEPT('Table', 'Table'[Id]))
VAR CS_Value = CALCULATE(MAX('Table'[Value]), 'Table'[Category] = "CS", ALLEXCEPT('Table', 'Table'[Id]))
VAR MD_Value = CALCULATE(MAX('Table'[Value]), 'Table'[Category] = "MD", ALLEXCEPT('Table', 'Table'[Id]))
RETURN
IF(
   CS_Count >= 1 && MD_Count >= 1,
   CS_Value,
   IF(
       CS_Count < 1,
       MD_Value,
       0
   )

Since the second group, does not have a clear logic, I set it to 0 here, so you can make your own changes if you need to.

vxingshenmsft_0-1726644722816.png

I hope my thoughts have solved your problem, if you have any further questions, you can always contact me and I will get back to you as soon as I get the message!

Hope it helps!

 

Best regards,
Community Support Team_ Tom Shen

 

If this post helps then please consider Accept it as the solution to help the other members find it more quickly.

 

 

 

View solution in original post

2 REPLIES 2
v-xingshen-msft
Community Support
Community Support

Hi All,
Firstly parry2k thank you for youe solution!
And @John_Foord , I'm glad to tell you that your needs can be realized, we can go through the MEASUREMENT to achieve your needs, when asking for the value, grouped by ID to ensure that he does not value the display in one line, but rather includes the calculation of this one group.

Measure 2 = 
VAR CS_Count = CALCULATE(COUNTROWS('Table'), 'Table'[Category] = "CS", ALLEXCEPT('Table', 'Table'[Id]))
VAR MD_Count = CALCULATE(COUNTROWS('Table'), 'Table'[Category] = "MD", ALLEXCEPT('Table', 'Table'[Id]))
VAR CS_Value = CALCULATE(MAX('Table'[Value]), 'Table'[Category] = "CS", ALLEXCEPT('Table', 'Table'[Id]))
VAR MD_Value = CALCULATE(MAX('Table'[Value]), 'Table'[Category] = "MD", ALLEXCEPT('Table', 'Table'[Id]))
RETURN
IF(
   CS_Count >= 1 && MD_Count >= 1,
   CS_Value,
   IF(
       CS_Count < 1,
       MD_Value,
       0
   )

Since the second group, does not have a clear logic, I set it to 0 here, so you can make your own changes if you need to.

vxingshenmsft_0-1726644722816.png

I hope my thoughts have solved your problem, if you have any further questions, you can always contact me and I will get back to you as soon as I get the message!

Hope it helps!

 

Best regards,
Community Support Team_ Tom Shen

 

If this post helps then please consider Accept it as the solution to help the other members find it more quickly.

 

 

 

parry2k
Super User
Super User

@John_Foord try adding new column using following expression, change the expression as you see fit:

 

New Column = 
VAR __Id = 'Table (3)'[Id]
VAR __Table0 = FILTER ( ALL ( 'Table (3)' ), 'Table (3)'[Id] = __Id )
VAR __Table = SELECTCOLUMNS ( __Table0, [Category] )
VAR __Test =
IF ( "CS" IN __Table && "MD" IN __Table, "CS", IF ( NOT "CS" IN __Table, "MD", "Other" ) ) 
RETURN __Test


Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!

Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo

If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤


Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.

Helpful resources

Announcements
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!

December 2024

A Year in Review - December 2024

Find out what content was popular in the Fabric community during 2024.