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.
Level1 Level2Level3Level4
PC_BMROACD_KENBM24158009
PC_BMROACD_KENBM24158010
PC_BMROACD_KENBM24158011
PC_BMROACD_KENBM24158012
PC_BMROACD_KENBM24158013
PC_BMROACD_KENBM24158014
PC_BMROACD_KENBM24158015
PC_BMROACD_KENBM24158072

<colgroup><col span="4"></colgroup><tbody>
</tbody>

And my output needs to be like this
ParentChild
PC_BMROACD_KENBM
CD_KENBM24158
24158009
24158010
24158011
24158012
24158013
24158014
24158015
24158072

<colgroup><col span="2"></colgroup><tbody>
</tbody>




Any help is appreciated. The number of rows will be dynamic but column can remain the same.

<colgroup><col><col></colgroup><tbody>
</tbody>
 

Some videos you may like

Excel Facts

Do you hate GETPIVOTDATA?
Prevent GETPIVOTDATA. Select inside a PivotTable. In the Analyze tab of the ribbon, open the dropown next to Options and turn it off

MickG

MrExcel MVP
Joined
Jan 9, 2008
Messages
14,841
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
 

subhojyoti

New Member
Joined
Nov 12, 2018
Messages
3
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.
 

subhojyoti

New Member
Joined
Nov 12, 2018
Messages
3
What if I now want to do the reverse. The source is in two column format and the output would be multiple levels.
 

MickG

MrExcel MVP
Joined
Jan 9, 2008
Messages
14,841
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
 

Forum statistics

Threads
1,089,558
Messages
5,408,952
Members
403,245
Latest member
Nanda Kishore

This Week's Hot Topics

  • help please
    SORRY NOT ANY GOOD AT EXCEL SO HELP WOULD BE MUCH APPRECIATED this formula is in a sheet called ignore...
  • two formulas needed
    Hello, I'll try my best to explain this: First formula needed in Sheet1 cell A2: If Sheet1 cell B2 = Sheet2 cell B2 then return a 1. If not then...
  • Dynamic Counts
    Good afternoon, we are tidying up some data & the data seems to be growing quicker than we are tidying it up! What we confirm (by reviewing it...
  • Help Excel formula eliminate duplicate values and keep only 2 identical rows.
    as picture below column A has a duplicate value. but the values are not the same as the rule. sometimes 4 rows, sometimes 10 rows or 7 or 9...
  • Macro Compile Error Sub or Function not defined
    Hello, I am trying to run macros from a validation list, all macros have been created and run perfectly on there own but I'm getting a compile...
  • Last row combined with Current Region VBA
    I'm generally happy finding the last row of data through something like Lastrow = Cells(Rows.Count, "D").End(xlUp) but I don't always receive data...
Top