Splitting data into multiple sheets

22strider

Active Member
Joined
Jun 11, 2007
Messages
311
Hello Friends

Could you please help me writing code in VBA for splitting data into multiple sheets?

The split needs to be based on value in one of the columns and the sheet where the data will be sent to should get sheet name same as value in the column. Following data sample may help me explain in a better way:

Following is the input sheet, the data needs to be split based on entry in the column "Job Type".


Excel 2007
ABCD
1Invoice NumberJob TypeInvoice DateAmount
21234Repair04-Apr-13$200
33456Contract Work10-Apr-13$400
47896General23-Apr-13$100
Input Sheet


Following tables are showing data split into multiple sheets and the sheet names are the same as entry under the column "Job Type"


Excel 2007
ABCD
1Invoice NumberJob TypeInvoice DateAmount
21234Repair04-Apr-13$200
Repair



Excel 2007
ABCD
1Invoice NumberJob TypeInvoice DateAmount
23456Contract Work10-Apr-13$400
Contract Work



Excel 2007
ABCD
1Invoice NumberJob TypeInvoice DateAmount
27896General23-Apr-13$100
General


Thanks for your help

Rajesh
 

Excel Facts

Format cells as date
Select range and press Ctrl+Shift+3 to format cells as date. (Shift 3 is the # sign which sort of looks like a small calendar).
Try this:
Code:
Sub SplitIntoSheets()
Dim lR As Long, vA As Variant, d As Object, JT As Variant, Wsht As Worksheet
Set Wsht = ActiveSheet
If Wsht.AutoFilterMode Then Wsht.Range("A1").AutoFilter
lR = Wsht.Range("B" & Rows.Count).End(xlUp).Row
vA = Wsht.Range("B2", "B" & lR).Value
Set d = CreateObject("Scripting.dictionary")
d.RemoveAll
For i = LBound(vA, 1) To UBound(vA, 1)
    If Not d.exists(vA(i, 1)) Then d.Add vA(i, 1), i
Next i
JT = d.keys
Application.ScreenUpdating = False
Application.DisplayAlerts = False
For i = LBound(JT) To UBound(JT)
    'remove any pre-existing sheet
    On Error Resume Next
    Sheets(JT(i)).Delete
    On Error GoTo 0
    With Wsht
        .Range("B2").AutoFilter field:=2, Criteria1:=JT(i)
        .Range("A1").CurrentRegion.SpecialCells(xlCellTypeVisible).Copy
        Sheets.Add after:=Sheets(Sheets.Count)
        ActiveSheet.Name = JT(i)
        With ActiveSheet.Range("A1")
            .PasteSpecial Paste:=xlPasteColumnWidths
            .PasteSpecial Paste:=xlPasteValues
            .PasteSpecial Paste:=xlPasteFormats
            Application.CutCopyMode = False
            Wsht.Select
        End With
    End With
Next i
If Wsht.AutoFilterMode Then Wsht.Range("A1").AutoFilter
Application.DisplayAlerts = True
End Sub
 
Upvote 0
Hello Friends

Could you please help me writing code in VBA for splitting data into multiple sheets?

The split needs to be based on value in one of the columns and the sheet where the data will be sent to should get sheet name same as value in the column. Following data sample may help me explain in a better way:

Following is the input sheet, the data needs to be split based on entry in the column "Job Type".

...
Perhaps tthis code is somewhat more general than you need, but it should do what you ask. Initial input sheet should be named "input".
Code:
Sub knux()

Const n& = 2
Dim a As Variant, q As Variant, hd
Dim rws&, cls&, p&, i&, b As Boolean
Application.ScreenUpdating = False

With Sheets.Add
    Sheets("input").Cells(1).CurrentRegion.Copy .Cells(1)
    Set a = .Cells(1).CurrentRegion
    rws = a.Rows.Count
    cls = a.Columns.Count
    hd = a.Rows(1)
    a.Sort a(1, n), Header:=xlYes
    .Name = a(2, n)
    a = a.Resize(rws + 1)
    p = 2
    For i = p To rws + 1
        If a(i, n) <> a(p, n) Then
            If b Then
                Sheets.Add.Name = a(p, n)
                .Cells(p, 1).Resize(i - p, cls).Cut Cells(2, 1)
                Cells(1).Resize(, cls) = hd
            End If
            b = True
            p = i
        End If
    Next i
End With

Application.ScreenUpdating = True


End Sub
 
Upvote 0
Here's an alternative that uses a function to pull the Unique job types into an array, then uses Advanced filter to populate the new sheets regardless of how many job types there are.

It's only down side is that it doesn't do checking to see if the new worksheet already exists.

Code:
Option Explicit
Public Function UniqueItems(ArrayIn, Optional Add2Arr As Variant, Optional count As Variant) As Variant
    
Dim Unique() As Variant
Dim Element As Variant
Dim i As Long
Dim NumUnique As Long
Dim IsInArray As Boolean

       
'   If 2nd argument is missing, assign default value
If IsMissing(count) Then count = False
If Not IsMissing(Add2Arr) Then
    Unique = Add2Arr
    NumUnique = UBound(Add2Arr) + 1
End If
        
For Each Element In ArrayIn
    IsInArray = False
    ' If Arr has not been established, skip the loop
    If Not ((Not Unique) = -1) Then
        For i = LBound(Unique) To UBound(Unique)
            If Element = Unique(i) Then
                IsInArray = True
                Exit For
            End If
        Next i
    End If
    If IsInArray = False And Element <> "" Then
        ReDim Preserve Unique(NumUnique)
        Unique(NumUnique) = Element
        NumUnique = NumUnique + 1
        IsInArray = True
    End If
Next Element


If count Then UniqueItems = NumUnique Else UniqueItems = Unique

End Function

Sub Input2Sheets()

Dim lr As Long
Dim i As Long
Dim NewWS As Worksheet
Dim InputSHT As Worksheet
Set InputSHT = Sheets("Input Sheet")

Dim JobTypeARR As Variant
lr = InputSHT.Range("B" & Rows.count).End(xlUp).Row
JobTypeARR = UniqueItems(Range("B2", "B" & lr))

For i = LBound(JobTypeARR) To UBound(JobTypeARR)
    InputSHT.Cells(1, "G").Value = InputSHT.Cells(1, "B").Value
    InputSHT.Cells(2, "G").Value = JobTypeARR(i)
    Sheets.Add.Name = JobTypeARR(i)
    Set NewWS = Sheets(JobTypeARR(i))
    
    InputSHT.Range("A1:D" & lr).AdvancedFilter Action:=xlFilterCopy, _
                        CriteriaRange:=InputSHT.Range("G1:G2"), _
                        CopyToRange:=NewWS.Range("A1:D1"), Unique:=False
Next i
InputSHT.Range("G1:G2").ClearContents

End Sub
 
Upvote 0
...
It's only down side is that it doesn't do checking to see if the new worksheet already exists.
...
Hi rjwebgraphix,

In the OP question, if the first two Job Types, instead of being named "Repair" and "Contract Work", were instead "A1" and "A10".

Would you still be happy that the only downside of your function/code is as you have identified above?
 
Upvote 0
Hello

Thanks for sharing this code. It works very well. One thing I forgot to mention in my original post was that I would have to use this code multiple times. That's no big deal because I added few lines to your code for identifying the sheets (created by your code) and if they were present then deleted them.
Could you please add some comments to your code. Many things in your code are new to me (I am still learning VBA). With the comments I will be able to understand it better and be able to incorporate into my actual project.

Thanks again.
 
Upvote 0
In the OP question, if the first two Job Types, instead of being named "Repair" and "Contract Work", were instead "A1" and "A10".

Would you still be happy that the only downside of your function/code is as you have identified above?

I'm not sure how that would matter. I don't understand where you're coming from. How would that pose a problem? Assuming that one is starting with a lone worksheet with the input data. The unique items UDF pulls all of the job types with no duplicates, the rest just adds the sheets then uses advanced filter to populate the sheets.

How would A1 or A10 matter? They are two different strings after-all. The only other thing someone might want to do is add character validity for the sheet names. IE: Job Type: A:Job would crash. If they're are never any invalid characters in the input data, then that's moot too.

Although, there could be something I'm missing. If that be the case, an existing ws check wouldn't take long to write.
 
Upvote 0
Could you please add some comments to your code.

Who's code are you referring to? JoeMo, mirabeau or mine? All 3 will do the job. They each just do it in a different fashion. I tested them all last night.

If you meant mine.... I hope this is enough comment for you. :)

Code:
'require variable declarations
Option Explicit
Public Function UniqueItems(ArrayIn, Optional Add2Arr As Variant, Optional count As Variant) As Variant
    
' Function will produce an array of Unique Items in a range or another array.

'Declarations
Dim Unique() As Variant
Dim Element As Variant
Dim i As Long
Dim NumUnique As Long
Dim IsInArray As Boolean

' If 2nd argument is missing, assign default value.
' Add2Arr is if the results will be added to an existing array, rather than
' a new array.
' Like so,  myarray = UniqueItems(Range("A1:B10"), myarray)
' in this case, myarray already contains array data and we will just add the results
' to the end of it.  Argument is optional and will produce a new array if 2nd arguement
' is missing.
If IsMissing(count) Then count = False
If Not IsMissing(Add2Arr) Then
    Unique = Add2Arr
    NumUnique = UBound(Add2Arr) + 1
End If
        
'Loop through the array
For Each Element In ArrayIn
    IsInArray = False
    ' If Arr has not been established, skip the loop
    ' This if line only works with arrays that have been declared
    ' like this.  Dim myarray() as variant
    ' if an array is declared with just Dim myarray as variant
    ' This will not determine if the array has been initialized
    ' it would instead fail.  I have another function altogether
    ' to determine if array's have been initialized, but this works
    ' for a one time use.  The double not states that if it is initialized
    ' it will run the for loop.
    If Not ((Not Unique) = -1) Then
        'Looks at each element of the array it is building (or each element in
        'the existing array if supplied) and determines if the element already
        'exists in the array.
        For i = LBound(Unique) To UBound(Unique)
            If Element = Unique(i) Then
                IsInArray = True
                Exit For
            End If
        Next i
    End If
    'If the element does not exist in the array, we will then add it to the array
    'Also eliminating any empty elements as we only want actual data, not blank data
    If IsInArray = False And Element <> "" Then
        ReDim Preserve Unique(NumUnique)
        Unique(NumUnique) = Element
        NumUnique = NumUnique + 1
        IsInArray = True
    End If
Next Element

'outputs the array, unless count is specified, then it will give a count of
'unique items in the range or array.
If count Then UniqueItems = NumUnique Else UniqueItems = Unique

End Function

Sub Input2Sheets()

'Declarations
Dim lr As Long
Dim i As Long
Dim NewWS As Worksheet
Dim InputSHT As Worksheet
'Sets the input worksheet so we can refer to it by it's short name InputSHT
Set InputSHT = Sheets("Input Sheet")

Dim JobTypeARR As Variant
lr = InputSHT.Range("B" & Rows.count).End(xlUp).Row

'Uses the above function to produce a list of unique job types.
JobTypeARR = UniqueItems(Range("B2", "B" & lr))

'Loop through the job types, create the sheets and move pertinant data to new sheet
For i = LBound(JobTypeARR) To UBound(JobTypeARR)
    'Sets the criteria to use for the Advanced Filter
    InputSHT.Cells(1, "G").Value = InputSHT.Cells(1, "B").Value
    InputSHT.Cells(2, "G").Value = JobTypeARR(i)
    
    'Adds the new sheet and names it
    Sheets.Add.Name = JobTypeARR(i)
    'sets New Worksheet so it can be referred to by its short name "NewWS"
    'Since its only used once, its not really needed and can refer to the sheet
    'name directly, but I figured it would be nice to have it if there was
    'anything else you'd like to do with the New worksheet before you moved
    'on to adding the next one.
    Set NewWS = Sheets(JobTypeARR(i))
    
    'Advanced Filter, uses the Criteria range set above to pull all records
    'matching the jobtype.
    InputSHT.Range("A1:D" & lr).AdvancedFilter Action:=xlFilterCopy, _
                        CriteriaRange:=InputSHT.Range("G1:G2"), _
                        CopyToRange:=NewWS.Range("A1:D1"), Unique:=False
Next i

'Clears the criteria range as its not needed afterwards.
InputSHT.Range("G1:G2").ClearContents

End Sub
 
Upvote 0
I'm not sure how that would matter. I don't understand where you're coming from. How would that pose a problem? Assuming that one is starting with a lone worksheet with the input data. The unique items UDF pulls all of the job types with no duplicates, the rest just adds the sheets then uses advanced filter to populate the sheets.

How would A1 or A10 matter? They are two different strings after-all. The only other thing someone might want to do is add character validity for the sheet names. IE: Job Type: A:Job would crash. If they're are never any invalid characters in the input data, then that's moot too.

Although, there could be something I'm missing. If that be the case, an existing ws check wouldn't take long to write.
It matters because in that case your code then gives the wrong output in the new sheet named A1. At least it did when I tried it out.

Why don't you try it and check your output? It seems from your response that you haven't done this.

If a code gives wrong result for one case, how is a user to know generally when it will work and when it won't?
 
Upvote 0

Forum statistics

Threads
1,215,372
Messages
6,124,542
Members
449,169
Latest member
mm424

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