cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
MartijnNL Member
Member

Replace data with certain text

Hello,

 

I load data with in a column several text that can change over time. I need only the LE 01 until LE 18 from this:

 

 List versions.PNG

What I am doing now is replacing text per text with a new text:

 

 

replacevalues.PNG

 

Then I delimite this column to extract the number, e.g. 13, from this:

 versions2.PNG

 

  Since it is a lot of work to do this text per text and the text can change in the future, is there a better option? E.g. prevent loading this data? So only 'LE 01' until 'LE 18' is loaded in the first place? 

 

 

1 ACCEPTED SOLUTION

Accepted Solutions
Community Support Team
Community Support Team

Re: Replace data with certain text

Hi @MartijnNL,

 

I'd like to suggest you add a custom column with if statement to check if records which start with 'LE ', otherwise replace it as null.

 

Then you can use fill functions to 'fill up' text to replace null records.


Finally, you can add custom column with text.middle function to extract number from custom column 'replaced'.

10.PNG

 

 

Full query:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("ZY5Ba4QwEIX/yuC5hplotHjbjSPIWgNRS0EksLClh9KFvfXfd9Qtuu0pk/e9eW/GMaosgUbKwDpIMadoehqjU/Jfq+o3LuGVfVe7VoH7+vwGe+XYdwtu0ATZyTHDLFCqnw0uOsl31sP58n69XUJlw6GsV6Qwf2DWec+2l/x7ZP53NUW1XtMw4G6CGCVNq9muAMgUxnzc9hwwE8PMgXRBKMqRK+cZDrZ/MC4XDtxtqt4mBTr5LRIvGa0LxI1DXLaDgF725bGu7YYX9tA2sDOtzfviJJqmHw==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [Type = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Type", type text}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "Replaced", each if Text.Start([Type],3)="LE " then [Type] else null),
    #"Filled Up" = Table.FillUp(#"Added Custom",{"Replaced"}),
    #"Added Custom1" = Table.AddColumn(#"Filled Up", "Custom", each Text.Middle([Replaced],3,2))
in
    #"Added Custom1"

 

Regards,

Xiaoxin Sheng

Community Support Team _ Xiaoxin Sheng
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.



For learning resources/Release notes, please visit: | |

View solution in original post

3 REPLIES 3
Super User
Super User

Re: Replace data with certain text

@MartijnNL Could you please provide a sample data to replicate your issue, so that it will be helpful to provide an accurate solution.



Did I answer your question? Mark my post as a solution !

Proud to be a Datanaut !





Community Support Team
Community Support Team

Re: Replace data with certain text

Hi @MartijnNL,

 

I'd like to suggest you add a custom column with if statement to check if records which start with 'LE ', otherwise replace it as null.

 

Then you can use fill functions to 'fill up' text to replace null records.


Finally, you can add custom column with text.middle function to extract number from custom column 'replaced'.

10.PNG

 

 

Full query:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("ZY5Ba4QwEIX/yuC5hplotHjbjSPIWgNRS0EksLClh9KFvfXfd9Qtuu0pk/e9eW/GMaosgUbKwDpIMadoehqjU/Jfq+o3LuGVfVe7VoH7+vwGe+XYdwtu0ATZyTHDLFCqnw0uOsl31sP58n69XUJlw6GsV6Qwf2DWec+2l/x7ZP53NUW1XtMw4G6CGCVNq9muAMgUxnzc9hwwE8PMgXRBKMqRK+cZDrZ/MC4XDtxtqt4mBTr5LRIvGa0LxI1DXLaDgF725bGu7YYX9tA2sDOtzfviJJqmHw==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type text) meta [Serialized.Text = true]) in type table [Type = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Type", type text}}),
    #"Added Custom" = Table.AddColumn(#"Changed Type", "Replaced", each if Text.Start([Type],3)="LE " then [Type] else null),
    #"Filled Up" = Table.FillUp(#"Added Custom",{"Replaced"}),
    #"Added Custom1" = Table.AddColumn(#"Filled Up", "Custom", each Text.Middle([Replaced],3,2))
in
    #"Added Custom1"

 

Regards,

Xiaoxin Sheng

Community Support Team _ Xiaoxin Sheng
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.



For learning resources/Release notes, please visit: | |

View solution in original post

MartijnNL Member
Member

Re: Replace data with certain text

@v-shex-msft Thank you! This is indeed working for me.  Great pragmatic solution. thank you again. 

Helpful resources

Announcements
Can You Solve These Challenge

Challenge: Can You Solve These?

Find out how to participate in the first Power BI 'Can You Solve These?' challenge.

Community News & Announcements

Community News & Announcements

Get your latest community news and announcements.

Virtual Launch Event

Microsoft Business Applications October Virtual Launch Event

Join us for an in-depth look at the new innovations across Dynamics 365 and the Microsoft Power Platform.

Community Kudopalooza

Win Power BI Swag with Community Kudopalooza!

Each week, complete activities and be qualified in the drawing for cool Power BI Swag.

Users Online
Currently online: 34 members 930 guests
Please welcome our newest community members: