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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
Anonymous
Not applicable

Measures with USERELATIONSHIP and conditions (filters) causing matrix/table to display duplicates

Hi there,

 

I have a measure which uses USERELATIONSHIP in conjunction with some filter conditions which works fine until I put the measure into a matrix and make one of the rows in the matrix the same as one of the columns in one of the filters. For example, one of the measures I am using has a condition which excludes any rows where the value in the Lab column equals "SEROLOGY":

 

TAT % (All) = (CALCULATE(
COUNTROWS('Mart vw_TestMeasures'), 
USERELATIONSHIP('Mart vw_DimDate'[Date],'Mart vw_TestMeasures'[Client Due Date]),
'Mart vw_TestMeasures'[TAT Met]="Yes",
'Mart vw_TestMeasures'[Lab]<>"SEROLOGY",
'Mart vw_TestMeasures'[Count in TAT]="Yes"
))
/ (CALCULATE(
COUNTROWS('Mart vw_TestMeasures'), 
USERELATIONSHIP('Mart vw_DimDate'[Date],'Mart vw_TestMeasures'[Client Due Date]),
'Mart vw_TestMeasures'[Lab]<>"SEROLOGY",
'Mart vw_TestMeasures'[Count in TAT]="Yes"
))

However, when I create a matrix which uses this measure and includes Lab as a row, while it correctly removes any SEROLOGY values, I now get duplicate values for each column in the matrix. For example, what I get is this:

Matrix with duplicate TATs.PNG

When what I expect to see is all different values, something like this:Matrix with correct TATs.PNG

 

Does anyone know how I could alter the DAX expression so that I don't get duplicates showing up in the matrix?

 

Thanks!

2 REPLIES 2
Jake91
Frequent Visitor

Hi @Anonymous,

 

I was recently faced with the same issue.

 

When you add the filter parameters to the calculate like that it is not taking into account any outside filter context for that column (clearing any filters on that column), you are essentially writing:

 

TAT % (All) = (CALCULATE(
COUNTROWS('Mart vw_TestMeasures'), 
USERELATIONSHIP('Mart vw_DimDate'[Date],'Mart vw_TestMeasures'[Client Due Date]),
FILTER(ALL([TAT Met]),'Mart vw_TestMeasures'[TAT Met]="Yes"),
FILTER(ALL([Lab]),'Mart vw_TestMeasures'[Lab]<>"SEROLOGY"),
FILTER(ALL([Count in TAT]),'Mart vw_TestMeasures'[Count in TAT]="Yes")
))
/ (CALCULATE(
COUNTROWS('Mart vw_TestMeasures'), 
USERELATIONSHIP('Mart vw_DimDate'[Date],'Mart vw_TestMeasures'[Client Due Date]),
FILTER(ALL([Lab]),'Mart vw_TestMeasures'[Lab]<>"SEROLOGY",)
FILTER(ALL([Count in TAT]),'Mart vw_TestMeasures'[Count in TAT]="Yes")
))

What worked for me is using the KEEPFILTERS function to make sure that it only adds to existing filters, Try this code:

 

TAT % (All) = (CALCULATE(
COUNTROWS('Mart vw_TestMeasures'), 
USERELATIONSHIP('Mart vw_DimDate'[Date],'Mart vw_TestMeasures'[Client Due Date]),
KEEPFILTERS('Mart vw_TestMeasures'[TAT Met]="Yes"),
KEEPFILTERS('Mart vw_TestMeasures'[Lab]<>"SEROLOGY"),
KEEPFILTERS('Mart vw_TestMeasures'[Count in TAT]="Yes")
))
/ (CALCULATE(
COUNTROWS('Mart vw_TestMeasures'), 
USERELATIONSHIP('Mart vw_DimDate'[Date],'Mart vw_TestMeasures'[Client Due Date]),
KEEPFILTERS('Mart vw_TestMeasures'[Lab]<>"SEROLOGY"),
KEEPFILTERS('Mart vw_TestMeasures'[Count in TAT]="Yes")
))

Also use DIVIDE function instead of / arithmetic

 

Hope that can help anyone else too

 

Thanks,

Jake

v-ljerr-msft
Employee
Employee

Hi @Anonymous,

 

Could you try the formula below to see if it works in your scenario? Smiley Happy

TAT % (All) =
IF (
    FIRSTNONBLANK ( 'Mart vw_TestMeasures', 1 ),
    BLANK (),
    DIVIDE (
        CALCULATE (
            COUNTROWS ( 'Mart vw_TestMeasures' ),
            USERELATIONSHIP ( 'Mart vw_DimDate'[Date], 'Mart vw_TestMeasures'[Client Due Date] ),
            'Mart vw_TestMeasures'[TAT Met] = "Yes",
            'Mart vw_TestMeasures'[Count in TAT] = "Yes"
        ),
        CALCULATE (
            COUNTROWS ( 'Mart vw_TestMeasures' ),
            USERELATIONSHIP ( 'Mart vw_DimDate'[Date], 'Mart vw_TestMeasures'[Client Due Date] ),
            'Mart vw_TestMeasures'[Count in TAT] = "Yes"
        )
    )
)

 

Regards

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

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.