Обсуждение: Increasing a NUMERIC column precision doesn't cause a table rewrite. Why?
Increasing a NUMERIC column precision doesn't cause a table rewrite. Why?
От
Marcelo Fernandes
Дата:
Hi everyone, A numeric field is defined as: NUMERIC(precision, scale) [0]. After doing some playing around with different operations against a numeric column, namely: increasing/decreasing the precision or increasing/decreasing the scale, I noticed that the table is rewritten in all cases except when increasing the precision number. Take the following snippet as example (tested on postgres 15): ```sql CREATE DATABASE test_precision_field; -- \c test_precision_field SET client_min_messages=debug1; DROP TABLE IF EXISTS foo; CREATE TABLE foo (id SERIAL PRIMARY KEY, bar NUMERIC(10, 2)); -- Only increase precision but keep the scale: -- This does not rewrite the table ALTER TABLE foo ALTER COLUMN bar TYPE numeric(20, 2); -- Only decrease the precision but keep the scale: -- This rewrites the table. ALTER TABLE foo ALTER COLUMN bar TYPE numeric(10, 2); -- DEBUG: rewriting table "foo" -- DEBUG: building index "foo_pkey" on table "foo" serially -- DEBUG: index "foo_pkey" can safely use deduplication -- Only increase the scale, but keep the precision: -- This rewrites the table. ALTER TABLE foo ALTER COLUMN bar TYPE numeric(10, 4); -- DEBUG: rewriting table "foo" -- DEBUG: building index "foo_pkey" on table "foo" serially -- DEBUG: index "foo_pkey" can safely use deduplication -- Only decrease the scale, but keep the precision: -- This rewrites the table. ALTER TABLE foo ALTER COLUMN bar TYPE numeric(10, 2); -- DEBUG: rewriting table "foo" -- DEBUG: building index "foo_pkey" on table "foo" serially -- DEBUG: index "foo_pkey" can safely use deduplication ``` My assumption is that once the precision is increased, Postgres can still interpret the old values that were generated with a lower precision, whereas this is not possible for any other types of changes on the numeric field. Is that assumption correct? How can I verify it? For example, is there a catalog table I can have a look to see how these values are defined, along with some form of documentation to understand how they are interpreted by Postgres? Thank you, Marcelo. - [0] https://www.postgresql.org/docs/current/datatype-numeric.html#DATATYPE-NUMERIC-DECIMAL
From: Marcelo Fernandes <marcefern7@gmail.com>Date: Monday, November 3, 2025 at 5:24 AMTo: pgsql-general@lists.postgresql.org <pgsql-general@lists.postgresql.org>Subject: Increasing a NUMERIC column precision doesn't cause a table rewrite. Why?Hi everyone,A numeric field is defined as: NUMERIC(precision, scale) [0].After doing some playing around with different operations against a numericcolumn, namely: increasing/decreasing the precision or increasing/decreasingthe scale, I noticed that the table is rewritten in all cases except whenincreasing the precision number.Take the following snippet as example (tested on postgres 15):```sqlCREATE DATABASE test_precision_field;-- \c test_precision_fieldSET client_min_messages=debug1;DROP TABLE IF EXISTS foo;CREATE TABLE foo (id SERIAL PRIMARY KEY, bar NUMERIC(10, 2));-- Only increase precision but keep the scale:-- This does not rewrite the tableALTER TABLE foo ALTER COLUMN bar TYPE numeric(20, 2);-- Only decrease the precision but keep the scale:-- This rewrites the table.ALTER TABLE foo ALTER COLUMN bar TYPE numeric(10, 2);-- DEBUG: rewriting table "foo"-- DEBUG: building index "foo_pkey" on table "foo" serially-- DEBUG: index "foo_pkey" can safely use deduplication-- Only increase the scale, but keep the precision:-- This rewrites the table.ALTER TABLE foo ALTER COLUMN bar TYPE numeric(10, 4);-- DEBUG: rewriting table "foo"-- DEBUG: building index "foo_pkey" on table "foo" serially-- DEBUG: index "foo_pkey" can safely use deduplication-- Only decrease the scale, but keep the precision:-- This rewrites the table.ALTER TABLE foo ALTER COLUMN bar TYPE numeric(10, 2);-- DEBUG: rewriting table "foo"-- DEBUG: building index "foo_pkey" on table "foo" serially-- DEBUG: index "foo_pkey" can safely use deduplication```My assumption is that once the precision is increased, Postgres can stillinterpret the old values that were generated with a lower precision, whereasthis is not possible for any other types of changes on the numeric field.Is that assumption correct? How can I verify it?For example, is there a catalog table I can have a look to see how these valuesare defined, along with some form of documentation to understand how they areinterpreted by Postgres?Thank you,Marcelo.
My understanding is that Postgres can guarantee that all the values in the table will fit the new precision without having to check. If you change the scale, it might be the case that some values won’t fit anymore and Postgres must return an error. Numeric by itself is a variable length type, similar to TEXT (in a sense). That’s why we can modify its size without requiring a table rewrite at all!
My understanding is that Postgres can guarantee that all the values in the table will fit the new precision without having to check. If you change the scale, it might be the case that some values won’t fit anymore, and Postgres must return an error. Numeric by itself is a variable length type, like TEXT (in a sense). That’s why we can modify its size without requiring a table rewrite at all!
Re: Increasing a NUMERIC column precision doesn't cause a table rewrite. Why?
От
Adrian Klaver
Дата:
On 11/3/25 00:24, Marcelo Fernandes wrote: > Hi everyone, > > A numeric field is defined as: NUMERIC(precision, scale) [0]. > > After doing some playing around with different operations against a numeric > column, namely: increasing/decreasing the precision or increasing/decreasing > the scale, I noticed that the table is rewritten in all cases except when > increasing the precision number. > > Take the following snippet as example (tested on postgres 15): > > ```sql > CREATE DATABASE test_precision_field; > -- \c test_precision_field > > SET client_min_messages=debug1; > > DROP TABLE IF EXISTS foo; > CREATE TABLE foo (id SERIAL PRIMARY KEY, bar NUMERIC(10, 2)); > > -- Only increase precision but keep the scale: > -- This does not rewrite the table > ALTER TABLE foo ALTER COLUMN bar TYPE numeric(20, 2); > > -- Only decrease the precision but keep the scale: > -- This rewrites the table. > ALTER TABLE foo ALTER COLUMN bar TYPE numeric(10, 2); > -- DEBUG: rewriting table "foo" > -- DEBUG: building index "foo_pkey" on table "foo" serially > -- DEBUG: index "foo_pkey" can safely use deduplication > > -- Only increase the scale, but keep the precision: > -- This rewrites the table. > ALTER TABLE foo ALTER COLUMN bar TYPE numeric(10, 4); > -- DEBUG: rewriting table "foo" > -- DEBUG: building index "foo_pkey" on table "foo" serially > -- DEBUG: index "foo_pkey" can safely use deduplication > > -- Only decrease the scale, but keep the precision: > -- This rewrites the table. > ALTER TABLE foo ALTER COLUMN bar TYPE numeric(10, 2); > -- DEBUG: rewriting table "foo" > -- DEBUG: building index "foo_pkey" on table "foo" serially > -- DEBUG: index "foo_pkey" can safely use deduplication > ``` > > My assumption is that once the precision is increased, Postgres can still > interpret the old values that were generated with a lower precision, whereas > this is not possible for any other types of changes on the numeric field. > > Is that assumption correct? How can I verify it? > > For example, is there a catalog table I can have a look to see how these values > are defined, along with some form of documentation to understand how they are > interpreted by Postgres? Short version: https://www.postgresql.org/docs/current/datatype-numeric.html#DATATYPE-NUMERIC-DECIMAL " Numeric values are physically stored without any extra leading or trailing zeroes. Thus, the declared precision and scale of a column are maximums, not fixed allocations. (In this sense the numeric type is more akin to varchar(n) than to char(n).) The actual storage requirement is two bytes for each group of four decimal digits, plus three to eight bytes overhead. " Long version, numeric.c: https://github.com/postgres/postgres/blob/master/src/backend/utils/adt/numeric.c > > Thank you, > Marcelo. > > - [0] https://www.postgresql.org/docs/current/datatype-numeric.html#DATATYPE-NUMERIC-DECIMAL > > -- Adrian Klaver adrian.klaver@aklaver.com
Marcelo Fernandes <marcefern7@gmail.com> writes: > After doing some playing around with different operations against a numeric > column, namely: increasing/decreasing the precision or increasing/decreasing > the scale, I noticed that the table is rewritten in all cases except when > increasing the precision number. Yup. > For example, is there a catalog table I can have a look to see how these values > are defined, along with some form of documentation to understand how they are > interpreted by Postgres? You'd have to look into the source code: https://github.com/postgres/postgres/blob/c4067383cb2c155c4cfea2351036709e2ebb3535/src/backend/utils/adt/numeric.c The first few hundred lines of numeric.c are largely comments that you'd find relevant. Also see numeric_support(): https://github.com/postgres/postgres/blob/c4067383cb2c155c4cfea2351036709e2ebb3535/src/backend/utils/adt/numeric.c#L1179 ALTER TABLE skips table rewrite if the datatype conversion expression is simplified to a no-op by a support function such as numeric_support. regards, tom lane