• Hi All

    Please note that at the Chandoo.org Forums there is Zero Tolerance to Spam

    Post Spam and you Will Be Deleted as a User

    Hui...

  • When starting a new post, to receive a quicker and more targeted answer, Please include a sample file in the initial post.

Creating worksheets based on data filtered with VBA - truncating names

Gizmo369

New Member
Hello,

I am currently using the following code to create a workbook that groups data based on a classification entered in a specific column. This worked great until people wanted more diversity between categories. I now have multiply categories that are over 31 characters in length therefore I have to manually copy and paste the data into new sheets (oh the pain!).

Is there a way that this could be modified so that any item that is over 31 character would just have the sheet name truncated? (on a side note, is it possible to modify this to copy column widths?)

Code:
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 = 13
Set ws = Sheets("Open Hazards")
lr = ws.Cells(ws.Rows.Count, vcol).End(xlUp).Row
title = "A1:R1"
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


Thank you in advance for your assistance!
 
Last edited by a moderator:
change the Sheets.add line as per below:

Code:
Sheets.Add(after:=Worksheets(Worksheets.Count)).Name = left(myarr(i),30) & ""

Also why are you using &"" at the end of the line?
 
@Gizmo369

If you are going to use the method Hui suggested every time you refer to that new sheet you will need to use the truncated name for the sheet.

I have knocked some lines out of your procedure and shown how this can be done with a sample. The following is the code.

Code:
Option Explicit
 
Sub parse_data()
Dim lr As Long
Dim ws As Worksheet
Dim i As Integer
Dim ar As Variant
Dim j As Long
Dim rng As Range
 
Set ws = Sheet1 'Sheets code name
lr = ws.Range("M" & Rows.Count).End(xlUp).Row
Set rng = ws.Range("M1:M" & lr)
j = [A1].CurrentRegion.Columns.Count + 1
 
rng.AdvancedFilter 2, , Cells(1, j), True
ar = ws.Range(ws.Cells(2, j), ws.Cells(Rows.Count, j).End(xlUp))
Columns(j).Clear
       
    For i = 1 To UBound(ar)
        rng.AutoFilter 1, ar(i, 1)
            If Not Evaluate("=ISREF('" & ar(i, 1) & "'!A1)") Then
                Sheets.Add(after:=Sheets(Sheets.Count)).Name = Left(ar(i, 1), 31)
            Else
                Sheets(ar(i, 1)).Move after:=Sheets(Sheets.Count)
            End If
        ws.Range("A1:A" & lr).Resize(, j - 1).Copy [A1]
        Sheets(Left(ar(i, 1), 31)).Columns.AutoFit
    Next
ws.AutoFilterMode = False
End Sub

File attached to show how it falls in place.

Take care

Smallman
 

Attachments

  • PassData.xlsm
    19.8 KB · Views: 9
Back
Top