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

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more

Reply
Anonymous
Not applicable

How to Calculate Subtotal of Other Rows (Exclude Current Row Value)

I am looking for a way to generate a subtotal column that's the sum of other rows of data, so in other words, it ignores / excludes the current row's value from the subtotal.

 

  • Per the screenshot below, I want to create what's displayed in col D (metric1_subtotal_other rows).  
    • Col E contains examples of how I am arriving at the subtotals I would like to create
  • I already have cols A-C in my PBI report.
 
 

Trend_test_ss.JPG

 

In case it's needed, you can access the sample PBI report here:

https://drive.google.com/file/d/1vGtN2pr8zHD_MSxANbs63KMcueOTcUPz/view?usp=sharing

 

Also, here is a link to the excel file used to create the PBI file and screenshot above:  https://drive.google.com/file/d/19spH03FeAMPh6SWE2zTYqFsSy8cWeHl8/view?usp=sharing

1 ACCEPTED SOLUTION

@Anonymoustry this

 

_test = 
IF (
    OR (
        OR ( ISINSCOPE ( SM[srg] ), ISINSCOPE ( SM[sds] ) ),
        ISINSCOPE ( SM[loc] )
    ),
    CALCULATE ( SUM ( CS1[metric1_subtotal] ), ALLSELECTED ( CS1 ) )
        - SUMX ( CS1, CS1[metric1_subtotal] ),
    IF (
        HASONEVALUE ( SM[sdv] ),
        VAR _1 =
            MAX ( SM[sdv] )
        VAR _2 =
            CALCULATE (
                SUMX ( CS1, CS1[metric1_subtotal] ),
                FILTER ( ALLSELECTED ( SM ), SM[sdv] <> _1 )
            )
        RETURN
            _2,
        SUMX ( CS1, CS1[metric1_subtotal] )
    )
)
Did I answer your question? Mark my post as a solution!
Proud to be a Super User!
My custom visualization projects
Plotting Live Sound: Viz1
Beautiful News:Viz1, Viz2, Viz3
Visual Capitalist: Working Hrs

View solution in original post

6 REPLIES 6
smpa01
Super User
Super User

@Anonymouscan you try this as a measure?

 

_x := 
IF (
    HASONEVALUE ( SM[sdv] ),
    VAR _1 =
        MAX ( SM[sdv] )
    VAR _2 =
        CALCULATE (
            SUMX ( CS1, CS1[metric1_subtotal] ),
            FILTER ( ALLSELECTED ( SM ), SM[sdv] <> _1 )
        )
    RETURN
        _2,
    SUMX ( CS1, CS1[metric1_subtotal] )
)

 Capture.PNG

Did I answer your question? Mark my post as a solution!
Proud to be a Super User!
My custom visualization projects
Plotting Live Sound: Viz1
Beautiful News:Viz1, Viz2, Viz3
Visual Capitalist: Working Hrs
Anonymous
Not applicable

@smpa01  - Thanks for sharing this approach!

It seems to work fine at the 'sdv' level (Level-1), but when i drill down to 'srg' (Level-2), it doesn't seem to follow the drill-level rows.

 

hashari_0-1614792978559.png

 

Thoughts?

@Anonymous  try this and see if it works as you desired

 

Measure :=
IF (
    OR (
        OR ( ISINSCOPE ( SM[srg] ), ISINSCOPE ( SM[sds] ) ),
        ISINSCOPE ( SM[loc] )
    ),
    SUMX ( CS1, CS1[metric1_subtotal] ),
    IF (
        HASONEVALUE ( SM[sdv] ),
        VAR _1 =
            MAX ( SM[sdv] )
        VAR _2 =
            CALCULATE (
                SUMX ( CS1, CS1[metric1_subtotal] ),
                FILTER ( ALLSELECTED ( SM ), SM[sdv] <> _1 )
            )
        RETURN
            _2,
        SUMX ( CS1, CS1[metric1_subtotal] )
    )
)
Did I answer your question? Mark my post as a solution!
Proud to be a Super User!
My custom visualization projects
Plotting Live Sound: Viz1
Beautiful News:Viz1, Viz2, Viz3
Visual Capitalist: Working Hrs

@AnonymousI am not sure how do you envision the calculation to pan out on a drill down level

 

On individualsdv level (non-subtotal filter context), I am telling my measure to calculate evrything but that particular sdv level. So with sdv=2, it sums up 4+5+7+10.

When you drill down and gove to sdv->srg lvel what do you plan this measure to return for sdv-srg level with 2-20 and 2-51?

 

Capture.PNG

Did I answer your question? Mark my post as a solution!
Proud to be a Super User!
My custom visualization projects
Plotting Live Sound: Viz1
Beautiful News:Viz1, Viz2, Viz3
Visual Capitalist: Working Hrs
Anonymous
Not applicable

@smpa01 

For 2-20 would it be possible to display 727 (870 - 143), instead of 640

For 2-51 would it be possible to display 783 (870 - 87), instead of 640

 

Also, would that carry if we drill down to Level-3, 'sds' ?

hashari_0-1614794821229.png

 

@Anonymoustry this

 

_test = 
IF (
    OR (
        OR ( ISINSCOPE ( SM[srg] ), ISINSCOPE ( SM[sds] ) ),
        ISINSCOPE ( SM[loc] )
    ),
    CALCULATE ( SUM ( CS1[metric1_subtotal] ), ALLSELECTED ( CS1 ) )
        - SUMX ( CS1, CS1[metric1_subtotal] ),
    IF (
        HASONEVALUE ( SM[sdv] ),
        VAR _1 =
            MAX ( SM[sdv] )
        VAR _2 =
            CALCULATE (
                SUMX ( CS1, CS1[metric1_subtotal] ),
                FILTER ( ALLSELECTED ( SM ), SM[sdv] <> _1 )
            )
        RETURN
            _2,
        SUMX ( CS1, CS1[metric1_subtotal] )
    )
)
Did I answer your question? Mark my post as a solution!
Proud to be a Super User!
My custom visualization projects
Plotting Live Sound: Viz1
Beautiful News:Viz1, Viz2, Viz3
Visual Capitalist: Working Hrs

Helpful resources

Announcements
November Power BI Update Carousel

Power BI Monthly Update - November 2025

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

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!

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.

Top Kudoed Authors