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
parimal
New Member

Summarize values by category across 2 fact tables

I have two fact tables  -

Fact1 (CustomerID, ProductID, DateKey, Value1) , Fact2 (CustomerID, ProductID,DateKey,Value2)

 

I'm trying to get a summarized table that gives me 

Summary Table = CustomerID, ProductID, DateKey, Sum(Value1), Sum(Value2)

 

I tried using the Summarize function, but it doesn't work.

If I do SUMMARIZE on Fact1, I get the Sum(Value1)  but Sum(Value2) is blank. If I do SUMMARIZE on Fact2 , the Sum(Value1) is blank.

 

The two FACTS are both related to a Customer, Product & Date Dim table. But there's no direct relationship between them. 

I tried creating a KEY column in both FACT tables and do a USERELATIONSHIP, that didn't work either. 

Appreciate any guidance to resolve this .. 

 

 

1 ACCEPTED SOLUTION
az38
Community Champion
Community Champion

hi @parimal 

for example

 

Table = 
AddColumns(
SUMMARIZE(Fact1, Fact1[CustomerID], Fact1[ProductID], Fact1[DateKey], "Sum1", SUM(Fact1[Value1])),
"Sum2", CALCULATE(SUM(Fact2[Value2]), FILTER(ALL(Fact2), Fact2[CustomerID]=[CustomerID] && Fact2[ProductID]=[ProductID] && Fact2[DateKey]=[DateKey]))
)

 


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

View solution in original post

3 REPLIES 3
az38
Community Champion
Community Champion

hi @parimal 

for example

 

Table = 
AddColumns(
SUMMARIZE(Fact1, Fact1[CustomerID], Fact1[ProductID], Fact1[DateKey], "Sum1", SUM(Fact1[Value1])),
"Sum2", CALCULATE(SUM(Fact2[Value2]), FILTER(ALL(Fact2), Fact2[CustomerID]=[CustomerID] && Fact2[ProductID]=[ProductID] && Fact2[DateKey]=[DateKey]))
)

 


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

Superb.. Thanks a lot. This worked.. 

I was trying a similar statement for a long time, but I was doing FILTER(Fact2, .... ) , whereas you did a FILTER(ALL(FACT2)... )

putting the ALL made all the difference.. , any idea why it might not have been working without the ALL ??

az38
Community Champion
Community Champion

HI @parimal 

without ALL() the statement enables row context (filters depending on your data model). ALL() give a confidence that all table is being calculated


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

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.