Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Changing Fonts in Multiple Workbooks.
Written by Allen Wyatt (last updated August 28, 2021)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
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 (564) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Changing Fonts in Multiple Workbooks.
Save Time and Supercharge Excel! Automate virtually any routine task and save yourself hours, days, maybe even weeks. Then, learn how to make Excel do things you thought were simply impossible! Mastering advanced Excel macros has never been easier. Check out Excel 2010 VBA and Macros today!
It is often desired to change what is displayed in a cell based on what is in a different cell. What if what you want to ...
Discover MoreWant to repeat cell contents over and over again within a single cell? Excel provides two ways you can duplicate the content.
Discover MoreExcel allows you to specify colors for the interior of cells in your worksheet. If you want those colors to be set ...
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 ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2024 Sharon Parq Associates, Inc.
Comments