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

Get Fabric Certified for FREE during Fabric Data Days. Don't miss your chance! Learn more

Reply
chulpanvl
Helper I
Helper I

Exclude rows from measure

Hello everyone!

I have a table of structure

rowmonthcontractparametervalue
101.01.2021NA100
201.02.2021NA100
301.03.2021NA100
401.04.2021NA100
501.01.2021NB20
601.02.2021NB30
701.03.2021NB0

 

I have measures:

param a =  CALCULATE(sum(‘Table’[value]),  ‘Table’[parameter] = «A»)

param b =  CALCULATE(sum(‘Table’[value]),  ‘Table’[parameter] = «B»)

ratio = DIVIDE(Table[param a], Table[param b])

 

What I want is to exclude from calculation of ratio the rows where value for parameter = b is 0 - for both numerator and denominator. I know how to do that for param b measure, I just need to add filter.

But how to filter out rows with the same month+contract for param a?

So, in the end I would get the ratio = (row 1 + row 2 + row 4)/(row 5 + row 6) for the example above.

 

Thank you!

1 ACCEPTED SOLUTION
Anonymous
Not applicable

Hi @chulpanvl ,

 

Since the data also needs to take into account the contract and the occurrence of 0 on multiple different dates, I added some data to the original sample data.

Sample data

vstephenmsft_0-1640919512290.png

 

1.Create the measure. I created a virtual table in the measure to filter out the value of parameter A corresponding to the date when the parameter B is 0, grouped by contract.

Ratio =
VAR _table1 =
    SELECTCOLUMNS (
        FILTER ( 'Table', [parameter] = "B" && [value] = 0 ),
        "month1", [month],
        "contract1", [contract]
    )
VAR _table2 =
    FILTER (
        CROSSJOIN ( 'Table', _table1 ),
        [month1] = [month]
            && [contract1] = [contract]
    )
VAR _unwantedvalue =
    SUMX ( FILTER ( _table2, [parameter] = "A" ), [value] )
RETURN
    DIVIDE (
        SUMX ( FILTER ( 'Table', [parameter] = "A" ), [value] ) - _unwantedvalue,
        SUMX ( FILTER ( 'Table', [parameter] = "B" ), [value] )
    )

 

vstephenmsft_1-1640919639140.png

 

 

 

Best Regards,

Stephen Tao

 

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

3 REPLIES 3
Ashish_Mathur
Super User
Super User

Hi,

You may download my PBI file from here.

Hope this helps.

4667d257-5e9f-4532-aaf7-d8f3057e0878.png


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/
Anonymous
Not applicable

Hi @chulpanvl ,

 

Since the data also needs to take into account the contract and the occurrence of 0 on multiple different dates, I added some data to the original sample data.

Sample data

vstephenmsft_0-1640919512290.png

 

1.Create the measure. I created a virtual table in the measure to filter out the value of parameter A corresponding to the date when the parameter B is 0, grouped by contract.

Ratio =
VAR _table1 =
    SELECTCOLUMNS (
        FILTER ( 'Table', [parameter] = "B" && [value] = 0 ),
        "month1", [month],
        "contract1", [contract]
    )
VAR _table2 =
    FILTER (
        CROSSJOIN ( 'Table', _table1 ),
        [month1] = [month]
            && [contract1] = [contract]
    )
VAR _unwantedvalue =
    SUMX ( FILTER ( _table2, [parameter] = "A" ), [value] )
RETURN
    DIVIDE (
        SUMX ( FILTER ( 'Table', [parameter] = "A" ), [value] ) - _unwantedvalue,
        SUMX ( FILTER ( 'Table', [parameter] = "B" ), [value] )
    )

 

vstephenmsft_1-1640919639140.png

 

 

 

Best Regards,

Stephen Tao

 

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

Jihwan_Kim
Super User
Super User

Hi,

Please check the below picture and the attached pbix file.

 

Picture1.png

 

Expected ratio: =
VAR filtertable_B_Zero =
FILTER ( Data, Data[parameter] = "B" && CALCULATE ( SUM ( Data[value] ) ) = 0 )
VAR extract_month =
MAXX ( filtertable_B_Zero, Data[month] )
VAR param_a =
FILTER ( Data, Data[parameter] = "A" && Data[month] <> extract_month )
VAR param_b =
FILTER ( Data, Data[parameter] = "B" && Data[month] <> extract_month )
RETURN
DIVIDE ( SUMX ( param_a, Data[value] ), SUMX ( param_b, Data[value] ) )


If this post helps, then please consider accepting it as the solution to help other members find it faster, and give a big thumbs up.


Click here to visit my LinkedIn page

Click here to schedule a short Teams meeting to discuss your question.

Helpful resources

Announcements
Fabric Data Days Carousel

Fabric Data Days

Advance your Data & AI career with 50 days of live learning, contests, hands-on challenges, study groups & certifications and more!

October Power BI Update Carousel

Power BI Monthly Update - October 2025

Check out the October 2025 Power BI update to learn about new features.

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.