Advance your Data & AI career with 50 days of live learning, dataviz contests, hands-on challenges, study groups & certifications and more!
Get registeredGet Fabric Certified for FREE during Fabric Data Days. Don't miss your chance! Request now
Hi,
I'm a little lost with the following transformation.
Currently, I have the following table :
| 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 |
However, to make it more readable by Power BI, I need to transform it like this (I think) :
| Type | Categorie | Status | Date | Amount |
| Type 1 | Categorie A | Actual | 2018 | 1000 |
| Type 2 | Categorie B | Actual | 2018 | 1500 |
| Type 2 | Categorie C | Actual | 2018 | 1700 |
| Type 1 | Catégorie A | Actual | 2019 | 2000 |
| Type 2 | Catégorie B | Actual | 2019 | 2500 |
| Type 2 | Catégroei C | Actual | 2019 | 2700 |
| Type 1 | Catégorie A | Forecast | 2020 | 3000 |
| Type 2 | Catégorie B | Forecast | 2020 | 3500 |
| Type 2 | Catégroei C | Forecast | 2020 | 3700 |
I tried some unpivot but difficult to make it work like I want.
Thanks by advance,
Alex
Solved! Go to Solution.
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
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
Check out the November 2025 Power BI update to learn about new features.
Advance your Data & AI career with 50 days of live learning, contests, hands-on challenges, study groups & certifications and more!
| User | Count |
|---|---|
| 8 | |
| 7 | |
| 6 | |
| 4 | |
| 3 |
| User | Count |
|---|---|
| 19 | |
| 14 | |
| 12 | |
| 10 | |
| 8 |