Microsoft Fabric Community Conference 2025, March 31 - April 2, Las Vegas, Nevada. Use code MSCUST for a $150 discount.
Register nowThe Power BI DataViz World Championships are on! With four chances to enter, you could win a spot in the LIVE Grand Finale in Las Vegas. Show off your skills.
Dear all,
I have stuck in calculating the Profit / Loss between two subgroups. I am pulling data from a single column and creating subgroup and group in power BI and drag that groups to Matrix table. But, I need to do some calculations as mentioned below, Please show me a way to achieve this result and it would be much appreciated.
1. Sum of Net Revenue - Sum of Cost of Revenue = Gross Profit (on a separate Total)
2. Sum of Other expenses + Gross Profit = Profit Other Expenses
3. Sum of Other income + Profit Other Expenses = Profit Before Tax
4. Sum of Tax + Profit Before Tax = Profit (Loss)
Note: We are using the formula for subtracting --> Sum of Net Revenue - Sum of Cost of Revenue = Gross Profit
Gross Profit = IF (
ISFILTERED ( sortedGroup[Column1 (groups)] ),
SUMX ( Sheet1, Sheet1[Amount] ),
SUMX (
FILTER (Sheet1,Sheet1[Account Reporting (groups)]= "Net Revenue" ),
Sheet1[Amount]
)
- SUMX (
FILTER (
Sheet1,
Sheet1[Account Reporting] = "Cost of Revenue"
),
Sheet1[Amount]
)
)
Many Thanks,
Praveen
Solved! Go to Solution.
Hi Praveen,
1. Add an index.
Index = SWITCH ( [Account Balance sheet (groups)], "Group A", 1, "Group B", 2, "Group C", 3, "Group D", 4, 9999 )
2. Create a measure.
Measure = IF ( ISFILTERED ( 'Single Column Data'[Account Balance sheet (groups)] ), SUM ( 'Single Column Data'[Amount] ), CALCULATE ( SUMX ( 'Single Column Data', IF ( [Index] IN { 2, 3 }, -1 * 'Single Column Data'[Amount], 'Single Column Data'[Amount] ) ), FILTER ( ALL ( 'Single Column Data' ), 'Single Column Data'[Index] <= MAX ( 'Single Column Data'[Index] ) ) ) )
Best Regards,
Dale
Hi @Anonymous,
Could you please mark the proper answers as solutions?
Best Regards,
Dale
Some great tips in this thread.
I have something similar, but getting some errors.
At a high level here is what led to the errors....I have added column fields (ie dimension) for all regions such as North, South, East, West. My column "Total" is correct, but individual regions are incorrect.
North | South | East | West | Total
Gross Profit 10 10 10 10 10
Sales 4 4 4 4 16
Expenses 1 1 1 3 6
Is it wrong to have the calculations rolled up into "top category" hierarchy?
Thank you in advance for any solution/tips.
Hi Praveen,
Please also try this formula. It worked base on your sample.
Measure = IF ( ISFILTERED ( sortedGroup[Column1] ), SUM ( Sheet1[Amount] ), CALCULATE ( SUMX ( Sheet1, IF ( Sheet1[Account Reporting (groups)] = "Cost of Revenue", -1 * Sheet1[Amount], Sheet1[Amount] ) ), FILTER ( ALL ( sortedGroup[Index] ), sortedGroup[Index] <= MAX ( sortedGroup[Index] ) ), ALL ( MajorGroup ) ) )
Best Regards,
Dale
Hello Dale,
Thank you so much for your solution. We got the answer for our sample data. We gave that sample data in a sorted manner for your understanding only. But, in real, what I am expecting is - a solution for non-sorted dataset. Please ref the below screenshot for your understanding and also I have attached an updated pbix file. We need solution for this pbix file. How to do that, please help us. It is so confusing. Your timely help would help us a lot.
Many Thanks,
Praveen.
Hi Praveen,
1. Add an index.
Index = SWITCH ( [Account Balance sheet (groups)], "Group A", 1, "Group B", 2, "Group C", 3, "Group D", 4, 9999 )
2. Create a measure.
Measure = IF ( ISFILTERED ( 'Single Column Data'[Account Balance sheet (groups)] ), SUM ( 'Single Column Data'[Amount] ), CALCULATE ( SUMX ( 'Single Column Data', IF ( [Index] IN { 2, 3 }, -1 * 'Single Column Data'[Amount], 'Single Column Data'[Amount] ) ), FILTER ( ALL ( 'Single Column Data' ), 'Single Column Data'[Index] <= MAX ( 'Single Column Data'[Index] ) ) ) )
Best Regards,
Dale
Hi Dale,
We are trying to achieve everthing from fact table and modified your consolidated measure but it is showing same data as NewAmountMST_ICS column not sure what is incorrect. MasterOrderIS is column in fact table holds 1, 2, 3, 4 etc values for each group.
ACCOUNTREPORTINGGROUP_INCOMESTATEMENTSSuperGroup: Revenue( consists of Net Revenue, Cost Revenue), Operating Expenses
ACCOUNTREPORTINGGROUP_INCOMESTATEMENTSGroup : Net Revenue , Cost of Revenue, Operating Expenses
MasterOrderIS column calulated based on each group: 1(Net Revenue), 2(Cost of Revenue), 3( Operating Expenses)
ACCOUNTREPORTINGGROUP_INCOMESTATEMENTS : Variables inside each group
NMeasure =
IF (
ISFILTERED ( 'LedgerTrans Fact'[ACCOUNTREPORTINGGROUP_INCOMESTATEMENTSGroup] ),
SUM ( 'LedgerTrans Fact'[NewAmountMST_ICS] ),
CALCULATE (
SUMX (
'LedgerTrans Fact',
IF (
'LedgerTrans Fact'[MASTERORDERIS] IN { 2, 3 },
-1 * 'LedgerTrans Fact'[NewAmountMST_ICS],
'LedgerTrans Fact'[NewAmountMST_ICS]
)
),
FILTER (
ALL ( 'LedgerTrans Fact'),
'LedgerTrans Fact'[MASTERORDERIS] <= MAX ( 'LedgerTrans Fact'[MASTERORDERIS] )
)
)
)
Thanks
Smita
Hi Smita,
Do you have the exact same data?
Best Regards,
Dale
Yes Dale data is same. Index columns which are derived in SortedGroup and Major Group are avaliable in LedgerTrans fact table itself.
MasterOrdeIS: Is to order by Each group. like column1, Index column from SortedGroup table
Each Account Reporting Group is sorted based on this column.
New Order: Is to order by each super group. Like column1 and Index column from Major Group table.
Each Account Reportinf Super group table is ordered based on this column
neworder = IF('LedgerTrans Fact'[ACCOUNTREPORTINGGROUP_INCOMESTATEMENTSGroup]="Net Revenue",1,
IF('LedgerTrans Fact'[ACCOUNTREPORTINGGROUP_INCOMESTATEMENTSGroup]="Operating Expenses",2,
IF('LedgerTrans Fact'[ACCOUNTREPORTINGGROUP_INCOMESTATEMENTSGroup]="Cost of Revenue",1,
IF('LedgerTrans Fact'[ACCOUNTREPORTINGGROUP_INCOMESTATEMENTSGroup]="Other income, (expense), net",3,
IF('LedgerTrans Fact'[ACCOUNTREPORTINGGROUP_INCOMESTATEMENTSGroup]="Provision for income taxes",4,
IF('LedgerTrans Fact'[ACCOUNTREPORTINGGROUP_INCOMESTATEMENTSGroup]="Check",5,
IF('LedgerTrans Fact'[ACCOUNTREPORTINGGROUP_INCOMESTATEMENTSGroup]="Unallocated IT",6,
IF('LedgerTrans Fact'[ACCOUNTREPORTINGGROUP_INCOMESTATEMENTSGroup]="Unallocated Facilities",7,
IF('LedgerTrans Fact'[ACCOUNTREPORTINGGROUP_INCOMESTATEMENTSGroup]="Unallocated Benefits",8,
IF('LedgerTrans Fact'[ACCOUNTREPORTINGGROUP_INCOMESTATEMENTSGroup]="Dept 0000 Costs",9,
IF('LedgerTrans Fact'[ACCOUNTREPORTINGGROUP_INCOMESTATEMENTSGroup]="Dept Blank Costs",10)))))))))))
MasterOrderIS: This is order by column to order
Hi @sjoshi,
I don't know how you plot the measure in a visual. But if you group the values like that, it could be a different question. The values will be grouped together. I would suggest you create a new thread in this forum with a sample file.
Best Regards,
Dale
Sure Dale I will. Thanks for all your help
Smita
You have to adjust your Group-tables a bit and then these measures will deliver the desired result:
P&L = IF(ISBLANK([RunningTotal]), SUM(Sheet1[Amount]), [RunningTotal])
with RunningTotal like this:
RunningTotal = IF ( ISFILTERED ( sortedGroup[Index] ), BLANK (), CALCULATE ( [AmountWithSigns], FILTER ( ALL ( sortedGroup ), sortedGroup[Index] <= MAX ( sortedGroup[Index] ) ) ) )
and AmountWithSigns like this:
AmountWithSigns = SUMX(Sheet1, Sheet1[Amount] * RELATED(sortedGroup[SwitchSignMultiplicator]))
Of course, you could put it all together into one measure, but I find this method easier to follow (see table in attached file).
Also, you might want to use AmountWithSigns for other purposes as well once you're realized its usefulness.
Link to file: https://1drv.ms/u/s!Av_aAl3fXRbehbJbXqn84pFD2Wc8fg
Imke Feldmann (The BIccountant)
If you liked my solution, please give it a thumbs up. And if I did answer your question, please mark this post as a solution. Thanks!
How to integrate M-code into your solution -- How to get your questions answered quickly -- How to provide sample data -- Check out more PBI- learning resources here -- Performance Tipps for M-queries
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
If you love stickers, then you will definitely want to check out our Community Sticker Challenge!
User | Count |
---|---|
123 | |
77 | |
71 | |
56 | |
48 |
User | Count |
---|---|
162 | |
84 | |
68 | |
66 | |
61 |