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

Join us for an expert-led overview of the tools and concepts you'll need to become a Certified Power BI Data Analyst and pass exam PL-300. Register now.

Reply
MaryF
Advocate II
Advocate II

Help needed to transform data via M

Hi all

 

I'm hoping someone can help me get past a big hurdle.. I have the following issue

 

My data is coming in as a single column

Raw DataRaw Data

 

 

.I need it to become this...I need it to become this...

Can anyone let me know if this is doable etc.

 

Many thanks in advance

 

Mary

2 ACCEPTED SOLUTIONS
KHorseman
Community Champion
Community Champion

I don't know if this is the optimal solution, but I did it this way:

 

  1. Added a custom column that repeats a sequence of the numbers 1 - 8 down the series so there is something to pivot on
  2. Repeated the account name or whatever you call that first row in each set in your sample
  3. Removed those first rows
  4. Removed the index column because it will be meaningless after this
  5. Pivoted on the column header number thing from step 2
  6. The next steps would probably be to rename all these columns and maybe add a new index column, but I didn't bother.

 

let
    Source = Excel.Workbook(File.Contents("M:\Reports\test.xlsx"), null, true),
    Table1_Table = Source{[Item="Table1",Kind="Table"]}[Data],
    #"Changed Type" = Table.TransformColumnTypes(Table1_Table,{{"Index", Int64.Type}}),
    #"Added Sorter" = Table.AddColumn(
		#"Changed Type",
		"Sorter",
		each Number.From(
			List.Min(
				List.Range(
					List.Repeat(
						{1, 2, 3, 4, 5, 6, 7, 8},
						Int32.From(
							(List.Count(#"Changed Type"[Index]) / 8),
							null,
							RoundingMode.Up
						)		
					),
					[Index] - 1,
					1
				)
			)
		)
	),
    #"Added Name" = Table.AddColumn(
		#"Added Sorter",
		"Name",
		each Text.From(
			List.Last(
				List.FirstN(
					#"Added Sorter"[Column1],
					[Index] - ([Sorter] - 1)
				),
				1
			)
		)
	),
    #"Reordered Columns" = Table.ReorderColumns(
		#"Added Name",
		{"Index", "Sorter", "Name", "Column1"}
	),
    #"Removed Rows" = Table.SelectRows(
		#"Reordered Columns",
		each [Sorter] > 1
	),
    #"Removed Columns" = Table.RemoveColumns(#"Removed Rows",{"Index"}),
    #"Pivoted Column" = Table.Pivot(
		Table.TransformColumnTypes(
			#"Removed Columns",
			{{"Sorter", type text}},
			"en-US"
		),
		List.Distinct(Table.TransformColumnTypes(#"Removed Columns", {{"Sorter", type text}}, "en-US")[Sorter]),
		"Sorter",
		"Column1"
	)
in
    #"Pivoted Column"




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

Proud to be a Super User!




View solution in original post

ImkeF
Community Champion
Community Champion

This is very similar, but a bit shorter:

 

let
    Source = Excel.CurrentWorkbook(){[Name="Tabelle1"]}[Content],
    #"Added Index" = Table.AddIndexColumn(Source, "Index", 1, 1),
    RowNumber = Table.AddColumn(#"Added Index", "Custom", each Number.RoundUp([Index]/8)),
    PivotCols = Table.AddColumn(RowNumber, "Pivot", each Number.Mod([Index], 8)),
    RemoveIndex = Table.RemoveColumns(PivotCols,{"Index"}),
    #"Pivoted Column" = Table.Pivot(Table.TransformColumnTypes(RemoveIndex, {{"Pivot", type text}}, "de-DE"), List.Distinct(Table.TransformColumnTypes(RemoveIndex, {{"Pivot", type text}}, "de-DE")[Pivot]), "Pivot", "Spalte1")
in
    #"Pivoted Column"

Imke Feldmann (The BIccountant)

If you liked my solution, please give it a thumbs up. And if I did answer your question, please mark this post as a solution. Thanks!

How to integrate M-code into your solution -- How to get your questions answered quickly -- How to provide sample data -- Check out more PBI- learning resources here -- Performance Tipps for M-queries

View solution in original post

7 REPLIES 7
KHorseman
Community Champion
Community Champion

I don't know if this is the optimal solution, but I did it this way:

 

  1. Added a custom column that repeats a sequence of the numbers 1 - 8 down the series so there is something to pivot on
  2. Repeated the account name or whatever you call that first row in each set in your sample
  3. Removed those first rows
  4. Removed the index column because it will be meaningless after this
  5. Pivoted on the column header number thing from step 2
  6. The next steps would probably be to rename all these columns and maybe add a new index column, but I didn't bother.

 

let
    Source = Excel.Workbook(File.Contents("M:\Reports\test.xlsx"), null, true),
    Table1_Table = Source{[Item="Table1",Kind="Table"]}[Data],
    #"Changed Type" = Table.TransformColumnTypes(Table1_Table,{{"Index", Int64.Type}}),
    #"Added Sorter" = Table.AddColumn(
		#"Changed Type",
		"Sorter",
		each Number.From(
			List.Min(
				List.Range(
					List.Repeat(
						{1, 2, 3, 4, 5, 6, 7, 8},
						Int32.From(
							(List.Count(#"Changed Type"[Index]) / 8),
							null,
							RoundingMode.Up
						)		
					),
					[Index] - 1,
					1
				)
			)
		)
	),
    #"Added Name" = Table.AddColumn(
		#"Added Sorter",
		"Name",
		each Text.From(
			List.Last(
				List.FirstN(
					#"Added Sorter"[Column1],
					[Index] - ([Sorter] - 1)
				),
				1
			)
		)
	),
    #"Reordered Columns" = Table.ReorderColumns(
		#"Added Name",
		{"Index", "Sorter", "Name", "Column1"}
	),
    #"Removed Rows" = Table.SelectRows(
		#"Reordered Columns",
		each [Sorter] > 1
	),
    #"Removed Columns" = Table.RemoveColumns(#"Removed Rows",{"Index"}),
    #"Pivoted Column" = Table.Pivot(
		Table.TransformColumnTypes(
			#"Removed Columns",
			{{"Sorter", type text}},
			"en-US"
		),
		List.Distinct(Table.TransformColumnTypes(#"Removed Columns", {{"Sorter", type text}}, "en-US")[Sorter]),
		"Sorter",
		"Column1"
	)
in
    #"Pivoted Column"




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

Proud to be a Super User!




@KHorseman Thanks LOADS!!! Very much appriate your input. Mary 🙂

KHorseman
Community Champion
Community Champion

Thanks. It was a fun problem to tackle. I'm sure there's a more efficient way to do the Sorter column, but that was the best I could think of. I'd be interested to see if someone else has a different solution to this.





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

Proud to be a Super User!




ImkeF
Community Champion
Community Champion

This is very similar, but a bit shorter:

 

let
    Source = Excel.CurrentWorkbook(){[Name="Tabelle1"]}[Content],
    #"Added Index" = Table.AddIndexColumn(Source, "Index", 1, 1),
    RowNumber = Table.AddColumn(#"Added Index", "Custom", each Number.RoundUp([Index]/8)),
    PivotCols = Table.AddColumn(RowNumber, "Pivot", each Number.Mod([Index], 8)),
    RemoveIndex = Table.RemoveColumns(PivotCols,{"Index"}),
    #"Pivoted Column" = Table.Pivot(Table.TransformColumnTypes(RemoveIndex, {{"Pivot", type text}}, "de-DE"), List.Distinct(Table.TransformColumnTypes(RemoveIndex, {{"Pivot", type text}}, "de-DE")[Pivot]), "Pivot", "Spalte1")
in
    #"Pivoted Column"

Imke Feldmann (The BIccountant)

If you liked my solution, please give it a thumbs up. And if I did answer your question, please mark this post as a solution. Thanks!

How to integrate M-code into your solution -- How to get your questions answered quickly -- How to provide sample data -- Check out more PBI- learning resources here -- Performance Tipps for M-queries

KHorseman
Community Champion
Community Champion

@ImkeF I knew there had to be an easier way to get the 1-8 count. Math, of course! Nicely done.

 

@MaryF you're welcome. I learned a lot here too.





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

Proud to be a Super User!




Thanks loads @ImkeF. I am so pleased to have a solution plus I learnt alot too. 

Sorry I should have said thank you @KHorseman & @ImkeF as I have two solutions to learn new stuff from.

Helpful resources

Announcements
Join our Fabric User Panel

Join our Fabric User Panel

This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.

June 2025 community update carousel

Fabric Community Update - June 2025

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