In an Oracle database, once a table is created, there is no obvious way to change the order of its columns. Sometimes you add a new column to an existing table and want it to be displayed in a different position by default for query results via SELECT *
. Imagine you add an ID column to a table after the fact. Wouldn’t it be nice if this appeared in the first position?
Of course you can drop the whole table and create it again with the new column order. But this is cumbersome and potentially dangerous if the table is already filled with data. However, there is a trick that allows you to rearrange the columns without having to recreate the table.
The key to this is an Oracle feature that allows invisible columns. The feature itself is interesting in its own right, but it has a useful side effect that we’ll exploit. The documentation says:
When you make an invisible column visible, the column is included in the table’s column order as the last column. When you make a visible column invisible, the invisible column is not included in the column order, and the order of the visible columns in the table might be re-arranged.
So the plan is to make the appropriate columns invisible first by clever choice, and then to make them visible again in the desired order. This is how it works:
First we have a table with the following columns.
CREATE TABLE t (a NUMBER, b NUMBER, c NUMBER, e NUMBER, f NUMBER);
Later we realize that we need a column d
that should be between c
and f
. So we add it to the table:
ALTER TABLE t ADD (d NUMBER);
This is of course added at the end:
DESC t;
Name Null? Type
---- ----- ------
A NUMBER
B NUMBER
C NUMBER
E NUMBER
F NUMBER
D NUMBER
To get it in the right position, we first hide the columns e
and f
, and then make them visible again.
ALTER TABLE t MODIFY (e INVISIBLE, f INVISIBLE);
ALTER TABLE t MODIFY (e VISIBLE, f VISIBLE);
And voilà, we have our desired order:
DESC t;
Name Null? Type
---- ----- ------
A NUMBER
B NUMBER
C NUMBER
D NUMBER
E NUMBER
F NUMBER
Note that this doesn’t change the internal, physical layout of the table on the disk. It’s just a cosmetic change.
Nice one!