Split data into different sheets VBA

glebret

New Member
Joined
Sep 16, 2015
Messages
13
Hi everyone,

i am pretty new here and need help on a VBA macro.

I have a bunch of data (expenses) for different clients in one single sheet that I would like to split on different sheets.
Basically what I would like to do is to create one sheet per client, each sheet named with the name of the client and, each sheet containing the data of that same client.

I'm sure it is pretty easy to do but I am too new in vba to succeed.

Thank you.
 

Excel Facts

How to change case of text in Excel?
Use =UPPER() for upper case, =LOWER() for lower case, and =PROPER() for proper case. PROPER won't capitalize second c in Mccartney
Hi welcome to the board.

Assuming that your master sheet (expenses) has a row that contains headers (field names) then you can use advanced filter.

Following is code I created for others on this board with same requirement.

Copy both codes to a standard module.

Code:
Option Explicit
Sub FilterData()
    Dim ws1Master As Worksheet, wsNew As Worksheet, wsFilter As Worksheet
    Dim Datarng As Range, FilterRange As Range, objRange As Range
    Dim rowcount As Long
    Dim colcount As Integer, FilterCol As Integer, FilterRow As Long
    Dim SheetName As String




    'master sheet
    Set ws1Master = ActiveSheet


    'set the Column you
    'are filtering
top:
    On Error Resume Next
    Set objRange = Application.InputBox("Select Field Name To Filter", "Range Input", , , , , , 8)
    On Error GoTo 0
    If objRange Is Nothing Then
        Exit Sub
    ElseIf objRange.Columns.Count > 1 Then
        GoTo top
    End If


    FilterCol = objRange.Column
    FilterRow = objRange.Row


    With Application
        .ScreenUpdating = False
        .DisplayAlerts = False
    End With


    On Error GoTo progend


    'add filter sheet
    Set wsFilter = Sheets.Add
    
    With ws1Master
        .Activate
        .Unprotect Password:=""  'add password if needed
        
        rowcount = .Cells(.Rows.Count, FilterCol).End(xlUp).Row
        colcount = .Cells(FilterRow, .Columns.Count).End(xlToLeft).Column


        If FilterCol > colcount Then
            Err.Raise 65000, "", "FilterCol Setting Is Outside Data Range.", "", 0
        End If


        Set Datarng = .Range(.Cells(FilterRow, 1), .Cells(rowcount, colcount))
        
        'extract Unique values from FilterCol
        .Range(.Cells(FilterRow, FilterCol), .Cells(rowcount, FilterCol)).AdvancedFilter _
                      Action:=xlFilterCopy, CopyToRange:=wsFilter.Range("A1"), Unique:=True
                      
        rowcount = wsFilter.Cells(wsFilter.Rows.Count, "A").End(xlUp).Row
        
        'set Criteria
        wsFilter.Range("B1").Value = wsFilter.Range("A1").Value


        For Each FilterRange In wsFilter.Range("A2:A" & rowcount)
        
            'check for blank cell in range
            If Len(FilterRange.Value) > 0 Then
            
                'add the FilterRange to criteria
                wsFilter.Range("B2").Value = FilterRange.Value
                
                SheetName = Trim(Left(FilterRange.Value, 31))
                
                'if FilterRange sheet exists
                'update it
                If SheetExists(SheetName) Then
                    Sheets(SheetName).Cells.Clear
                Else
                    'add new sheet
                    Set wsNew = Sheets.Add(after:=Worksheets(Worksheets.Count))
                    wsNew.Name = SheetName
                End If
                
                Datarng.AdvancedFilter Action:=xlFilterCopy, CriteriaRange:=wsFilter.Range("B1:B2"), _
                                       CopyToRange:=Sheets(SheetName).Range("A1"), Unique:=False


            End If
            
            Set wsNew = Nothing
        Next
        
        .Select
    End With
    
progend:
    wsFilter.Delete
    With Application
        .ScreenUpdating = True
        .DisplayAlerts = True
    End With
    If Err > 0 Then
        MsgBox (Error(Err)), 16, "Error"
        Err.Clear
    End If
End Sub


Function SheetExists(ByVal sh As String) As Boolean
'stock function
    On Error Resume Next
    SheetExists = CBool(Len(Worksheets(sh).Name) > 0)
    On Error GoTo 0
End Function

When run, an inputbox will appear, just select the field heading you want to filter data by & press ok. Code should create individual sheets as required.

Dave
 
Upvote 0
Dave,

THANK YOU so much. That is pretty amazing and it works like a charm and also thank you for answering so fast.

Now I really want to spend some time and understand every single line of it.

Thanks again.

Gerald

PS: Since I am new to this forum, do I need to close this thread?
 
Upvote 0
Dave,

THANK YOU so much. That is pretty amazing and it works like a charm and also thank you for answering so fast.

Now I really want to spend some time and understand every single line of it.

Thanks again.

Gerald

PS: Since I am new to this forum, do I need to close this thread?

Hi Gerald,
Your request is quite a common one so I created stock code (Function is stock - not mine) & have posted it many times.
Glad solution did what you wanted - for future reference, I have an add-on to the code that gives choice to save the sheets as individual files if required.

Your feedback closes thread as others will see problem solved.

There are many established experts that often contribute on Forum so you found a good place to start.

Many thanks for feedback

Dave
 
Upvote 0
Hi Dave,

Little update, it works perfect, but it seems like some sheet names are missing some characters. I thought I just had to modify: "SheetName = Trim(Left(FilterRange.Value, 31))" and put any value I wanted instead of 31 but even if I put 32, I get an error message.

Can you tell me where the lenght of the sheet name is specified?

Thank you

Gerald
 
Upvote 0
31 is the max length (including spaces) of a tab name which is why that line is there. You need to change it back to 31.

Dave
 
Upvote 0
Hello Dave,

I'm sorry to bother you again.

I added a few lines of code to my macro and one of them does not work.
I want to get in column B and C the value of my budget and my real transaction in my summary sheet.
I added the following line but it does not work:
Range("A3").Offset(lSht, 1).Formula = "=(SUMIF('" & Worksheets(lSht).Name & "'!C[1], ""*Total*""," '"Worksheets(lSht).Name& "'!C[3])"

Can you tell me whats wrong in this formula?

Thank you.
 
Upvote 0
Hi,

Don't have much time today - if this problem relates to macro i provided then post whole code so can see what you are trying to do. If however, this relates to another macro problem then you should start a new thread.

Dave
 
Upvote 0

Forum statistics

Threads
1,216,099
Messages
6,128,823
Members
449,470
Latest member
Subhash Chand

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