The ultimate Fabric, Power BI, SQL, and AI community-led learning event. Save €200 with code FABCOMM.
Get registeredEnhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends September 15. Request your voucher.
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])
Solved! Go to Solution.
try this:
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
After
try this:
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
After