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, get a free DP-600 exam voucher to use by the end of 2024. Register now

Reply
dogburalHK82
Helper III
Helper III

replace values with If condition

Hi, 

 

I am trying to replace values based on its own condition. 

I want [Part number] column to be [common part]. 

 

If the part number starts with 999, then it becomes 9xxx

If the part number starts with AT99, then it AT.. and so on. 

 

How can you please advise how I can acheive it?

 

Part NumberCommon Part
999-1-009xxx
990-1-119xxx
666-1-116xxx
AT990-1-11AT
ICD-0000-0000ICD-0000-
ICD-1030-0000ICD-1030-

 

1 ACCEPTED SOLUTION
v-junyant-msft
Community Support
Community Support

Hi @dogburalHK82 ,

Here's the rule as I understand it: if the first "-" is preceded by numbers, return the first number as well as "xxx"; if the first "-" is preceded by both numbers and letters, return all of the letters; if the first "-" is preceded by all of the letters, return the entirety of what's preceded by the second "-".
You can put all of these M functions into the Advanced Editor:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WsrS01DXUNTBQitUBcQyAHENDMMfMzAzBcQxBkfN0dgHqMTAAE3ARQwNjmEgsAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Part Number" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Part Number", type text}}),
    AddedCustom = Table.AddColumn(#"Changed Type", "Custom", each 
        let 
            PartNumber = [Part Number],
            DashIndex = Text.PositionOf(PartNumber, "-"),
            BeforeDash = Text.Start(PartNumber, DashIndex),
            IsDigit = Text.Contains(Text.Select(BeforeDash, {"0".."9"}), "-") = false and Text.Length(Text.Select(BeforeDash, {"0".."9"})) = Text.Length(BeforeDash),
            IsLetter = Text.Contains(Text.Select(BeforeDash, {"A".."Z","a".."z"}), "-") = false and Text.Length(Text.Select(BeforeDash, {"A".."Z","a".."z"})) = Text.Length(BeforeDash),
            FirstChar = Text.Start(BeforeDash, 1),
            FirstCharIsLetter = Text.Middle(BeforeDash, 0, 1) <> " " and List.Contains({"A".."Z","a".."z"}, FirstChar),
            Result = if IsDigit then Text.Start(BeforeDash, 1) & "xxx" else if not IsDigit and FirstCharIsLetter and not IsLetter then Text.Select(BeforeDash,{"a".."z","A".."Z"})
            else if IsLetter then let SecondDashIndex = Text.PositionOf(Text.Middle(PartNumber, DashIndex + 1), "-") in Text.Start(PartNumber, DashIndex + SecondDashIndex +1) & "-"
            else null
        in Result
    )
in
    AddedCustom

The final output is as below:

vjunyantmsft_0-1708916071526.png


Best Regards,
Dino Tao
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

3 REPLIES 3
v-junyant-msft
Community Support
Community Support

Hi @dogburalHK82 ,

Here's the rule as I understand it: if the first "-" is preceded by numbers, return the first number as well as "xxx"; if the first "-" is preceded by both numbers and letters, return all of the letters; if the first "-" is preceded by all of the letters, return the entirety of what's preceded by the second "-".
You can put all of these M functions into the Advanced Editor:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WsrS01DXUNTBQitUBcQyAHENDMMfMzAzBcQxBkfN0dgHqMTAAE3ARQwNjmEgsAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Part Number" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Part Number", type text}}),
    AddedCustom = Table.AddColumn(#"Changed Type", "Custom", each 
        let 
            PartNumber = [Part Number],
            DashIndex = Text.PositionOf(PartNumber, "-"),
            BeforeDash = Text.Start(PartNumber, DashIndex),
            IsDigit = Text.Contains(Text.Select(BeforeDash, {"0".."9"}), "-") = false and Text.Length(Text.Select(BeforeDash, {"0".."9"})) = Text.Length(BeforeDash),
            IsLetter = Text.Contains(Text.Select(BeforeDash, {"A".."Z","a".."z"}), "-") = false and Text.Length(Text.Select(BeforeDash, {"A".."Z","a".."z"})) = Text.Length(BeforeDash),
            FirstChar = Text.Start(BeforeDash, 1),
            FirstCharIsLetter = Text.Middle(BeforeDash, 0, 1) <> " " and List.Contains({"A".."Z","a".."z"}, FirstChar),
            Result = if IsDigit then Text.Start(BeforeDash, 1) & "xxx" else if not IsDigit and FirstCharIsLetter and not IsLetter then Text.Select(BeforeDash,{"a".."z","A".."Z"})
            else if IsLetter then let SecondDashIndex = Text.PositionOf(Text.Middle(PartNumber, DashIndex + 1), "-") in Text.Start(PartNumber, DashIndex + SecondDashIndex +1) & "-"
            else null
        in Result
    )
in
    AddedCustom

The final output is as below:

vjunyantmsft_0-1708916071526.png


Best Regards,
Dino Tao
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Chakravarthy
Resolver II
Resolver II

Hi @dogburalHK82 , Please try to use Text.StartWith function in power query. Below is the Snip of code

Chakravarthy_0-1708877131198.png

 

lbendlin
Super User
Super User

where is your rules table? How do we know to group 999 after the first digit but AT990 after the second?

Helpful resources

Announcements
November Carousel

Fabric Community Update - November 2024

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

Live Sessions with Fabric DB

Be one of the first to start using Fabric Databases

Starting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.

Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.

Nov PBI Update Carousel

Power BI Monthly Update - November 2024

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