Widening Multiple Columns Proportionally

Written by Allen Wyatt (last updated September 10, 2022)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021


2

Keith has a worksheet that uses columns A through H. He would like to be able to widen each column by a proportional amount. For instance, if he selects all 8 columns, it would be great if he could grab the right edge of column H and as he drags right, all of the columns would be proportionally spaced out. He wonders if there is a way to do this type of column widening.

To better understand what Keith is talking about, perhaps an example is in order. The normal way of adjusting column width using the mouse is to select the columns and then drag a divider between the column headers to the right or left. Let's say that column A's width is 5, column B is 10, and column C is 15. If you select A:C and drag the divider at the right side of the column C header to 20, that is an increase of 33% for column C. Ideally, both column A and B would also be resized by 33% (as Keith desires), but they are, instead, both set to a width of 20 to match column C.

Further, holding down a modifier key (Ctrl, Alt, or Shift) as you drag the mouse has no effect; the column widths are still all set equal to each other. If you try to right-click and drag, that does nothing except display a Context menu. Thus, from all the testing we've been able to do, there is no way to proportionally adjust column widths in in Excel that we've been able to discover.

Perhaps the easiest way is to use a macro to adjust the column widths. The following is a good example of such an approach.

Sub ProportionalWidth()
    Dim C As Range
    Dim sRaw As String
    Dim sTemp As String
    Dim P As Single

    sRaw = InputBox("Increase width by how what % (0 to 100)?")
    P = Val(sRaw)
    If P >= 0 And P <= 100 Then
        P = 1 + (P / 100)
        sTemp = ""
        For Each C In Selection.Columns
            sTemp = sTemp & "Column " & ColumnLetter(C.Column)
            sTemp = sTemp & ": " & C.ColumnWidth & " ==> "
            C.ColumnWidth = C.ColumnWidth * P
            sTemp = sTemp & C.ColumnWidth & vbCrLf
        Next C
        MsgBox sTemp
    Else
        MsgBox "Out of range; no adjustment made"
    End If
End Sub
Function ColumnLetter(Col As Long) As String
    Dim Arr
    Arr = Split(Cells(1, Col).Address(True, False), "$")
    ColumnLetter = Arr(0)
End Function

There are actually two macros in this example. The first (ProportionalWidth) changes the width of whatever columns you've selected. The second (ColumnLetter) is used to convert a numeric column number into the column letters. It is only used in putting together the report (in sTemp) of the before and after widths of the columns.

When you select columns and run the macro, it prompts you for how much wider you want to make those columns. Enter a number between 0 and 100, click OK, and the columns are widened by that percentage. In addition, you'll see a message box that shows the original width of each column and the adjusted width.

Note that this macro only widens columns. If you wanted use it to also make columns proportionally narrower, you would need to modify it to, perhaps, handle negative values.

Note:

If you would like to know how to use the macros described on this page (or on any other page on the ExcelTips sites), I've prepared a special page that includes helpful information. Click here to open that special page in a new browser tab.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (13429) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Picking Up in the Last Document Edited

Sometimes it seems that we focus on getting a particular document hammered out to the exclusion of other documents we ...

Discover More

Searching and Replacing Graphics

Got a bunch of graphics in a document that need replacing? (Perhaps you need to replace an old logo with a new one.) Word ...

Discover More

Changing Your Name

One of the many pieces of information that Excel keeps track of is your name. If you want to change your name for Excel's ...

Discover More

Comprehensive VBA Guide Visual Basic for Applications (VBA) is the language used for writing macros in all Office programs. This complete guide shows both professionals and novices how to master VBA in order to customize the entire Office suite for their needs. Check out Mastering VBA for Office 2010 today!

More ExcelTips (ribbon)

Shortcuts to Hide Columns

Need a quick way to hide and unhide columns in a worksheet? The shortcuts described in this tip can help fill the bill.

Discover More

Widening a Column to a Particular Cell's Width

Do you want to set a column's width based on whatever is in the currently selected cell? There are actually a number of ...

Discover More

Setting Minimums and Maximums when AutoFitting Column Widths

Using AutoFit can help you maximize your use of screen space. In certain situations, though, it can make your data harder ...

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] (all 7 characters, in the sequence shown) in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is 2 + 2?

2022-09-12 10:05:25

Kelly

Maybe I'm misunderstanding the example, but if you highlight columns A:C then double click the handle at the end of C, each column will adjust to the max width of each column. Not a predetermined width of 5, 10, 15 however, but whatever width is needed for each column


2022-09-10 10:04:35

J. Woolley

My Excel Toolbox includes the AdjustColumnWidths macro to adjust the width of selected columns by a fixed increment or a proportional multiplier. The AdjustRowHeights macro will adjust the height of selected rows in the same way. Both macros support Undo (Ctrl+Z).
See https://sites.google.com/view/MyExcelToolbox/


This Site

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.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.