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
soldstatic
Resolver I
Resolver I

Measure to Sum Joined Tables

I have my data model set up with a customer table and an eventtable. Multiple customers go to each event, and events have different durations. I want to sum up the total minutes that customers are at events. In SQL I could do:

 

select sum(duration)
from Events E
join CustomerEvents CE on E.id = CE.EventID

 

Because the join would duplicate rows for each event to show one record per combination of event and customer, this should work. 

 

How do I do the same thing in PBI? I tried sumx(CustomerEvents,sum(Events[Duration])) and it isn't giving me the correct number.

 

Thanks in advance!

Andy

1 ACCEPTED SOLUTION

Hi @soldstatic ,

 

You don't need to sum it twice. Please refer to the following measure:

Measure =
CALCULATE (
    SUM ( Events[Duration] ),
    NATURALINNERJOIN ( 'Events', 'CustomerEvents' )
)

 

Community Support Team _ Eads
If this post helps, then please consider Accept it as the solution to help the other members find it.

View solution in original post

3 REPLIES 3
az38
Community Champion
Community Champion

@soldstatic hi

you need set up relationships between tables by ID field, then just create a measure like CALCULATE(SUM(Events[Duration]))


do not hesitate to give a kudo to useful posts and mark solutions as solution
LinkedIn

The relationships are already set up. They are 1-*, and only cross filter one direction for necessity. There are other relationships involved, so the actual calculate measure I am using has more to it than this, but I am currently using something like this:

measure = 
calculate(
  sumx(CustomerEvents,sum(Events[Duration]))
  ,crossfilter(CustomerEvents,Events,both)
)

 

This doesn't result in the correct answer. Here's why:

Sum(Events[Duration]) = 392
Countrows(CustomerEvents) = 38
sumx(CustomerEvents,sum(Events[Duration])) = 14,896
sumx(CustomerEvents,sumx(Events,[Duration])) = 14,896

 So what this is doing is giving me 392*38 as the answer, when that is not correct. I need the durations to be spread out / weighted by how many customers attended each event. The correct answer is 1,305 when calculated correctly using the join method above in SQL, but I can't get that to happen in PBI.

Hi @soldstatic ,

 

You don't need to sum it twice. Please refer to the following measure:

Measure =
CALCULATE (
    SUM ( Events[Duration] ),
    NATURALINNERJOIN ( 'Events', 'CustomerEvents' )
)

 

Community Support Team _ Eads
If this post helps, then please consider Accept it as the solution to help the other members find it.

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.