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
prabhatnath
Advocate III
Advocate III

Split a Text column by delimiter multiple combinations - mQuery

Hi Friends,

I have a table that is loaded into Power BI and has a column as "Cycles" and has text data as below.
And I wanted to add another column "FY Quarter" during the data load steps using mQuery. Can you please advise the best way for this?

CyclesFY Quarter
Project\FY23\FY23-Q4\Cycle-1FY23-Q4
Project\FY23\FY23-Q4\Cycle-2FY23-Q4
Project\FY24FY24
Project\FY24\FY24-Q1FY24-Q1
Project\FY24\FY24-Q1\Cycle-3FY24-Q1
Project\FY24\FY24-Q1\Cycle-4FY24-Q1
Project\FY24\FY24-Q1\Cycle-5FY24-Q1
Project\FY24\FY24-Q2FY24-Q2
Project\FY24\FY24-Q2\Cycle-6FY24-Q2
Project\FY24\FY24-Q2\Cycle-7FY24-Q2

 

Thanks,
Prabhat

2 ACCEPTED SOLUTIONS
danextian
Super User
Super User

Hi @prabhatnath ,

 

Try the following custom column in the query editor:

if Text.Contains([Cycles], "\Cycle-") then Text.BetweenDelimiters([Cycles], "\", "\Cycle-", {1, RelativePosition.FromEnd}, 0) else Text.AfterDelimiter([Cycles], "\", {0, RelativePosition.FromEnd})

Here's the complete M Code

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WCijKz0pNLomJcYs0MoaQuoEmMTHOlck5qbqGSjpKUCGlWB1Cqo3wqDaByGGRgJC6gVC7wCzcimB2GZOk2oQk1abEqDaCKzLCowhmpBlJqs2RVccCAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Cycles = _t, #"FY Quarter" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Cycles", type text}, {"FY Quarter", type text}}),
    Custom = Table.AddColumn(#"Changed Type", "Custom", each 
if Text.Contains([Cycles], "\Cycle-") then Text.BetweenDelimiters([Cycles], "\", "\Cycle-", {1, RelativePosition.FromEnd}, 0) else Text.AfterDelimiter([Cycles], "\", {0, RelativePosition.FromEnd}), type text)
in
    Custom

danextian_0-1697887556751.png

 










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


Proud to be a Super User!









"Tell me and I’ll forget; show me and I may remember; involve me and I’ll understand."
Need Power BI consultation, get in touch with me on LinkedIn or hire me on UpWork.
Learn with me on YouTube @DAXJutsu or follow my page on Facebook @DAXJutsuPBI.

View solution in original post

Ahmedx
Super User
Super User

plse try this

try
List.Select(
Text.Split([Cycles],"\"),(x)=> Text.Contains(x,"-Q", Comparer.OrdinalIgnoreCase)){0} otherwise List.Select(
Text.Split([Cycles],"\"),(x)=> Text.Contains(x,"FY", Comparer.OrdinalIgnoreCase)){0}

 

Screenshot_2.png 

View solution in original post

4 REPLIES 4
prabhatnath
Advocate III
Advocate III

Thanks, @Ahmedx and @danextian both the solution is working great, not sure how can I mark both as the solution, but just mark one based on the number of views. Thank you friends for the solution.

- Prabhat

v-shex-msft
Community Support
Community Support

Hi @prabhatnath ,

Did the above suggestions help with your scenario? if that is the case, you can consider Kudo or Accept the helpful suggestions to help others who faced similar requirements.

If these also don't help, please share more detailed information and description to help us clarify your scenario to test.

How to Get Your Question Answered Quickly 

Regards,

Xiaoxin Sheng

 

Community Support Team _ Xiaoxin
If this post helps, please consider accept as solution to help other members find it more quickly.
Ahmedx
Super User
Super User

plse try this

try
List.Select(
Text.Split([Cycles],"\"),(x)=> Text.Contains(x,"-Q", Comparer.OrdinalIgnoreCase)){0} otherwise List.Select(
Text.Split([Cycles],"\"),(x)=> Text.Contains(x,"FY", Comparer.OrdinalIgnoreCase)){0}

 

Screenshot_2.png 

danextian
Super User
Super User

Hi @prabhatnath ,

 

Try the following custom column in the query editor:

if Text.Contains([Cycles], "\Cycle-") then Text.BetweenDelimiters([Cycles], "\", "\Cycle-", {1, RelativePosition.FromEnd}, 0) else Text.AfterDelimiter([Cycles], "\", {0, RelativePosition.FromEnd})

Here's the complete M Code

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WCijKz0pNLomJcYs0MoaQuoEmMTHOlck5qbqGSjpKUCGlWB1Cqo3wqDaByGGRgJC6gVC7wCzcimB2GZOk2oQk1abEqDaCKzLCowhmpBlJqs2RVccCAA==", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Cycles = _t, #"FY Quarter" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Cycles", type text}, {"FY Quarter", type text}}),
    Custom = Table.AddColumn(#"Changed Type", "Custom", each 
if Text.Contains([Cycles], "\Cycle-") then Text.BetweenDelimiters([Cycles], "\", "\Cycle-", {1, RelativePosition.FromEnd}, 0) else Text.AfterDelimiter([Cycles], "\", {0, RelativePosition.FromEnd}), type text)
in
    Custom

danextian_0-1697887556751.png

 










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


Proud to be a Super User!









"Tell me and I’ll forget; show me and I may remember; involve me and I’ll understand."
Need Power BI consultation, get in touch with me on LinkedIn or hire me on UpWork.
Learn with me on YouTube @DAXJutsu or follow my page on Facebook @DAXJutsuPBI.

Helpful resources

Announcements
RTI Forums Carousel3

New forum boards available in Real-Time Intelligence.

Ask questions in Eventhouse and KQL, Eventstream, and Reflex.

LearnSurvey

Fabric certifications survey

Certification feedback opportunity for the community.