March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.
Register NowGet certified in Microsoft Fabric—for free! For a limited time, the Microsoft Fabric Community team will be offering free DP-600 exam vouchers. Prepare now
Hello PBI Forum,
So my issue is as follow, I have a parent child relationship as given below and I need (within Power Query and not DAX) a way to find out the highest parent of any child
Team ID - Parent ID
1 - null
2 - null
3 - 1
4 - 3
5 - 2
6 - 5
Result should be as follows
Team ID - Highest Parent ID
1 - null
2 - null
3 - 1
4 - 1
5 - 2
6 - 2
So esentially need to go up the tree to the highest parent that exists. I need for this to happen at the Power Query level
Thanks,
Moiz
Solved! Go to Solution.
you just need to change the data types then like this:
let Source = Excel.CurrentWorkbook(){[Name="Hierarchy"]}[Content], ChangedType = Table.TransformColumnTypes(Source,{{"Team ID", type text}, {"Parent ID", type text}}), ListTeamID = List.Buffer( ChangedType[Team ID] ), ListParentID = List.Buffer( ChangedType[Parent ID] ), fnGetHighestParent = (n as text) as text => let PosOfParent = List.PositionOf( ListTeamID, n ), ParID = ListParentID{PosOfParent} in if ParID = null then ListTeamID{PosOfParent} else @fnGetHighestParent(ListParentID{PosOfParent}), FinalTable = Table.AddColumn( ChangedType, "HighestParent", each fnGetHighestParent( [Team ID] ), type text) in FinalTable
Did I answer your question correctly? Mark my answer as a solution!
Proud to be a Datanaut!
I tried below and it worked out fine..
1. Create an Alias/Duplicate table for the main table
2. Use Merge Queries to merge both Main & Duplicate table joining ParentID in Duplicate table with TeamID in Main table (Left Outer Join).
3. You can see a tabular new field, expand it.
4. Add a conditional column, to have ParentID from Main table in case it is NULL in Duplicate table
Here is the code for the above steps:
TableName : HighParent
DuplicateTableName : HighParentDup
let
Source = Table.NestedJoin(HighParentDup,{"ParentID"},HighParent,{"TeamID"},"HighParent",JoinKind.LeftOuter),
#"Expanded HighParent" = Table.ExpandTableColumn(Source, "HighParent", {"TeamID", "ParentID"}, {"HighParent.TeamID", "HighParent.ParentID"}),
#"Sorted Rows" = Table.Sort(#"Expanded HighParent",{{"TeamID", Order.Ascending}}),
#"Added Conditional Column" = Table.AddColumn(#"Sorted Rows", "FinalParent", each if [HighParent.ParentID] = null then [ParentID] else [HighParent.ParentID]),
#"Removed Columns" = Table.RemoveColumns(#"Added Conditional Column",{"HighParent.TeamID", "HighParent.ParentID"})
in
#"Removed Columns"
Proud to be a PBI Community Champion
@moizsherwani As far as I know, my code should work on your real dataset
could you post a dataset on which it does not work ?
Did I answer your question correctly? Mark my answer as a solution!
Proud to be a Datanaut!
@LivioLanzo sorry I should have mentioned I was referring to the problem in the solution as proposed by @PattemManohar.
@LivioLanzo I will test your solution and get back to you.
Hi @LivioLanzo so your query does not work because I believe you are checking the numbers for the smallest number whereas in fact my team names are not really numbers but as follows
Team ID - Parent ID - Higest Parent
B1 - null - B1 (because it is null)
B2 - null - B2 (because it is null)
T1 - B1 - B1
T2 - T1 - B1
T3 - B2 - B2
T4 - T3 - B2
Removing the B or the T is also not a solution as there is a B1 and a T1, we need to climb up the hierarchy
Thanks,
Moiz
you just need to change the data types then like this:
let Source = Excel.CurrentWorkbook(){[Name="Hierarchy"]}[Content], ChangedType = Table.TransformColumnTypes(Source,{{"Team ID", type text}, {"Parent ID", type text}}), ListTeamID = List.Buffer( ChangedType[Team ID] ), ListParentID = List.Buffer( ChangedType[Parent ID] ), fnGetHighestParent = (n as text) as text => let PosOfParent = List.PositionOf( ListTeamID, n ), ParID = ListParentID{PosOfParent} in if ParID = null then ListTeamID{PosOfParent} else @fnGetHighestParent(ListParentID{PosOfParent}), FinalTable = Table.AddColumn( ChangedType, "HighestParent", each fnGetHighestParent( [Team ID] ), type text) in FinalTable
Did I answer your question correctly? Mark my answer as a solution!
Proud to be a Datanaut!
Thanks to @moizsherwani and @LivioLanzo
But when we using the same for larger dataset like 32k rows it shows the below error
@LivioLanzo Get an error
Here is the link to an excel file with the teams
@LivioLanzo I managed to fix that error but get an error on the final step now saying
"Expression.Error: We cannot convert a value of type List to type Table.
Details:
Value=List
Type=Type"
@moizsherwani Are you pasting the code exactly as it is? If not, what is the complete M code?
Did I answer your question correctly? Mark my answer as a solution!
Proud to be a Datanaut!
@LivioLanzo I realized I was making a mistake with the code. The solution works perfectly. Thanks so much.
Try this (your table name is Hierarchy):
let Source = Excel.CurrentWorkbook(){[Name="Hierarchy"]}[Content], ChangedType = Table.TransformColumnTypes(Source,{{"Team ID", Int64.Type}, {"Parent ID", Int64.Type}}), ListTeamID = List.Buffer( ChangedType[Team ID] ), ListParentID = List.Buffer( ChangedType[Parent ID] ), fnGetHighestParent = (n as number) as number => let PosOfParent = List.PositionOf( ListTeamID, n ), ParID = ListParentID{PosOfParent} in if ParID = null then ListTeamID{PosOfParent} else @fnGetHighestParent(ListParentID{PosOfParent}), FinalTable = Table.AddColumn( ChangedType, "HighestParent", each if [Parent ID] = null then null else fnGetHighestParent( [Team ID] ), type number ) in FinalTable
Did I answer your question correctly? Mark my answer as a solution!
Proud to be a Datanaut!
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.
Check out the November 2024 Power BI update to learn about new features.
User | Count |
---|---|
118 | |
96 | |
87 | |
71 | |
62 |
User | Count |
---|---|
138 | |
116 | |
114 | |
99 | |
98 |