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

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

Hello,

 

I have tried to look in the community for the answer.  Few issues with the exact error can be found.  However, I cannot fix mine.  Appreciate that any one can look at my formula.

 

Positive Recovery = If (Category = "Income", - value, value)

 

The formula above is too convert the credit sign of income (in accounting) to positive while keeping the expenses side as (debit / positive).

 

It has been worked until I refresh the data.  It is wired.  Thanks!

1 ACCEPTED SOLUTION

Accepted Solutions
Highlighted
Community Support
Community Support

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

Hi @stella_moon ,

Based on the error message, it is caused by the different data types in column. I think you are trying to use both number value and text value (the value with sign) in one calculate column. So power bi can't auto analysis data type of it.

 

Maybe you could try like this:

 

Positive Recovery =
IF ( 'Table'[Category] = "Income", "-" & 'Table'[value], 'Table'[value] )

 

 1.PNG

 

Or you could try the function of FORMAT to convert values to text value.

FORMAT 

Pre-Defined Numeric Formats for the FORMAT function 

 

If you want to change all the values to number, you need to split the sign in Power Query firstly.

  • 2.PNG
  • And create a new column.

= Table.AddColumn(#"Changed Type1", "Custom", each if [value.1] = null then [value.2] else [value.1])

  • Then remove other columns.

3.PNG

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45W8sxLzs9NVdJRMjQwUIrViVZyBLK1DA1MwRwnkISRMZjtrADimAFVxQIA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [Category = _t, value = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Category", type text}, {"value", type text}}),
    #"Split Column by Delimiter" = Table.SplitColumn(#"Changed Type", "value", Splitter.SplitTextByDelimiter("*", QuoteStyle.Csv), {"value.1", "value.2"}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Split Column by Delimiter",{{"value.1", Int64.Type}, {"value.2", Int64.Type}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type1", "Custom", each if [value.1] = null then [value.2] else [value.1]),
    #"Removed Columns" = Table.RemoveColumns(#"Added Custom",{"value.1", "value.2"})
in
    #"Removed Columns"

 

 

For more details, please see the attachment.

 

 

Best Regards,
Xue Ding
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

2 REPLIES 2
Highlighted
Super User IV
Super User IV

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

@stella_moon Try like

Positive Recovery = If ([Category] = "Income", -1*[value],[value])



Did I answer your question? Mark my post as a solution! Appreciate your Kudos!!
My Recent Blog -Week is not so Weak Connect on Linkedin

Proud to be a Super User!

Highlighted
Community Support
Community Support

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

Hi @stella_moon ,

Based on the error message, it is caused by the different data types in column. I think you are trying to use both number value and text value (the value with sign) in one calculate column. So power bi can't auto analysis data type of it.

 

Maybe you could try like this:

 

Positive Recovery =
IF ( 'Table'[Category] = "Income", "-" & 'Table'[value], 'Table'[value] )

 

 1.PNG

 

Or you could try the function of FORMAT to convert values to text value.

FORMAT 

Pre-Defined Numeric Formats for the FORMAT function 

 

If you want to change all the values to number, you need to split the sign in Power Query firstly.

  • 2.PNG
  • And create a new column.

= Table.AddColumn(#"Changed Type1", "Custom", each if [value.1] = null then [value.2] else [value.1])

  • Then remove other columns.

3.PNG

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45W8sxLzs9NVdJRMjQwUIrViVZyBLK1DA1MwRwnkISRMZjtrADimAFVxQIA", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [Category = _t, value = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Category", type text}, {"value", type text}}),
    #"Split Column by Delimiter" = Table.SplitColumn(#"Changed Type", "value", Splitter.SplitTextByDelimiter("*", QuoteStyle.Csv), {"value.1", "value.2"}),
    #"Changed Type1" = Table.TransformColumnTypes(#"Split Column by Delimiter",{{"value.1", Int64.Type}, {"value.2", Int64.Type}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type1", "Custom", each if [value.1] = null then [value.2] else [value.1]),
    #"Removed Columns" = Table.RemoveColumns(#"Added Custom",{"value.1", "value.2"})
in
    #"Removed Columns"

 

 

For more details, please see the attachment.

 

 

Best Regards,
Xue Ding
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
Community Blog

Community Blog

Visit our Community Blog for articles, guides, and information created by fellow community members.

Using the Community

Using the Community

Need help with the Power BI Community? Our 'Using the Community' support articles are a great place to start.

Community Summit North America

Community Summit North America

Innovate, Collaborate, Grow. The top training and networking event across the globe for Microsoft Business Applications

Power Platform 2020 release wave 2 plan

Power Platform 2020 release wave 2 plan

Features releasing from October 2020 through March 2021

Top Solution Authors
Top Kudoed Authors