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

Get certified in Microsoft Fabric—for free! For a limited time, get a free DP-600 exam voucher to use by the end of 2024. Register now

Reply
jenani_user
Frequent Visitor

Sum and Difference based on column field

Hi All,

I have table Similar to the Input image shown , how do I obtain the output similar to the image shown,

INPUT:

jenani_user_0-1730980520024.png

OUTPUT:

jenani_user_1-1730980608821.png

 

Kindly suggest any idea as there are around 10 columns similar to values(in B column of input)

Thanks

Jen

 

 

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

Thanks for the reply from KNP , please allow me to provide another insight: 
Hi  @jenani_user ,

Here are the steps you can follow:

1. Create calculated table.

Table =
var _table1=
SUMMARIZE(
    'Input',
    [A],
    "C","B+C",
    "B",
    SUMX(FILTER('Input',[A]=EARLIER([A])&&[C]="B"),[B])+
    SUMX(FILTER('Input',[A]=EARLIER([A])&&[C]="C"),[B]))
var _table2=
SUMMARIZE(
    _table1,
    [A],
    "C","A-(B+C)",
    "B",
    SUMX(FILTER('Input',[A]=EARLIER([A])&&[C]="A"),[B])-
    SUMX(FILTER(_table1,[A]=EARLIER([A])&&[C]="B+C"),[B]))
var _table=
SUMMARIZE(
    'Input',[A],[C],[B])
return
UNION(
    _table,_table1,_table2)

vyangliumsft_0-1731047134969.png

2. Result:

vyangliumsft_1-1731047134970.png

 

 

Best Regards,

Liu Yang

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

Thanks for the reply from KNP , please allow me to provide another insight: 
Hi  @jenani_user ,

Here are the steps you can follow:

1. Create calculated table.

Table =
var _table1=
SUMMARIZE(
    'Input',
    [A],
    "C","B+C",
    "B",
    SUMX(FILTER('Input',[A]=EARLIER([A])&&[C]="B"),[B])+
    SUMX(FILTER('Input',[A]=EARLIER([A])&&[C]="C"),[B]))
var _table2=
SUMMARIZE(
    _table1,
    [A],
    "C","A-(B+C)",
    "B",
    SUMX(FILTER('Input',[A]=EARLIER([A])&&[C]="A"),[B])-
    SUMX(FILTER(_table1,[A]=EARLIER([A])&&[C]="B+C"),[B]))
var _table=
SUMMARIZE(
    'Input',[A],[C],[B])
return
UNION(
    _table,_table1,_table2)

vyangliumsft_0-1731047134969.png

2. Result:

vyangliumsft_1-1731047134970.png

 

 

Best Regards,

Liu Yang

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

KNP
Super User
Super User

I'm not sure how complex your actual scenario is but have a look at the attached and see if it helps at all.

 

Have I solved your problem?
Please click Accept as Solution so I don't keep coming back to this post, oh yeah, others may find it useful also ;).
chrome-9xf-Zagzel-B

If you found this post helpful, please give Kudos.
It gives me a sense of instant gratification and, if you give me Kudos enough times, magical unicorns will appear on your screen.
If you find my signature vaguely amusing, please give Kudos.
KIfp67uy-Sr
Proud to be a Super User!PBI-Super-User-Rank-30x30-1x

Helpful resources

Announcements
November Carousel

Fabric Community Update - November 2024

Find out what's new and trending in the Fabric Community.

Live Sessions with Fabric DB

Be one of the first to start using Fabric Databases

Starting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.

Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.

Nov PBI Update Carousel

Power BI Monthly Update - November 2024

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