Reply
gvg Member
Member
Posts: 168
Registered: ‎04-26-2017
Accepted Solution

Help with IF (The expression refers to multiple columns. )

Hi experts,

Can you help to figure out how would I check for the year in the following measure:

 

 

testSales = 
CALCULATE (
        SUM ( Sales[Amount] ),
	IF ( YEAR(Sales[Date]) < YEAR(TODAY()),
              ALL ( Sales ),
              ALL ( Sales[ProductId] )
        )
)

 

I get "The expression refers to multiple columns." error. Can't figure out, where are those "multiple columns".


Accepted Solutions
Highlighted
Established Member
Posts: 194
Registered: ‎04-13-2016

Re: Help with IF (The expression refers to multiple columns. )

Yes sorry, misread. The other problem comes from the fact that you cannot store somewhere the All(Sales) part because it returns more than one column. So you need to use your If statement earlier in the expression and recompute the calculate in each case.

 

[Measure]= IF(Year(max(Sales[Date]))< YEAR(TODAY()) , CALCULATE(SUM(Sales[Amount]),ALL(Sales)),CALCULATE(SUM(Sales[Amount]),ALL(Sales[ProductID])))

 

A bit clearer if you use variables, indentation and create first the separate measure [Total Amount] = Sum(Sales[Amount]).

 

[Measure] = VAR YearDate = Year(max(Sales[Date])) VAR CurrentYear = YEAR(TODAY()) RETURN
IF(YearDate< CurrentYear ,
CALCULATE([Total Amount],ALL(Sales));
CALCULATE([Total Amount],ALL(Sales[ProductID]))
)

View solution in original post


All Replies
Established Member
Posts: 194
Registered: ‎04-13-2016

Re: Help with IF (The expression refers to multiple columns. )

Hi,

 

Your problem lies in the Year(Sales[Date]) part.

Sales[Date] refers to the whole column since there is no row context in your expression. So you need to wrap it into an aggregator before computing the year.

 

Something like : Year ( Max(Sales[Date) ) or Year ( Min (Sales[Date) )

gvg Member
Member
Posts: 168
Registered: ‎04-26-2017

Re: Help with IF (The expression refers to multiple columns. )

Well, in this case I get A function 'MAX' has been used in a True/False expression that is used as a table filter expression.  Smiley Sad

Highlighted
Established Member
Posts: 194
Registered: ‎04-13-2016

Re: Help with IF (The expression refers to multiple columns. )

Yes sorry, misread. The other problem comes from the fact that you cannot store somewhere the All(Sales) part because it returns more than one column. So you need to use your If statement earlier in the expression and recompute the calculate in each case.

 

[Measure]= IF(Year(max(Sales[Date]))< YEAR(TODAY()) , CALCULATE(SUM(Sales[Amount]),ALL(Sales)),CALCULATE(SUM(Sales[Amount]),ALL(Sales[ProductID])))

 

A bit clearer if you use variables, indentation and create first the separate measure [Total Amount] = Sum(Sales[Amount]).

 

[Measure] = VAR YearDate = Year(max(Sales[Date])) VAR CurrentYear = YEAR(TODAY()) RETURN
IF(YearDate< CurrentYear ,
CALCULATE([Total Amount],ALL(Sales));
CALCULATE([Total Amount],ALL(Sales[ProductID]))
)