diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml index 4bf449587c..1c222d63e0 100644 --- a/doc/src/sgml/ref/alter_table.sgml +++ b/doc/src/sgml/ref/alter_table.sgml @@ -203,10 +203,11 @@ WITH ( MODULUS numeric_literal, REM SET/DROP DEFAULT - These forms set or remove the default value for a column. - Default values only apply in subsequent INSERT - or UPDATE commands; they do not cause rows already in the - table to change. + These forms set or remove the default value for a column (where + removal is equivalent to setting the default value to NULL). The new + default value will only apply in subsequent INSERT + or UPDATE commands; it does not cause rows already + in the table to change. @@ -268,6 +269,10 @@ WITH ( MODULUS numeric_literal, REM These forms change whether a column is an identity column or change the generation attribute of an existing identity column. See for details. + Like SET DEFAULT, these forms only affect the + behavior of subsequent INSERT + and UPDATE commands; they do not cause rows + already in the table to change. @@ -1370,6 +1375,32 @@ WITH ( MODULUS numeric_literal, REM ALTER TABLE distributors ADD COLUMN address varchar(30); + That will cause all existing rows in the table to be filled with null + values for the new column. + + + + To add a column with a non-null default: + +ALTER TABLE measurements + ADD COLUMN mtime timestamp with time zone DEFAULT now(); + + Existing rows will be filled with the current time as the value of the + new column, and then new rows will receive the time of their insertion. + + + + To add a column and fill it with a value different from the default to + be used later: + +ALTER TABLE transactions + ADD COLUMN status varchar(30) DEFAULT 'old', + ALTER COLUMN status SET default 'current'; + + Existing rows will be filled with old, but then + the default for subsequent commands will be current. + The effects are the same as if the two sub-commands had been issued + in separate ALTER TABLE commands. diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c index 30b72b6297..faf0db99e2 100644 --- a/src/backend/commands/tablecmds.c +++ b/src/backend/commands/tablecmds.c @@ -6126,14 +6126,18 @@ ATExecAddColumn(List **wqueue, AlteredTableInfo *tab, Relation rel, * returned by AddRelationNewConstraints, so that the right thing happens * when a datatype's default applies. * - * We skip this step completely for views and foreign tables. For a view, - * we can only get here from CREATE OR REPLACE VIEW, which historically - * doesn't set up defaults, not even for domain-typed columns. And in any - * case we mustn't invoke Phase 3 on a view or foreign table, since they - * have no storage. + * Note: it might seem that this should happen at the end of Phase 2, so + * that the effects of subsequent subcommands can be taken into account. + * It's intentional that we do it now, though. The new column should be + * filled according to what is said in the ADD COLUMN subcommand, so that + * the effects are the same as if this subcommand had been run by itself + * and the later subcommands had been issued in new ALTER TABLE commands. + * + * We can skip this entirely for relations without storage, since Phase 3 + * is certainly not going to touch them. System attributes don't have + * interesting defaults, either. */ - if (relkind != RELKIND_VIEW && relkind != RELKIND_COMPOSITE_TYPE - && relkind != RELKIND_FOREIGN_TABLE && attribute.attnum > 0) + if (RELKIND_HAS_STORAGE(relkind) && attribute.attnum > 0) { /* * For an identity column, we can't use build_column_default(), diff --git a/src/test/regress/expected/identity.out b/src/test/regress/expected/identity.out index 7cf4696ec9..1a614b85f9 100644 --- a/src/test/regress/expected/identity.out +++ b/src/test/regress/expected/identity.out @@ -409,6 +409,12 @@ ALTER TABLE itest8 ALTER COLUMN f5 DROP NOT NULL, ALTER COLUMN f5 SET DATA TYPE bigint; INSERT INTO itest8 VALUES(0), (1); +-- This does not work when the table isn't empty. That's intentional, +-- since ADD GENERATED should only affect later insertions: +ALTER TABLE itest8 + ADD COLUMN f22 int NOT NULL, + ALTER COLUMN f22 ADD GENERATED ALWAYS AS IDENTITY; +ERROR: column "f22" contains null values TABLE itest8; f1 | f2 | f3 | f4 | f5 ----+----+----+----+---- diff --git a/src/test/regress/sql/identity.sql b/src/test/regress/sql/identity.sql index 685607c90c..b4cdd21bdd 100644 --- a/src/test/regress/sql/identity.sql +++ b/src/test/regress/sql/identity.sql @@ -269,6 +269,12 @@ ALTER TABLE itest8 INSERT INTO itest8 VALUES(0), (1); +-- This does not work when the table isn't empty. That's intentional, +-- since ADD GENERATED should only affect later insertions: +ALTER TABLE itest8 + ADD COLUMN f22 int NOT NULL, + ALTER COLUMN f22 ADD GENERATED ALWAYS AS IDENTITY; + TABLE itest8; \d+ itest8 \d itest8_f2_seq