Thread: Default Value Retention After Dropping Default
Hi folks, I am experiencing an interesting behavior in PostgreSQL and would like to seek some clarification. In the following snippet, I first add a column with a default value, then drop that default. However, when I query the table, the column still retains the dropped default for existing rows: SET client_min_messages=debug1; DROP TABLE IF EXISTS foo CASCADE; CREATE TABLE foo (id SERIAL PRIMARY KEY); INSERT INTO foo (id) SELECT generate_series(1, 10000); ALTER TABLE foo ADD COLUMN bar varchar(255) NOT NULL DEFAULT 'default'; ALTER TABLE foo ALTER COLUMN bar DROP DEFAULT; SELECT * from foo order by id desc limit 5; -- id | bar -- -------+--------- -- 10000 | default -- 9999 | default -- 9998 | default -- 9997 | default -- 9996 | default In this example, even after dropping the default value from the bar column, the rows that were previously inserted (prior to dropping the default) still show 'default' as their value in the bar column. It does not see that the table has been rewritten or rescanned, otherwise the debug1 messages would be triggered. Can anyone explain how PostgreSQL "knows about" the default value that has just been dropped and what is happened under the scenes? I am keen on a deep understanding on how Postgres achieves this. Here is what I could find in the docs, but it does not satisfy my question: > From PostgreSQL 11, adding a column with a constant default value no longer > means that each row of the table needs to be updated when the ALTER TABLE > statement is executed. Instead, the default value will be returned the next > time the row is accessed, and applied when the table is rewritten, making the > ALTER TABLE very fast even on large tables. https://www.postgresql.org/docs/current/ddl-alter.html#DDL-ALTER-ADDING-A-COLUMN
On Mon, 2025-02-24 at 20:56 +1300, Marcelo Fernandes wrote: > I am experiencing an interesting behavior in PostgreSQL and would like to seek > some clarification. > > In the following snippet, I first add a column with a default value, then drop > that default. However, when I query the table, the column still retains the > dropped default for existing rows: > > SET client_min_messages=debug1; > > DROP TABLE IF EXISTS foo CASCADE; > CREATE TABLE foo (id SERIAL PRIMARY KEY); > > INSERT INTO foo (id) SELECT generate_series(1, 10000); > > ALTER TABLE foo ADD COLUMN bar varchar(255) NOT NULL DEFAULT 'default'; > ALTER TABLE foo ALTER COLUMN bar DROP DEFAULT; > > SELECT * from foo order by id desc limit 5; > -- id | bar > -- -------+--------- > -- 10000 | default > -- 9999 | default > -- 9998 | default > -- 9997 | default > -- 9996 | default > > In this example, even after dropping the default value from the bar column, the > rows that were previously inserted (prior to dropping the default) still show > 'default' as their value in the bar column. > > It does not see that the table has been rewritten or rescanned, otherwise the > debug1 messages would be triggered. > > Can anyone explain how PostgreSQL "knows about" the default value that has just > been dropped and what is happened under the scenes? I am keen on a deep > understanding on how Postgres achieves this. The "missing value" is stored in pg_attribute.admissingval: SELECT attmissingval FROM pg_attribute WHERE attrelid = 'foo'::regclass AND attname = 'bar'; attmissingval ═══════════════ {default} (1 row) That value is used for all rows that don't yet physically have the column. Yours, Laurenz Albe -- *E-Mail Disclaimer* Der Inhalt dieser E-Mail ist ausschliesslich fuer den bezeichneten Adressaten bestimmt. Wenn Sie nicht der vorgesehene Adressat dieser E-Mail oder dessen Vertreter sein sollten, so beachten Sie bitte, dass jede Form der Kenntnisnahme, Veroeffentlichung, Vervielfaeltigung oder Weitergabe des Inhalts dieser E-Mail unzulaessig ist. Wir bitten Sie, sich in diesem Fall mit dem Absender der E-Mail in Verbindung zu setzen. *CONFIDENTIALITY NOTICE & DISCLAIMER *This message and any attachment are confidential and may be privileged or otherwise protected from disclosure and solely for the use of the person(s) or entity to whom it is intended. If you have received this message in error and are not the intended recipient, please notify the sender immediately and delete this message and any attachment from your system. If you are not the intended recipient, be advised that any use of this message is prohibited and may be unlawful, and you must not copy this message or attachment or disclose the contents to any other person.
On 2/23/25 23:56, Marcelo Fernandes wrote: > Hi folks, > > I am experiencing an interesting behavior in PostgreSQL and would like to seek > some clarification. > > In the following snippet, I first add a column with a default value, then drop > that default. However, when I query the table, the column still retains the > dropped default for existing rows: > > SET client_min_messages=debug1; > > DROP TABLE IF EXISTS foo CASCADE; > CREATE TABLE foo (id SERIAL PRIMARY KEY); > > INSERT INTO foo (id) SELECT generate_series(1, 10000); > > ALTER TABLE foo ADD COLUMN bar varchar(255) NOT NULL DEFAULT 'default'; > ALTER TABLE foo ALTER COLUMN bar DROP DEFAULT; > > SELECT * from foo order by id desc limit 5; > -- id | bar > -- -------+--------- > -- 10000 | default > -- 9999 | default > -- 9998 | default > -- 9997 | default > -- 9996 | default > > In this example, even after dropping the default value from the bar column, the > rows that were previously inserted (prior to dropping the default) still show > 'default' as their value in the bar column. From https://www.postgresql.org/docs/current/sql-createtable.html " DEFAULT default_expr The DEFAULT clause assigns a default data value for the column whose column definition it appears within. The value is any variable-free expression (in particular, cross-references to other columns in the current table are not allowed). Subqueries are not allowed either. The data type of the default expression must match the data type of the column. The default expression will be used in any insert operation that does not specify a value for the column. If there is no default for a column, then the default is null. " The DEFAULT is just a value that is entered when you do not explicitly provide a value for a given field. That value is saved just like any other value and will not disappear once it is no longer the DEFAULT. > > It does not see that the table has been rewritten or rescanned, otherwise the > debug1 messages would be triggered. > > Can anyone explain how PostgreSQL "knows about" the default value that has just > been dropped and what is happened under the scenes? I am keen on a deep > understanding on how Postgres achieves this. > > Here is what I could find in the docs, but it does not satisfy my question: > >> From PostgreSQL 11, adding a column with a constant default value no longer >> means that each row of the table needs to be updated when the ALTER TABLE >> statement is executed. Instead, the default value will be returned the next >> time the row is accessed, and applied when the table is rewritten, making the >> ALTER TABLE very fast even on large tables. > > https://www.postgresql.org/docs/current/ddl-alter.html#DDL-ALTER-ADDING-A-COLUMN > > -- Adrian Klaver adrian.klaver@aklaver.com
On 2/24/25 03:50, Laurenz Albe wrote: > On Mon, 2025-02-24 at 20:56 +1300, Marcelo Fernandes wrote: >> I am experiencing an interesting behavior in PostgreSQL and would like to seek >> some clarification. >> >> Can anyone explain how PostgreSQL "knows about" the default value that has just >> been dropped and what is happened under the scenes? I am keen on a deep >> understanding on how Postgres achieves this. > > The "missing value" is stored in pg_attribute.admissingval: > > SELECT attmissingval > FROM pg_attribute > WHERE attrelid = 'foo'::regclass > AND attname = 'bar'; > > attmissingval > ═══════════════ > {default} > (1 row) > > That value is used for all rows that don't yet physically have the column. That answers this part of the process: ALTER TABLE foo ADD COLUMN bar varchar(255) NOT NULL DEFAULT 'default'; I believe the OP is asking about this: ALTER TABLE foo ALTER COLUMN bar DROP DEFAULT; Because if after dropping the DEFAULT you do this: INSERT INTO foo (id) SELECT generate_series(1001, 1010); You get: ERROR: null value in column "bar" of relation "foo" violates not-null constraint DETAIL: Failing row contains (1001, null). The DEFAULT is no longer in use, but the values still exist in the previously entered rows: SELECT * from foo order by id desc limit 5; id | bar -------+--------- 10000 | default 9999 | default 9998 | default 9997 | default 9996 | default > > Yours, > Laurenz Albe > -- Adrian Klaver adrian.klaver@aklaver.com
On Mon, Feb 24, 2025 at 9:37 AM Adrian Klaver <adrian.klaver@aklaver.com> wrote:
On 2/24/25 03:50, Laurenz Albe wrote:
> On Mon, 2025-02-24 at 20:56 +1300, Marcelo Fernandes wrote:
>> I am experiencing an interesting behavior in PostgreSQL and would like to seek
>> some clarification.
>>
>> Can anyone explain how PostgreSQL "knows about" the default value that has just
>> been dropped and what is happened under the scenes? I am keen on a deep
>> understanding on how Postgres achieves this.
>
> The "missing value" is stored in pg_attribute.admissingval:
>
> SELECT attmissingval
> FROM pg_attribute
> WHERE attrelid = 'foo'::regclass
> AND attname = 'bar';
>
> attmissingval
> ═══════════════
> {default}
> (1 row)
>
> That value is used for all rows that don't yet physically have the column.
That answers this part of the process:
ALTER TABLE foo ADD COLUMN bar varchar(255) NOT NULL DEFAULT 'default';
I believe the OP is asking about this:
ALTER TABLE foo ALTER COLUMN bar DROP DEFAULT;
Because if after dropping the DEFAULT you do this:
INSERT INTO foo (id) SELECT generate_series(1001, 1010);
You get:
ERROR: null value in column "bar" of relation "foo" violates not-null
constraint
DETAIL: Failing row contains (1001, null).
The DEFAULT is no longer in use, but the values still exist in the
previously entered rows:
The alter table command established a persistent substitute value for the new column, for all existing rows, when it was executed. While the value of the substitute is equal to the non-volatile default specified for the column it is an independent thing. Subsequently dropping or changing the default does not impact this substitute value. There is no way to impact the substitute value via SQL that I know of.
David J.