Get our FREE VBA eBook of the 30 most useful Excel VBA macros.

Automate Excel so that you can save time and stop doing the jobs a trained monkey could do.

Claim your free eBook


Power Query: Stop Excel Table columns resizing

Power Query - Stop Column Widths Resizing

If we use Power Query to load data into an Excel Table, we may encounter an annoying default setting, whereby Table columns resize every time we refresh the query.

It isn’t a problem if this is just data used for other calculations. However, if the query is part of your reporting, it may not display correctly in your reports.

Excel Table Column width changes

In this post, we will look at how to fix this problem.

Watch the video


Watch the video on YouTube.

Manually change the Table Properties

Thankfully, there is an easy way to stop this from happening.

  • Select a cell within the Table.
  • Click Table Design > Properties
    Table Properties option
  • The External Data Properties window opens
    External data properties

There are lots of useful options in here, so let’s just look at them briefly:

  • Include row numbers: Will add a _RowNum column to the start of the Table. From a power query perspective, this is not particularly useful. If we wanted a row number, we could add this as an Index column before loading the query into the Excel Table.
    Adding a row number to a Table
  • Adjust column width: For our scenario, this option is causing the problem. Uncheck that option, and the columns will no longer resize.
  • Preserve column sort/filter/layout: This allows us to retain the sort, filter, or layout options that existed prior to clicking refresh. If we want a clean start each time we load, we should uncheck this box.
  • Preserve cell formatting: If you have cell formatting applied, this will be retained based on the position of the cells. So, for example, if you highlighted the 2nd row, the 2nd row will still be highlighted after refreshing the query. The exception is if the formatting is below the length of the refreshed query; at this point, the formatting is lost going forwards. Uncheck this box if you always want formatting removed.
  • If the number of rows in the data range changes upon refresh: There are 3 options in this section. For Power Query, I don’t believe it makes any difference which option is selected. Therefore, I always leave it on the first selection by default.

Once you’ve made your selections, click OK to close the External Data Properties dialog box.

Ta-dah!!! Now, each time we refresh the query, the Table column widths should not resize.

Macro to change all Tables in the Active Workbook

If you have a lot of Tables, it might take you a bit of time. So I have created the following VBA Macro to change all the Tables in the ActiveWorkbook.

Sub StopTableColumnsResize()

Dim ws As Worksheet
Dim tbl As ListObject
Dim qryTbl As QueryTable

'Loop through all worksheets in active workbook
For Each ws In ActiveWorkbook.Worksheets

    'Loop through all Tables in the worksheet
    For Each tbl In ws.ListObjects

        'Check if the Table is a Query Table
        Set qryTbl = Nothing
        On Error Resume Next
        Set qryTbl = tbl.QueryTable
        On Error GoTo 0

        'If the Table is a Query Table then change settings
        If Not (qryTbl Is Nothing) Then

            'Change the settings
            qryTbl.AdjustColumnWidth = False

            'Alternative options you may want to apply
            'qryTbl.RowNumbers = True
            'qryTbl.PreserveFormatting = True
            'qryTbl.PreserveColumnInfo = True

        End If

    Next tbl

Next ws

End Sub

Conclusion

Whether you have applied the manual method or used the VBA Macro, you never need to have Table columns resizing ever again.


Headshot Round

About the author

Hey, I’m Mark, and I run Excel Off The Grid.

My parents tell me that at the age of 7 I declared I was going to become a qualified accountant. I was either psychic or had no imagination, as that is exactly what happened. However, it wasn't until I was 35 that my journey really began.

In 2015, I started a new job, for which I was regularly working after 10pm. As a result, I rarely saw my children during the week. So, I started searching for the secrets to automating Excel. I discovered that by building a small number of simple tools, I could combine them together in different ways to automate nearly all my regular tasks. This meant I could work less hours (and I got pay raises!). Today, I teach these techniques to other professionals in our training program so they too can spend less time at work (and more time with their children and doing the things they love).


Do you need help adapting this post to your needs?

I'm guessing the examples in this post don't exactly match your situation. We all use Excel differently, so it's impossible to write a post that will meet everybody's needs. By taking the time to understand the techniques and principles in this post (and elsewhere on this site), you should be able to adapt it to your needs.

But, if you're still struggling you should:

  1. Read other blogs, or watch YouTube videos on the same topic. You will benefit much more by discovering your own solutions.
  2. Ask the 'Excel Ninja' in your office. It's amazing what things other people know.
  3. Ask a question in a forum like Mr Excel, or the Microsoft Answers Community. Remember, the people on these forums are generally giving their time for free. So take care to craft your question, make sure it's clear and concise.  List all the things you've tried, and provide screenshots, code segments and example workbooks.
  4. Use Excel Rescue, who are my consultancy partner. They help by providing solutions to smaller Excel problems.

What next?
Don't go yet, there is plenty more to learn on Excel Off The Grid.  Check out the latest posts:

Leave a Reply

Your email address will not be published. Required fields are marked *