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

Get certified in Microsoft Fabric—for free! For a limited time, the Microsoft Fabric Community team will be offering free DP-600 exam vouchers. Prepare now

Reply
leungi
New Member

Convert text to number across multiple columns where each column is a mix of text and numbers

Scenario

Source table has multiple columns, where columns are a mix of Text and Number data.

 

Upon data import, Power Query automatically assigns column to Text data type for conformity.

 

Goal

For each column, convert Number data to Number type and keep Text data as-is.

 

Currently, custom columns are added with the below expression. It is manual and unnecessarily double the column count.

 

Ideally, expression is applied to and replace existing columns in data source.

 

Expression

try Number.FromText([1]) otherwise [1])

 

1 ACCEPTED SOLUTION
ronrsnfld
Super User
Super User

try this:

  • Set the data type for all the columns to "any"
  • For each column, do a Table.Transform which changes values that can converted to numbers as such, otherwise leave them as is.

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WSkxKVtJRMlSK1YlWSklNA7KNwGxDIMsYzDICskCqQGxjIBukKjYWAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Column1 = _t, Column2 = _t]),
    
//set data type to any
    #"Changed Type" = Table.TransformColumnTypes(Source,
        List.Transform(Table.ColumnNames(Source), each {_, type any})),

//If they can transformed to a number, do it, otherwise leave it as is
    #"Text Numbers to Numbers" = Table.TransformColumns(#"Changed Type",
        List.Transform(Table.ColumnNames(#"Changed Type"), (cn)=> {cn, each try Number.From(_) otherwise _}))
in
    #"Text Numbers to Numbers"

Before

ronrsnfld_0-1665191841096.png

After

ronrsnfld_1-1665191874813.png

 

 

 

 

View solution in original post

2 REPLIES 2
leungi
New Member

Thanks for the prompt solution @ronrsnfld...a Solution Sage indeed 🙂

ronrsnfld
Super User
Super User

try this:

  • Set the data type for all the columns to "any"
  • For each column, do a Table.Transform which changes values that can converted to numbers as such, otherwise leave them as is.

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WSkxKVtJRMlSK1YlWSklNA7KNwGxDIMsYzDICskCqQGxjIBukKjYWAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Column1 = _t, Column2 = _t]),
    
//set data type to any
    #"Changed Type" = Table.TransformColumnTypes(Source,
        List.Transform(Table.ColumnNames(Source), each {_, type any})),

//If they can transformed to a number, do it, otherwise leave it as is
    #"Text Numbers to Numbers" = Table.TransformColumns(#"Changed Type",
        List.Transform(Table.ColumnNames(#"Changed Type"), (cn)=> {cn, each try Number.From(_) otherwise _}))
in
    #"Text Numbers to Numbers"

Before

ronrsnfld_0-1665191841096.png

After

ronrsnfld_1-1665191874813.png

 

 

 

 

Helpful resources

Announcements
OCT PBI Update Carousel

Power BI Monthly Update - October 2024

Check out the October 2024 Power BI update to learn about new features.

September Hackathon Carousel

Microsoft Fabric & AI Learning Hackathon

Learn from experts, get hands-on experience, and win awesome prizes.

October NL Carousel

Fabric Community Update - October 2024

Find out what's new and trending in the Fabric Community.

Top Solution Authors