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
dmartiprev
Frequent Visitor

Sum data from another table with different aggregation of time

I have two tables: DailyData and MonthlyData. 

 

In the DailyData table, I have columns: "Date", "YrMo" which is shows the year and month that the Date resides in, and I have a third column of data called "Sales".  

 

In the MonthlyData table I only have one column "YrMo".  I would like to sum all the Sales data from the DailyData table into the MonthlyData table by matching the YrMo column. 

 

I have tried to make this both as a column and as a measure and neither seems to work: 

MonthlySalesTotal = CALCULATE(SUM(DailyData[Sales]),DailyData[YrMo]=MonthlyData[YrMo]).
 
Power BI doesn't seem to recognize the MonthlyData[YrMo].  I am getting a message that says "This expression contains columns from multiple tables, but only columns from a single table can be used in a True/False expression that is used as a table filter expression"  there is only be one table called DailyData with a column called "YrMo" and only one table called MonthlyData with a column called "YrMo".  Although, it is true that within the DailyData table there are multiple rows with the same YrMo since all dates that are within one month of time will have the same YrMo by design.  I thought this is how i could use the calculation function to aggregate to monthly table but maybe this is the cause for the error?
1 ACCEPTED SOLUTION
v-jianboli-msft
Community Support
Community Support

Hi @dmartiprev ,

 

Based on your description, I have creeated a simple sample:

vjianbolimsft_4-1678240480712.png

vjianbolimsft_3-1678240376416.png

If you need a measure:

Measure = CALCULATE(SUM(DailyData[Sales]),FILTER(ALL(DailyData),[YrMo]=MAX('MonthlyData'[YrMo])))

Output:

vjianbolimsft_5-1678240513889.png

If you need a column:

Column = SUMX(FILTER('DailyData',[YrMo]=EARLIER(MonthlyData[YrMo])),[Sales])

Output:

vjianbolimsft_6-1678240580794.png

Best Regards,

Jianbo Li

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

2 REPLIES 2
dmartiprev
Frequent Visitor

Thank you, this worked!

v-jianboli-msft
Community Support
Community Support

Hi @dmartiprev ,

 

Based on your description, I have creeated a simple sample:

vjianbolimsft_4-1678240480712.png

vjianbolimsft_3-1678240376416.png

If you need a measure:

Measure = CALCULATE(SUM(DailyData[Sales]),FILTER(ALL(DailyData),[YrMo]=MAX('MonthlyData'[YrMo])))

Output:

vjianbolimsft_5-1678240513889.png

If you need a column:

Column = SUMX(FILTER('DailyData',[YrMo]=EARLIER(MonthlyData[YrMo])),[Sales])

Output:

vjianbolimsft_6-1678240580794.png

Best Regards,

Jianbo Li

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

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.