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

How to Use Aggregate function In PowerBi

Dear All,

             We want to Use Aggregate function in Power Bi but we unable to use Aggregate Function. For Example We have Multiple Items Sale Available in Year 2017 and 2016. we want Current Year Item sum which Item already available in Year 2016. for Example.

 

Year ItemQty
2017Item110
2017Item28
2017Item39
2017Item47
2017Item512
2016Item111
2016Item26
2016Item55
2016Item68
2016Item79

 

Item 1 to 5 sale available in 2017 and Item1,Item2,Item5,Item6,Item7 sale in 2016,So Item1, Item2 Item5 available in Both Year so we Want Sum Item1,Item2&Item5 in 2017 is (30) how to achieve in Power BI Please suggest.

1 ACCEPTED SOLUTION
TomMartens
Super User
Super User

Hey,

 

this measure

 

Measure = 
var currentYear = MAXX(VALUES('Table1'[Year]),'Table1'[Year])
var itemsMaxYear =
	SELECTCOLUMNS( 
		FILTER(
			ALL('Table1')
			,'Table1'[Year] = currentYear
		)
		,"Item", 'Table1'[Item]
	)
var itemsPrevYear =
	SELECTCOLUMNS( 
		FILTER(
			ALL('Table1')
			,'Table1'[Year] = currentYear - 1
		)
		,"Item", 'Table1'[Item])
var itemsIntersect = 
	INTERSECT(itemsMaxYear, itemsPrevYear)
return
CALCULATE(
	SUM(Table1[Qty])
	,FILTER(
		ALL('Table1')
		,'Table1'[Year] = currentYear &&
		'Table1'[Item] in itemsIntersect
	)
)

creates this output

 

2017-09-20_8-47-51.png

 

First the "current" year is stored in a variable. Does the column Year not contribute to the Filter Context (the card visual, and the total row of the table visual, the DAX statement makes sure that the max value is stored to the variable.

 

This variable is used to create two table variables containing the items of the current year and the previous year (either from the row context or the latest year, using SELECTCOLUMNS(FILTER(...),...)

 

A 3rd table variable is calculated that finally contains the items present in both years

 

This 3rd table variable is finally used to filter down the table in combination with the variable currentYear.

 

Hope this helps

 

Regards

Tom



Did I answer your question? Mark my post as a solution, this will help others!

Proud to be a Super User!
I accept Kudos 😉
Hamburg, Germany

View solution in original post

1 REPLY 1
TomMartens
Super User
Super User

Hey,

 

this measure

 

Measure = 
var currentYear = MAXX(VALUES('Table1'[Year]),'Table1'[Year])
var itemsMaxYear =
	SELECTCOLUMNS( 
		FILTER(
			ALL('Table1')
			,'Table1'[Year] = currentYear
		)
		,"Item", 'Table1'[Item]
	)
var itemsPrevYear =
	SELECTCOLUMNS( 
		FILTER(
			ALL('Table1')
			,'Table1'[Year] = currentYear - 1
		)
		,"Item", 'Table1'[Item])
var itemsIntersect = 
	INTERSECT(itemsMaxYear, itemsPrevYear)
return
CALCULATE(
	SUM(Table1[Qty])
	,FILTER(
		ALL('Table1')
		,'Table1'[Year] = currentYear &&
		'Table1'[Item] in itemsIntersect
	)
)

creates this output

 

2017-09-20_8-47-51.png

 

First the "current" year is stored in a variable. Does the column Year not contribute to the Filter Context (the card visual, and the total row of the table visual, the DAX statement makes sure that the max value is stored to the variable.

 

This variable is used to create two table variables containing the items of the current year and the previous year (either from the row context or the latest year, using SELECTCOLUMNS(FILTER(...),...)

 

A 3rd table variable is calculated that finally contains the items present in both years

 

This 3rd table variable is finally used to filter down the table in combination with the variable currentYear.

 

Hope this helps

 

Regards

Tom



Did I answer your question? Mark my post as a solution, this will help others!

Proud to be a Super User!
I accept Kudos 😉
Hamburg, Germany

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.