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
gvg
Post Prodigy
Post Prodigy

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".

1 ACCEPTED SOLUTION

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

3 REPLIES 3

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) )

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.  😞

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]))
)

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.