Consulting

Results 1 to 3 of 3

Thread: Break single row into multiple rows based on FORMAT

  1. #1
    VBAX Newbie
    Joined
    Apr 2017
    Posts
    2
    Location

    Question Break single column into multiple columns based on FORMATTING

    Dear all,
    I'm quite new to VBA but really need a way to sort this out. Made a lot of googling but never found something to get through.
    I have an excel sheet with a lot of information listed under the same column, where the entry title (the name of the person - NAME SURNAME) has a specific formatting, say Courier Bold 40.

    The sheet is as follows (not all entries have all Subtitles):

    A |
    NAME SURNAME |
    Subtitle 1 |
    Subtitle 2 |
    Subtitle 3 |
    (Subtitle 4) |
    |
    NAME SURNAME |
    Subtitle 1 |
    Subtitle 2 |
    Subtitle 3 |
    (Subtitle 4)
    ....


    What I am looking for is to create a spreadsheet where every A column contains NAME SURNAME, while all other information (subtitles) get reordered in the respective B, C, D, E, .... columns. Any idea?

    A | | C | D | ....
    NAME SURNAME | Subtitle 1 | Subtitle 2 | Subtitle 3 | ...


    This is really a puzzle for me!

    Thanks a lot!!
    Attached Files Attached Files
    Last edited by Jacopo; 04-11-2017 at 05:17 AM. Reason: Corrected title and added attachment.

  2. #2
    Knowledge Base Approver VBAX Wizard p45cal's Avatar
    Joined
    Oct 2005
    Location
    Surrey UK
    Posts
    5,876
    Try either of these, the second might run a bit faster. They work on whichever sheet is the active sheet.
    Sub blah()
    Sheets("Sheet1").Copy After:=Sheets(Sheets.Count)
    LastRw = Cells(Rows.Count, 1).End(xlUp).Row
    Set FirstCell = Range("A1")
    If Len(Trim(FirstCell.Value)) = 0 Then Set FirstCell = FirstCell.End(xlDown)
    If FirstCell.Row >= LastRw Then Exit Sub  'nothing (or just 1 cell with something) in column A.
    rw = LastRw
    Do Until rw <= FirstCell.Row
      myCount = 1
      Do Until Cells(rw, 1).Font.Name = "Courier" And Cells(rw, 1).Font.Size = 40 And Cells(rw, 1).Font.Bold = True
        With Cells(rw, 1).Resize(, myCount)
          '.Select
          .Copy Cells(rw - 1, 2)
          .ClearContents
        End With
        myCount = myCount + 1
        rw = rw - 1
      Loop
      rw = rw - 1
    Loop
    'optional line below to close up remaining spaces if you haven't anything you want to preserve elswhere on those rows:
    Range(FirstCell, Cells(LastRw, 1)).SpecialCells(xlCellTypeBlanks).EntireRow.Delete
    End Sub
    Sub blah2()
    'Sheets("Sheet1").Copy After:=Sheets(Sheets.Count)
    LastRw = Cells(Rows.Count, 1).End(xlUp).Row
    Set FirstCell = Range("A1")
    If Len(Trim(FirstCell.Value)) = 0 Then Set FirstCell = FirstCell.End(xlDown)
    If FirstCell.Row >= LastRw Then Exit Sub  'nothing (or just 1 cell with something) in column A.
    
    Count = 0: StartBlock = LastRw
    For rw = LastRw To FirstCell.Row Step -1
      With Cells(rw, 1)
        If .Font.Name = "Courier" And .Font.Size = 40 And Cells(rw, 1).Font.Bold Then
          If Count > 0 Then
            Set bbb = Cells(StartBlock - Count + 1, 1).Resize(Count)
            'bbb.Select
            bbb.Copy
            .Offset(, 1).PasteSpecial Transpose:=True
            bbb.EntireRow.Delete
            'bbb.ClearContents 'an alternative to the line above.
          End If
          StartBlock = rw - 1: Count = 0
        Else
          Count = Count + 1
        End If
      End With
    Next rw
    End Sub
    p45cal
    Everyone: If I've helped and you can't be bothered to acknowledge it, I can't be bothered to look at further posts from you.

  3. #3
    VBAX Newbie
    Joined
    Apr 2017
    Posts
    2
    Location
    In 1 word: AWESOME!
    It worked like a charm. I tried the second one and it did what it had to, smoothly and quickly.
    Thanks a lot for your support!!

    Quote Originally Posted by p45cal View Post
    Try either of these, the second might run a bit faster. They work on whichever sheet is the active sheet.
    Sub blah()
    Sheets("Sheet1").Copy After:=Sheets(Sheets.Count)
    LastRw = Cells(Rows.Count, 1).End(xlUp).Row
    Set FirstCell = Range("A1")
    If Len(Trim(FirstCell.Value)) = 0 Then Set FirstCell = FirstCell.End(xlDown)
    If FirstCell.Row >= LastRw Then Exit Sub  'nothing (or just 1 cell with something) in column A.
    rw = LastRw
    Do Until rw <= FirstCell.Row
      myCount = 1
      Do Until Cells(rw, 1).Font.Name = "Courier" And Cells(rw, 1).Font.Size = 40 And Cells(rw, 1).Font.Bold = True
        With Cells(rw, 1).Resize(, myCount)
          '.Select
          .Copy Cells(rw - 1, 2)
          .ClearContents
        End With
        myCount = myCount + 1
        rw = rw - 1
      Loop
      rw = rw - 1
    Loop
    'optional line below to close up remaining spaces if you haven't anything you want to preserve elswhere on those rows:
    Range(FirstCell, Cells(LastRw, 1)).SpecialCells(xlCellTypeBlanks).EntireRow.Delete
    End Sub
    Sub blah2()
    'Sheets("Sheet1").Copy After:=Sheets(Sheets.Count)
    LastRw = Cells(Rows.Count, 1).End(xlUp).Row
    Set FirstCell = Range("A1")
    If Len(Trim(FirstCell.Value)) = 0 Then Set FirstCell = FirstCell.End(xlDown)
    If FirstCell.Row >= LastRw Then Exit Sub  'nothing (or just 1 cell with something) in column A.
    
    Count = 0: StartBlock = LastRw
    For rw = LastRw To FirstCell.Row Step -1
      With Cells(rw, 1)
        If .Font.Name = "Courier" And .Font.Size = 40 And Cells(rw, 1).Font.Bold Then
          If Count > 0 Then
            Set bbb = Cells(StartBlock - Count + 1, 1).Resize(Count)
            'bbb.Select
            bbb.Copy
            .Offset(, 1).PasteSpecial Transpose:=True
            bbb.EntireRow.Delete
            'bbb.ClearContents 'an alternative to the line above.
          End If
          StartBlock = rw - 1: Count = 0
        Else
          Count = Count + 1
        End If
      End With
    Next rw
    End Sub

Tags for this Thread

Posting Permissions

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