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
d_h
Regular Visitor

Matrix visual with difference calculation from total row

I need to create a matrix visual that looks like the following:

TrainDay 6Day 7Day 8

Loc. A

208822042088
Loc. B150815082436
Total359637124524
Capacity400040004000
Difference-404-288524

(train load in tons, capacity is specific to Company A, I have different tables featuring different trains and capacities on a per company basis).

 

Source data features 2 different tables. One for the load that the train is carrying and one for the companies and their total capacity that follow a simple relationship with eachother:

CompanyTrainDayLoad
Company ALoc. A61392
Company ALoc. A6696
Company ALoc. B61508
Company BLoc. A6928
Company BLoc. A61044

 

CompanyCapacity
Company A4000
Company B4200

 

I have been able to create the matrix without the capacity and difference row. But I do need to display the capacity and the difference from the actual planning preferably within one table. Any other ideas are also welcome!

 

Thank you in advance!

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

Hi @d_h ,

 

Please create a new table.

 

Table = 
VAR newcapacity =
    CROSSJOIN ( Capacity, VALUES ( Train[Day] ) )
VAR UnionTab =
    UNION (
        Train,
        SELECTCOLUMNS (
            newcapacity,
            "Company", [Company],
            "Train", "Capacity",
            "Day", [Day],
            "Load", [Capacity]
        )
    )
RETURN
    ADDCOLUMNS (
        UnionTab,
        "Type", IF ( [Train] = "Capacity", "Capacity", "Train" )
    )

vkkfmsft_0-1653550454634.png

 

Then create these measures.

 

Load and Capacity = 
CALCULATE ( SUM ( 'Table'[Load] ), 'Table'[Company] = "Company A" )
TotalValue = 
VAR diff =
    CALCULATE ( [Load and Capacity], 'Table'[Type] = "Train" )
        - CALCULATE ( [Load and Capacity], 'Table'[Type] = "Capacity" )
RETURN
    IF ( ISFILTERED ( 'Table'[Type] ), [Load and Capacity], diff )

vkkfmsft_1-1653550520378.png

 

If the problem is still not resolved, please provide detailed error information or the expected result you expect. Let me know immediately, looking forward to your reply.
Best Regards,
Winniz
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

3 REPLIES 3
v-kkf-msft
Community Support
Community Support

Hi @d_h ,

 

Please create a new table.

 

Table = 
VAR newcapacity =
    CROSSJOIN ( Capacity, VALUES ( Train[Day] ) )
VAR UnionTab =
    UNION (
        Train,
        SELECTCOLUMNS (
            newcapacity,
            "Company", [Company],
            "Train", "Capacity",
            "Day", [Day],
            "Load", [Capacity]
        )
    )
RETURN
    ADDCOLUMNS (
        UnionTab,
        "Type", IF ( [Train] = "Capacity", "Capacity", "Train" )
    )

vkkfmsft_0-1653550454634.png

 

Then create these measures.

 

Load and Capacity = 
CALCULATE ( SUM ( 'Table'[Load] ), 'Table'[Company] = "Company A" )
TotalValue = 
VAR diff =
    CALCULATE ( [Load and Capacity], 'Table'[Type] = "Train" )
        - CALCULATE ( [Load and Capacity], 'Table'[Type] = "Capacity" )
RETURN
    IF ( ISFILTERED ( 'Table'[Type] ), [Load and Capacity], diff )

vkkfmsft_1-1653550520378.png

 

If the problem is still not resolved, please provide detailed error information or the expected result you expect. Let me know immediately, looking forward to your reply.
Best Regards,
Winniz
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

amitchandak
Super User
Super User

@d_h , there is work around suggeted here

 

Power bi Excel for P&L , add in app
Curbal
https://www.youtube.com/watch?v=IISYzTaIyu4
Guyinacube
https://www.youtube.com/watch?v=1yJnmZRTNZg

Join us as experts from around the world come together to shape the future of data and AI!
At the Microsoft Analytics Community Conference, global leaders and influential voices are stepping up to share their knowledge and help you master the latest in Microsoft Fabric, Copilot, and Purview.
️ November 12th-14th, 2024
 Online Event
Register Here

@amitchandak Thank you for your reply.

 

I watched both videos that suggest adding an Excel workbook to a Power BI app.

Is that the only way to achieve this? I'd like to have the matrix within a report.

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.