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

Compete to become Power BI Data Viz World Champion! First round ends August 18th. Get started.

Reply
Jacb
Frequent Visitor

Split Column into Rows in Power BI

Hi,
I am trying to ascertain the most efficient way to split the 'Details' column into multiple columns.  

DetailsTransaction
• Client A7.29
• A00217.29
• 9928607.29
•Client B150
•C0035550
• 992860150
• 984521400
• Client C250
• EC003250
• 992860250

 

I want the output to look something like this:

CustomerCodeAccountTransaction
Client AA00219928607.29
Client BC0035992860150
Client BC0035984521400
Client CEC003992860250


I've tried to use the UI to split the Details Column by using delimiter and special character line feed •#(lf) but it splits out the columns and only displays null values. 
I've tried to add an index column to the data and then created a custom field called, 'Column' that looks at each Number.mod([index], 3})) however, when I apply this the new field is showing the correct sequence for those that only have one account associated to them i.e. Column would contain values  0,1,2 .  However, when it encounters an instance with more than one account the sequence values change and it thinks its a new identity. and displays this as 0,1,2,0.  Any ideas how I can easily rectify the above? 

Thanks

1 ACCEPTED SOLUTION

@Jacb In that case you can check if the Text doesn't contain Number or you can prepare a list of Client Name and check if the Text is in that list.

 

AntrikshSharma_0-1731590026049.png

 

( x, y ) => Byte.From ( 
    List.Count ( 
        List.Intersect ( 
            { Text.ToList ( y[Details] ), 
            { "0".."9" } } 
        ) 
    ) = 0 
)

 

With Client Name List

( x, y ) => Byte.From ( List.Contains ( ClientNames, y[Details] ) )

AntrikshSharma_1-1731590068175.png

 

Refer to Solution_v2 and Solution_v3 in the PBIX attached below.

View solution in original post

10 REPLIES 10
AlienSx
Super User
Super User

let
    group = Table.Group(
        data, 
        "Details", 
        {"x", (x) => Table.AddColumn(Table.Skip(x,2), "Code", (w) => x[Details]{1})}, 
        GroupKind.Local, 
        (s, c) => Number.From(Text.Contains(c, "Client"))
    ),
    expand = Table.ExpandTableColumn(group, "x", {"Code", "Details", "Transaction"}, {"Code", "Account", "Transaction"})
in
    expand
Jacb
Frequent Visitor

Thanks for the solution. 
Where you have stated the Text.Contains "Client" - my actual data doesn't contain the word Client - it contains the actual client name but I can't disclose that here.   What would I change this statement to use instead?
Thanks

Anonymous
Not applicable

I would add two custom columns as

 

if Text.StartsWith([Client], "Client" then [Client] else null

 

Fill that column down, then Table.SelectRows using each [Client] <> [NewClientColumn].
Do the same thing with the Code column ( add column, fill down, select rows). Then just rearrange your columns--that's it.

 

--Nate

 

Omid_Motamedise
Super User
Super User

Use the following formula which is based on Table.Group

 

let
Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45Wcs7JTM0rUXBU0lEy1zOyVIrViVZyNDAwMkQWsLQ0sjAzQBaBanMCihmaGkCEDAyMTYF8UygfrgmmwNLCxBRsromBAbIhzkAhI6gaV5ApSHy4IWCBWAA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Details = _t, Transaction = _t]),
#"Grouped Rows" = Table.Group(Source, "Details", {{"Count", each [a=_,b=Table.AddColumn(Table.FirstN(a,1),"Code", (x)=> Text.Combine(List.Skip(a[Details])))][b]}},0,(a,b)=>Number.From(Text.StartsWith(b,"Client"))),
#"Removed Columns" = Table.RemoveColumns(#"Grouped Rows",{"Details"}),
#"Expanded Count" = Table.ExpandTableColumn(#"Removed Columns", "Count", {"Details", "Transaction", "Code"}, {"Details", "Transaction", "Code"})
in
#"Expanded Count"

If my answer helped solve your issue, please consider marking it as the accepted solution. It helps others in the community find answers faster—and keeps the community growing stronger!
You can also check out my YouTube channel for tutorials, tips, and real-world solutions in Power Query with the following link
https://youtube.com/@omidbi?si=96Bo-ZsSwOx0Z36h

Thanks for the solution. 
Where you have stated the Text.StartsWith "Client" - my actual data doesn't contain the word Client - it contains the actual client name but I can't disclose that here.   What would I change this statement to use instead?
Thanks

AntrikshSharma
Super User
Super User

@Jacb Try this:

 

let
    Source = Table,
    GroupedRows = Table.Group (
            Source,
            { "Details" },
            {
                {
                    "Transform",
                    each
                        let
                            a = _,
                            b = Table.Skip ( a ),
                            c = b[Details]{0},
                            d = Table.TransformColumns (
                                    Table.Skip ( b ),
                                    { { "Details", each c & _ } }
                                ),
                            e = { List.Repeat ( { Table.FirstValue ( a ) }, Table.RowCount ( d ) ) }
                                & Table.ToColumns ( d ),
                            f = Table.FromColumns (
                                    e,
                                    type table [
                                        Customer Code = text,
                                        Account = text,
                                        Transaction = Currency.Type
                                    ]
                                )
                        in
                            f
                }
            },
            GroupKind.Local,
            ( x, y ) => Byte.From ( Text.StartsWith ( y[Details], "Client" ) )
        ),
    Combine = 
        Table.Combine ( GroupedRows[Transform] )
in
    Combine

AntrikshSharma_0-1731522780209.png

PBIX attached below:

Thanks for the solution. 
Where you have stated the Text.StartsWith "Client" - my actual data doesn't contain the word Client - it contains the actual client name but I can't disclose that here.   What would I change this statement to use instead?
Thanks

@Jacb In that case you can check if the Text doesn't contain Number or you can prepare a list of Client Name and check if the Text is in that list.

 

AntrikshSharma_0-1731590026049.png

 

( x, y ) => Byte.From ( 
    List.Count ( 
        List.Intersect ( 
            { Text.ToList ( y[Details] ), 
            { "0".."9" } } 
        ) 
    ) = 0 
)

 

With Client Name List

( x, y ) => Byte.From ( List.Contains ( ClientNames, y[Details] ) )

AntrikshSharma_1-1731590068175.png

 

Refer to Solution_v2 and Solution_v3 in the PBIX attached below.

BA_Pete
Super User
Super User

Hi @Jacb ,

 

I wouldn't say this is an 'easy' way to rectify your scenario, but it's 'a' way. It's not at all elegant, but should do the job:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WetSwSME5JzM1r0TBUUlHyVzPyFIpVgci7mhgYGSILmhpaWRhZoAmCjXBCShsaGoAFzUwMDYFCpkihBDaDZEFLUxMwTaZGCAEoWY6A4WNkNS6gkxFE4MbChaMBQA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Details = _t, Transaction = _t]),
    addClient = Table.AddColumn(Source, "Client", each if Text.Contains([Details], "Client") then Text.Trim(Text.Select([Details], {"a".."z", " ", "A".."Z"})) else null),
    fillDownClient = Table.FillDown(addClient, {"Client"}),
    groupClient = Table.Group(fillDownClient, {"Client"}, {{"data", each _, type table [Details=nullable text, Transaction=nullable text, Client=text]}}),
    addNestedClientIndex = Table.TransformColumns(groupClient, {"data", each Table.AddIndexColumn(_, "ClientIndex", 1, 1)}),
    addNestedAcctStart = Table.TransformColumns(addNestedClientIndex, {"data", each Table.AddColumn(_, "acctStart", each if [ClientIndex] = 2 then Text.Select([Details], {"a".."z", "A".."Z", "0".."9"}) else null)}),
    addNestedAcctEnd = Table.TransformColumns(addNestedAcctStart, {"data", each Table.AddColumn(_, "acctEnd", each try Number.From(Text.Select([Details], {"a".."z", "A".."Z", "0".."9"})) otherwise null)}),
    fillDownAcctStart = Table.TransformColumns(addNestedAcctEnd, {"data", each Table.FillDown(_, {"acctStart"})}),
    filterNestedAcctEnd = Table.TransformColumns(fillDownAcctStart, {"data", each Table.SelectRows(_, each [acctEnd] <> null)}),
    addNestedAccount = Table.TransformColumns(filterNestedAcctEnd, {"data", each Table.AddColumn(_, "Account", each Text.Combine({[acctStart], Text.From([acctEnd])}))}),
    expandNested = Table.ExpandTableColumn(addNestedAccount, "data", {"Transaction", "Account"}, {"Transaction", "Account"})
in
    expandNested

 

The above example transforms this:

BA_Pete_0-1731517574457.png

 

...to this:

BA_Pete_1-1731517604601.png

 

I suspect some hero will swoop in here in a couple of hours with a one-liner solution but, until then, this should sort you out.

 

Pete



Now accepting Kudos! If my post helped you, why not give it a thumbs-up?

Proud to be a Datanaut!




Jacb
Frequent Visitor

Thanks for the solution. 
Where you have stated the Text.Contains "Client" - my actual data doesn't contain the word Client - it contains the actual client name but I can't disclose that here.   What would I change this statement to use instead?
Thanks

Helpful resources

Announcements
August Power BI Update Carousel

Power BI Monthly Update - August 2025

Check out the August 2025 Power BI update to learn about new features.

August 2025 community update carousel

Fabric Community Update - August 2025

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

Top Solution Authors