Please Note: This article is written for users of the following Microsoft Excel versions: 97, 2000, 2002, and 2003. If you are using a later version (Excel 2007 or later), this tip may not work for you. For a version of this tip written specifically for later versions of Excel, click here: Changing Fonts in Multiple Workbooks.
Written by Allen Wyatt (last updated August 30, 2025)
This tip applies to Excel 97, 2000, 2002, and 2003
Hamish is facing a daunting task: He needs to change the default fonts used in a large number of Excel workbooks. He has over 100 workbooks, and the fonts used in those workbooks need to be changed to a new font specified by corporate mandate. (You know how corporate mandates can be!)
The manual way to approach this task is to load each workbook, go through each worksheet, select the cells, and change the fonts in those cells. To make Hamish's task even more complex, he needs to change multiple fonts in each workbook. In other words, given fonts A, B, C, and D, Hamish needs to change font A to C and font B to D.
The best way to approach this problem is through the use of a macro. There is so much loading, searching, and changing that is necessary that it only makes sense to relegate the work to a macro. The following macro should do the job:
Sub ChangeFontNames()
Dim vNamesFind
Dim vNamesReplace
Dim sFileName As String
Dim Wkb As Workbook
Dim Wks As Worksheet
Dim rCell As Range
Dim x As Integer
Dim iFonts As Integer
Dim sPath As String
'Change these lines as appropriate
'These are the fontnames to find
vNamesFind = Array("Arial", "Allegro BT")
'These are the fontnames to replace
vNamesReplace = Array("Wingdings", "Times New Roman")
'This is the folder to look for xls files
sPath = "C:\foldername\"
Application.ScreenUpdating = False
iFonts = UBound(vNamesFind)
If iFonts <> UBound(vNamesReplace) Then
MsgBox "Find and Replace Arrays must be the same size"
Exit Sub
End If
sFileName = Dir(sPath & "*.xls")
Do While sFileName <> ""
Set Wkb = Workbooks.Open(sPath & sFileName)
For Each Wks In Wkb.Worksheets
For Each rCell In Wks.UsedRange
For x = 0 To iFonts
With rCell.Font
If .Name = vNamesFind(x) Then _
.Name = vNamesReplace(x)
End With
Next
Next
Next
Wkb.Close(True)
sFileName = Dir
Loop
Application.ScreenUpdating = True
Set rCell = Nothing
Set Wks = Nothing
Set Wkb = Nothing
End Sub
To use the macro with your own workbooks, there are a couple of things you need to do. First, make sure that all the workbooks you want to change are stored in a single folder and that you know the name of the folder. Then, within the macro, change the variables defined near the beginning of the macro. Change the elements of the vNamesFind and vNamesReplace arrays to match the names of the fonts you want to respectively find and replace. You should then change the sPath variable so it contains the full path to the folder containing your workbooks. (Don't forget a trailing backslash on the path.)
When you run the macro, it loads each workbook in the folder, in turn. Then, it goes through each worksheet in each workbook, and examines every cell. If the cell has one of the fonts to be found, then it is replaced with the respective replacement font. When the macro is done with the workbook, it is saved and the next workbook is processed.
Those interested in avoiding this type of problem on new worksheets should explore how to use styles in Excel. You can define any number of styles and use them throughout a workbook. If you later need to change the formatting for specific cells, all you need to do is change the underlying styles. (Styles have been covered in other issues of ExcelTips.)
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (2526) applies to Microsoft Excel 97, 2000, 2002, and 2003. You can find a version of this tip for the ribbon interface of Excel (Excel 2007 and later) here: Changing Fonts in Multiple Workbooks.
Best-Selling VBA Tutorial for Beginners Take your Excel knowledge to the next level. With a little background in VBA programming, you can go well beyond basic spreadsheets and functions. Use macros to reduce errors, save time, and integrate with other Microsoft applications. Fully updated for the latest version of Office 365. Check out Microsoft 365 Excel VBA Programming For Dummies today!
Keyboard shortcuts can save time and make developing a workbook much easier. Here's how to apply the most common of ...
Discover MoreNeed to merge a bunch of cells together on a regular basis? You'll love the two macros in this tip which can make short ...
Discover MoreCreating custom formats is a very powerful way to display information exactly as you want it to appear. Most custom ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
Got a version of Excel that uses the menu interface (Excel 97, Excel 2000, Excel 2002, or Excel 2003)? This site is for you! If you use a later version of Excel, visit our ExcelTips site focusing on the ribbon interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2025 Sharon Parq Associates, Inc.
Comments