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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
Anonymous
Not applicable

Generate parent id from BOM level information

I am trying to figure out a DAX formula (or Power Query) to determine each rows parent if it exists.

 

I have data which contains the index, level and component information. Parent column is the one I would like to generate. Below is an example of what is wanted to generate a parent-child relationship (like here https://www.daxpatterns.com/parent-child-hierarchies/)

 

 

Index    Level    Component    Parent
1        1        A            -
2        2        B            1
3        3        C            2
4        3        D            2
5        2        E            1
6        3        F            5
7        1        G            -
8        2        H            7

 

I have accomplished this recursively with VBA to group my rows in Excel according to the BOM grouping of sub-components of each assembly. I cannot figure out how to do a similar thing with DAX since it seems recursive formulas are not possible.

 

There was also some example in this forum about finding earlier matching values but it does not work out of the box with my case. The below code only finds the first matching value the filter of Level - 1. It does not work with the data above for row with index 8 for example. It generates a parent id of 1 for row 8 when it should be 7.

 

Parent = 
CALCULATE(
    FIRSTNONBLANK(VALUES(BOM[Index]);0);
    FILTER(
        ALL(BOM);
        BOM[Level] = EARLIER(BOM[Level]) - 1 &&
        BOM[Index] < EARLIER(BOM[Index])
    )
)

 

 

 

 

 

1 ACCEPTED SOLUTION
Zubair_Muhammad
Community Champion
Community Champion

@Anonymous 

 

Your DAX formula also seems correct.

JUST REPLACE FIRSTNONBLANK with LASTNONBLANK


Regards
Zubair

Please try my custom visuals

View solution in original post

9 REPLIES 9
Zubair_Muhammad
Community Champion
Community Champion

@Anonymous 

 

Your DAX formula also seems correct.

JUST REPLACE FIRSTNONBLANK with LASTNONBLANK


Regards
Zubair

Please try my custom visuals
Anonymous
Not applicable

@Zubair_Muhammad Thank you, that DAX suggestion works, but I could not get the Power Query one to work. It only generates null values.

 

Now I have two working solutions to this:

Parent = 
MAXX(
    TOPN(
        1;
        FILTER(
            'BOM';
            'BOM'[Level] = EARLIER('BOM'[Level]) - 1 &&
            'BOM'[Index] < EARLIER('BOM'[Index])
        );
        'BOM'[Index]; DESC
        );
    'BOM'[Index]
)

and

Parent = 
CALCULATE(
    LASTNONBLANK(VALUES(BOM[Index]);0);
    FILTER(
        ALL(BOM);
        BOM[Level] = EARLIER(BOM[Level]) - 1 &&
        BOM[Index] < EARLIER(BOM[Index])
    )
)

hi @Anonymous 

 

I am attaching the pbix file with Power Query Custom formulas

It works with me

 

 


Regards
Zubair

Please try my custom visuals
Anonymous
Not applicable

Thanks, figured it out. You cannot just copy and paste those Power Query formulas because they have some reference to each step done with the data before.

 

Any ideas on how to generate the PATH directly in Power Query? Or how to generate the Level 1, Level 2, Level ..., Level n automatically? Since I do not know how many levels the data might include.

@Anonymous 

 

In Power Query, we can use List.Generate to replicate the PATH function.

 

If you can copy paste some data with expected results, I will try to write it for you

 

 


Regards
Zubair

Please try my custom visuals
Anonymous
Not applicable

The expected result using DAX with the example you sent is just a new column with:

Column = PATH(BOM[Index]; BOM[Custom])

Untitled.png

 

If this can be done with Power Query, then I can split the column to all the levels required without creating the columns manually and worrying if the level depth changes.

@Anonymous 

 

You can use this custom column

 

I am attaching sample file with this formula

 

=let mylist=
        {[Index]} & (let myparent=[Custom] in
        List.Generate(()=>[x=0,y=myparent,w=1],each [w] > 0, each [z=
        [y], x=Table.SelectRows(#"Changed Type1",each  [Index]=z)[Custom],
        y=x{0},
        w=List.Count(x)],each [y]))
        in
        Text.Combine(List.Reverse(List.RemoveItems(List.Transform(mylist,each Number.ToText(_)),{null,""})),"|")

Pathee.png


Regards
Zubair

Please try my custom visuals
Zubair_Muhammad
Community Champion
Community Champion

@Anonymous 

 

As a Power Query Custom Column, try this

 

=try
let myindex=[Index],
mylevel=[Level]
in
Table.Max(Table.SelectRows(#"Changed Type",each  [Index]< myindex and [Level]=mylevel-1),"Index")[Index]
otherwise
null

 

 


Regards
Zubair

Please try my custom visuals

Great input, thank you!  How can I use this approach on a dataset which only has parent and child keys but no level column?

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

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