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
Anonymous
Not applicable

Using one row as variable for calculations

This will require some explaining.

Let's say we have 4 clients to which we book time against their code.
We also have internal code agasint which internal work is booked.
We want to divvy up the internal work amongst the 4 clients, apportioned to their weighting, i.e. the proportion of time booked against them.
Client Jan Feb March

A        $5  $1   $3

B        $1  $2   $1

C        $3  $1   $4

C        $1  $2   $3

Int     $10 $12   $4

So, I want 

JAN (Slider)

Client Mth$   Delivery Costs

A        $5       $2.5

B        $1       $2

C        $3       $1.5

C        $1       $2

Feb(Slider)

Client Mth$   Delivery Costs

A        $1       $2

B        $2       $4

C        $1       $2

C        $3       $4

So the "Delivery costs" is something like "Internal costs*client $ / total$
But I can't get anything to work!

1 ACCEPTED SOLUTION
d_gosbell
Super User
Super User

So I think your Jan example has an error in it as the total delivery cost only adds up to 8 when I think it should be 10.

 

But otherwise if I understand your requirements correctly I think the following calc should work for you

Delivery Costs = 
VAR _intAmt = CALCULATE(sum('Table'[Value]), 'Table'[Client] = "Int")
VAR _totalAmt = CALCULATE(SUM('Table'[Value]) , ALL('Table'[Client]) , 'Table'[Client] <> "Int")
VAR _clientAmt = CALCULATE(SUM('Table'[Value]) , KEEPFILTERS('Table'[Client] <> "Int"))
VAR _proportion = DIVIDE(_clientAmt , _totalAmt)
return (_proportion  * _intAmt)

 

The only slightly advanced bit in the above is that I've used the KEEPFILTERS() function when calculating the clientAmt (which is the total excluding the internal costs). In this way when you use the measure when the client column is on the rows it will get correctly filtered for the current client.

View solution in original post

2 REPLIES 2
d_gosbell
Super User
Super User

So I think your Jan example has an error in it as the total delivery cost only adds up to 8 when I think it should be 10.

 

But otherwise if I understand your requirements correctly I think the following calc should work for you

Delivery Costs = 
VAR _intAmt = CALCULATE(sum('Table'[Value]), 'Table'[Client] = "Int")
VAR _totalAmt = CALCULATE(SUM('Table'[Value]) , ALL('Table'[Client]) , 'Table'[Client] <> "Int")
VAR _clientAmt = CALCULATE(SUM('Table'[Value]) , KEEPFILTERS('Table'[Client] <> "Int"))
VAR _proportion = DIVIDE(_clientAmt , _totalAmt)
return (_proportion  * _intAmt)

 

The only slightly advanced bit in the above is that I've used the KEEPFILTERS() function when calculating the clientAmt (which is the total excluding the internal costs). In this way when you use the measure when the client column is on the rows it will get correctly filtered for the current client.

Anonymous
Not applicable

Absolutely Brilliant!
I literally plugged in with my field names and it worked no errors first time! 

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.