Create Parent Child relationship in Excel

subhojyoti

New Member
Joined
Nov 12, 2018
Messages
3
Hi,
I'm new to Excel Scripting.
I need help to create below parent child relationship in excel. I have the source file in below format.
[TABLE="width: 480"]
<colgroup><col span="4"></colgroup><tbody>[TR]
[TD]Level1 [/TD]
[TD]Level2[/TD]
[TD]Level3[/TD]
[TD]Level4[/TD]
[/TR]
[TR]
[TD]PC_BMROA[/TD]
[TD]CD_KENBM[/TD]
[TD]24158[/TD]
[TD]009[/TD]
[/TR]
[TR]
[TD]PC_BMROA[/TD]
[TD]CD_KENBM[/TD]
[TD]24158[/TD]
[TD]010[/TD]
[/TR]
[TR]
[TD]PC_BMROA[/TD]
[TD]CD_KENBM[/TD]
[TD]24158[/TD]
[TD]011[/TD]
[/TR]
[TR]
[TD]PC_BMROA[/TD]
[TD]CD_KENBM[/TD]
[TD]24158[/TD]
[TD]012[/TD]
[/TR]
[TR]
[TD]PC_BMROA[/TD]
[TD]CD_KENBM[/TD]
[TD]24158[/TD]
[TD]013[/TD]
[/TR]
[TR]
[TD]PC_BMROA[/TD]
[TD]CD_KENBM[/TD]
[TD]24158[/TD]
[TD]014[/TD]
[/TR]
[TR]
[TD]PC_BMROA[/TD]
[TD]CD_KENBM[/TD]
[TD]24158[/TD]
[TD]015[/TD]
[/TR]
[TR]
[TD]PC_BMROA[/TD]
[TD]CD_KENBM[/TD]
[TD]24158[/TD]
[TD]072[/TD]
[/TR]
</tbody>[/TABLE]

And my output needs to be like this
[TABLE="width: 240"]
<colgroup><col span="2"></colgroup><tbody>[TR]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]Parent[/TD]
[TD]Child[/TD]
[/TR]
[TR]
[TD]PC_BMROA[/TD]
[TD]CD_KENBM[/TD]
[/TR]
[TR]
[TD]CD_KENBM[/TD]
[TD]24158[/TD]
[/TR]
[TR]
[TD]24158[/TD]
[TD]009[/TD]
[/TR]
[TR]
[TD]24158[/TD]
[TD]010[/TD]
[/TR]
[TR]
[TD]24158[/TD]
[TD]011[/TD]
[/TR]
[TR]
[TD]24158[/TD]
[TD]012[/TD]
[/TR]
[TR]
[TD]24158[/TD]
[TD]013[/TD]
[/TR]
[TR]
[TD]24158[/TD]
[TD]014[/TD]
[/TR]
[TR]
[TD]24158[/TD]
[TD]015[/TD]
[/TR]
[TR]
[TD]24158[/TD]
[TD]072[/TD]
[/TR]
</tbody>[/TABLE]
[TABLE="width: 179"]
<colgroup><col><col></colgroup><tbody>[TR]
[TD][/TD]
[TD]



Any help is appreciated. The number of rows will be dynamic but column can remain the same.[/TD]
[/TR]
</tbody>[/TABLE]
 

Excel Facts

How to create a cell-sized chart?
Tiny charts, called Sparklines, were added to Excel 2010. Look for Sparklines on the Insert tab.
Try this for results in columns "F & G".
Code:
[COLOR="Navy"]Sub[/COLOR] MG12Nov56
[COLOR="Navy"]Dim[/COLOR] Rng [COLOR="Navy"]As[/COLOR] Range, Dn [COLOR="Navy"]As[/COLOR] Range, n [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Long,[/COLOR] Ray [COLOR="Navy"]As[/COLOR] Variant, ac [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Long[/COLOR]
[COLOR="Navy"]Dim[/COLOR] Dic [COLOR="Navy"]As[/COLOR] Object, K [COLOR="Navy"]As[/COLOR] Variant, P [COLOR="Navy"]As[/COLOR] Variant
[COLOR="Navy"]Dim[/COLOR] c [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Long[/COLOR]

Ray = Range("A1").CurrentRegion
[COLOR="Navy"]Set[/COLOR] Dic = CreateObject("scripting.dictionary")
Dic.CompareMode = vbTextCompare


[COLOR="Navy"]For[/COLOR] ac = 1 To UBound(Ray, 2) - 1
    [COLOR="Navy"]For[/COLOR] n = 2 To UBound(Ray, 1)
        [COLOR="Navy"]If[/COLOR] Not Dic.exists(Ray(n, ac)) [COLOR="Navy"]Then[/COLOR]
                [COLOR="Navy"]Set[/COLOR] Dic(Ray(n, ac)) = CreateObject("Scripting.Dictionary")
          [COLOR="Navy"]End[/COLOR] If
        [COLOR="Navy"]If[/COLOR] Not Dic(Ray(n, ac)).exists(Ray(n, ac + 1)) [COLOR="Navy"]Then[/COLOR]
                Dic(Ray(n, ac)).Add (Ray(n, ac + 1)), Nothing
        [COLOR="Navy"]End[/COLOR] If
    [COLOR="Navy"]Next[/COLOR] n
[COLOR="Navy"]Next[/COLOR] ac
   
c = 1
Cells(c, "F") = "Parent"
Cells(c, "G") = "Child"

[COLOR="Navy"]For[/COLOR] [COLOR="Navy"]Each[/COLOR] K [COLOR="Navy"]In[/COLOR] Dic.Keys
    [COLOR="Navy"]For[/COLOR] [COLOR="Navy"]Each[/COLOR] P [COLOR="Navy"]In[/COLOR] Dic(K)
        c = c + 1
        Cells(c, "F") = K
        Cells(c, "G") = P
    [COLOR="Navy"]Next[/COLOR] P
[COLOR="Navy"]Next[/COLOR] K
[COLOR="Navy"]End[/COLOR] [COLOR="Navy"]Sub[/COLOR]
Regards Mick
 
Upvote 0
Thannks the code worked.
Now what if my columns are also varying. How to tackle that?
If you could please let me know that one.
 
Upvote 0
What if I now want to do the reverse. The source is in two column format and the output would be multiple levels.
 
Upvote 0
The original code should cover Multi columns of data.

Reversing your data is possible as below, but depending on its complexity there could be problems
Your data for reversing in "A & B" reversed results for previous data in columns "G to J".

Code:
[COLOR="Navy"]Sub[/COLOR] MG13Nov11
'[COLOR="Green"][B]Reverse[/B][/COLOR]
[COLOR="Navy"]Dim[/COLOR] Rng         [COLOR="Navy"]As[/COLOR] Range
[COLOR="Navy"]Dim[/COLOR] Dn          [COLOR="Navy"]As[/COLOR] Range
[COLOR="Navy"]Dim[/COLOR] c           [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Long[/COLOR]
[COLOR="Navy"]Dim[/COLOR] Dic         [COLOR="Navy"]As[/COLOR] Object
[COLOR="Navy"]Dim[/COLOR] R           [COLOR="Navy"]As[/COLOR] Range
[COLOR="Navy"]Dim[/COLOR] ac          [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Long[/COLOR]
[COLOR="Navy"]Dim[/COLOR] K           [COLOR="Navy"]As[/COLOR] Variant
[COLOR="Navy"]Dim[/COLOR] Txt         [COLOR="Navy"]As[/COLOR] Variant


[COLOR="Navy"]Set[/COLOR] Rng = Range(Range("B2"), Range("B" & Rows.Count).End(xlUp))
[COLOR="Navy"]Set[/COLOR] Dic = CreateObject("scripting.dictionary")
Dic.CompareMode = vbTextCompare

[COLOR="Navy"]For[/COLOR] [COLOR="Navy"]Each[/COLOR] Dn [COLOR="Navy"]In[/COLOR] Rng
   [COLOR="Navy"]If[/COLOR] Dn.Offset(, -1) <> "" [COLOR="Navy"]Then[/COLOR]
   [COLOR="Navy"]If[/COLOR] Not Dic.exists(Dn.Value) [COLOR="Navy"]Then[/COLOR]
         Dic.Add (Dn.Value), Dn.Offset(, -1)
    [COLOR="Navy"]Else[/COLOR]
        [COLOR="Navy"]Set[/COLOR] Dic(Dn.Value) = Union(Dic(Dn.Value), Dn.Offset(, -1))
    [COLOR="Navy"]End[/COLOR] If
[COLOR="Navy"]End[/COLOR] If
[COLOR="Navy"]Next[/COLOR] Dn


[COLOR="Navy"]Dim[/COLOR] n
c = 1
[COLOR="Navy"]For[/COLOR] n = Dic.Count To 1 [COLOR="Navy"]Step[/COLOR] -1
   ac = 10: c = c + 1
    Txt = Rng(n)
    [COLOR="Navy"]If[/COLOR] Application.CountIf(Rng.Offset(, -1), Txt) = 0 [COLOR="Navy"]Then[/COLOR]
    Cells(c, ac) = Txt
    Cells(1, ac) = "Level " & ac - 5
        [COLOR="Navy"]Do[/COLOR] [COLOR="Navy"]While[/COLOR] Dic.exists(Txt)
            ac = ac - 1
            Txt = Dic(Txt)
           Cells(1, ac) = "Level " & ac - 5
           Cells(c, ac) = Txt
        [COLOR="Navy"]Loop[/COLOR]
    [COLOR="Navy"]End[/COLOR] If
 [COLOR="Navy"]Next[/COLOR] n
[COLOR="Navy"]End[/COLOR] [COLOR="Navy"]Sub[/COLOR]
Regards Mick
 
Upvote 0

Forum statistics

Threads
1,223,909
Messages
6,175,310
Members
452,634
Latest member
cpostell

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top