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

Earn a 50% discount on the DP-600 certification exam by completing the Fabric 30 Days to Learn It challenge.

Reply
HaNguyen97
Frequent Visitor

How to partially apply filter context

I have data like this 

SegmentCompanyPrincipalDateAmount
A1ABC1/3/2024100
A1ABC1/4/2024300
A1DEF1/5/2024230
A1ABC1/6/2024140
A1ABC1/7/2024200
B1MNO

1/1/2024

 

100
B1DEF1/2/2024200
B1MNO1/3/2024100
B1MNO1/4/2024300
B1DEF1/5/2024230
B1MNO1/6/2024140
B1MNO1/7/2024200
B1ABC1/8/2024200

 

I need get the MAX(count the distinct value of date from Jan of selected Year to selected Month) and the filter context need to be applied partially.

For example, if I select 1/7/2024, then segment A will have 5 Month, segment B will have 7 Month Count. But since principal ABC is not in the list of segment B from 1/1/2024 to 1/7/2024, segment B will not be counted.

The expected result will be:

CompanyPrincipalCount distinct Date YTD 
1ABC5

I have tried Allexcept and AllSelected but it doesn't give me corrected result.
If I used Allexcept:

 

VAR MaxDate =
MAX ( 'Dim Date'[Date] )
RETURN CALCULATE(
DISTINCTCOUNT(Table[Date]),
FILTER(ALL('Dim Date'),'Dim Date'[Year]=YEAR(MaxDate)&&'Dim Date'[Date]<=MaxDate),
ALLEXCEPT(Table,Table[Segment]),
USERELATIONSHIP( Table[Date],'Dim Date'[Date])
)

 

 

it will ignore completely all filter and give me 7

if I used AllSelected

 

 

VAR MaxDate =
MAX ( 'Dim Date'[Date] )
RETURN CALCULATE(
DISTINCTCOUNT(Table[Date]),
FILTER(ALL('Dim Date'),'Dim Date'[Year]=YEAR(MaxDate)&&'Dim Date'[Date]<=MaxDate),
ALLSELECTED(Table[Segment]),
USERELATIONSHIP(Table,'Dim Date'[Date])
)

 

 

 

It will take the filter Copmany=A and Principal=ABC into account and only give me 4.

Could anyone help me?

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

Hi @HaNguyen97 ,

 

According to your description, here are my steps you can follow as a solution.

(1) This is my model relationship. Because you are doing partial screening, sometimes model relationships can affect the results. You can use the CROSSFILTER function in the calculation to change the relationship to none if you need a model relationship.

vtangjiemsft_0-1712889811907.png

(2) We can create a slicer table.

Slicer Table = VALUES('Table'[Principal])

(3) We can create measures. 

Measure 1 = 
VAR MaxDate =
    MAX ( 'Dim Date'[Date] )
RETURN CALCULATE(DISTINCTCOUNT('Table'[Date]),FILTER(ALLSELECTED('Table'), YEAR('Table'[Date])=YEAR(MaxDate) && 'Table'[Date]<=MaxDate ))
Measure 2 = 
var _table= CALCULATETABLE(VALUES('Table'[Segment]),'Table'[Principal] in VALUES('Slicer Table'[Principal]) && 'Table'[Date]<=MAX('Dim Date'[Date]))

RETURN CALCULATE([Measure 1],FILTER(ALL('Table'),'Table'[Segment] in _table))
Flag = IF( MAX('Table'[Principal]) in VALUES('Slicer Table'[Principal]),1,0)

(3) Place [Flag=1] on the visual object screening and then the result is as follows.

vtangjiemsft_2-1712890008566.png

Best Regards,

Neeko Tang

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-tangjie-msft
Community Support
Community Support

Hi @HaNguyen97 ,

 

According to your description, here are my steps you can follow as a solution.

(1) This is my model relationship. Because you are doing partial screening, sometimes model relationships can affect the results. You can use the CROSSFILTER function in the calculation to change the relationship to none if you need a model relationship.

vtangjiemsft_0-1712889811907.png

(2) We can create a slicer table.

Slicer Table = VALUES('Table'[Principal])

(3) We can create measures. 

Measure 1 = 
VAR MaxDate =
    MAX ( 'Dim Date'[Date] )
RETURN CALCULATE(DISTINCTCOUNT('Table'[Date]),FILTER(ALLSELECTED('Table'), YEAR('Table'[Date])=YEAR(MaxDate) && 'Table'[Date]<=MaxDate ))
Measure 2 = 
var _table= CALCULATETABLE(VALUES('Table'[Segment]),'Table'[Principal] in VALUES('Slicer Table'[Principal]) && 'Table'[Date]<=MAX('Dim Date'[Date]))

RETURN CALCULATE([Measure 1],FILTER(ALL('Table'),'Table'[Segment] in _table))
Flag = IF( MAX('Table'[Principal]) in VALUES('Slicer Table'[Principal]),1,0)

(3) Place [Flag=1] on the visual object screening and then the result is as follows.

vtangjiemsft_2-1712890008566.png

Best Regards,

Neeko Tang

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

This looks great, thanks for your support.

Helpful resources

Announcements
LearnSurvey

Fabric certifications survey

Certification feedback opportunity for the community.

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.