March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early bird discount ends December 31.
Register NowBe one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now
Hello, is it possible to prorate by drivers in Power BI?
example, right now i have in my dataset a table with the costs to operate monthly every plant:
and I also have another table that describes how much every plant is used by every business line:
is it possible to do something similar to excel's index match match, to be able then to prorate the plant cost by business line?
something like this:
more so, i would like to apply the "business" field as a filter, then if nothing is filtered I would show the total cost for every plant, but if for example I select Business A in the "business filter" then plant 1 would show 7,334.47, plant 2 shows 37,631.09, and so and so.
any help is GREATLY appreciated!
Solved! Go to Solution.
Hi @Anonymous,
Please refer to below steps, but it may not achieve your requirement completely.
In Query Editor mode, choose all "Business" columns and click "Unpivot columns" to convert table structure to below.
Apply changes, in Data view mode, create a calculated table.
Usage2 = UNION ( ADDCOLUMNS ( VALUES ( Cost[Plants] ), "Business", "Total", "Percentage", 1 ), Usage )
Add [Business] from above 'Usage2' table into slicer. Add Usage2[Plants], Usage2[Business] and below measure into Matrix. Remember to turn off "Column Subtotals" under "Subtotals" option in Format pane.
cost by business = IF ( CALCULATE ( ISFILTERED ( Usage2[Business] ), ALLSELECTED ( Cost ) ), CALCULATE ( SUM ( Cost[Cost] ), FILTER ( ALLSELECTED ( Cost ), Cost[Plants] = SELECTEDVALUE ( Usage2[Plants] ) ) ) * SUM ( Usage2[Percentage] ), CALCULATE ( SUM ( Cost[Cost] ), FILTER ( ALLSELECTED ( Cost ), Cost[Plants] = SELECTEDVALUE ( Usage2[Plants] ) ) ) )
If nothing is filtered, Matrix would show total cost as well as each business. To show total cost only, you need to select "Total" from slicer.
Best regards,
Yuliana Gu
Hi @Anonymous,
Please refer to below steps, but it may not achieve your requirement completely.
In Query Editor mode, choose all "Business" columns and click "Unpivot columns" to convert table structure to below.
Apply changes, in Data view mode, create a calculated table.
Usage2 = UNION ( ADDCOLUMNS ( VALUES ( Cost[Plants] ), "Business", "Total", "Percentage", 1 ), Usage )
Add [Business] from above 'Usage2' table into slicer. Add Usage2[Plants], Usage2[Business] and below measure into Matrix. Remember to turn off "Column Subtotals" under "Subtotals" option in Format pane.
cost by business = IF ( CALCULATE ( ISFILTERED ( Usage2[Business] ), ALLSELECTED ( Cost ) ), CALCULATE ( SUM ( Cost[Cost] ), FILTER ( ALLSELECTED ( Cost ), Cost[Plants] = SELECTEDVALUE ( Usage2[Plants] ) ) ) * SUM ( Usage2[Percentage] ), CALCULATE ( SUM ( Cost[Cost] ), FILTER ( ALLSELECTED ( Cost ), Cost[Plants] = SELECTEDVALUE ( Usage2[Plants] ) ) ) )
If nothing is filtered, Matrix would show total cost as well as each business. To show total cost only, you need to select "Total" from slicer.
Best regards,
Yuliana Gu
awesome this has helped a lot, thank you so much!
Yes, but you will want to unpivot the last 3 columns of your 2nd table in Power Query so that you end up with:
Plant,Business,Usage
Plant1,Business A, 25%
Plant1,Business B, 32%
Plant1,Business C, 43%
...
Okay and after I unpivot the data how is the syntaxis to make the proration?
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions.
Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.
User | Count |
---|---|
129 | |
97 | |
95 | |
84 | |
52 |
User | Count |
---|---|
209 | |
160 | |
90 | |
90 | |
73 |