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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
Daxmax
Helper I
Helper I

How to include measures (NOI, Net Income) into table?

Hello,

I'm reproducing an income statement from Excel into Power BI. 

The generic structure of the income statement is like this:

1.png

 

My datasource is a SQL database and I've desined my table like this:

2.png

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

1 ACCEPTED SOLUTION
danextian
Super User
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:

danextian_1-1653452723535.png

 

Here's the sample PBIX for your reference: https://drive.google.com/file/d/1KZo45MbHRIui1v1hLKrpJKyMDpYdm081/view?usp=sharing 










Did I answer your question? Mark my post as a solution!


Proud to be a Super User!









"Tell me and I’ll forget; show me and I may remember; involve me and I’ll understand."
Need Power BI consultation, get in touch with me on LinkedIn or hire me on UpWork.
Learn with me on YouTube @DAXJutsu or follow my page on Facebook @DAXJutsuPBI.

View solution in original post

2 REPLIES 2
danextian
Super User
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:

danextian_1-1653452723535.png

 

Here's the sample PBIX for your reference: https://drive.google.com/file/d/1KZo45MbHRIui1v1hLKrpJKyMDpYdm081/view?usp=sharing 










Did I answer your question? Mark my post as a solution!


Proud to be a Super User!









"Tell me and I’ll forget; show me and I may remember; involve me and I’ll understand."
Need Power BI consultation, get in touch with me on LinkedIn or hire me on UpWork.
Learn with me on YouTube @DAXJutsu or follow my page on Facebook @DAXJutsuPBI.

This works. Thank you very much!

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

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

April Fabric Community Update

Fabric Community Update - April 2024

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