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

Enhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends August 31st. Request your voucher.

Reply
Praveen_KS
Frequent Visitor

Need Help on Power Query to transform data

I have a data as below after joining 2 tables.

Emp CodeEmp NameEmp DeptPart
1234ABCPaintingDoor
1234ABCPaintingHood
5678XYZAssemblyEngine
5678XYZAssemblyClutch
5678XYZAssemblyBrake
9876ASDCastingEngine
9876ASDCastingWheel

 

Need to have the output as below. Can you please help. 

 

Emp CodeEmp NameEmp DeptPart1Part2Part3
1234ABCPaintingDoorHood 
5678XYZAssemblyEngineClutchBrake
9876ASDCastingEngineWheel 
1 ACCEPTED SOLUTION

@nilendraFabric , The below worked perfectly. Thanks

 

let Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjQyNlHSUXJ0cgaSAYmZeSWZeelApkt+fpFSrA5uBR75+SlgBaZm5hZAfkRkFEhZcXFqblJOJZDpmpeemZeKV4lzTmlJcgZeJU5FidkQQywtzM1AcsEuIJ2JxVB3IFmDQ0V4RmpqjlJsLAA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Emp Code" = _t, #"Emp Name" = _t, #"Emp Dept" = _t, Part = _t]), group = Table.Group(Source, {"Emp Code", "Emp Name", "Emp Dept"}, {"Part", (x) => x[Part]}), part_cols = List.Transform({1..List.Max(List.Transform(group[Part], List.Count))}, (x) => "Part " & Text.From(x)), split = Table.SplitColumn(group, "Part", (x) => x, part_cols) in split

View solution in original post

9 REPLIES 9
v-sgandrathi
Community Support
Community Support

Hi @Praveen_KS,

Hope you are doing well.

Thanks for connecting with the Microsoft Fabric Community Forum.

 

we haven't heard back from you regarding the last response and wanted to check if your issue has been resolved.

If our response addressed by the community member for your query, please mark it as Accept Answer and give us Kudos if you found it helpful.

Should you have any further questions, feel free to reach out.

 

Thank you, @nilendraFabric for your prompt response to the query.

 

Regards,
Sahasra.

 

 

nilendraFabric
Super User
Super User

@Praveen_KS 

Give it a try 

let
Source = Excel.CurrentWorkbook(){[Name="YourTableName"]}[Content],
GroupedRows = Table.Group(
Source,
{"Emp Code", "Emp Name", "Emp Dept"},
{{"Rows", each _, type table [Emp Code=nullable text, Emp Name=nullable text, Emp Dept=nullable text, Part=nullable text]}}
),
AddIndex = Table.AddColumn(
GroupedRows,
"IndexedRows",
each Table.AddIndexColumn([Rows], "PartIndex", 1, 1)
),
ExpandedRows = Table.ExpandTableColumn(
AddIndex,
"IndexedRows",
{"Part", "PartIndex"},
{"Part", "PartIndex"}
),
Pivoted = Table.Pivot(
ExpandedRows,
List.Distinct(ExpandedRows[PartIndex]),
"PartIndex",
"Part"
)
in
Pivoted

Thanks @nilendraFabric 

It worked fine till here

Praveen_KS_1-1738950560254.png

 

Giving an error when expanding with Index

Praveen_KS_0-1738950512709.png

 

@Praveen_KS 

 

Try this

 

let
Source = Excel.CurrentWorkbook(){[Name="YourTableName"]}[Content],
GroupedRows = Table.Group(
Source,
{"Emp Code", "Emp Name", "Emp Dept"},
{{"Rows", each _, type table [Emp Code=nullable text, Emp Name=nullable text, Emp Dept=nullable text, Part=nullable text]}}
),
AddIndex = Table.AddColumn(
GroupedRows,
"IndexedRows",
each Table.AddIndexColumn([Rows], "PartIndex", 1, 1)
),
ExpandedRows = Table.ExpandTableColumn(
AddIndex,
"IndexedRows",
{"Part", "PartIndex"},
{"Part", "PartIndex"}
),
ConvertedRows = Table.TransformColumnTypes(ExpandedRows, {{"PartIndex", type text}}),
Pivoted = Table.Pivot(
ConvertedRows,
List.Distinct(ConvertedRows[PartIndex]),
"PartIndex",
"Part"
)
in
Pivoted

Thanks @nilendraFabric 

Pivot is not allowing over the nested Index Column

Praveen_KS_0-1739206733274.png

 

let
// Source Data
Source = Excel.CurrentWorkbook(){[Name="YourTableName"]}[Content],

// Group by Employee Details
GroupedRows = Table.Group(
Source,
{"Emp Code", "Emp Name", "Emp Dept"},
{{"Rows", each _, type table [Emp Code=nullable text, Emp Name=nullable text, Emp Dept=nullable text, Part=nullable text]}}
),

// Add Index Column Within Each Group
AddIndex = Table.AddColumn(
GroupedRows,
"IndexedRows",
each Table.AddIndexColumn([Rows], "PartIndex", 1, 1)
),

// Expand Indexed Rows
ExpandedRows = Table.ExpandTableColumn(
AddIndex,
"IndexedRows",
{"Part", "PartIndex"}
),

// Pivot Part Column Based on PartIndex
Pivoted = Table.Pivot(
ExpandedRows,
List.Distinct(ExpandedRows[PartIndex]),
"PartIndex",
"Part"
)
in
Pivoted

Thanks @nilendraFabric 

 

Still, it doesn't seem to work.

Praveen_KS_0-1739273334135.png

 

@nilendraFabric , The below worked perfectly. Thanks

 

let Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMjQyNlHSUXJ0cgaSAYmZeSWZeelApkt+fpFSrA5uBR75+SlgBaZm5hZAfkRkFEhZcXFqblJOJZDpmpeemZeKV4lzTmlJcgZeJU5FidkQQywtzM1AcsEuIJ2JxVB3IFmDQ0V4RmpqjlJsLAA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Emp Code" = _t, #"Emp Name" = _t, #"Emp Dept" = _t, Part = _t]), group = Table.Group(Source, {"Emp Code", "Emp Name", "Emp Dept"}, {"Part", (x) => x[Part]}), part_cols = List.Transform({1..List.Max(List.Transform(group[Part], List.Count))}, (x) => "Part " & Text.From(x)), split = Table.SplitColumn(group, "Part", (x) => x, part_cols) in split

Hello @Praveen_KS,

 

I'm glad you found a solution and resloved  the query. Thank you very much for sharing here.

Kindly mark your reply as the accepted solution so that others in the community can find it quickly.

 

Thankyou for connecting with Microsoft Community Forum.

Helpful resources

Announcements
Fabric July 2025 Monthly Update Carousel

Fabric Monthly Update - July 2025

Check out the July 2025 Fabric 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.