Transposing a Range (Multiple Columns and Rows) to a Single Row - new row based on cell value from one column

alscno

New Member
Joined
Oct 21, 2020
Messages
2
Office Version
  1. 365
Platform
  1. Windows
Hi,
I am trying to transpose multiple data from multiple columns into a single row in a new workbook. Every new row should contain the data from range "TX" to new "TX" in column 1.
My original data simplifies to what is seen below:
Col1 Col2
TX 1
A 2
B 3
TX 5
C 6
D 7
E 8

Needed output:
row1: TX 1 A 2 B 3
row 2: TX 5 C 6 D 7 E 8

Thanks!
 

Some videos you may like

Excel Facts

Will the fill handle fill 1, 2, 3?
Yes! Type 1 in a cell. Hold down Ctrl while you drag the fill handle.

sandy666

Banned - Rules violations
Joined
Oct 24, 2015
Messages
7,499
Column1Column2Custom.1
TX1TX 1 A 2 B 3
A2TX 5 C 6 D 7 E 8
B3
TX5
C6
D7
E8

Power Query:
let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    TCC = Table.CombineColumns(Table.TransformColumnTypes(Source, {{"Column2", type text}}, "en-GB"),{"Column1", "Column2"},Combiner.CombineTextByDelimiter(" ", QuoteStyle.None),"Merged"),
    Contains = Table.AddColumn(TCC, "Custom", each if Text.Contains([Merged], "TX") then [Merged] else null),
    FillD = Table.FillDown(Contains,{"Custom"}),
    Group = Table.Group(FillD, {"Custom"}, {{"Count", each _, type table}}),
    List = Table.AddColumn(Group, "Custom.1", each [Count][Merged]),
    Extract = Table.TransformColumns(List, {"Custom.1", each Text.Combine(List.Transform(_, Text.From), " "), type text}),
    TSC = Table.SelectColumns(Extract,{"Custom.1"})
in
    TSC
 

alscno

New Member
Joined
Oct 21, 2020
Messages
2
Office Version
  1. 365
Platform
  1. Windows
Thank you sandy666 ! I described the needed output not correctly above. How can i change the code so that the output is placed in seperat columns and not merged into one cell?

Column1Column2Column1Column2Column3Column4Column5Column6Column7Column8
TX1TX1A2B3
A2TX5C6D7E8
B3
TX5
C6
D7
E8
 

sandy666

Banned - Rules violations
Joined
Oct 24, 2015
Messages
7,499
Column1Column2List.1List.2List.3List.4List.5List.6List.7List.8
TX1TX1A2B3
A2TX5C6D7E8
B3
TX5
C6
D7
E8

Power Query:
let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    TCC = Table.CombineColumns(Table.TransformColumnTypes(Source, {{"Column2", type text}}, "en-GB"),{"Column1", "Column2"},Combiner.CombineTextByDelimiter(" ", QuoteStyle.None),"Merged"),
    Contains = Table.AddColumn(TCC, "Custom", each if Text.Contains([Merged], "TX") then [Merged] else null),
    FillD = Table.FillDown(Contains,{"Custom"}),
    Group = Table.Group(FillD, {"Custom"}, {{"Count", each _, type table}}),
    List = Table.AddColumn(Group, "List", each [Count][Merged]),
    Extract = Table.TransformColumns(List, {"List", each Text.Combine(List.Transform(_, Text.From), " "), type text}),
    MaxCount = List.Max(Table.AddColumn(Extract, "SCount", each List.Count(Text.Split([List]," ")))[SCount]),
    Split = Table.SplitColumn(Extract, "List", Splitter.SplitTextByDelimiter(" "), MaxCount),
    TSC = Table.SelectColumns(Split,{"List.1", "List.2", "List.3", "List.4", "List.5", "List.6", "List.7", "List.8"})
in
    TSC
 
Solution

Watch MrExcel Video

Forum statistics

Threads
1,127,530
Messages
5,625,361
Members
416,096
Latest member
forevans

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Top