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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
Jim_PBI
Frequent Visitor

DAX to only include rows outside of filter context

Hi all,

 

I'm stuck on a DAX issue relating to filter context - have tried a few ways with little success. 

 

I'm building the table below in Power BI which only allows single select on the slicer, which in this case is Kitchen. I'm struggling to calculate the last column 'Other Active Products' which sums all of the rows for the sales agent which do not equal kitchen but all other filters will be applied. 

 

Sales AgentProductVolume SoldOther Active Products
Sales agent 1Kitchen 12
Sales agent 2Kitchen 131
Sales agent 3Kitchen 224

 

An example of the underlying data is below and I'm trying to sum 'Active Product'.

 

Sales AgentProductActive ProductVolume Sold
Sales agent 1Kitchen 11
Sales agent 1Sofa14
Sales agent 1TV07
Sales agent 1Bathroom110
Sales agent 2Kitchen 113
Sales agent 2Sofa116
Sales agent 2TV019
Sales agent 3Kitchen 122
Sales agent 3Sofa125
Sales agent 3TV028
Sales agent 3Bathroom131
Sales agent 3Bed134

 

Any help would be greatly appreciated 🙂

1 ACCEPTED SOLUTION

Hi @Jim_PBI 

Due to you use All function, you need to add a filter 'Table'[Sales Agent]=MAX('Table'[Sales Agent]) in your code to calculate sum 'Active Product' for each Sales Agent

Other Active Products =
VAR _SELECTVALUE =
    SELECTEDVALUE ( 'Table'[Product] )
VAR _SUM =
    CALCULATE (
        SUM ( 'Table'[Active Product] ),
        FILTER (
            ALL ( 'Table' ),
            'Table'[Product] <> _SELECTVALUE
                && 'Table'[Sales Agent] = MAX ( 'Table'[Sales Agent] )
        )
    )
RETURN
    _SUM

Result is as below.

1.png

Best Regards,
Rico Zhou

 

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

5 REPLIES 5
CNENFRNL
Community Champion
Community Champion

Screenshot 2021-11-27 205218.png


Thanks to the great efforts by MS engineers to simplify syntax of DAX! Most beginners are SUCCESSFULLY MISLED to think that they could easily master DAX; but it turns out that the intricacy of the most frequently used RANKX() is still way beyond their comprehension!

DAX is simple, but NOT EASY!

speedramps
Super User
Super User

Please consider and adapt this solution and click the thumbs up and accepts the the solution

 

Other products =
VAR myproduct = SELECTEDVALUE(Facts[Product])
VAR mysubset = FILTER(
  ALL(Facts[Product]),
   Facts[Product] <> myproduct)
RETURN
CALCULATE(
SUM(Facts[Volume Sold]),
mysubset)

How it works:-

myproduct gets the single product you have selected (eg Kitchen)

mysubset use the ALL commnd to get all records, but then filters the records not = kitchen

The CALCULATE then sums the volume sold just for the subset.
 
You can adapt just for active products if required.


 
 

I think this is very close to what I need so thank you for the response. In my real life scenario my data model is across two tables with a DIM table for the sales agents with a many to one relationship using the unique key. The slicer on the page is for the 'Sales Agent' from the DIM table and I believe this is stopping the DAX working correctly on the FACT table. I have included my DIM table below. 

 

Unique KeySales Agent
123Sales agent 1
124Sales agent 2
125Sales agent 3

 

Hi @Jim_PBI 

Due to you use All function, you need to add a filter 'Table'[Sales Agent]=MAX('Table'[Sales Agent]) in your code to calculate sum 'Active Product' for each Sales Agent

Other Active Products =
VAR _SELECTVALUE =
    SELECTEDVALUE ( 'Table'[Product] )
VAR _SUM =
    CALCULATE (
        SUM ( 'Table'[Active Product] ),
        FILTER (
            ALL ( 'Table' ),
            'Table'[Product] <> _SELECTVALUE
                && 'Table'[Sales Agent] = MAX ( 'Table'[Sales Agent] )
        )
    )
RETURN
    _SUM

Result is as below.

1.png

Best Regards,
Rico Zhou

 

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

Many thanks for the solution 🙂

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

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