Thread: ALTER COLUMN to change GENERATED ALWAYS AS expression?
Hi all, I have a column defined GENERATED ALWAYS AS {my_expression} STORED. I’d like to change the {my_expression} part. After readingthe documentation for ALTER TABLE (https://www.postgresql.org/docs/current/sql-altertable.html) and trying a few thingsthat resulted in syntax errors, there doesn’t seem to be a way to alter the column’s GENERATED expression in place.It seems like my only option is to drop and re-add the column. Is that correct? Thanks Philip
On Mon, 2023-02-06 at 12:04 -0500, Philip Semanchuk wrote: > I have a column defined GENERATED ALWAYS AS {my_expression} STORED. I’d like to change the > {my_expression} part. After reading the documentation for ALTER TABLE > (https://www.postgresql.org/docs/current/sql-altertable.html) and trying a few things that > resulted in syntax errors, there doesn’t seem to be a way to alter the column’s GENERATED > expression in place. It seems like my only option is to drop and re-add the column. > Is that correct? I think that is correct. But changing the expression would mean rewriting the column anyway. The only downside is that a dropped column remains in the table, and no even a VACUUM (FULL) will get rid of it. Yours, Laurenz Albe
> On Feb 7, 2023, at 3:30 AM, Laurenz Albe <laurenz.albe@cybertec.at> wrote: > > On Mon, 2023-02-06 at 12:04 -0500, Philip Semanchuk wrote: >> I have a column defined GENERATED ALWAYS AS {my_expression} STORED. I’d like to change the >> {my_expression} part. After reading the documentation for ALTER TABLE >> (https://www.postgresql.org/docs/current/sql-altertable.html) and trying a few things that >> resulted in syntax errors, there doesn’t seem to be a way to alter the column’s GENERATED >> expression in place. It seems like my only option is to drop and re-add the column. >> Is that correct? > > I think that is correct. But changing the expression would mean rewriting the column > anyway. The only downside is that a dropped column remains in the table, and no even > a VACUUM (FULL) will get rid of it. Thanks for the confirmation. I hadn’t realized that the column would remain in the table even after a DROP + VACUUM FULL.I’m curious — its presence as a deleted column doesn't affect performance in any meaningful way, does it? In this case we have the option of dropping and re-creating the table entirely, and that's probably what I'll do. Cheers Philip
On 2/7/23 06:09, Philip Semanchuk wrote: > > >> On Feb 7, 2023, at 3:30 AM, Laurenz Albe <laurenz.albe@cybertec.at> wrote: >> >> On Mon, 2023-02-06 at 12:04 -0500, Philip Semanchuk wrote: >>> I have a column defined GENERATED ALWAYS AS {my_expression} STORED. I’d like to change the >>> {my_expression} part. After reading the documentation for ALTER TABLE >>> (https://www.postgresql.org/docs/current/sql-altertable.html) and trying a few things that >>> resulted in syntax errors, there doesn’t seem to be a way to alter the column’s GENERATED >>> expression in place. It seems like my only option is to drop and re-add the column. >>> Is that correct? >> >> I think that is correct. But changing the expression would mean rewriting the column >> anyway. The only downside is that a dropped column remains in the table, and no even >> a VACUUM (FULL) will get rid of it. > > Thanks for the confirmation. I hadn’t realized that the column would remain in the table even after a DROP + VACUUM FULL.I’m curious — its presence as a deleted column doesn't affect performance in any meaningful way, does it? From docs: https://www.postgresql.org/docs/current/sql-altertable.html "The DROP COLUMN form does not physically remove the column, but simply makes it invisible to SQL operations. Subsequent insert and update operations in the table will store a null value for the column. Thus, dropping a column is quick but it will not immediately reduce the on-disk size of your table, as the space occupied by the dropped column is not reclaimed. The space will be reclaimed over time as existing rows are updated. To force immediate reclamation of space occupied by a dropped column, you can execute one of the forms of ALTER TABLE that performs a rewrite of the whole table. This results in reconstructing each row with the dropped column replaced by a null value." > > In this case we have the option of dropping and re-creating the table entirely, and that's probably what I'll do. > > Cheers > Philip > -- Adrian Klaver adrian.klaver@aklaver.com
On 2/7/23 09:06, Adrian Klaver wrote:
VACUUM FULL doesn't rewrite the table?
The doc page seems to say that it does:
https://www.postgresql.org/docs/current/sql-vacuum.html
"
On 2/7/23 06:09, Philip Semanchuk wrote:On Feb 7, 2023, at 3:30 AM, Laurenz Albe <laurenz.albe@cybertec.at> wrote:
On Mon, 2023-02-06 at 12:04 -0500, Philip Semanchuk wrote:I have a column defined GENERATED ALWAYS AS {my_expression} STORED. I’d like to change the
{my_expression} part. After reading the documentation for ALTER TABLE
(https://www.postgresql.org/docs/current/sql-altertable.html) and trying a few things that
resulted in syntax errors, there doesn’t seem to be a way to alter the column’s GENERATED
expression in place. It seems like my only option is to drop and re-add the column.
Is that correct?
I think that is correct. But changing the expression would mean rewriting the column
anyway. The only downside is that a dropped column remains in the table, and no even
a VACUUM (FULL) will get rid of it.
Thanks for the confirmation. I hadn’t realized that the column would remain in the table even after a DROP + VACUUM FULL. I’m curious — its presence as a deleted column doesn't affect performance in any meaningful way, does it?
From docs:
https://www.postgresql.org/docs/current/sql-altertable.html
"The DROP COLUMN form does not physically remove the column, but simply makes it invisible to SQL operations. Subsequent insert and update operations in the table will store a null value for the column. Thus, dropping a column is quick but it will not immediately reduce the on-disk size of your table, as the space occupied by the dropped column is not reclaimed. The space will be reclaimed over time as existing rows are updated.
To force immediate reclamation of space occupied by a dropped column, you can execute one of the forms of ALTER TABLE that performs a rewrite of the whole table. This results in reconstructing each row with the dropped column replaced by a null value."
VACUUM FULL doesn't rewrite the table?
The doc page seems to say that it does:
https://www.postgresql.org/docs/current/sql-vacuum.html
"
VACUUM FULL
rewrites the entire contents of the table into a new disk file with no extra space".--
Born in Arizona, moved to Babylonia.
Born in Arizona, moved to Babylonia.
On Tue, 2023-02-07 at 12:40 -0600, Ron wrote: > > "The DROP COLUMN form does not physically remove the column, but simply makes it > > invisible to SQL operations. Subsequent insert and update operations in the table > > will store a null value for the column. Thus, dropping a column is quick but it > > will not immediately reduce the on-disk size of your table, as the space occupied > > by the dropped column is not reclaimed. The space will be reclaimed over time as > > existing rows are updated. > > > > To force immediate reclamation of space occupied by a dropped column, you can > > execute one of the forms of ALTER TABLE that performs a rewrite of the whole table. > > This results in reconstructing each row with the dropped column replaced by a > > null value." > > VACUUM FULL doesn't rewrite the table? It rewrites the table, but it just copies rows rather than reconstructing them. Yours, Laurenz Albe
Ron <ronljohnsonjr@gmail.com> writes: > On 2/7/23 09:06, Adrian Klaver wrote: >> To force immediate reclamation of space occupied by a dropped column, you >> can execute one of the forms of ALTER TABLE that performs a rewrite of the >> whole table. This results in reconstructing each row with the dropped >> column replaced by a null value." > VACUUM FULL doesn't rewrite the table? It moves all the tuples into a new file, but it does not rebuild individual tuples, as would be needed to delete column values. regards, tom lane
On 2/7/23 09:06, Adrian Klaver wrote:
VACUUM FULL doesn't rewrite the table?
The doc page seems to say that it does:
https://www.postgresql.org/docs/current/sql-vacuum.html
"
On 2/7/23 06:09, Philip Semanchuk wrote:On Feb 7, 2023, at 3:30 AM, Laurenz Albe <laurenz.albe@cybertec.at> wrote:
On Mon, 2023-02-06 at 12:04 -0500, Philip Semanchuk wrote:I have a column defined GENERATED ALWAYS AS {my_expression} STORED. I’d like to change the
{my_expression} part. After reading the documentation for ALTER TABLE
(https://www.postgresql.org/docs/current/sql-altertable.html) and trying a few things that
resulted in syntax errors, there doesn’t seem to be a way to alter the column’s GENERATED
expression in place. It seems like my only option is to drop and re-add the column.
Is that correct?
I think that is correct. But changing the expression would mean rewriting the column
anyway. The only downside is that a dropped column remains in the table, and no even
a VACUUM (FULL) will get rid of it.
Thanks for the confirmation. I hadn’t realized that the column would remain in the table even after a DROP + VACUUM FULL. I’m curious — its presence as a deleted column doesn't affect performance in any meaningful way, does it?
From docs:
https://www.postgresql.org/docs/current/sql-altertable.html
"The DROP COLUMN form does not physically remove the column, but simply makes it invisible to SQL operations. Subsequent insert and update operations in the table will store a null value for the column. Thus, dropping a column is quick but it will not immediately reduce the on-disk size of your table, as the space occupied by the dropped column is not reclaimed. The space will be reclaimed over time as existing rows are updated.
To force immediate reclamation of space occupied by a dropped column, you can execute one of the forms of ALTER TABLE that performs a rewrite of the whole table. This results in reconstructing each row with the dropped column replaced by a null value."
VACUUM FULL doesn't rewrite the table?
The doc page seems to say that it does:
https://www.postgresql.org/docs/current/sql-vacuum.html
"
VACUUM FULL
rewrites the entire contents of the table into a new disk file with no extra space".--
Born in Arizona, moved to Babylonia.
Born in Arizona, moved to Babylonia.
Ignore this...
On 2/7/23 13:05, Ron wrote:
On 2/7/23 09:06, Adrian Klaver wrote:On 2/7/23 06:09, Philip Semanchuk wrote:On Feb 7, 2023, at 3:30 AM, Laurenz Albe <laurenz.albe@cybertec.at> wrote:
On Mon, 2023-02-06 at 12:04 -0500, Philip Semanchuk wrote:I have a column defined GENERATED ALWAYS AS {my_expression} STORED. I’d like to change the
{my_expression} part. After reading the documentation for ALTER TABLE
(https://www.postgresql.org/docs/current/sql-altertable.html) and trying a few things that
resulted in syntax errors, there doesn’t seem to be a way to alter the column’s GENERATED
expression in place. It seems like my only option is to drop and re-add the column.
Is that correct?
I think that is correct. But changing the expression would mean rewriting the column
anyway. The only downside is that a dropped column remains in the table, and no even
a VACUUM (FULL) will get rid of it.
Thanks for the confirmation. I hadn’t realized that the column would remain in the table even after a DROP + VACUUM FULL. I’m curious — its presence as a deleted column doesn't affect performance in any meaningful way, does it?
From docs:
https://www.postgresql.org/docs/current/sql-altertable.html
"The DROP COLUMN form does not physically remove the column, but simply makes it invisible to SQL operations. Subsequent insert and update operations in the table will store a null value for the column. Thus, dropping a column is quick but it will not immediately reduce the on-disk size of your table, as the space occupied by the dropped column is not reclaimed. The space will be reclaimed over time as existing rows are updated.
To force immediate reclamation of space occupied by a dropped column, you can execute one of the forms of ALTER TABLE that performs a rewrite of the whole table. This results in reconstructing each row with the dropped column replaced by a null value."
VACUUM FULL doesn't rewrite the table?
The doc page seems to say that it does:
https://www.postgresql.org/docs/current/sql-vacuum.html
"VACUUM FULL
rewrites the entire contents of the table into a new disk file with no extra space".--
Born in Arizona, moved to Babylonia.
--
Born in Arizona, moved to Babylonia.
Born in Arizona, moved to Babylonia.