cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Tad17 Frequent Visitor
Frequent Visitor

Expressions that yield variant data-type cannot be used to define calculated columns.

Hey Guys
 
BIZ DATE = if(and(Format([ATD],"")=blank(),format([BIZ DAYS],"")=blank()),"",
var dateidx = calculate( max('Calendar'[WorkingDayIndex] ) , 'P FILES'[ATD] = RELATED('Calendar'[Date] ) )
var newdateidx = dateidx + 'P FILES'[BIZ DAYS]

return
calculate(
max('Calendar'[Date]),
filter(
ALL('Calendar'),
'Calendar'[WorkingDayIndex] = newdateidx
&& 'Calendar'[IsWorkDay] = 1
)
)
)
 
Data is company sensetive.
 
I found a forum that suggested creating a calendar table to add days to a date and that seems to work (everything after the first line). However, the if statement will not seem to work. I understand that I am looking at two columns with different formatting (one is date and the other is text) I have tried using several combinations of value and format functions to no avail. I cannot change the formatting of these columns as their formatting is necessary for other calculated columns. I have tried making helper columns a little, but haven't had much luck.
 
Also, the ATD column, which is date format, has blanks (null) in it.
 
Any suggestions are appreciated.
 
-Tad
1 ACCEPTED SOLUTION

Accepted Solutions
Community Support Team
Community Support Team

Re: Expressions that yield variant data-type cannot be used to define calculated columns.

Hi @Tad17 

This error indicates you try to use both date and text format values in one calculated column, so Power BI can't analyze the data type for this calcualted column.

eg. Column=IF([CL1]=1,DATE(2009,1,1)," ")

 

I can reproduce your problem, then i split two formula in two column

Capture1.JPG

Finally, you can modify the column as below to make it work

BIZ DATE modify = 
var dateidx = calculate( max('Calendar'[WorkingDayIndex] ) , Sheet1[ATD] = RELATED('Calendar'[Date] ) )
var newdateidx = dateidx + Sheet1[BIZ DAYS]

var datevalue=
calculate(
max('Calendar'[Date]),
filter(
ALL('Calendar'),
'Calendar'[WorkingDayIndex] = newdateidx
&& 'Calendar'[IsWorkDay] = 1
)
)
return if(NOT(and(Format([ATD],"")=blank(),format([BIZ DAYS],"")=blank())),datevalue)

Capture2.JPG

 

Best Regards
Maggie
Community Support Team _ Maggie Li
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

 

 

View solution in original post

1 REPLY 1
Community Support Team
Community Support Team

Re: Expressions that yield variant data-type cannot be used to define calculated columns.

Hi @Tad17 

This error indicates you try to use both date and text format values in one calculated column, so Power BI can't analyze the data type for this calcualted column.

eg. Column=IF([CL1]=1,DATE(2009,1,1)," ")

 

I can reproduce your problem, then i split two formula in two column

Capture1.JPG

Finally, you can modify the column as below to make it work

BIZ DATE modify = 
var dateidx = calculate( max('Calendar'[WorkingDayIndex] ) , Sheet1[ATD] = RELATED('Calendar'[Date] ) )
var newdateidx = dateidx + Sheet1[BIZ DAYS]

var datevalue=
calculate(
max('Calendar'[Date]),
filter(
ALL('Calendar'),
'Calendar'[WorkingDayIndex] = newdateidx
&& 'Calendar'[IsWorkDay] = 1
)
)
return if(NOT(and(Format([ATD],"")=blank(),format([BIZ DAYS],"")=blank())),datevalue)

Capture2.JPG

 

Best Regards
Maggie
Community Support Team _ Maggie Li
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

 

 

View solution in original post

Helpful resources

Announcements
October 2019 Community Highlights

October 2019 Community Highlights

October was a busy month in the community. Read the recap article to learn about some of the events and content.

New Solution Badges

New Solution Badges

Two waves of brand new solution badges are coming! Read the article for more information on our new community badges.

Ask Amir Anything

Exclusive LIVE Community Event No. 2 – Ask Amir Anything

Next in our Triple A series: Ask Amir Netz questions about the latest updates, features and future.

Analytics in Azure virtual event

Analytics in Azure virtual event

Experience a limitless analytics service built to ingest, prep, manage, and serve data for immediate use in Power BI.

Users Online
Currently online: 311 members 2,956 guests
Please welcome our newest community members: