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
powerbiuser1000
Frequent Visitor

DAX to Lookup Values in Another Column and Subtract to Achieve Remaining Columns

Hi All,

 

Hoping you you may be able to assist with my questions/challenge.

 

I have the below table and am wanting to achieve the output of the Column named "Remaining Sites"

 

Current :

powerbiuser1000_1-1683792395916.png

 

Hoping to create a Column named "Remaining Sites" :

powerbiuser1000_0-1683792342304.png

 

The unique combination of values are Ship, Ship Type, Ship Style and Sites.

 

So for each combination of Ship, Ship Type, Ship Style and Sites there are areas which get enetered in.

 

I am looking to have a column called "Remaining Sites" which looks up the value of 'Sites' and removes the 'Areas'.

 

Using the first 2 rows as an example, the Sites are: BB,EE,FF and I am needing to take away the areas for that Ship, Ship Type, Ship Style which are BB and EE. This would leave the column with FF.

 

I have tried to use a Matrix and then use LOOKUP VALUE which any luck. Have also tried to use the FIND and SEARCH functions but haven't got anywhere as of yet.

Apprecaite any help or guidance.

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

Hi @powerbiuser1000 ,

Dax's text functions are not very good at solving such problems.

Remaining Sites = 
VAR _TEXT = 
SUBSTITUTE (
    [Sites],
    CONCATENATEX (
        FILTER ( ALL ( 'Table' ), 'Table'[Ship] = EARLIER ( 'Table'[Ship] ) ),
        'Table'[Area],
        ","
    ),
    ""
)
VAR _RESULT = 
SWITCH(
    TRUE(),
    LEFT(_TEXT,1)=",",MID(_TEXT,2,LEN(_TEXT)-1),
    RIGHT(_TEXT,1)=",",MID(_TEXT,2,LEN(_TEXT)-1)
)
RETURN
_RESULT

vcgaomsft_0-1684741166315.png

This may only be appropriate for sample data. I'm guessing that [Sites] and [Areas] are probably calculated columns, so please consider refactoring them in the PowerQuery Editor to make the question much simpler.

 

Best Regards,
Gao

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!

How to get your questions answered quickly --  How to provide sample data in the Power BI Forum

View solution in original post

6 REPLIES 6
v-cgao-msft
Community Support
Community Support

Hi @powerbiuser1000 ,

Dax's text functions are not very good at solving such problems.

Remaining Sites = 
VAR _TEXT = 
SUBSTITUTE (
    [Sites],
    CONCATENATEX (
        FILTER ( ALL ( 'Table' ), 'Table'[Ship] = EARLIER ( 'Table'[Ship] ) ),
        'Table'[Area],
        ","
    ),
    ""
)
VAR _RESULT = 
SWITCH(
    TRUE(),
    LEFT(_TEXT,1)=",",MID(_TEXT,2,LEN(_TEXT)-1),
    RIGHT(_TEXT,1)=",",MID(_TEXT,2,LEN(_TEXT)-1)
)
RETURN
_RESULT

vcgaomsft_0-1684741166315.png

This may only be appropriate for sample data. I'm guessing that [Sites] and [Areas] are probably calculated columns, so please consider refactoring them in the PowerQuery Editor to make the question much simpler.

 

Best Regards,
Gao

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!

How to get your questions answered quickly --  How to provide sample data in the Power BI Forum

Thank you, this is exactly what I am after! Cheers

lbendlin
Super User
Super User

Use EXCEPT for that, or NOT IN { }.

Hi Ibendlin, thank you for that. However for Ship 1, it needs to lookup the 'area' for both the 1st and 2nd row and then use NOT IN { }.

 

For example, the 1st row needs to consider the 2nd row. And the 2nd row needs to consider the first. So need to add BB and EE and then subtract from 'Sites':

So BB, EE NOT IN {'Sites'), so the result can be FF as shown in the second table above.

Yes, I assumed you know how to handle filter context.

Hi Ibendlin, Thank you for your reply. I am not exactly sure how to do that. Are you able to clarify? thank you.

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.