Renaming Worksheets in files in a directory

dariushou

Board Regular
Joined
Feb 17, 2008
Messages
126
Hope i can get some help here as my vba experience is extremely limited. I'm trying to run a macro from a spreadsheet that will go down a list of file names that i have entered in a worksheet where the macro resides and open those spreadsheets and rename the worksheets in each file according to a list of names that i have entered in the 10 columns next to the file name. It's easier to explain with the layout of my macro spreadsheet:

Sheet1


<TABLE style="PADDING-RIGHT: 2pt; PADDING-LEFT: 2pt; FONT-SIZE: 10pt; FONT-FAMILY: Arial,Arial; BACKGROUND-COLOR: #ffffff" cellSpacing=0 cellPadding=0 border=1><COLGROUP><COL style="FONT-WEIGHT: bold; WIDTH: 30px"><COL style="WIDTH: 377px"><COL style="WIDTH: 60px"><COL style="WIDTH: 70px"><COL style="WIDTH: 60px"><COL style="WIDTH: 60px"><COL style="WIDTH: 62px"><COL style="WIDTH: 60px"><COL style="WIDTH: 61px"><COL style="WIDTH: 60px"><COL style="WIDTH: 60px"><COL style="WIDTH: 67px"></COLGROUP><TBODY><TR style="FONT-WEIGHT: bold; FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center"><TD> </TD><TD>D</TD><TD>E</TD><TD>F</TD><TD>G</TD><TD>H</TD><TD>I</TD><TD>J</TD><TD>K</TD><TD>L</TD><TD>M</TD><TD>N</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">2</TD><TD style="FONT-WEIGHT: bold"> </TD><TD style="FONT-WEIGHT: bold; TEXT-ALIGN: center">Sheet1</TD><TD style="FONT-WEIGHT: bold; TEXT-ALIGN: center">Sheet2</TD><TD style="FONT-WEIGHT: bold; TEXT-ALIGN: center">Sheet3</TD><TD style="FONT-WEIGHT: bold; TEXT-ALIGN: center">Sheet4</TD><TD style="FONT-WEIGHT: bold; TEXT-ALIGN: center">Sheet5</TD><TD style="FONT-WEIGHT: bold; TEXT-ALIGN: center">Sheet6</TD><TD style="FONT-WEIGHT: bold; TEXT-ALIGN: center">Sheet7</TD><TD style="FONT-WEIGHT: bold; TEXT-ALIGN: center">Sheet8</TD><TD style="FONT-WEIGHT: bold; TEXT-ALIGN: center">Sheet9</TD><TD style="FONT-WEIGHT: bold; TEXT-ALIGN: center">Sheet10</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">3</TD><TD style="FONT-WEIGHT: bold; TEXT-ALIGN: center">Full Path</TD><TD style="FONT-WEIGHT: bold; TEXT-ALIGN: center">Name</TD><TD style="FONT-WEIGHT: bold; TEXT-ALIGN: center">Name</TD><TD style="FONT-WEIGHT: bold; TEXT-ALIGN: center">Name</TD><TD style="FONT-WEIGHT: bold; TEXT-ALIGN: center">Name</TD><TD style="FONT-WEIGHT: bold; TEXT-ALIGN: center">Name</TD><TD style="FONT-WEIGHT: bold; TEXT-ALIGN: center">Name</TD><TD style="FONT-WEIGHT: bold; TEXT-ALIGN: center">Name</TD><TD style="FONT-WEIGHT: bold; TEXT-ALIGN: center">Name</TD><TD style="FONT-WEIGHT: bold; TEXT-ALIGN: center">Name</TD><TD style="FONT-WEIGHT: bold; TEXT-ALIGN: center">Name</TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">4</TD><TD>R:\Capital Markets\01B</TD><TD>01B PY</TD><TD>01B Collat</TD><TD>01B XIO</TD><TD> </TD><TD> </TD><TD> </TD><TD> </TD><TD> </TD><TD> </TD><TD> </TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">5</TD><TD>R:\Capital Markets\02A</TD><TD>02A PY</TD><TD>02A Collat</TD><TD>02A XIO</TD><TD>02A P</TD><TD>02A M10</TD><TD> </TD><TD> </TD><TD> </TD><TD> </TD><TD> </TD></TR><TR style="HEIGHT: 17px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">6</TD><TD>R:\Capital Markets\02C</TD><TD>02C PY</TD><TD>02C Collat</TD><TD>02C XIO</TD><TD>02C P</TD><TD>02C M7B</TD><TD>02C M8</TD><TD>02C M9B</TD><TD> </TD><TD> </TD><TD> </TD></TR></TBODY></TABLE>


Excel tables to the web >> http://www.excel-jeanie-html.de/index.php?f=1" target="_blank"> Excel Jeanie HTML 4




So i would like the macro to go down column D and open up the corresponding file and then rename the worksheets according to the corresponding cells in the columns to the right (columns E thru N). Then save and then close the file the macro just opened. As you can see from my data, sometimes there are only a few worksheets in each workbook and the number of worksheets per workbook varies.

Any help would be greatly appreciated.
 

Excel Facts

Control Word Wrap
Press Alt+Enter to move to a new row in a cell. Lets you control where the words wrap.
Something like this perhaps?
Code:
Sub RenameWS()
Dim wb As Workbook
Dim ws As Worksheet
Dim rngFile As Range
Dim rngName As Range
Dim I As Long
    Set rngFile = Range("D4")
    
    While rngFile.Value <> ""
        Set wb = Workbooks.Open(rngFile.Value)
        Set rngName = rngFile.Offset(, 1)
        While rngName.Value <> ""
            I = I + 1
            Set ws = wb.Worksheets(I)
            ws.Name = rngName.Value
        Wend
        wb.Close True
        I = 0
    Wend
    
End Sub
 
Upvote 0
wow!! that was a quick response. The code just about works. I'm getting an error that says "cannot rename a sheet to the same name as another sheet, a referenced object library or a workbook referenced by Visual Basic."

It opened the first workbook, renamed the first sheet correctly then I got this error as it was renaming the 2nd sheet.

Any ideas?

Thanks!!
 
Upvote 0
Sorry, my bad.:oops:
Code:
Sub RenameWS()
Dim wb As Workbook
Dim ws As Worksheet
Dim rngFile As Range
Dim rngName As Range
Dim I As Long
    Set rngFile = Range("D4")
    
    While rngFile.Value <> ""
        Set wb = Workbooks.Open(rngFile.Value)
        Set rngName = rngFile.Offset(, 1)
        While rngName.Value <> ""
            I = I + 1
            Set ws = wb.Worksheets(I)
            ws.Name = rngName.Value
            Set rngName = rngName.Offset(, 1)
        Wend
        wb.Close True
        I = 0
    Wend
    
End Sub
 
Upvote 0
Closer. It gets thru the first spreadsheet, saves it and then closes it. But then it keeps opening the same one and repeating the process over and over. It doesn't actually move down the list.
 
Upvote 0
God am I being thick tonight.:oops:
Code:
Sub RenameWS()
Dim wb As Workbook
Dim ws As Worksheet
Dim rngFile As Range
Dim rngName As Range
Dim I As Long
    Set rngFile = Range("D4")
    
    While rngFile.Value <> ""
        Set wb = Workbooks.Open(rngFile.Value)
        Set rngName = rngFile.Offset(, 1)
        While rngName.Value <> ""
            I = I + 1
            Set ws = wb.Worksheets(I)
            ws.Name = rngName.Value
            Set rngName = rngName.Offset(, 1)
        Wend
        wb.Close True
        Set rngFile = rngFile.Offset(1)
        I = 0
    Wend
    
End Sub
 
Upvote 0
Thank you Norie!! This really helps. I was wondering if you could help me out with one other step. While i'm in each of the workbooks renaming the worksheets i would like to delete all of the rows above a certain word when it appears in column A.

In all of the workbooks. when "Price/Yield" occurs in column A in the first worksheet for each workbook i would like to delete all of the rows above that. In the rest of the worksheets in each workbook, the word is "Period". I can get the following code to work for one workbook without integrating it into your code. However, it would be great if i can put this into your code to process at the same time. Below is my code. Any idea?

Thanks Agian!!!

Code:
For I = 1 To 1
            With Sheets(I)
                x = .Columns("A").Find("Price/Yield").Row
                    .Rows("1:" & x - 1).Delete
            End With
        Next I

        For I = 2 To Sheets.Count
            With Sheets(I)
                x = .Columns("A").Find("Period").Row
                    .Rows("1:" & x - 1).Delete
            End With
        Next I
 
Upvote 0
I can't figure this out. I can't get my grips on why this code doesn't work. I added the following code into the last code provided by Norie before the code wb.Close True. I would think this would work but i get an error at x = .Columns("A").Find("Period").Row. It finishes deleting the rows and renaming the sheets in the the first workbook, but doesn't close/save and move to the next file. The deleting rows macro is something i added to this code. It works on one workbook when you run it--i thought i could add it into Norie's code thru the loop and it would work. Any ideas?

Thanks


Code:
For t = 1 To 1
            With Sheets(t)
                x = .Columns("A").Find("Price/Yield").Row
                    .Rows("1:" & x - 1).Delete
            End With
        Next t

        For t = 2 To Sheets.Count
            With Sheets(t)
                x = .Columns("A").Find("Period").Row
                    .Rows("1:" & x - 1).Delete
            End With
        Next t
 
Upvote 0
try
Code:
Sub test()
Dim rng As Range, i As Long, ii As Long
With Activehseet
    Set rng = .Range("a1", .Cells.SpecialCells(11))
End With
For i = 4 To rng.Rows.Count
    If rng.Cells(i,1).Value <> "" Then
        With Workbooks.Open(rng.Cells(i,1).Value)
            For ii = 1 To .Sheets.Count
                If rng.Cells(i, ii + 4).Value = "" Then Exit For
                With .Sheets(ii)
                    .Name = rng.Cells(i, ii + 4).Value
                    myFind = IIf(ii=1,"Price/Yield","Period")
                    On Error Resume Next
                    .Range("a1",.Columns("a").Find(myFind)).EntireRow.Delete
                    On Error GoTo 0
                End With
            Next
            .Close True
        End With
    Else
        Exit For
    End If
Next
End Sub
 
Upvote 0
I get an error at this line:

Set rng = .Range("a1", .Cells.SpecialCells(11))

The error says: Run-time error 424 Object Required

Any ideas?
 
Upvote 0

Forum statistics

Threads
1,214,927
Messages
6,122,311
Members
449,080
Latest member
jmsotelo

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