Power BI is turning 10, and we’re marking the occasion with a special community challenge. Use your creativity to tell a story, uncover trends, or highlight something unexpected.
Get startedJoin us for an expert-led overview of the tools and concepts you'll need to become a Certified Power BI Data Analyst and pass exam PL-300. Register now.
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
This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.
Check out the June 2025 Power BI update to learn about new features.
User | Count |
---|---|
15 | |
12 | |
8 | |
8 | |
7 |
User | Count |
---|---|
15 | |
13 | |
9 | |
7 | |
6 |