Written by Allen Wyatt (last updated September 12, 2024)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and 2021
Ken has a worksheet with over 100 columns of varying widths. To make it readable, he selects the whole worksheet (except for the header row) and uses AutoFit Column Width. Some columns have a single digit and he loses the ability to read the header. Some columns have 200+ characters, so they become too wide. Ken wonders if there is a way to set a minimum (7) and maximum (50) column width for the AutoFit function.
This cannot be done natively within Excel as there is no built-in way to set the minimum or maximum. However, it is easy enough to do using a macro. Here's an example of one that will do the trick:
Sub SetColWidths() Dim c As Range Dim iMin As Integer Dim iMax As Integer iMin = 7 iMax = 50 Application.ScreenUpdating = False For Each c In Selection.Columns c.AutoFit If c.ColumnWidth < iMin Then c.ColumnWidth = iMin If c.ColumnWidth > iMax Then c.ColumnWidth = iMax Next c Application.ScreenUpdating = True End Sub
In order to use the macro, simply select cells in the columns you want to affect (as Ken does), and then run the macro. It applies AutoFit to the columns and then steps through each one to make sure that nothing is narrow than 7 or wider than 50.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (13825) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and 2021.
Program Successfully in Excel! John Walkenbach's name is synonymous with excellence in deciphering complex technical topics. With this comprehensive guide, "Mr. Spreadsheet" shows how to maximize your Excel experience using professional spreadsheet application development tips from his own personal bookshelf. Check out Excel 2013 Power Programming with VBA today!
In a worksheet with lots of hidden columns it is a real pain to try to unhide just one or two columns. The best solution ...
Discover MoreIf you have a bunch of hidden columns in your worksheet, you might want to unhide only a portion of those columns. This ...
Discover MoreIf you were trying to format a worksheet and nothing you did could make the first two columns appear, would you be ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2021-02-20 10:30:33
Allen Cody
The above macro requires that columns be selected before execution. The "c.autofit" line can be removed entirely, as it is unnecessary. Change the line, "For Each c In Selection.Columns" to "For Each c In Cells.Columns" so that the subroutine will autofit all columns in the worksheet within the minimum and maximum parameters established - 7 and 50, respectively.
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 © 2025 Sharon Parq Associates, Inc.
Comments