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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
decshz
Helper I
Helper I

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
v-yulgu-msft
Employee
Employee

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.

View solution in original post

4 REPLIES 4
v-yulgu-msft
Employee
Employee

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.

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

Greg_Deckler
Super User
Super User

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%

...

 

 


@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
Mastering Power BI 2nd Edition

DAX is easy, CALCULATE makes DAX hard...

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

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

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