cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
srlabhe123 Member
Member

Nested Filter

Hi Team,

I have below data where I need to put filter on the customers which has order instance as 5. Once I get those customers I need to sum of the revenue of those customers only but revenue should be summed for all the order instance till 5.

 

Customer Order Instance revenue
Cust01110
Cust01220
Cust01330
Cust01440
Cust01550
Cust01660
Cust05160
Cust05270
Cust05380
Cust08190
Cust092100
Cust101110
Cust111120
Cust121130
Cust122140
Cust141150
Cust151160
Cust161170

 

Like in above example only Cust01 has orer instance 5, so the Cust01 shold be filtered out and then sum of revenue for Cust01 where Order Instance is <=5 so in this case revenue should be $150.

Please note Cust01 is filtered on the base of all those customers which reached upto order instance =5 and then put another filter to get sum of revenue for all order instance <=5, the 6th order instance wont be considered here.

This is kind of nested filter , kindly guide how it can be done in Power BI desktop may be with the help of DAX reference.

 

Thanks

Swapnil

2 ACCEPTED SOLUTIONS

Accepted Solutions
Highlighted
v-ljerr-msft Super Contributor
Super Contributor

Re: Nested Filter

Hi @srlabhe123,

 

Based on my test, you can firstly use the formula below to create a new calculate column in your table to indicate if a customer has order instance as 5.

HasFive = 
IF (
    COUNTROWS (
        FILTER (
            ALL ( Table1 ),
            Table1[Customer] = EARLIER ( Table1[Customer] )
                && Table1[Order Instance] = 5
        )
    )
        >= 1,
    1,
    0
)

 c1.PNG

 

Then you should be able to use the formula below to create a measure to calculate sum of the revenue of those customers only but revenue should be summed for all the order instance till 5.

Measure = 
CALCULATE (
    SUM ( Table1[revenue] ),
    FILTER ( Table1, Table1[HasFive] = 1 && Table1[Order Instance] <= 5 )
)

 m1.PNG

 

Here is the sample pbix file for your reference. Smiley Happy

 

Regards

View solution in original post

srlabhe123 Member
Member

Re: Nested Filter

it worked with bit work around, thank you 

View solution in original post

2 REPLIES 2
Highlighted
v-ljerr-msft Super Contributor
Super Contributor

Re: Nested Filter

Hi @srlabhe123,

 

Based on my test, you can firstly use the formula below to create a new calculate column in your table to indicate if a customer has order instance as 5.

HasFive = 
IF (
    COUNTROWS (
        FILTER (
            ALL ( Table1 ),
            Table1[Customer] = EARLIER ( Table1[Customer] )
                && Table1[Order Instance] = 5
        )
    )
        >= 1,
    1,
    0
)

 c1.PNG

 

Then you should be able to use the formula below to create a measure to calculate sum of the revenue of those customers only but revenue should be summed for all the order instance till 5.

Measure = 
CALCULATE (
    SUM ( Table1[revenue] ),
    FILTER ( Table1, Table1[HasFive] = 1 && Table1[Order Instance] <= 5 )
)

 m1.PNG

 

Here is the sample pbix file for your reference. Smiley Happy

 

Regards

View solution in original post

srlabhe123 Member
Member

Re: Nested Filter

it worked with bit work around, thank you 

View solution in original post

Helpful resources

Announcements
Ask Amir Anything

Exclusive LIVE Community Event No. 2 – Ask Amir Anything

Next in our Triple A series: Ask Amir Netz questions about the latest updates, features and future.

Ask Amanda Anything Q&A

Ask Amanda Anything Q&A

Learn the answers to some of the questions asked during the Amanda Triple A event.

October 2019 Community Highlights

October 2019 Community Highlights

October was a busy month in the community. Read the recap article to learn about some of the events and content.

New Solution Badges

New Solution Badges

Two waves of brand new solution badges are coming! Read the article for more information on our new community badges.

Users Online
Currently online: 201 members 1,937 guests
Please welcome our newest community members: