cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Highlighted
decshz Regular Visitor
Regular Visitor

PRORATE by drivers

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:

 

 

plants.PNG

 

 

and  I also have another table that describes how much every plant is used by every business line:

usage.PNG

 

 

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:

result.PNG

 

 

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!

 

 

1 ACCEPTED SOLUTION

Accepted Solutions
v-yulgu-msft Super Contributor
Super Contributor

Re: PRORATE by drivers

Hi @decshz,

 

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.

1.PNG

 

Apply changes, in Data view mode, create a calculated table.

Usage2 =
UNION (
    ADDCOLUMNS ( VALUES ( Cost[Plants] ), "Business", "Total", "Percentage", 1 ),
    Usage
)

2.PNG

 

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.

1.PNG2.PNG

Best regards,

Yuliana Gu

Community Support Team _ Yuliana Gu
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
4 REPLIES 4
Super User
Super User

Re: PRORATE by drivers

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%

...

 

 


I have book! Learn Power BI from Packt


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

Proud to be a Datanaut!

decshz Regular Visitor
Regular Visitor

Re: PRORATE by drivers

Okay and after I unpivot the data how is the syntaxis to make the proration?

v-yulgu-msft Super Contributor
Super Contributor

Re: PRORATE by drivers

Hi @decshz,

 

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.

1.PNG

 

Apply changes, in Data view mode, create a calculated table.

Usage2 =
UNION (
    ADDCOLUMNS ( VALUES ( Cost[Plants] ), "Business", "Total", "Percentage", 1 ),
    Usage
)

2.PNG

 

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.

1.PNG2.PNG

Best regards,

Yuliana Gu

Community Support Team _ Yuliana Gu
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
decshz Regular Visitor
Regular Visitor

Re: PRORATE by drivers

awesome this has helped a lot, thank you so much!

Helpful resources

Announcements
Community Kudopalooza

Win Power BI Swag with Community Kudopalooza!

Each week, complete activities and be qualified in the drawing for cool Power BI Swag.

Summit North America

Power Platform Summit North America

Register by September 5 to save $200

Virtual Launch Event

Microsoft Business Applications Virtual Launch Event

Watch the event on demand for an in-depth look at the new innovations across Dynamics 365 and the Microsoft Power Platform.

MBAS Gallery

Watch Sessions On Demand!

Continue your learning in our online communities.

Users Online
Currently online: 428 members 4,103 guests
Please welcome our newest community members: