Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Earn a 50% discount on the DP-600 certification exam by completing the Fabric 30 Days to Learn It challenge.

Reply
cmncp
Helper III
Helper III

DAX Calculate the MAX of a SUM measure

I have an SSAS tabular model based on Inventory data.  The data contains not only the current (i.e. todays) On Hand values, but also 90 days worth of history.  Here is a very small sample of data:

 

2017-12-06_15-38-18.png

 

I need to create a DAX measure that will return that MAX Qty on Hand for each Material over the 90 days worth of history. In the sample above, the MAX would be 6, because on 2-Dec there was 3 in Loc A and 3 in Loc b.

 

I have tried the following DAX calculation:

 

CALCULATE (MAX(Inventory[SAP Qty On Hand]), ALL('Date'))

 

However, this is returning 3, rather than 6. It needs to aggregate by date before doing the MAX.

 

Any ideas?

1 ACCEPTED SOLUTION
DAX0110
Resolver V
Resolver V

Hi @cmncp, the following measure should do the job:

 

Max Daily Qty Over 90 Days :=
VAR currentDate = MAX( table[Dte] )
VAR beginDate = currentDate - 90
RETURN MAXX(
	CALCULATETABLE(
		VALUES(table[Date])
		, ALLEXCEPT( table[Material] ) 
		, table[Date] >= beginDate
		)
	, CALCULATE(
		SUM(table[Qty On Hand])
		)
	)
	

 

View solution in original post

2 REPLIES 2
DAX0110
Resolver V
Resolver V

Hi @cmncp, the following measure should do the job:

 

Max Daily Qty Over 90 Days :=
VAR currentDate = MAX( table[Dte] )
VAR beginDate = currentDate - 90
RETURN MAXX(
	CALCULATETABLE(
		VALUES(table[Date])
		, ALLEXCEPT( table[Material] ) 
		, table[Date] >= beginDate
		)
	, CALCULATE(
		SUM(table[Qty On Hand])
		)
	)
	

 

Thanks @DAX0110.  That worked well.

Helpful resources

Announcements
RTI Forums Carousel3

New forum boards available in Real-Time Intelligence.

Ask questions in Eventhouse and KQL, Eventstream, and Reflex.

LearnSurvey

Fabric certifications survey

Certification feedback opportunity for the community.