+ Reply to Thread
Results 1 to 2 of 2

Split into Multiple sheets based on beginning string in a set column - Code help

Hybrid View

  1. #1
    Registered User
    Join Date
    12-10-2005
    Posts
    8

    Split into Multiple sheets based on beginning string in a set column - Code help

    Hello,

    I have used this code below to split a large excel file into multiple sheets from matching column data, but now I need to split it by a partial match (set number of characters from the beginning) from beginning of the column data.

    For Example:

    Date  Name  Description
    1/1    Jack    Safe-22
    1/1    Jan     Safe-21
    1/2    Jake    Fail-4
    1/2    Jen     Fail-3
    1/3    Jen     Dont-1
    1/3    Matt    Poop-7
    1/4    Mike    Fail33
    1/5    Sean    Safe-9
    1/6    Pete    Pooper
    1/8    Anne    21-43
    So with the code provided below using column 3 I would get 10 different sheets since none of the data in the column is identical. I want to modify the code (or come up with new code) so I can set the number of characters to compare from the beginning of the data in the set column and split into sheets based on that. So if I set it to the first 4 characters in column 3 I would receive only 5 sheets sheets: Safe, Fail, Dont, Poop, & 21-4.

    Would anyone kindly assist me with the modifications or new code needed for this? I have searched for a bit with no luck, just keep finding code to check the full cell data for matches in a set column like this code I have:



    SPLIT DATA FROM ONE SHEET TO MULTIPLE SHEETS
    Sub parse_data()
    
    Dim lr As Long
    Dim ws As Worksheet
    Dim vcol, i As Integer
    Dim icol As Long
    Dim myarr As Variant
    Dim title As String
    Dim titlerow As Integer
    
    vcol = 2        'CHANGE THE COLUMN NUMBER AS PER YOUR NEED
    
    Set ws = Sheets("Data")        'CHANGE THE SHEET NAME AS PER YOUR NEED
    
    lr = ws.Cells(ws.Rows.Count, vcol).End(xlUp).Row
    
    title = "A1:Z1"             'CHANGE THE TITLE ROW AS PER YOUR NEED
    titlerow = ws.Range(title).Cells(1).Row
    icol = ws.Columns.Count
    
    ws.Cells(1, icol) = "Unique"
    
    For i = 2 To lr
    On Error Resume Next
    If ws.Cells(i, vcol) <> "" And Application.WorksheetFunction.Match(ws.Cells(i, vcol), ws.Columns(icol), 0) = 0 Then
    ws.Cells(ws.Rows.Count, icol).End(xlUp).Offset(1) = ws.Cells(i, vcol)
    End If
    Next
    
    myarr = Application.WorksheetFunction.Transpose(ws.Columns(icol).SpecialCells(xlCellTypeConstants))
    
    ws.Columns(icol).Clear
    
    For i = 2 To UBound(myarr)
    ws.Range(title).AutoFilter field:=vcol, Criteria1:=myarr(i) & ""
    
    If Not Evaluate("=ISREF('" & myarr(i) & "'!A1)") Then
    Sheets.Add(after:=Worksheets(Worksheets.Count)).Name = myarr(i) & ""
    Else
    Sheets(myarr(i) & "").Move after:=Worksheets(Worksheets.Count)
    End If
    
    ws.Range("A" & titlerow & ":A" & lr).EntireRow.Copy Sheets(myarr(i) & "").Range("A1")
    Sheets(myarr(i) & "").Columns.AutoFit
    Next
    
    ws.AutoFilterMode = False
    ws.Activate
    
    End Sub

  2. #2
    Forum Expert mrice's Avatar
    Join Date
    06-22-2004
    Location
    Surrey, England
    MS-Off Ver
    Excel 2013
    Posts
    4,967

    Re: Split into Multiple sheets based on beginning string in a set column - Code help

    Try this

    Sub parse_data()
    
    Dim lr As Long
    Dim ws As Worksheet
    Dim vcol, i As Integer
    Dim icol As Long
    Dim myarr As Variant
    Dim title As String
    Dim titlerow As Integer
    Dim charcount As Integer
    
    vcol = 3        'CHANGE THE COLUMN NUMBER AS PER YOUR NEED
    charcount = 4
    
    Set ws = Sheets("Data")        'CHANGE THE SHEET NAME AS PER YOUR NEED
    
    lr = ws.Cells(ws.Rows.Count, vcol).End(xlUp).Row
    
    title = "A1:Z1"             'CHANGE THE TITLE ROW AS PER YOUR NEED
    titlerow = ws.Range(title).Cells(1).Row
    icol = ws.Columns.Count
    
    ws.Cells(1, icol) = "Unique"
    
    For i = 2 To lr
    On Error Resume Next
    If ws.Cells(i, vcol) <> "" And Application.WorksheetFunction.Match(Left(ws.Cells(i, vcol), charcount), ws.Columns(icol), 0) = 0 Then
    ws.Cells(ws.Rows.Count, icol).End(xlUp).Offset(1) = Left(ws.Cells(i, vcol), charcount)
    End If
    Next
    
    myarr = Application.WorksheetFunction.Transpose(ws.Columns(icol).SpecialCells(xlCellTypeConstants))
    
    ws.Columns(icol).Clear
    
    For i = 2 To UBound(myarr)
    ws.Range(title).AutoFilter field:=vcol, Criteria1:=myarr(i) & "*"
    
    If Not Evaluate("=ISREF('" & myarr(i) & "'!A1)") Then
    Sheets.Add(after:=Worksheets(Worksheets.Count)).Name = myarr(i) & ""
    Else
    Sheets(myarr(i) & "").Move after:=Worksheets(Worksheets.Count)
    End If
    
    ws.Range("A" & titlerow & ":A" & lr).EntireRow.Copy Sheets(myarr(i) & "").Range("A1")
    Sheets(myarr(i) & "").Columns.AutoFit
    Next
    
    ws.AutoFilterMode = False
    ws.Activate
    
    End Sub
    Martin

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Similar Threads

  1. Split row into multiple row based on column text
    By chicagoland8 in forum Excel Programming / VBA / Macros
    Replies: 8
    Last Post: 03-10-2014, 04:20 PM
  2. [SOLVED] How to split this long string code in multiple line to avoid an error???
    By tuongtu3 in forum Excel Programming / VBA / Macros
    Replies: 2
    Last Post: 11-24-2013, 10:08 PM
  3. Replies: 0
    Last Post: 02-06-2013, 09:10 PM
  4. Split String From A Cell Based On Multiple Criteria
    By ssanjju in forum Excel Formulas & Functions
    Replies: 3
    Last Post: 01-05-2013, 03:21 PM
  5. Can excels Split() function split a string up at multiple spots?
    By 111StepsAhead in forum Excel Programming / VBA / Macros
    Replies: 2
    Last Post: 12-14-2011, 02:36 PM

Bookmarks

Posting Permissions

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

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1