Is there no way to move table columns and preserve all column widths?

JenniferMurphy

Well-known Member
Joined
Jul 23, 2011
Messages
2,535
Office Version
  1. 365
Platform
  1. Windows
Whenever I had tried to move a table column, the widths of many of the other columns get all messed up. I've tried moving just the table columns (by dragging the table header) and moving the sheet column (by dragging the column header). They each mess up other column widths, but in different ways.

The table I am currently working on is way too large to post as a minisheet. If examples are needed, I can try creating a test table.

This was discussed in this thread about 18 months ago with no solution:


And it referred to this tread in the Microsoft Community, also with no solution:


Is there a way to move columns and preserve all column widths, or is this just another M$FT bug that will be ignored for 20 years?
 
Does anyone have a macro that will effectively reorder columns and preserve all widths? It could prompt for a text string representing the new column order.

A text string like "b e c d h f g" would move column E over between B & C and H over between H over between D & F.

If there is one, I'd be happy to test it.
 
Upvote 0

Excel Facts

Why does 9 mean SUM in SUBTOTAL?
It is because Sum is the 9th alphabetically in Average, Count, CountA, Max, Min, Product, StDev.S, StDev.P, Sum, VAR.S, VAR.P.
No one has posted a macro, so I started to write one myself.

I got this code from the Macro Recorder for moving Column C to the right of Column D. It sorta works.

VBA Code:
Columns("C:C").Select
Selection.Cut
Columns("E:E").Select
Selection.Insert Shift:=xlToRight
Columns("E:E").Select
Selection.ColumnWidth = 10

I was initially puzzled by the "E:E" when I made the move to the right of D. Then I realized that when C is cut, D becomes E.

The move is working, but the width setting (last 2 statements) is not. Columns B:H are a table. The first time I run the macro, those commands apply to Column I, not E. I is the column to the right of the table. If I run it again, it changes the width of J. Each successive time, it affects the next column to the right (K, L, M, ...)

Is there a way I can refer to the columns by numbers? I am not sure how I can keep track of the moves if I have to use letters.

Thanks
 
Upvote 0
See if this gives you any ideas. The assumption is that the issue is only when rearranging table columns.
It picks the table from the active cell and sorts based on a row with numbers representing the required column order immediately above the table.

VBA Code:
   Sub ReOrderTableColumns()
    ' The code relies on the row directly above the table containing
    ' a sequential series of numbers which will be used to sort the columns
    ' It uses the active cell to determine the table to be sorted
   
    Dim ws As Worksheet
    Dim tbl As ListObject
    Dim rngHdr As Range, cellHdr As Range
    Dim rngSort As Range
    Dim dictCol As Object, dictKey As String
   
    Set ws = ActiveSheet
   
    ' Select Table using the active cell
    On Error Resume Next
    Set tbl = ActiveCell.ListObject
    On Error GoTo 0
   
    'Confirm if a cell is in a Table
    If tbl Is Nothing Then
        MsgBox "Select table and try again"
        Exit Sub
    End If
   
    Set rngHdr = tbl.HeaderRowRange
   
    Set dictCol = CreateObject("Scripting.dictionary")
   
    ' Load column widths into Dictionary
    For Each cellHdr In rngHdr.Cells
        dictKey = cellHdr.Value
        dictCol(dictKey) = ws.Columns(cellHdr.Column).ColumnWidth
    Next cellHdr
   
    ' Move columns
    Set rngSort = tbl.Range.Resize(tbl.Range.Rows.Count + 1).Offset(-1)
   
    ws.Sort.SortFields.Clear
    ws.Sort.SortFields.Add2 Key:=rngSort.Rows(1) _
        , SortOn:=xlSortOnValues, Order:=xlAscending, DataOption:=xlSortNormal
    With ActiveWorkbook.Worksheets("Final").Sort
        .SetRange rngSort
        .Header = xlYes
        .MatchCase = False
        .Orientation = xlLeftToRight
        .SortMethod = xlPinYin
        .Apply
    End With
   
    ' Reset Column widths
    For Each cellHdr In rngHdr.Cells
        dictKey = cellHdr.Value
        ws.Columns(cellHdr.Column).ColumnWidth = dictCol(dictKey)
    Next cellHdr

End Sub

My sample Data:

20240421 ListObject Tables Move Column column width JenniferMurphy v03.xlsm
BCDEFGHIJKL
1109876543210
2NumDateIDPriceCommentsMore Cols another colQtytotalMore Cols2More Cols22More Cols222
3120-Apr-24abc1239.99This field contains some textabc1099.9abcabcabc
423-Apr-24xyz99919.99Here's some more textdef10199.9defdefdef
535-Mar-2429.99And still more and morezzz10299.9zzzzzzzzz
Final
Cell Formulas
RangeFormula
I3:I5I3=[@Price]*[@Qty]
 
Upvote 0

Forum statistics

Threads
1,215,398
Messages
6,124,693
Members
449,179
Latest member
kfhw720

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