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
Ade1991
Helper I
Helper I

Column Transformation (for Excel PnL)

Hi,

 

I'm a little lost with the following transformation.

 

Currently, I have the following table :

 

  201820192020
  ActualActualForecast
Type 1    
 Catégorie A100020003000
Type2    
 Catégorie B150025003500
 Catégorie C170027003700


However, to make it more readable by Power BI, I need to transform it like this (I think) :

TypeCategorieStatusDateAmount
Type 1Categorie AActual20181000
Type 2Categorie BActual20181500
Type 2Categorie CActual20181700
Type 1Catégorie AActual20192000
Type 2Catégorie BActual20192500
Type 2Catégroei CActual20192700
Type 1Catégorie AForecast20203000
Type 2Catégorie BForecast20203500
Type 2Catégroei CForecast20203700

 

I tried some unpivot but difficult to make it work like I want.

 

Thanks by advance,

 

Alex

1 ACCEPTED SOLUTION
Jimmy801
Community Champion
Community Champion

Hello @Ade1991 

 

you have to fix the first row, then promote first row to header and then Unpivot Other

Here the complete solution

let
	Source = #table
	(
		{"Column1","Column2","2018","2019","2020"},
		{
			{"","","Actual","Actual","Forecast"},	{"Type 1","","","",""},	{"","Catégorie A","1000","2000","3000"},	{"Type2","","","",""},	{"","Catégorie B","1500","2500","3500"},	
			{"","Catégorie C","1700","2700","3700"}
		}
	),
	FixFirstRow = Table.FromRecords({ Record.FromTable( Table.FromRecords( Table.TransformRows
	(
		Record.ToTable
		(
			Table.First(Source)

		),
		(row)=> if row[Name]="Column1" then [Name = "Column1", Value="Type"] else
		if row[Name]="Column2" then [Name = "Column2", Value="Cat."] else
		[Name= row[Name], Value= row[Name]&"-"&row[Value]] 

	)))}),
	CombineBoth = Table.Combine
	(
		{
			FixFirstRow,
			Table.Skip(Source,1)
		}
	),
    PromoteHeader = Table.PromoteHeaders(CombineBoth, [PromoteAllScalars=true]),
    ChangeType = Table.TransformColumnTypes(PromoteHeader,{{"Type", type text}, {"Cat.", type text}, {"2018-Actual", Int64.Type}, {"2019-Actual", Int64.Type}, {"2020-Forecast", Int64.Type}}),
    ChangeSpaceToNull = Table.ReplaceValue(ChangeType,"",null,Replacer.ReplaceValue,{"Type", "Cat."}),
    FillDown = Table.FillDown(ChangeSpaceToNull,{"Type"}),
    FillUp = Table.FillUp(FillDown,{"Cat."}),
    UnpivotOther = Table.UnpivotOtherColumns(FillUp, {"Type", "Cat."}, "Attribut", "Wert"),
    SplitColumn = Table.SplitColumn(UnpivotOther, "Attribut", Splitter.SplitTextByDelimiter("-", QuoteStyle.Csv), {"Attribut.1", "Attribut.2"}),
    ChangeType1 = Table.TransformColumnTypes(SplitColumn,{{"Attribut.1", Int64.Type}, {"Attribut.2", type text}}),
    RenameColumns = Table.RenameColumns(ChangeType1,{{"Attribut.1", "Year"}, {"Attribut.2", "Status"}, {"Wert", "Value"}})
in
    RenameColumns

 

Copy paste this code to the advanced editor in a new blank query to see how the solution works. If this solution fits your need, copy and past a part of it and implement it in your query

If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too

Have fun

Jimmy

View solution in original post

1 REPLY 1
Jimmy801
Community Champion
Community Champion

Hello @Ade1991 

 

you have to fix the first row, then promote first row to header and then Unpivot Other

Here the complete solution

let
	Source = #table
	(
		{"Column1","Column2","2018","2019","2020"},
		{
			{"","","Actual","Actual","Forecast"},	{"Type 1","","","",""},	{"","Catégorie A","1000","2000","3000"},	{"Type2","","","",""},	{"","Catégorie B","1500","2500","3500"},	
			{"","Catégorie C","1700","2700","3700"}
		}
	),
	FixFirstRow = Table.FromRecords({ Record.FromTable( Table.FromRecords( Table.TransformRows
	(
		Record.ToTable
		(
			Table.First(Source)

		),
		(row)=> if row[Name]="Column1" then [Name = "Column1", Value="Type"] else
		if row[Name]="Column2" then [Name = "Column2", Value="Cat."] else
		[Name= row[Name], Value= row[Name]&"-"&row[Value]] 

	)))}),
	CombineBoth = Table.Combine
	(
		{
			FixFirstRow,
			Table.Skip(Source,1)
		}
	),
    PromoteHeader = Table.PromoteHeaders(CombineBoth, [PromoteAllScalars=true]),
    ChangeType = Table.TransformColumnTypes(PromoteHeader,{{"Type", type text}, {"Cat.", type text}, {"2018-Actual", Int64.Type}, {"2019-Actual", Int64.Type}, {"2020-Forecast", Int64.Type}}),
    ChangeSpaceToNull = Table.ReplaceValue(ChangeType,"",null,Replacer.ReplaceValue,{"Type", "Cat."}),
    FillDown = Table.FillDown(ChangeSpaceToNull,{"Type"}),
    FillUp = Table.FillUp(FillDown,{"Cat."}),
    UnpivotOther = Table.UnpivotOtherColumns(FillUp, {"Type", "Cat."}, "Attribut", "Wert"),
    SplitColumn = Table.SplitColumn(UnpivotOther, "Attribut", Splitter.SplitTextByDelimiter("-", QuoteStyle.Csv), {"Attribut.1", "Attribut.2"}),
    ChangeType1 = Table.TransformColumnTypes(SplitColumn,{{"Attribut.1", Int64.Type}, {"Attribut.2", type text}}),
    RenameColumns = Table.RenameColumns(ChangeType1,{{"Attribut.1", "Year"}, {"Attribut.2", "Status"}, {"Wert", "Value"}})
in
    RenameColumns

 

Copy paste this code to the advanced editor in a new blank query to see how the solution works. If this solution fits your need, copy and past a part of it and implement it in your query

If this post helps or solves your problem, please mark it as solution (to help other users find useful content and to acknowledge the work of users that helped you)
Kudoes are nice too

Have fun

Jimmy

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.

Top Solution Authors
Top Kudoed Authors