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

Grow your Fabric skills and prepare for the DP-600 certification exam by completing the latest Microsoft Fabric challenge.

Reply
Damian89
New Member

Replace numeric values with NULL in power query

Hi all,

 

I'd like to ged rid of all numbers from cells in the table1 as shown below.

Damian89_1-1612873307910.png

For now i have something like this, but i think there is better way to do it 😁

 

 

    #"Replaced Value" = Table.ReplaceValue(#"Filtered Rows1","1","",Replacer.ReplaceText,{"table1"}), 

    #"Replaced Value2" = Table.ReplaceValue(#"Replaced Value","2","",Replacer.ReplaceText,{"table1"}), 

    #"Replaced Value3" = Table.ReplaceValue(#"Replaced Value2","3","",Replacer.ReplaceText,{"table1"}), 

    #"Replaced Value4" = Table.ReplaceValue(#"Replaced Value3","4","",Replacer.ReplaceText,{"table1"}), 

    #"Replaced Value5" = Table.ReplaceValue(#"Replaced Value4","5","",Replacer.ReplaceText,{"table1"}), 

    #"Replaced Value6" = Table.ReplaceValue(#"Replaced Value5","6","",Replacer.ReplaceText,{"table1"}), 

    #"Replaced Value7" = Table.ReplaceValue(#"Replaced Value6","7","",Replacer.ReplaceText,{"table1"}), 

    #"Replaced Value8" = Table.ReplaceValue(#"Replaced Value7","8","",Replacer.ReplaceText,{"table1"}), 

    #"Replaced Value9" = Table.ReplaceValue(#"Replaced Value8","9","",Replacer.ReplaceText,{"table1"}), 

    #"Replaced Value0" = Table.ReplaceValue(#"Replaced Value9","0","",Replacer.ReplaceText,{"table1"}) 

in 

    #"Replaced Value0" 

 

 

Any suggestions? 

1 ACCEPTED SOLUTION
Jimmy801
Community Champion
Community Champion

Hello @Damian89 

 

the simplest way to remove numbers is to use Text.Remove and indicating 0 - 9 in the second parameter

Text.Remove(text,{"0".."9"})

Here a complete example where I included this function into a Table.TranformColumns. You can also create a new column.

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("Pcy7CQAhEATQVpaNjY792IsYCLqBXiZcaTZgY6cGZjOPYULAOXrLVh2knm2OxkKQNr5LiTC6gMIkJPDsSU+WD+7ivedbipUPllxQPVFVmfn8Y4w/", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Table1 = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Table1", type text}}),
    GetRidOfNumber = Table.TransformColumns
    (
        #"Changed Type",
        {
            {
                "Table1",
                (text)=> Text.Remove(text,{"0".."9"})
            }
        }
    )
in
    GetRidOfNumber

Jimmy801_0-1612878439029.png

Jimmy801_1-1612878447848.png

 

Copy paste this code to the advanced editor in a new blank query to see how the solution works.

If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too

Have fun

Jimmy

View solution in original post

5 REPLIES 5
Jimmy801
Community Champion
Community Champion

Hello @Damian89 

 

the simplest way to remove numbers is to use Text.Remove and indicating 0 - 9 in the second parameter

Text.Remove(text,{"0".."9"})

Here a complete example where I included this function into a Table.TranformColumns. You can also create a new column.

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("Pcy7CQAhEATQVpaNjY792IsYCLqBXiZcaTZgY6cGZjOPYULAOXrLVh2knm2OxkKQNr5LiTC6gMIkJPDsSU+WD+7ivedbipUPllxQPVFVmfn8Y4w/", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Table1 = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Table1", type text}}),
    GetRidOfNumber = Table.TransformColumns
    (
        #"Changed Type",
        {
            {
                "Table1",
                (text)=> Text.Remove(text,{"0".."9"})
            }
        }
    )
in
    GetRidOfNumber

Jimmy801_0-1612878439029.png

Jimmy801_1-1612878447848.png

 

Copy paste this code to the advanced editor in a new blank query to see how the solution works.

If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too

Have fun

Jimmy

It works perfectly 😃

JW_van_Holst
Resolver IV
Resolver IV

There is:

Table.AddColumn(#"Changed Type", "Custom", each Text.Combine( List.RemoveItems(Text.ToList([Column1]),{"1".."9"})))

Short sentence and works, but I needed to fix it to this version

 

= Table.AddColumn(#"Changed Type", "Column2", each if [Column] = null then [Column] else Text.Combine( List.RemoveItems(Text.ToList([Column]),{"0".."9"})), type text)

 

mahoneypat
Employee
Employee

You can use Text.Select to keep only the characters you want in a custom column in the query editor.

 

= Text.Select([TextColumn], {"A".."Z", "a..z", ",", "."})

 

Pat





Did I answer your question? Mark my post as a solution! Kudos are also appreciated!

To learn more about Power BI, follow me on Twitter or subscribe on YouTube.


@mahoneypa HoosierBI on YouTube


Helpful resources

Announcements
RTI Forums Carousel3

New forum boards available in Real-Time Intelligence.

Ask questions in Eventhouse and KQL, Eventstream, and Reflex.

MayPowerBICarousel

Power BI Monthly Update - May 2024

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

Top Solution Authors
Top Kudoed Authors