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
Nico_Saar
Regular Visitor

DAX Filter on matrix not working when using ALLSELECTED in measure

Hi everyone,

I need some help solving the following problem:

I have 3 tables (1 fact + 2 dimensions) which contain the following columns:

 

Fact_Table   
ProductIDGradeDefectCodeDateID
1BD120230101
1BD420230101
1CD4

20230101

2BD120230102
3BD220230105
3CD320230105
3CD420230105
4BD220230106
5BD120230114
5CD120230114

 

Dim_Table 
DefectCodeDefectDescription
D1Defect 1
D2Defect 2
D3Defect 3
D4

Defect 4

 

The second dimension table is a standard date dimension.

 

My goal is to build a matrix visual which looks like this:

Matrix    
ProductIDDefect 1Defect 2Defect 3Defect 4
1BAAC
2BAAA
3ABCC
4ABAA
5CAAA

 

  • The column "ProductID" from my fact table is used as "Rows" in my matrix visual
  • The column "DefectDescription" from my dimension table is used as a column in my matrix visual
  • The column "Grade" should be used as values.
    • IMPORTANT: there could be multiple grades for one ProductID and for the same DefectCode. E.g. for ProductID = 1 and DefectCode = D4 there are 2 grades, "B" & "C".
      In this case, the "lowest" grade should be selected -> C
    • If there is no Grade available for a DefectCode, I want to show "A" instead of a blank cell.

In order to achieve this a created the following measure which I use in the matrix visual:

 

Grade =
VAR result =
    CALCULATE (
        MAX ( 'Fact_Table'[Grade] ),
        FILTER (           ALLSELECTED ( 'Fact_Table' ),
            'Fact_Table'[Grade] IN VALUES ( 'Fact_Table'[Grade] )
        )
    )
RETURN
    IF ( result <> BLANK (), result, "A+" )

 

On the first sight this works pretty well but a problem occures as soon as I want to filter the data inside the matrix using a slicer. (e.g. Date) Date date slicers is using the date dimension with a relationship to my fact table. When I set the date range starting at 20230102, all values for ProductID = 1 will bet set a "A". I know that the visual is supposed the replace not existing values with "A" but in this case, I don't want to show ProductID = 1 at all. 

I think that the problem is located in the "ALLSELECTED" part of the FILTER function but I can't figure out what to change in order to get the result needed.

 

Best regards

1 REPLY 1
v-rzhou-msft
Community Support
Community Support

Hi @Nico_Saar ,

 

Here I create a sample to have a test.

RicoZhou_0-1677054881537.png

I think you can try this code to create a measure.

M_Grade = 
VAR _Count =
    CALCULATE (
        COUNT ( Fact_Table[DefectCode] ),
        ALLEXCEPT ( Fact_Table, Fact_Table[ProductID], Dim_Date[DateID] )
    )
VAR _LowestGrade =
    CALCULATE ( MAX ( Fact_Table[Grade] ) )
RETURN
    IF ( _Count = 0, BLANK (), IF ( ISBLANK ( _LowestGrade ), "A", _LowestGrade ) )

Result is as below.

By Default:

RicoZhou_2-1677055350879.png

Select "20230102" in slicer:

RicoZhou_3-1677055387526.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.

 

 

 

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