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

Earn a 50% discount on the DP-600 certification exam by completing the Fabric 30 Days to Learn It challenge.

Reply
aqeel_shaikh
Helper I
Helper I

How to Remove special character from Alphanumeric character

In the case study, i want to remove special character which is "-" hyphen if it is coming between Alphanumeric character.
if it is between numeric should not be removed. 

can you please help me with the query

Sample:

1) XYZ-1-ACD - expectation is XYZ1ACD
2) 123-456-XYZ - expectation is 123-456XYZ.

2 ACCEPTED SOLUTIONS
dufoq3
Super User
Super User

Hi @aqeel_shaikh, check this.

 

Result

dufoq3_0-1714454886120.png

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WioiM0jXUdXR2UYrViVYyNDLWNTE10wWKKsXGAgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Column1 = _t]),
    Ad_Cleaned = Table.AddColumn(Source, "Cleaned", each 
        [ lst = {"0".."9"},
          a1 = Splitter.SplitTextByCharacterTransition(each true, (x)=> not List.Contains(lst, x))([Column1]),
          a2 = Text.Combine(List.RemoveItems(a1, {"-"})),
          b1 = Splitter.SplitTextByCharacterTransition((x)=> not List.Contains(lst, x), each true)(a2),
          b2 = Text.Combine(List.RemoveItems(b1, {"-"}))
        ][b2], type text)
in
    Ad_Cleaned

 


Note: Check this link to learn how to use my query.
Check this link if you don't know how to provide sample data.

View solution in original post

Try this:

let
    Source = Excel.Workbook(File.Contents("C:\Users\s441801\OneDrive - Emirates Group\General - AQEEL\Power query\POWER Q TEST SAMPLE.xlsx"), null, true),
    Sheet1_Sheet = Source{[Item="Sheet1",Kind="Sheet"]}[Data],
    Ad_Cleaned = Table.AddColumn(Sheet1_Sheet, "Cleaned", each 
        [ lst = {"0".."9"},
          a1 = Splitter.SplitTextByCharacterTransition(each true, (x)=> not List.Contains(lst, x))([Column1]),
          a2 = Text.Combine(List.RemoveItems(a1, {"-"})),
          b1 = Splitter.SplitTextByCharacterTransition((x)=> not List.Contains(lst, x), each true)(a2),
          b2 = Text.Combine(List.RemoveItems(b1, {"-"}))
        ][b2], type text)
in
    Ad_Cleaned

Note: Check this link to learn how to use my query.
Check this link if you don't know how to provide sample data.

View solution in original post

13 REPLIES 13
dufoq3
Super User
Super User

Hi @aqeel_shaikh, check this.

 

Result

dufoq3_0-1714454886120.png

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WioiM0jXUdXR2UYrViVYyNDLWNTE10wWKKsXGAgA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Column1 = _t]),
    Ad_Cleaned = Table.AddColumn(Source, "Cleaned", each 
        [ lst = {"0".."9"},
          a1 = Splitter.SplitTextByCharacterTransition(each true, (x)=> not List.Contains(lst, x))([Column1]),
          a2 = Text.Combine(List.RemoveItems(a1, {"-"})),
          b1 = Splitter.SplitTextByCharacterTransition((x)=> not List.Contains(lst, x), each true)(a2),
          b2 = Text.Combine(List.RemoveItems(b1, {"-"}))
        ][b2], type text)
in
    Ad_Cleaned

 


Note: Check this link to learn how to use my query.
Check this link if you don't know how to provide sample data.

getting below error

aqeel_shaikh_0-1714459235263.png

 




let
Source = Excel.Workbook(File.Contents("C:\Users\s441801\OneDrive - Emirates Group\General - AQEEL\Power query\POWER Q TEST SAMPLE.xlsx"), null, true),
Sheet1_Sheet = Source{[Item="Sheet1",Kind="Sheet"]}[Data],
#"Changed Type" = Table.TransformColumnTypes(Sheet1_Sheet,{{"Column1", type text}}),
Ad_Cleaned = Table.AddColumn(Source, "Cleaned", each
[ lst = {"0".."9"},
a1 = Splitter.SplitTextByCharacterTransition(each true, (x)=> not List.Contains(lst, x))([Column1]),
a2 = Text.Combine(List.RemoveItems(a1, {"-"})),
b1 = Splitter.SplitTextByCharacterTransition((x)=> not List.Contains(lst, x), each true)(a2),
b2 = Text.Combine(List.RemoveItems(b1, {"-"}))
][b2], type text
in
#"Changed Type"

Try this:

let
    Source = Excel.Workbook(File.Contents("C:\Users\s441801\OneDrive - Emirates Group\General - AQEEL\Power query\POWER Q TEST SAMPLE.xlsx"), null, true),
    Sheet1_Sheet = Source{[Item="Sheet1",Kind="Sheet"]}[Data],
    Ad_Cleaned = Table.AddColumn(Sheet1_Sheet, "Cleaned", each 
        [ lst = {"0".."9"},
          a1 = Splitter.SplitTextByCharacterTransition(each true, (x)=> not List.Contains(lst, x))([Column1]),
          a2 = Text.Combine(List.RemoveItems(a1, {"-"})),
          b1 = Splitter.SplitTextByCharacterTransition((x)=> not List.Contains(lst, x), each true)(a2),
          b2 = Text.Combine(List.RemoveItems(b1, {"-"}))
        ][b2], type text)
in
    Ad_Cleaned

Note: Check this link to learn how to use my query.
Check this link if you don't know how to provide sample data.

@dufoq3  Thanks for the solution. Much appreciated😊

You're welcome 😉


Note: Check this link to learn how to use my query.
Check this link if you don't know how to provide sample data.

@dufoq3 

If i want to add one more query,

e.g: between numeric there is a special character but to be replaced with "-" hypen.

how can i add that to the same above query?

Do you want to replace that special character only if it is between numbers?


Note: Check this link to learn how to use my query.
Check this link if you don't know how to provide sample data.

Only between numeric replace Special character but with "-" hypen.
also remove special character between Alhpabets.

can this be combined with the query provided above

https://community.fabric.microsoft.com/t5/Power-Query/Between-two-numeric-there-is-a-special-charact...


Note: Check this link to learn how to use my query.
Check this link if you don't know how to provide sample data.

will this help me to remove special character between Alhpabets. if there is a different query can you please share?

You should provide new sample data with expected result because there can be many variants.


Note: Check this link to learn how to use my query.
Check this link if you don't know how to provide sample data.

@dufoq3 ,

 

My sample data is 

1234-567-AB$C#DEF-123

expectation is to remove bold special character in RED and provide this result "1234-567-ABCDEF123"

AnalyticPulse
Skilled Sharer
Skilled Sharer

RemoveHyphens =
try this and let me know if this works:
VAR inputText = [YourColumn]
VAR length = LEN(inputText)

VAR result =
GENERATESERIES(1, length, 1)
RETURN
VAR currentIndex = VALUE([Value])
VAR currentChar = MID(inputText, currentIndex, 1)
VAR prevChar = MID(inputText, currentIndex - 1, 1)
VAR nextChar = MID(inputText, currentIndex + 1, 1)
RETURN
IF(
currentChar = "-" &&
(ISALPHA(prevChar) && ISALPHA(nextChar) || ISALPHA(prevChar) && ISNUMERIC(nextChar) || ISNUMERIC(prevChar) && ISALPHA(nextChar)),
"",
currentChar
)
)
VAR modifiedText = CONCATENATEX(result, result, "")
RETURN modifiedText

 

My blog:
https://analyticpulse.blogspot.com/2024/03/superstore-sales-2022-vs-2023-year-on.html
https://analyticpulse.blogspot.com/
https://analyticpulse.blogspot.com/2024/04/case-study-powerbi-dashboard-developer.html

See my Pins :
https://pin.it/5aoqgZUft
https://in.pinterest.com/AnalyticPulse/

 

Helpful resources

Announcements
LearnSurvey

Fabric certifications survey

Certification feedback opportunity for the community.

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