Check your eligibility for this 50% exam voucher offer and join us for free live learning sessions to get prepared for Exam DP-700.
Get StartedDon't miss out! 2025 Microsoft Fabric Community Conference, March 31 - April 2, Las Vegas, Nevada. Use code MSCUST for a $150 discount. Prices go up February 11th. Register now.
Hello,
I'm reproducing an income statement from Excel into Power BI.
The generic structure of the income statement is like this:
My datasource is a SQL database and I've desined my table like this:
In Power BI, I've created a Pivot Table, and pulled in the relevant columns, but I still need to show NOI, and Net Income, which are measures.
How do I show these measures within the table itself?
Thank You
Solved! Go to Solution.
Hi @Daxmax ,
There is not out of the box solution to your use case but DAX is flexible enough for that. My approach would be to create a disconnected table (no relationship to Fact or Dimension tables) that will hold the value of each group plus the one for net income). There are many ways to create that table - you can use the Enter Data table or create one using DAX. I'll be using DAX for this.
Create a calculated table using the formula below and then sort the Group by Order column.
Group =
DATATABLE (
"Group", STRING,
"Order", INTEGER,
{
{ "Revenue", 1 },
{ "Expenses", 2 },
{ "Other Expenses", 3 },
{ "Net Income", 4 }
}
)
Create these measures:
Sum of Actuals =
SUM ( 'Table'[Actuals] )
Net Income =
CALCULATE ( [Sum of Actuals], FILTER ( 'Table', 'Table'[Group] = "Revenue" ) )
- CALCULATE (
[Sum of Actuals],
FILTER ( 'Table', 'Table'[Group] IN { "Expenses", "Other Expenses" } )
)
Actuals with Net Income =
VAR __GROUP =
SELECTEDVALUE ( 'Group'[Group] )
RETURN
IF (
__GROUP = "Net Income",
[Net Income],
CALCULATE ( [Sum of Actuals], FILTER ( 'Table', 'Table'[Group] = __GROUP ) )
)
Here's a screenshot of the final output:
Here's the sample PBIX for your reference: https://drive.google.com/file/d/1KZo45MbHRIui1v1hLKrpJKyMDpYdm081/view?usp=sharing
Proud to be a Super User!
Hi @Daxmax ,
There is not out of the box solution to your use case but DAX is flexible enough for that. My approach would be to create a disconnected table (no relationship to Fact or Dimension tables) that will hold the value of each group plus the one for net income). There are many ways to create that table - you can use the Enter Data table or create one using DAX. I'll be using DAX for this.
Create a calculated table using the formula below and then sort the Group by Order column.
Group =
DATATABLE (
"Group", STRING,
"Order", INTEGER,
{
{ "Revenue", 1 },
{ "Expenses", 2 },
{ "Other Expenses", 3 },
{ "Net Income", 4 }
}
)
Create these measures:
Sum of Actuals =
SUM ( 'Table'[Actuals] )
Net Income =
CALCULATE ( [Sum of Actuals], FILTER ( 'Table', 'Table'[Group] = "Revenue" ) )
- CALCULATE (
[Sum of Actuals],
FILTER ( 'Table', 'Table'[Group] IN { "Expenses", "Other Expenses" } )
)
Actuals with Net Income =
VAR __GROUP =
SELECTEDVALUE ( 'Group'[Group] )
RETURN
IF (
__GROUP = "Net Income",
[Net Income],
CALCULATE ( [Sum of Actuals], FILTER ( 'Table', 'Table'[Group] = __GROUP ) )
)
Here's a screenshot of the final output:
Here's the sample PBIX for your reference: https://drive.google.com/file/d/1KZo45MbHRIui1v1hLKrpJKyMDpYdm081/view?usp=sharing
Proud to be a Super User!
This works. Thank you very much!
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Prices go up Feb. 11th.
Check out the January 2025 Power BI update to learn about new features in Reporting, Modeling, and Data Connectivity.
User | Count |
---|---|
147 | |
85 | |
66 | |
52 | |
46 |
User | Count |
---|---|
215 | |
90 | |
83 | |
66 | |
58 |