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

Help on accumulation on all previous year and current year Month

Hello Team

 

Please help me on computation of matrix mentioned below in PowerBi desktop matrix.

I have data for every day as source for which I want to sum the data for month and year wise.

For current year it should be month wise accummulation however for previous year it should be year wise accumulation

 

Input Data:

DateAmountName
1-Jan-2020500Rony
4-Jan-2020500Avik
1-Jan-20211000Ronak
5-Mar-20211500caty
02-Feb-2022800caty
05-Mar-2022500Ronak

 

Output Matrix:

Total20201000
Total20212500
Feb-2022800
Mar-2022500

 

2 ACCEPTED SOLUTIONS
v-jingzhang
Community Support
Community Support

Hi @Anonymous 

 

First you need to add a Date table in the model. You can add it with DAX simply. 

Date = ADDCOLUMNS(CALENDAR(DATE(2020,1,1),DATE(2022,12,31)),"Year",YEAR([Date]),"Month",MONTH([Date]),"Month-Year",FORMAT([Date],"mmm-yyyy"))

 

And create a relationship on Date columns: Single direction, one-to-many. Date table is on the one side. 

vjingzhang_1-1653372611827.png

 

Then you can create a new table to summarize amount values. 

New Table = 
var current_year = YEAR(TODAY())
var year_total_table = SUMMARIZE(FILTER('Date','Date'[Year]<current_year),'Date'[Year],"Total Amount",SUM('Table'[Amount]))
var month_total_table = SUMMARIZE(FILTER('Date','Date'[Year]=current_year),'Date'[Month-Year],"Total Amount",SUM('Table'[Amount]))
return
UNION(year_total_table,month_total_table)

vjingzhang_0-1653372446838.png

 

Use data from this new table into a table visual. If you want to change the field name displayed in the table visual, you can right click on a field in Columns well and select Rename for this visual. Or you can also change the column names in above DAX code directly. 

vjingzhang_2-1653373024281.png

 

The sample file has been attached. 

 

Best Regards,
Community Support Team _ Jing
If this post helps, please Accept it as Solution to help other members find it.

View solution in original post

Hi @Anonymous 

 

You can create multiple aggregation columns within SUMMARIZE function for the variable tables before unioning. For example, 

var year_total_table = SUMMARIZE(FILTER('Date','Date'[Year]<current_year),'Date'[Year],"Total Amount",SUM('Table'[Amount]),"Total Count",COUNTROWS('Table'))

var month_total_table = SUMMARIZE(FILTER('Date','Date'[Year]=current_year),'Date'[Month-Year],"Total Amount",SUM('Table'[Amount]),"Total Count",COUNTROWS('Table'))

 

The syntax for SUMMARIZE is 

SUMMARIZE (<table>, <groupBy_columnName>[, <groupBy_columnName>]…[, <name>, <expression>]…)

 

Jing

View solution in original post

5 REPLIES 5
v-jingzhang
Community Support
Community Support

Hi @Anonymous 

 

First you need to add a Date table in the model. You can add it with DAX simply. 

Date = ADDCOLUMNS(CALENDAR(DATE(2020,1,1),DATE(2022,12,31)),"Year",YEAR([Date]),"Month",MONTH([Date]),"Month-Year",FORMAT([Date],"mmm-yyyy"))

 

And create a relationship on Date columns: Single direction, one-to-many. Date table is on the one side. 

vjingzhang_1-1653372611827.png

 

Then you can create a new table to summarize amount values. 

New Table = 
var current_year = YEAR(TODAY())
var year_total_table = SUMMARIZE(FILTER('Date','Date'[Year]<current_year),'Date'[Year],"Total Amount",SUM('Table'[Amount]))
var month_total_table = SUMMARIZE(FILTER('Date','Date'[Year]=current_year),'Date'[Month-Year],"Total Amount",SUM('Table'[Amount]))
return
UNION(year_total_table,month_total_table)

vjingzhang_0-1653372446838.png

 

Use data from this new table into a table visual. If you want to change the field name displayed in the table visual, you can right click on a field in Columns well and select Rename for this visual. Or you can also change the column names in above DAX code directly. 

vjingzhang_2-1653373024281.png

 

The sample file has been attached. 

 

Best Regards,
Community Support Team _ Jing
If this post helps, please Accept it as Solution to help other members find it.

Anonymous
Not applicable

Thanks v_jingzhang

 

This solution seems to be working but I want to stuck on one issue where I want to return multiple columns. WIth this solution we can only get single column value having union but what if we want to have multiple values for example count of table as well with respect to Current Year's Month & Previous year then what can we do there?

Hi @Anonymous 

 

You can create multiple aggregation columns within SUMMARIZE function for the variable tables before unioning. For example, 

var year_total_table = SUMMARIZE(FILTER('Date','Date'[Year]<current_year),'Date'[Year],"Total Amount",SUM('Table'[Amount]),"Total Count",COUNTROWS('Table'))

var month_total_table = SUMMARIZE(FILTER('Date','Date'[Year]=current_year),'Date'[Month-Year],"Total Amount",SUM('Table'[Amount]),"Total Count",COUNTROWS('Table'))

 

The syntax for SUMMARIZE is 

SUMMARIZE (<table>, <groupBy_columnName>[, <groupBy_columnName>]…[, <name>, <expression>]…)

 

Jing

Anonymous
Not applicable

Hello Amit

 

Thanks for your reply!!

This means I would have to create measure for all previous year instead of dynamic measures/data (say for last 10 years) and for all months in current year?

and again I would have to create the same for all columns of matrix as we created for sales here in example?

 

amitchandak
Super User
Super User

@Anonymous , According to me create 4 measures This Year, Last year , This Month Last Month , Based on the selection.

 

Create a date table and have the year there

 

MTD Sales = CALCULATE(SUM(Sales[Sales Amount]),DATESMTD('Date'[Date]))
last MTD Sales = CALCULATE(SUM(Sales[Sales Amount]),DATESMTD(dateadd('Date'[Date],-1,MONTH)))

 

YTD Sales = CALCULATE(SUM(Sales[Sales Amount]),DATESYTD('Date'[Date],"12/31"))
Last YTD Sales = CALCULATE(SUM(Sales[Sales Amount]),DATESYTD(dateadd('Date'[Date],-1,Year),"12/31"))
This year Sales = CALCULATE(SUM(Sales[Sales Amount]),DATESYTD(ENDOFYEAR('Date'[Date]),"12/31"))
Last year Sales = CALCULATE(SUM(Sales[Sales Amount]),DATESYTD(ENDOFYEAR(dateadd('Date'[Date],-1,Year)),"12/31"))

 

 

//Only year vs Year, not a level below

This Year = CALCULATE(sum('Table'[Qty]),filter(ALL('Date'),'Date'[Year]=max('Date'[Year])))
Last Year = CALCULATE(sum('Table'[Qty]),filter(ALL('Date'),'Date'[Year]=max('Date'[Year])-1))

 

 

Not in a matrix you can use them on using -> Show value on Row /show on row

 

Or you can create calculation groups

 

Calculation Groups- Measure Slicer, Measure Header Grouping, Measure to dimension conversion. Complex Table display : https://youtu.be/qMNv67P8Go0

 

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.