Rearrange Columns by position

hatstand

Well-known Member
Joined
Mar 17, 2005
Messages
778
Office Version
  1. 2016
Platform
  1. Windows
Hi All,

If I have Column1, Column2, Column3 and add a new Column and then move this to position 2, the code will reflect this. The problem is that if new columns are added to the data or renamed etc the code will fail.

Can I add a new column but directly into position 2 or can I move the column without the list needing to list all the existing columns?

I have read numerous pages and watched numerus videos but can't seem to find an answer. so any help would be very much appreciated.
 

Excel Facts

How to change case of text in Excel?
Use =UPPER() for upper case, =LOWER() for lower case, and =PROPER() for proper case. PROPER won't capitalize second c in Mccartney
You can use a combination of List.RemoveRange and List.InsertRange to move items around in a list, so applying that to Table.ColumnNames should get the result you need.
 
Upvote 0
Solution
Thanks Rory. That gave me what I needed to solve it. I'm quite new to query, so it took a while. Here is the code I created, just in case anyone needs it in future.
let
Source = MyFile,
Sheet1_Sheet = Source{[Item="Sheet1",Kind="Sheet"]}[Data],
#"Promoted Headers" = Table.PromoteHeaders(Sheet1_Sheet, [PromoteAllScalars=true]),

// Get the index of the column "Column6"
Column3Index = List.PositionOf(Table.ColumnNames(#"Promoted Headers"), "Header6"),

// Exclude "Column6" from the list of columns
ColumnsList = List.RemoveItems(Table.ColumnNames(#"Promoted Headers"), {"Header6"}),

// Calculate the new position for "Column6" after excluding it from the list
NewPosition = if Column3Index < 2 then 1 else Column3Index - 3,

// Insert "Column6" at the desired position
ReorderedColumns = Table.ReorderColumns(#"Promoted Headers", List.InsertRange(ColumnsList, NewPosition, {"Header6"}))
in
ReorderedColumns
 
Upvote 0

Forum statistics

Threads
1,223,956
Messages
6,175,609
Members
452,660
Latest member
Zatman

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