cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Highlighted
saikon Frequent Visitor
Frequent Visitor

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

Accepted Solutions
Super User III
Super User III

Re: Generate parent id from BOM level information

@saikon 

 

Your DAX formula also seems correct.

JUST REPLACE FIRSTNONBLANK with LASTNONBLANK

Try my new Power BI game Cross the River

View solution in original post

8 REPLIES 8
Super User III
Super User III

Re: Generate parent id from BOM level information

@saikon 

 

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

 

 

Try my new Power BI game Cross the River
Super User III
Super User III

Re: Generate parent id from BOM level information

@saikon 

 

Your DAX formula also seems correct.

JUST REPLACE FIRSTNONBLANK with LASTNONBLANK

Try my new Power BI game Cross the River

View solution in original post

saikon Frequent Visitor
Frequent Visitor

Re: Generate parent id from BOM level information

@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])
    )
)
Super User III
Super User III

Re: Generate parent id from BOM level information

hi @saikon 

 

I am attaching the pbix file with Power Query Custom formulas

It works with me

 

 

Try my new Power BI game Cross the River
saikon Frequent Visitor
Frequent Visitor

Re: Generate parent id from BOM level information

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.

Super User III
Super User III

Re: Generate parent id from BOM level information

@saikon 

 

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

 

 

Try my new Power BI game Cross the River
saikon Frequent Visitor
Frequent Visitor

Re: Generate parent id from BOM level information

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.

Super User III
Super User III

Re: Generate parent id from BOM level information

@saikon 

 

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

Try my new Power BI game Cross the River

Helpful resources

Announcements
Coming Soon: T-Shirt Design Contest

Coming Soon: T-Shirt Design Contest

Keep your eyes open for our upcoming T-shirt design contest!

Meet the 2020 Season 1 Power BI Super Users!

Meet the 2020 Season 1 Power BI Super Users!

It’s the start of a new Super User season! Learn all about the new Super Users and brand-new tiered recognition system.

Super User Challenge: Can You Solve These?

Super User Challenge: Can You Solve These?

We're celebrating the start of the New Super User season with our first ever Super User 'Can You Solve These?' challenge.

Power BI Desktop Update - February 2020

Power BI Desktop Update - February 2020

We are super excited for our update this month, as we are releasing two of our top community requests!

Power Platform Online Conference

Power Platform Online Conference

Join us for the first ever Power Platform Online Conference!

Top Solution Authors
Top Kudoed Authors