Page 1 of 2 12 LastLast
Results 1 to 10 of 19

VBA Create Unique Parent Child Relationship

This is a discussion on VBA Create Unique Parent Child Relationship within the Excel Questions forums, part of the Question Forums category; Dear All Parent in Column A and Child in B. Sheet1 tab Parent Child 100 2 100 3 200 7 ...

  1. #1
    Biz
    Biz is offline
    Board Regular
    Join Date
    May 2009
    Location
    Perth, Australia
    Posts
    1,341

    Default VBA Create Unique Parent Child Relationship

    Dear All

    Parent in Column A and Child in B.

    Sheet1 tab
    ParentChild
    1002
    1003
    2007
    2008
    9


    What vba code do I need to use to create Parent Child Relationship?
    In our case above

    Results tab
    Parent Child
    100 2,3
    200 7,8
    No Parent 9

    Biz

  2. #2
    Board Regular
    Join Date
    Apr 2009
    Location
    Northeast PA, USA
    Posts
    11,420

    Default Re: VBA Create Unique Parent Child Relationship

    Biz,


    Sample data before the macro:


    Sheet1

     AB
    1ParentChild
    21002
    31003
    42007
    52008
    6 9
    7  


    Excel tables to the web >> Excel Jeanie HTML 4




    After the macro:


    Sheet1

     AB
    1ParentChild
    21002
    31003
    42007
    52008
    6No Parent9
    7  


    Excel tables to the web >> Excel Jeanie HTML 4




    Results

     AB
    1ParentChild
    21002,3
    32007,8
    4No Parent9
    5  


    Excel tables to the web >> Excel Jeanie HTML 4




    Please TEST this FIRST in a COPY of your workbook (always make a backup copy before trying new code, you never know what you might lose).


    1. Copy the below code, by highlighting the code and pressing the keys CTRL + C
    2. Open your workbook
    3. Press the keys ALT + F11 to open the Visual Basic Editor
    4. Press the keys ALT + I to activate the Insert menu
    5. Press M to insert a Standard Module
    6. Where the cursor is flashing, paste the code by pressing the keys CTRL + V
    7. Press the keys ALT + Q to exit the Editor, and return to Excel
    8. To run the macro from Excel, open the workbook, and press ALT + F8 to display the Run Macro Dialog. Double Click the macro's name to Run it.


    Code:
    Option Explicit
    Sub ParentChild()
    ' hiker95, 02/09/2011
    ' http://www.mrexcel.com/forum/showthread.php?t=527943
    Dim w1 As Worksheet, wR As Worksheet
    Dim LR As Long, LR2 As Long, a As Long, aa As Long, SR As Long, ER As Long, H As String
    Application.ScreenUpdating = False
    Set w1 = Worksheets("Sheet1")
    LR = w1.Cells(Rows.Count, 1).End(xlUp).Row
    LR2 = w1.Cells(Rows.Count, 2).End(xlUp).Row
    If LR2 > LR Then LR = LR2
    With w1.Range("A1:A" & LR)
      .AutoFilter Field:=1, Criteria1:="="
      .Offset(1).Resize(.Rows.Count - 1).Value = "No Parent"
      .AutoFilter
    End With
    w1.Range("A2:B" & LR).Sort Key1:=w1.Range("A2"), Order1:=xlAscending, Key2:=w1.Range("B2") _
      , Order2:=xlAscending, Header:=xlNo, OrderCustom:=1, MatchCase:=False, _
      Orientation:=xlTopToBottom, DataOption1:=xlSortNormal, DataOption2:=xlSortNormal
    If Not Evaluate("ISREF(Results!A1)") Then Worksheets.Add(After:=w1).Name = "Results"
    Set wR = Worksheets("Results")
    wR.UsedRange.Clear
    w1.Columns(1).AdvancedFilter Action:=xlFilterCopy, CopyToRange:=wR.Columns(1), Unique:=True
    wR.Range("A1:B1") = [{"Parent","Child"}]
    LR = wR.Cells(Rows.Count, 1).End(xlUp).Row
    For a = 2 To LR Step 1
      H = ""
      SR = Application.Match(wR.Cells(a, 1), w1.Columns(1), 0)
      ER = Application.Match(wR.Cells(a, 1), w1.Columns(1), 1)
      For aa = SR To ER Step 1
        H = H & w1.Cells(aa, 2) & ","
      Next aa
      If Right(H, 1) = "," Then H = Left(H, Len(H) - 1)
      wR.Cells(a, 2) = H
    Next a
    wR.UsedRange.Columns.AutoFit
    wR.Activate
    Application.ScreenUpdating = True
    End Sub

    Then run ParentChild macro.
    Last edited by hiker95; Feb 9th, 2011 at 10:10 PM.
    Have a great day,
    hiker95

    Windows 8.1, Excel 2007

  3. #3
    Board Regular
    Join Date
    Sep 2008
    Location
    Melbourne, Australia
    Posts
    945

    Default Re: VBA Create Unique Parent Child Relationship

    Hello hiker95,

    I tried that code, It didn't work for me when I changed one value. I changed one of 200s into 100 and empty cell with 200. So I had 3 entries with 100 and two with 200. When I ran your macro, it changed all of them to No PArents and showed the result with No Parents and all five children allocated to that.
    Where did I go wrong?
    Can you please help?
    Asad

  4. #4
    Board Regular
    Join Date
    Apr 2009
    Location
    Northeast PA, USA
    Posts
    11,420

    Default Re: VBA Create Unique Parent Child Relationship

    Asad,

    According to the original request from Biz, there were no blank entries in column B.



    If your requirements are different, then I suggest that you start your own new Post.

    Please attach screenshots of your workbook or a sample workbook that accurately portrays your current workbook on one sheet, and what it should look like 'After' on another sheet.

    This makes it much easier to see exactly what you want to do, as well as shows us whether there is a consistent number of rows between tables and such.

    Here are three possible ways to post small (copyable) screen shots directly in your post:

    Please post a screenshot of your sheet(s), what you have and what you expect to achieve, with Excel Jeanie HTML 4 (contains graphic instructions).
    http://www.excel-jeanie-html.de/html/hlp_schnell_en.php

    or
    http://RichardSchollar’s beta HTML M...om of his post

    or
    Borders-Copy-Paste


    If you are not able to give us screenshots:

    To get the most precise answer, it is best to upload/attach a sample workbook (sensitive data scrubbed/removed) that contains an example of your raw data on one worksheet, and on another worksheet your desired results.

    The structure and data types of the sample workbook must exactly duplicate the real workbook. Include a clear and explicit explanation of your requirements.

    You can upload your workbook to www.box.net and provide us with a link to your workbook.
    Last edited by hiker95; Feb 9th, 2011 at 11:01 PM.
    Have a great day,
    hiker95

    Windows 8.1, Excel 2007

  5. #5
    Biz
    Biz is offline
    Board Regular
    Join Date
    May 2009
    Location
    Perth, Australia
    Posts
    1,341

    Default Re: VBA Create Unique Parent Child Relationship

    Hi Hiker,

    If I change values and re-run I get Errors.
    Only problem with my vb can't handle no Parent

    Code:
    Sub MakeParentChild()
    Dim LR As Long
    Dim aStartTime
    aStartTime = Now()
    LR = Range("A" & Rows.Count).End(xlUp).Row
     'Speeding Up VBA Code
        Application.ScreenUpdating = False 'Prevent screen flickering
        'Application.Calculation = False 'Preventing calculation
        Application.DisplayAlerts = False 'Turn OFF alerts
        Application.EnableEvents = False 'Prevent All Events
        Application.DisplayStatusBar = False
    'Advanced Filter copy Unique Values
    Columns("A:A").AdvancedFilter Action:=xlFilterCopy, CopyToRange:=Range("E1" _
            ), Unique:=True
    'Function MultipleVlookup
    Range("F2:F" & LR + 1).Formula = "=IF(RC5="""","""",IF(ISNA(MultiLOOKUP(RC[-1],R1C1:R65000C1,2)),"""",MultiLOOKUP(RC[-1],R1C1:R65000C1,2)))"
    
    'Speeding Up VBA Code
        Application.ScreenUpdating = True 'Prevent screen flickering
        Application.Calculation = True 'Preventing calculation
        Application.DisplayAlerts = True 'Turn OFF alerts
        Application.EnableEvents = True 'Prevent All Events
        'Application.DisplayStatusBar = True
    
            
    MsgBox "Time taken: " & Format(Now() - aStartTime, "h:mm:ss"), vbInformation, "Process Time"
            
            
            
            
    End Sub
     
    Public Function MultiLOOKUP(lookup_value As Variant, table_array As Range, _
        col_index_num As Long) As Variant
     
        Application.Volatile (False)
        Dim Cell As Range
        Dim a, B
        a = ""
        MultiLOOKUP = CVErr(xlErrNA)
     
        Set table_array = Intersect(table_array, table_array.Parent.UsedRange)
        If table_array Is Nothing Then Exit Function
     
        For Each Cell In Union(table_array.Columns(1), table_array.Cells(1))
            If Cell = lookup_value Then
                If a <> "" Then
                    a = a & ", " & Cell.Offset(0, col_index_num - 1)
                    GoTo 10
                End If
     
                a = Cell.Offset(0, col_index_num - 1)
            End If
     
    10         Next Cell
            If a = "" Then MultiLOOKUP = ""
            MultiLOOKUP = a
     
        End Function
    Biz

  6. #6
    Biz
    Biz is offline
    Board Regular
    Join Date
    May 2009
    Location
    Perth, Australia
    Posts
    1,341

    Default Re: VBA Create Unique Parent Child Relationship

    Hi Hiker

    First Try
    Sheet 1 tab
    ParentChild
    1002
    1003
    2007
    2008
    No Parent9


    Second Try
    Sheet 1 tab
    ParentChild
    1002
    1003
    2007
    3008
    No Parent9


    thats when it crashes
    Sheet 1

    ParentChild
    No Parent2
    No Parent3
    No Parent7
    No Parent8
    No Parent9


    Results
    ParentChild
    No Parent2,3,7,8,9


    I think need to add code that deletes No Parent on Error No Parrent

    Not sure how to do that.

    Biz

  7. #7
    Board Regular
    Join Date
    Apr 2009
    Location
    Northeast PA, USA
    Posts
    11,420

    Default Re: VBA Create Unique Parent Child Relationship

    Biz,

    If my screenshots do not match your Sheet1 setup, and output on worksheet Results:


    Please attach screenshots of your workbook or a sample workbook that accurately portrays your current workbook on one sheet, and what it should look like 'After' on another sheet.

    This makes it much easier to see exactly what you want to do, as well as shows us whether there is a consistent number of rows between tables and such.

    Here are three possible ways to post small (copyable) screen shots directly in your post:

    Please post a screenshot of your sheet(s), what you have and what you expect to achieve, with Excel Jeanie HTML 4 (contains graphic instructions).
    http://www.excel-jeanie-html.de/html/hlp_schnell_en.php

    or
    http://RichardSchollarís beta HTML M...om of his post

    or
    Borders-Copy-Paste



    If you are not able to give us screenshots:

    To get the most precise answer, it is best to upload/attach a sample workbook (sensitive data scrubbed/removed) that contains an example of your raw data on one worksheet, and on another worksheet your desired results.

    The structure and data types of the sample workbook must exactly duplicate the real workbook. Include a clear and explicit explanation of your requirements.

    You can upload your workbook to www.box.net and provide us with a link to your workbook.
    Have a great day,
    hiker95

    Windows 8.1, Excel 2007

  8. #8
    Biz
    Biz is offline
    Board Regular
    Join Date
    May 2009
    Location
    Perth, Australia
    Posts
    1,341

    Default Re: VBA Create Unique Parent Child Relationship

    Hi Hiker,

    Run your macro as it is.


    Then go back to Sheet 1 and change cell A5 to 300 and re-run macro that's when it fails.

    Can you please help me to fix this?

    Please refer to file below.


    http://www.box.net/shared/lqhp2igzgu

    Biz

  9. #9
    Board Regular
    Join Date
    Apr 2009
    Location
    Northeast PA, USA
    Posts
    11,420

    Default Re: VBA Create Unique Parent Child Relationship

    Biz,

    Thanks for the workbook.


    In your workbook you have in column F, several Functions MultiLOOKUP.


    When my macro code gets to this line of code:

    Code:
      .AutoFilter Field:=1, Criteria1:="="

    Somehow, code execution jumps to your:

    Code:
    Public Function MultiLOOKUP(lookup_value As Variant, table_array As Range, _
        col_index_num As Long) As Variant


    If I remove Function MultiLOOKUP, and Sub MakeParentChild(), and I have made a slight change to my macro (see below), my code does what you want.


    Please TEST this FIRST in a COPY of your workbook (always make a backup copy before trying new code, you never know what you might lose).


    Code:
    Option Explicit
    Sub ParentChildV2()
    ' hiker95, 02/09/2011
    ' http://www.mrexcel.com/forum/showthread.php?t=527943
    Dim w1 As Worksheet, wR As Worksheet
    Dim LR As Long, LR2 As Long, a As Long, aa As Long, SR As Long, ER As Long, H As String
    Application.ScreenUpdating = False
    Set w1 = Worksheets("Sheet1")
    LR = w1.Cells(Rows.Count, 1).End(xlUp).Row
    LR2 = w1.Cells(Rows.Count, 2).End(xlUp).Row
    If LR2 > LR Then LR = LR2
    With w1.Range("A1:A" & LR)
      .AutoFilter Field:=1, Criteria1:="="
    
      On Error Resume Next
      .Offset(1).Resize(.Rows.Count - 1).SpecialCells(12).Value = "No Parent"
      On Error GoTo 0
    
      .AutoFilter
    End With
    w1.Range("A2:B" & LR).Sort Key1:=w1.Range("A2"), Order1:=xlAscending, Key2:=w1.Range("B2") _
      , Order2:=xlAscending, Header:=xlNo, OrderCustom:=1, MatchCase:=False, _
      Orientation:=xlTopToBottom, DataOption1:=xlSortNormal, DataOption2:=xlSortNormal
    If Not Evaluate("ISREF(Results!A1)") Then Worksheets.Add(After:=w1).Name = "Results"
    Set wR = Worksheets("Results")
    wR.UsedRange.Clear
    w1.Columns(1).AdvancedFilter Action:=xlFilterCopy, CopyToRange:=wR.Columns(1), Unique:=True
    wR.Range("A1:B1") = [{"Parent","Child"}]
    LR = wR.Cells(Rows.Count, 1).End(xlUp).Row
    For a = 2 To LR Step 1
      H = ""
      SR = Application.Match(wR.Cells(a, 1), w1.Columns(1), 0)
      ER = Application.Match(wR.Cells(a, 1), w1.Columns(1), 1)
      For aa = SR To ER Step 1
        H = H & w1.Cells(aa, 2) & ","
      Next aa
      If Right(H, 1) = "," Then H = Left(H, Len(H) - 1)
      wR.Cells(a, 2) = H
    Next a
    wR.UsedRange.Columns.AutoFit
    wR.Activate
    Application.ScreenUpdating = True
    End Sub

    Then run the ParentChildV2 macro.
    Have a great day,
    hiker95

    Windows 8.1, Excel 2007

  10. #10
    Board Regular
    Join Date
    Apr 2009
    Location
    Northeast PA, USA
    Posts
    11,420

    Default Re: VBA Create Unique Parent Child Relationship

    Biz,


    Before and after test results with the above updated macro:


    Sheet1

     NOPQR
    1Sheet1  Results 
    2AB AB
    3ParentChild ParentChild
    41002 1002,3
    51003 2007,8
    61007 No Parent9
    72008   
    8 9   
    9     
    10     
    11ParentChild ParentChild
    121002 1002,3
    131003 2007,8
    142007 No Parent9
    152008   
    16No Parent9   
    17     
    18     
    19ParentChild ParentChild
    201002 1002,3
    211003 2007
    222007 3008
    233008 No Parent9
    24No Parent9   
    25     


    Excel tables to the web >> Excel Jeanie HTML 4
    Have a great day,
    hiker95

    Windows 8.1, Excel 2007

Page 1 of 2 12 LastLast

Like this thread? Share it with others

Like this thread? Share it with others

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •  


DMCA.com