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
tuanminhtr
New Member

I need to extract text from an URL

Example:

I have an URL column with value as below 

https://testlink-1258139023.mycloud.com/text01.png

https://testlink-1258139023.mycloud.com/texting01.png

https://testlink-1258139023.mycloud.com/text0124.png

I need to create a new column that contains:

text01

texting01

text0124

 

Many thanks!

2 ACCEPTED SOLUTIONS
amustafa
Super User
Super User

Hi @tuanminhtr 

 

In DAX, here's how you can exract the text between last slash and before the .png.

Extracted Filename =
VAR FullURL = urltable[URL]
VAR URLLength = LEN(FullURL)
VAR LastSlashIndex =
    CALCULATE(
        MAXX(
            GENERATESERIES(1, URLLength, 1),
            IF(
                MID(FullURL, [Value], 1) = "/",
                [Value],
                BLANK()
            )
        )
    )
VAR FileNameWithExtension = IF(LastSlashIndex > 0, RIGHT(FullURL, URLLength - LastSlashIndex), BLANK())
VAR IsPng = RIGHT(FileNameWithExtension, 4) = ".png"
RETURN
IF(IsPng, LEFT(FileNameWithExtension, LEN(FileNameWithExtension) - 4), FileNameWithExtension)
 
Or you can do this in M Qery:
 
let
Source = Csv.Document(File.Contents("C:\Users\aliom\OneDrive\Desktop\url.txt"),[Delimiter=",", Columns=1, Encoding=1252, QuoteStyle=QuoteStyle.None]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Column1", type text}}),
#"Promoted Headers" = Table.PromoteHeaders(#"Changed Type", [PromoteAllScalars=true]),
#"Changed Type1" = Table.TransformColumnTypes(#"Promoted Headers",{{"URL", type text}}),
#"Added Custom" = Table.AddColumn(#"Changed Type1", "Extracted Text", each let
SourceText = [URL],
LastSlashIndex = Text.PositionOf(SourceText, "/", Occurrence.Last),
DotPngIndex = Text.PositionOf(SourceText, ".png"),
ExtractedText = Text.Middle(SourceText, LastSlashIndex + 1, DotPngIndex - LastSlashIndex - 1)
in
ExtractedText),
#"Renamed Columns" = Table.RenameColumns(#"Added Custom",{{"Extracted Text", "URL (M)"}}),
#"Changed Type2" = Table.TransformColumnTypes(#"Renamed Columns",{{"URL (M)", type text}})
in
#"Changed Type2"
 
If I answered your question, please mark this thread as accepted.
Follow me on LinkedIn:
https://www.linkedin.com/in/mustafa-ali-70133451/




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

Proud to be a Super User!




View solution in original post

miTutorials
Super User
Super User

Use the AI feature in Power Query called 'Column from Example'.

Go to Power Query Editor, right click on your URL column and choose 'Add Column from Examples' and type in the Text that you want to extract.. Thats it !!

See the video in case you are unable to follow.

 

Split column using AI Feature in Power BI | Column from Example | MiTutorials (youtube.com)

 

Regards
Ismail 

View solution in original post

2 REPLIES 2
miTutorials
Super User
Super User

Use the AI feature in Power Query called 'Column from Example'.

Go to Power Query Editor, right click on your URL column and choose 'Add Column from Examples' and type in the Text that you want to extract.. Thats it !!

See the video in case you are unable to follow.

 

Split column using AI Feature in Power BI | Column from Example | MiTutorials (youtube.com)

 

Regards
Ismail 

amustafa
Super User
Super User

Hi @tuanminhtr 

 

In DAX, here's how you can exract the text between last slash and before the .png.

Extracted Filename =
VAR FullURL = urltable[URL]
VAR URLLength = LEN(FullURL)
VAR LastSlashIndex =
    CALCULATE(
        MAXX(
            GENERATESERIES(1, URLLength, 1),
            IF(
                MID(FullURL, [Value], 1) = "/",
                [Value],
                BLANK()
            )
        )
    )
VAR FileNameWithExtension = IF(LastSlashIndex > 0, RIGHT(FullURL, URLLength - LastSlashIndex), BLANK())
VAR IsPng = RIGHT(FileNameWithExtension, 4) = ".png"
RETURN
IF(IsPng, LEFT(FileNameWithExtension, LEN(FileNameWithExtension) - 4), FileNameWithExtension)
 
Or you can do this in M Qery:
 
let
Source = Csv.Document(File.Contents("C:\Users\aliom\OneDrive\Desktop\url.txt"),[Delimiter=",", Columns=1, Encoding=1252, QuoteStyle=QuoteStyle.None]),
#"Changed Type" = Table.TransformColumnTypes(Source,{{"Column1", type text}}),
#"Promoted Headers" = Table.PromoteHeaders(#"Changed Type", [PromoteAllScalars=true]),
#"Changed Type1" = Table.TransformColumnTypes(#"Promoted Headers",{{"URL", type text}}),
#"Added Custom" = Table.AddColumn(#"Changed Type1", "Extracted Text", each let
SourceText = [URL],
LastSlashIndex = Text.PositionOf(SourceText, "/", Occurrence.Last),
DotPngIndex = Text.PositionOf(SourceText, ".png"),
ExtractedText = Text.Middle(SourceText, LastSlashIndex + 1, DotPngIndex - LastSlashIndex - 1)
in
ExtractedText),
#"Renamed Columns" = Table.RenameColumns(#"Added Custom",{{"Extracted Text", "URL (M)"}}),
#"Changed Type2" = Table.TransformColumnTypes(#"Renamed Columns",{{"URL (M)", type text}})
in
#"Changed Type2"
 
If I answered your question, please mark this thread as accepted.
Follow me on LinkedIn:
https://www.linkedin.com/in/mustafa-ali-70133451/




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

Proud to be a Super User!




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.