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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
aman720
Regular Visitor

How to remove GUID from rows in a column when it is combined with other text?

So I have a query that imports rows such as 

\\Server\Database\Unit01\Reactor?2f2eb94f-adb5-11eb-bacf-f0d5bf3c2f98|TEMP?b67078ec-0420-569f-204e-f6c9c28a9896

 

Where that string of characters is the GUID of the asset. Is there a way to dynamically remove the GUID from the row so it will look like 

 

\\Server\Database\Unit01\Reactor|TEMP

 

but also be applicable to other GUIDs?

1 ACCEPTED SOLUTION

@aman720 Try this:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("dc1BDoIwEEDRu7B2TFuhtCs2kLjQaLQkJgyLmTKTuNEEiSsOrx7Af4D3h6HAb1eZ3zIjtrQQ00sQ+8d9MRbxIpSX59w4dcKxVKCJK7BWGJiygpqpYt1lpzGsqTueG/a1qYNkMKUzUPmo4EwpoD7H7ALFEH0xbv6N97f11KdDl7Y/rRjHDw==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Column1 = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Column1", type text}}),
    #"Added Custom2" = Table.AddColumn(#"Changed Type", "Custom2", each Text.BeforeDelimiter([Column1], "?", {0, RelativePosition.FromEnd})),
    #"Added Custom3" = Table.AddColumn(#"Added Custom2", "Custom3", each if Text.Length([Custom2]) = 0 then [Column1] else [Custom2]),
    #"Removed Columns1" = Table.RemoveColumns(#"Added Custom3",{"Column1", "Custom2"}),
    #"Renamed Columns1" = Table.RenameColumns(#"Removed Columns1",{{"Custom3", "Column1"}}),
    #"Added Custom" = Table.AddColumn(#"Renamed Columns1", "Custom", each "?" & Text.BetweenDelimiters([Column1], "?", "|", {0, RelativePosition.FromEnd}, 0)),
    #"Added Custom1" = Table.AddColumn(#"Added Custom", "Custom.1", each Replacer.ReplaceText([Column1],[Custom],"")),
    #"Removed Columns" = Table.RemoveColumns(#"Added Custom1",{"Column1", "Custom"}),
    #"Renamed Columns" = Table.RenameColumns(#"Removed Columns",{{"Custom.1", "Column1"}})
in
    #"Renamed Columns"

@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
The Definitive Guide to Power Query (M)

DAX is easy, CALCULATE makes DAX hard...

View solution in original post

7 REPLIES 7
Greg_Deckler
Super User
Super User

@aman720 Try this:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("DcE7DsIwDADQu3S35JgkTaYuMCIhPlPdwU5tiaVIJWLi8PDePA/8d7P9YzvzUbqovI35sT07BuarSeuvfSIn0xodZNUEIZiCSnNwXJP6oZHX8r2fzpdJ84hjsQYYCSHl6kAYDTy32qhILTUPy/ID", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Column1 = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Column1", type text}}),
    #"Extracted Text Before Delimiter" = Table.TransformColumns(#"Changed Type", {{"Column1", each Text.BeforeDelimiter(_, "?", {0, RelativePosition.FromEnd}), type text}}),
    #"Added Custom" = Table.AddColumn(#"Extracted Text Before Delimiter", "Custom", each "?" & Text.BetweenDelimiters([Column1], "?", "|", {0, RelativePosition.FromEnd}, 0)),
    #"Added Custom1" = Table.AddColumn(#"Added Custom", "Custom.1", each Replacer.ReplaceText([Column1],[Custom],"")),
    #"Removed Columns" = Table.RemoveColumns(#"Added Custom1",{"Column1", "Custom"}),
    #"Renamed Columns" = Table.RenameColumns(#"Removed Columns",{{"Custom.1", "Column1"}})
in
    #"Renamed Columns"

@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
The Definitive Guide to Power Query (M)

DAX is easy, CALCULATE makes DAX hard...

@Greg_Deckler I apologize I am still quite new to Power BI. I have the data pulled in from SQL. I will call the column Column1 to fit your syntax. How does that fit into the overall steps? For example, do I drop that in after Source in the Applied Steps. Thanks!

 

Edit: Actually I got it to work with your code. So thanks for that! In doing so, I found not all the rows have that GUID in them and what you wrote puts in a blank row if there is no GUID (my bad). I am trying to find a way to skip these rows if they don't have the GUID now.

@aman720 Can you provide an example of one without GUIDs?


@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
The Definitive Guide to Power Query (M)

DAX is easy, CALCULATE makes DAX hard...

@Greg_Deckler

 

\\Server\Database\HX|OUTLET.TEMP    

 

The ones without the GUIDs have the same form of the target rows your code fixed. 

@aman720 Try this:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("dc1BDoIwEEDRu7B2TFuhtCs2kLjQaLQkJgyLmTKTuNEEiSsOrx7Af4D3h6HAb1eZ3zIjtrQQ00sQ+8d9MRbxIpSX59w4dcKxVKCJK7BWGJiygpqpYt1lpzGsqTueG/a1qYNkMKUzUPmo4EwpoD7H7ALFEH0xbv6N97f11KdDl7Y/rRjHDw==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Column1 = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Column1", type text}}),
    #"Added Custom2" = Table.AddColumn(#"Changed Type", "Custom2", each Text.BeforeDelimiter([Column1], "?", {0, RelativePosition.FromEnd})),
    #"Added Custom3" = Table.AddColumn(#"Added Custom2", "Custom3", each if Text.Length([Custom2]) = 0 then [Column1] else [Custom2]),
    #"Removed Columns1" = Table.RemoveColumns(#"Added Custom3",{"Column1", "Custom2"}),
    #"Renamed Columns1" = Table.RenameColumns(#"Removed Columns1",{{"Custom3", "Column1"}}),
    #"Added Custom" = Table.AddColumn(#"Renamed Columns1", "Custom", each "?" & Text.BetweenDelimiters([Column1], "?", "|", {0, RelativePosition.FromEnd}, 0)),
    #"Added Custom1" = Table.AddColumn(#"Added Custom", "Custom.1", each Replacer.ReplaceText([Column1],[Custom],"")),
    #"Removed Columns" = Table.RemoveColumns(#"Added Custom1",{"Column1", "Custom"}),
    #"Renamed Columns" = Table.RenameColumns(#"Removed Columns",{{"Custom.1", "Column1"}})
in
    #"Renamed Columns"

@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
The Definitive Guide to Power Query (M)

DAX is easy, CALCULATE makes DAX hard...

@Greg_Deckler Looks good now! Thank you!

@Greg_Deckler Looks good now! Thank you!

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

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

April Fabric Community Update

Fabric Community Update - April 2024

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

Top Solution Authors
Top Kudoed Authors