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
ThomasSan
Helper III
Helper III

Use double filter when calculating a sum

Hi everyone, 

 

I have the following table:

Order ID

Order DateOrder ValueCustomer

O1

01.01.2021            248,00 €C1
O1619.01.2022               40,00 €C1
O1512.03.2021            112,00 €C2
O915.03.2021            599,00 €C2
O822.04.2022            567,00 €C2
O230.04.2022            457,00 €C1

 

I am creating a company specific view where the user can filter the page with the help of a customer filter. In this company specific view, I would like to create a pie chart in which I can show the share of sales to the selected customer in 2022 to the total. It should look as follows:

ThomasSan_0-1664705312478.png

 

My DAX formula for C1 works fine*. However, my DAX formula for Rest does not quite work. It looks as follows:

 

Gross Margin CY ALL = 
calculate(
    sum(OrderDetails[Unit Margin]),
    all(),
    filter(Orders,
        year(Orders[Order Date]) = 2022
    )
)

 

 

As you can see, while I would like to keep the date filter, I would like to extend my calculate to all customers. However, I only seem to get the same value returned Can anyone please help me in correcting my DAX formula?


-------------------------

* formula looks as follows:

 

Gross Margin CY= 
calculate(
    sum(OrderDetails[Unit Margin]),
    filter(Orders,
        year(Orders[Order Date]) = 2022
    )
)

 

1 ACCEPTED SOLUTION

Hi, @ThomasSan 

You can replace the [Rest] measure :

Rest = 
VAR _slice = VALUES('Sheet1'[Customer])
return 
SUMX( FILTER(ALL(Sheet1) , YEAR('Sheet1'[Order Date]) =2022 && not 'Sheet1'[Customer] in _slice ),'Sheet1'[Order Value]) 

The result is as follows:

vyueyunzhmsft_0-1664786333657.png

Best Regards,

Aniya Zhang

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

9 REPLIES 9
v-yueyunzh-msft
Community Support
Community Support

Hi , @ThomasSan 

You want to show the value of the selected Customer and the value of the other Customer in the pie chart. Right?

Here are the steps you can refer to :

(1)This is my test data:

vyueyunzhmsft_0-1664781797309.png

(2)We can create two measures :

Custom Value = SUMX( FILTER('Sheet1',YEAR('Sheet1'[Order Date])=2022 ) , 'Sheet1'[Order Value])
Rest = SUMX( FILTER(ALL(Sheet1) , YEAR('Sheet1'[Order Date]) =2022 && 'Sheet1'[Customer] <> SELECTEDVALUE('Sheet1'[Customer]) ),'Sheet1'[Order Value]) 

(3)Then we can put the [Customer] in slice and the measure in the pie chart and we will meet your need :

vyueyunzhmsft_1-1664781866278.png

 

If this method does not meet your needs, you can provide us with your special sample data and the desired output sample data in the form of tables, so that we can better help you solve the problem.

 

Best Regards,

Aniya Zhang

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

 

Thank you for your response, @v-yueyunzh-msft !

Unfortunately, in my description above, I failed to mention that I have more than two customers. Do you happen to know how to successfully transform the "<> SELECTEDVALUE('Sheet1'[Customer]) " bit into a list?

Hi, @ThomasSan 

You can replace the [Rest] measure :

Rest = 
VAR _slice = VALUES('Sheet1'[Customer])
return 
SUMX( FILTER(ALL(Sheet1) , YEAR('Sheet1'[Order Date]) =2022 && not 'Sheet1'[Customer] in _slice ),'Sheet1'[Order Value]) 

The result is as follows:

vyueyunzhmsft_0-1664786333657.png

Best Regards,

Aniya Zhang

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

 

@v-yueyunzh-msft 

thanks, that was the solution!

 

tamerj1
Super User
Super User

Hi @ThomasSan 

please try

Gross Margin CY Other =
CALCULATE (
    SUM ( OrderDetails[Unit Margin] ),
    ALL (),
    FILTER (
        Orders,
        YEAR ( Orders[Order Date] ) = 2022
            && Orders[Customer] <> SELECTEDVALUE ( Orders[Customer] )
    )
)

Hi @tamerj1 ,

thank you for your reply. Unfortunately, I get a (Blank) returned which I do not quite understand. My filter is using Orders[Customer] so I do not quite know why it won't respond to SELECTEDVALUE(Orders[Customer]). Naturally, I checked the data and there are other sales by customers that are not C1 in that year. Do you maybe know where else I could check or what else might help?

 

Edit:
I realize that the problem is that in my larger data set, I have more than two customers. I was not aware that my data extract with only two customers may pose an issue here. Do you know how to transform the SELECTEDVALUE(Orders[Customer]) bit to a list? I have already unsuccessfully tried not(Orders[Customers] in {SELECTEDVALUE(Orders[Customer])})

@ThomasSan 
Please try

Gross Margin CY Other =
CALCULATE (
    SUM ( OrderDetails[Unit Margin] ),
    ALL (),
    FILTER (
        Orders,
        YEAR ( Orders[Order Date] ) = 2022
            && NOT ( Orders[Customer] IN VALUE ( Orders[Customer] ) )
    )
)

@tamerj1 

Unfortunately, it says "The function expects a table expression for argument '2', but a string or numeric expression was used." here

@ThomasSan 
Sorry a typo mistake. Missed the "S" in VALUE(S)

Gross Margin CY Other =
CALCULATE (
    SUM ( OrderDetails[Unit Margin] ),
    ALL (),
    FILTER (
        Orders,
        YEAR ( Orders[Order Date] ) = 2022
            && NOT ( Orders[Customer] IN VALUES ( Orders[Customer] ) )
    )
)

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.

Top Solution Authors