Difference in dump from original and restored database due to NOT NULL constraints on children

Started by Ashutosh Bapatabout 1 year ago11 messages
#1Ashutosh Bapat
ashutosh.bapat.oss@gmail.com
4 attachment(s)

Hi Alvaro,
Because of the test I am developing under discussion at [1], I noticed
that the DDLs dumped for inheritance children with NOT NULL
constraints defer between original database and database restored from
a dump of original database. I investigated those differences, but can
not decide whether they are expected and whether they are intentional
or not. Look something related to
14e87ffa5c543b5f30ead7413084c25f7735039f.

I have attached four files. Original dumps from source (src_dump.sql)
and restored databases (dest_dump.plain.sql). Dumps adjusted for known
differences (src_dump.sql_adjusted and
dest_dump.plain.sql_adjusted respectively)
as per AdjustDump.pm module added by 0001 patch attached to [1].

Are these differences safe? Are they intentional?

--
Best Wishes,
Ashutosh Bapat

Attachments:

src_dump.sql_adjustedapplication/octet-stream; name=src_dump.sql_adjustedDownload
dest_dump.plain.sqlapplication/sql; name=dest_dump.plain.sqlDownload
dest_dump.plain.sql_adjustedapplication/octet-stream; name=dest_dump.plain.sql_adjustedDownload
src_dump.sqlapplication/sql; name=src_dump.sqlDownload
#2Alvaro Herrera
alvherre@alvh.no-ip.org
In reply to: Ashutosh Bapat (#1)
Re: Difference in dump from original and restored database due to NOT NULL constraints on children

Hello Ashutosh,

On 2024-Nov-14, Ashutosh Bapat wrote:

Because of the test I am developing under discussion at [1], I noticed
that the DDLs dumped for inheritance children with NOT NULL
constraints defer between original database and database restored from
a dump of original database. I investigated those differences, but can
not decide whether they are expected and whether they are intentional
or not. Look something related to
14e87ffa5c543b5f30ead7413084c25f7735039f.

It does and it is, thanks.

So there are two differences:

1.

CREATE TABLE generated_stored_tests.gtest1 (
a integer NOT NULL,
b integer GENERATED ALWAYS AS ((a * 2)) STORED
);

 CREATE TABLE generated_stored_tests.gtestxx_4 (
-    a integer,
-    b integer NOT NULL
+    a integer NOT NULL,
+    b integer
 )
 INHERITS (generated_stored_tests.gtest1);

In this case, I think it's wrong to add NOT NULL to gtestxx_4.a because
the constraint was not local originally and it should be acquired by the
inheritance. I'm not sure about gtestxx_4.b ... the GENERATED
constraint should induce a not-null if I recall correctly, so an
explicit not-null marking in the child might not be necessary. But I'll
have a look.

2.

CREATE TABLE public.notnull_tbl4 (
a integer NOT NULL
);

 CREATE TABLE public.notnull_tbl4_cld2 (
 )
 INHERITS (public.notnull_tbl4);
-ALTER TABLE ONLY public.notnull_tbl4_cld2 ALTER COLUMN a SET NOT NULL;
+ALTER TABLE ONLY public.notnull_tbl4_cld2 ADD CONSTRAINT notnull_tbl4_a_not_null NOT NULL a;
 CREATE TABLE public.notnull_tbl4_cld3 (
 )
 INHERITS (public.notnull_tbl4);
-ALTER TABLE ONLY public.notnull_tbl4_cld3 ADD CONSTRAINT a_nn NOT NULL a;
+ALTER TABLE ONLY public.notnull_tbl4_cld3 ADD CONSTRAINT notnull_tbl4_a_not_null NOT NULL a;

For notnull_tbl4_cld2 we try to set the column not-null, but it's
already not-null due to inheritance ... so why are we doing that?
Weird. These lines should just go away in both dumps.

In notnull_tbl4_cld3's case we have the same, but we also want to set a
constraint name, but the constraint already exists, so that doesn't
work, and that's the reason why the next dump uses the standard name.
Maybe we could dump the name change as ALTER TABLE RENAME CONSTRAINT in
that case instead, _if_ we can obtain the original name (should be
doable, because we can see it's a nonstandard name.)

--
Álvaro Herrera 48°01'N 7°57'E — https://www.EnterpriseDB.com/

#3Ashutosh Bapat
ashutosh.bapat.oss@gmail.com
In reply to: Alvaro Herrera (#2)
Re: Difference in dump from original and restored database due to NOT NULL constraints on children

On Thu, Nov 14, 2024 at 6:08 PM Alvaro Herrera <alvherre@alvh.no-ip.org> wrote:

Hello Ashutosh,

On 2024-Nov-14, Ashutosh Bapat wrote:

Because of the test I am developing under discussion at [1], I noticed
that the DDLs dumped for inheritance children with NOT NULL
constraints defer between original database and database restored from
a dump of original database. I investigated those differences, but can
not decide whether they are expected and whether they are intentional
or not. Look something related to
14e87ffa5c543b5f30ead7413084c25f7735039f.

It does and it is, thanks.

So there are two differences:

1.

CREATE TABLE generated_stored_tests.gtest1 (
a integer NOT NULL,
b integer GENERATED ALWAYS AS ((a * 2)) STORED
);

CREATE TABLE generated_stored_tests.gtestxx_4 (
-    a integer,
-    b integer NOT NULL
+    a integer NOT NULL,
+    b integer
)
INHERITS (generated_stored_tests.gtest1);

In this case, I think it's wrong to add NOT NULL to gtestxx_4.a because
the constraint was not local originally and it should be acquired by the
inheritance.

The constaint is local and does not get acquired by the inheritance.
But the DDL to create inheritance child with NOT NULL constraint has
changed, which required a change in adjustment code in that test. The
diff does not indicate any bug in
14e87ffa5c543b5f30ead7413084c25f7735039f. Let's leave that aside.

I'm not sure about gtestxx_4.b ... the GENERATED
constraint should induce a not-null if I recall correctly, so an
explicit not-null marking in the child might not be necessary. But I'll
have a look.

You may forget that since the NOT NULL constraint was attached to
gtestxx_4.b by the dump adjustment code in that test. It's not there
in the dump itself.

2.

CREATE TABLE public.notnull_tbl4 (
a integer NOT NULL
);

CREATE TABLE public.notnull_tbl4_cld2 (
)
INHERITS (public.notnull_tbl4);
-ALTER TABLE ONLY public.notnull_tbl4_cld2 ALTER COLUMN a SET NOT NULL;
+ALTER TABLE ONLY public.notnull_tbl4_cld2 ADD CONSTRAINT notnull_tbl4_a_not_null NOT NULL a;
CREATE TABLE public.notnull_tbl4_cld3 (
)
INHERITS (public.notnull_tbl4);
-ALTER TABLE ONLY public.notnull_tbl4_cld3 ADD CONSTRAINT a_nn NOT NULL a;
+ALTER TABLE ONLY public.notnull_tbl4_cld3 ADD CONSTRAINT notnull_tbl4_a_not_null NOT NULL a;

For notnull_tbl4_cld2 we try to set the column not-null, but it's
already not-null due to inheritance ... so why are we doing that?
Weird. These lines should just go away in both dumps.

I created the tables using the same DDLs that the test uses
#CREATE TABLE notnull_tbl4 (a INTEGER PRIMARY KEY INITIALLY DEFERRED);
#CREATE TABLE notnull_tbl4_cld2 (PRIMARY KEY (a) DEFERRABLE) INHERITS
(notnull_tbl4);

Notice that coninhcount = 1
#\x
Expanded display is on.
db1@624204=#select * from pg_constraint where conrelid =
'notnull_tbl4_cld2'::regclass;
-[ RECORD 1 ]--+-----------------------------
oid | 16437
conname | notnull_tbl4_cld2_a_not_null
... snip ...
condeferrable | f
condeferred | f
... snip
conislocal | t
coninhcount | 1
connoinherit | f

Since PRIMARY KEY Is declared in both, parent and child, the
constraint on the child is considered local as well as inherited. In
order to adjust that, it dumps the NOT NULL constraint separately? Is
that so?

`````` original database dump
-- Name: notnull_tbl4_cld2; Type: TABLE; Schema: public; Owner: ashutoshpg
--

CREATE TABLE public.notnull_tbl4_cld2 (
)
INHERITS (public.notnull_tbl4);
ALTER TABLE ONLY public.notnull_tbl4_cld2 ALTER COLUMN a SET NOT NULL;
``````` original database dump ends

```` restored database dump
--
-- Name: notnull_tbl4_cld2; Type: TABLE; Schema: public; Owner: ashutoshpg
--

CREATE TABLE public.notnull_tbl4_cld2 (
)
INHERITS (public.notnull_tbl4);
ALTER TABLE ONLY public.notnull_tbl4_cld2 ADD CONSTRAINT
notnull_tbl4_a_not_null NOT NULL a;
````` restored database dump ends

The question why is the constraint dumped as ALTER TABLE ... ALTER
COLUMN ... NOT NULL from original database and as an ADD CONSTRAINT
from the restored database? Notice the change in the names of
constraint. On the original database the name is
notnull_tbl4_cld2_a_not_null whereas on the restored database it is
notnull_tbl4_a_not_null. Is that the reason behind the difference in
the DDLs? Looks like a bug to me.

In notnull_tbl4_cld3's case we have the same, but we also want to set a
constraint name, but the constraint already exists, so that doesn't
work, and that's the reason why the next dump uses the standard name.
Maybe we could dump the name change as ALTER TABLE RENAME CONSTRAINT in
that case instead, _if_ we can obtain the original name (should be
doable, because we can see it's a nonstandard name.)

I think both of these problems are the same. In both the cases, the
name of the constraint on the restored database is
notnull_tbl4_a_not_null, which is the name of the constraint on the
parent table. I think somewhere the code is ignoring the name of the
constraint on the child table if the constraint is local and also
inherited.

--
Best Wishes,
Ashutosh Bapat

#4Ashutosh Bapat
ashutosh.bapat.oss@gmail.com
In reply to: Alvaro Herrera (#2)
1 attachment(s)
Re: Difference in dump from original and restored database due to NOT NULL constraints on children

Hi Alvaro,

On Thu, Nov 14, 2024 at 6:08 PM Alvaro Herrera <alvherre@alvh.no-ip.org> wrote:

2.

CREATE TABLE public.notnull_tbl4 (
a integer NOT NULL
);

CREATE TABLE public.notnull_tbl4_cld2 (
)
INHERITS (public.notnull_tbl4);
-ALTER TABLE ONLY public.notnull_tbl4_cld2 ALTER COLUMN a SET NOT NULL;
+ALTER TABLE ONLY public.notnull_tbl4_cld2 ADD CONSTRAINT notnull_tbl4_a_not_null NOT NULL a;
CREATE TABLE public.notnull_tbl4_cld3 (
)
INHERITS (public.notnull_tbl4);
-ALTER TABLE ONLY public.notnull_tbl4_cld3 ADD CONSTRAINT a_nn NOT NULL a;
+ALTER TABLE ONLY public.notnull_tbl4_cld3 ADD CONSTRAINT notnull_tbl4_a_not_null NOT NULL a;

For notnull_tbl4_cld2 we try to set the column not-null, but it's
already not-null due to inheritance ... so why are we doing that?
Weird. These lines should just go away in both dumps.

In notnull_tbl4_cld3's case we have the same, but we also want to set a
constraint name, but the constraint already exists, so that doesn't
work, and that's the reason why the next dump uses the standard name.
Maybe we could dump the name change as ALTER TABLE RENAME CONSTRAINT in
that case instead, _if_ we can obtain the original name (should be
doable, because we can see it's a nonstandard name.)

I studied this in more details. Here's what is happening

First case: unnamed/default named constraint
-------------------------------------------------------------
On original database following DDLs are executed
#CREATE TABLE notnull_tbl4 (a INTEGER PRIMARY KEY INITIALLY DEFERRED);
#CREATE TABLE notnull_tbl4_cld2 (PRIMARY KEY (a) DEFERRABLE) INHERITS
(notnull_tbl4);
#select conname, coninhcount, conislocal, contype from pg_constraint
where conrelid = 'notnull_tbl4_cld2'::regclass;
conname | coninhcount | conislocal | contype
------------------------------+-------------+------------+---------
notnull_tbl4_cld2_a_not_null | 1 | t | n
notnull_tbl4_cld2_pkey | 0 | t | p
(2 rows)

Though the child inherited primary key constraint it was overridden by
local constraint that's how we see coninhcount = 0 and conislocal = t.
But NOT NULL constraint shows both inherited and local (coninhcount =
1 and conislocal = t) because of the logic in
AdjustNotNullInheritance(). When the table is dumped, it is dumped as

CREATE TABLE public.notnull_tbl4 (
a integer NOT NULL
);
CREATE TABLE public.notnull_tbl4_cld2 (
)
INHERITS (public.notnull_tbl4);
ALTER TABLE ONLY public.notnull_tbl4_cld2 ALTER COLUMN a SET NOT
NULL;Dump and restore of inherited and local child NOT NULL
constraints

Fixes two issues described below:
1. A child table will inherit NOT NULL constraints from the parent. But it's
allowed to add local NOT NULL constraints on the same column. If a user
specifies a name while adding such a constraint it will be ignored. That may not
be intended. But ignoring the given name has an ill-effect on dump and restore
of such a constraint. A named NOT NULL constraint which is inherited and is
also local will be dumped as ALTER TABLE ... ADD CONSTRAINT ... command
specifying its name. If we ignore this name, it will not be restored and thus
lost. Hence while ADDing a local NOT NULL constraint on the child
table, change the
name of the inherited constraint, if one exists.

2. Consider a parent with NOT NULL col1. If a child is created with
CREATE TABLE child (NOT NULL col1) INHERITS (parent), col1 would be an
inherited column with a local as well as inherited NOT NULL constraint
with the default name containing the name of the child table in it.
We will dump "CREATE TABLE child() INHERITS parent" to create the
child table. This will add the inherited constraint on child with name
of the parent constraint. To turn it into a local constraint we will
dump "ALTER TABLE child ALTER COLUMN col1 SET NOT NULL". This will not
restore the original name of the constraint. Hence instead of dumping
ALTER TABLE ... ALTER COLUMN, we dump ALTER TABLE ... ADD CONSTRAINT
with the child's default name. This would preserve the child's default
name across dump and restore.
Dump and restore of inherited and local child NOT NULL constraints

Fixes two issues described below:
1. A child table will inherit NOT NULL constraints from the parent. But it's
allowed to add local NOT NULL constraints on the same column. If a user
specifies a name while adding such a constraint it will be ignored. That may not
be intended. But ignoring the given name has an ill-effect on dump and restore
of such a constraint. A named NOT NULL constraint which is inherited and is
also local will be dumped as ALTER TABLE ... ADD CONSTRAINT ... command
specifying its name. If we ignore this name, it will not be restored and thus
lost. Hence while ADDing a local NOT NULL constraint on the child
table, change the
name of the inherited constraint, if one exists.

2. Consider a parent with NOT NULL col1. If a child is created with
CREATE TABLE child (NOT NULL col1) INHERITS (parent), col1 would be an
inherited column with a local as well as inherited NOT NULL constraint
with the default name containing the name of the child table in it.
We will dump "CREATE TABLE child() INHERITS parent" to create the
child table. This will add the inherited constraint on child with name
of the parent constraint. To turn it into a local constraint we will
dump "ALTER TABLE child ALTER COLUMN col1 SET NOT NULL". This will not
restore the original name of the constraint. Hence instead of dumping
ALTER TABLE ... ALTER COLUMN, we dump ALTER TABLE ... ADD CONSTRAINT
with the child's default name. This would preserve the child's default
name across dump and restore.

... primary key constraint DDLs follow - they don't affect NOT NULL
constraints now

The extra ALTER TABLE ... ALTER COLUMN is because the constraint is
local and has the default name as per logic in
determineNotNullFlags().
When the dump is restored, the status of constraints on notnull_tbl4_cld2 is
#select conname, coninhcount, conislocal, contype from pg_constraint
where conrelid = 'notnull_tbl4_cld2'::regclass;
conname | coninhcount | conislocal | contype
-------------------------+-------------+------------+---------
notnull_tbl4_a_not_null | 1 | t | n
notnull_tbl4_cld2_pkey | 0 | t | p
(2 rows)

Please note that the coninhcount and conislocal are restored, but the
name of the constraint has changed. The name of the constraint is the
same as the parent's constraint name (notnull_tbl4_a_not_null) which
is the default name for parent.
This happens because the CREATE TABLE ... INHERITS () creates an
inherited constraint on the child with the same name of the parent.
ALTER TABLE ... ALTER COLUMN ... SET NOT NULL, changes itsDump and
restore of inherited and local child NOT NULL constraints

Fixes two issues described below:
1. A child table will inherit NOT NULL constraints from the parent. But it's
allowed to add local NOT NULL constraints on the same column. If a user
specifies a name while adding such a constraint it will be ignored. That may not
be intended. But ignoring the given name has an ill-effect on dump and restore
of such a constraint. A named NOT NULL constraint which is inherited and is
also local will be dumped as ALTER TABLE ... ADD CONSTRAINT ... command
specifying its name. If we ignore this name, it will not be restored and thus
lost. Hence while ADDing a local NOT NULL constraint on the child
table, change the
name of the inherited constraint, if one exists.

2. Consider a parent with NOT NULL col1. If a child is created with
CREATE TABLE child (NOT NULL col1) INHERITS (parent), col1 would be an
inherited column with a local as well as inherited NOT NULL constraint
with the default name containing the name of the child table in it.
We will dump "CREATE TABLE child() INHERITS parent" to create the
child table. This will add the inherited constraint on child with name
of the parent constraint. To turn it into a local constraint we will
dump "ALTER TABLE child ALTER COLUMN col1 SET NOT NULL". This will not
restore the original name of the constraint. Hence instead of dumping
ALTER TABLE ... ALTER COLUMN, we dump ALTER TABLE ... ADD CONSTRAINT
with the child's default name. This would preserve the child's default
name across dump and restore.
conislocal to "true' (again because of AdjustNotNullInheritance())
keeping coninhcount same. When the restored database is dumped it
looks like below

CREATE TABLE public.notnull_tbl4 (
a integer NOT NULL
);
CREATE TABLE public.notnull_tbl4_cld2 (
)
INHERITS (public.notnull_tbl4);
ALTER TABLE ONLY public.notnull_tbl4_cld2 ADD CONSTRAINT
notnull_tbl4_a_not_null NOT NULL a;
... primary key constraint DDLs follow - they don't affect NOT NULL
constraints now

ALTER TABLE now uses ADD CONSTRAINT since the name of the constraint
is not default one per determineNotNullFlags(). But the original name
of the constraint is lost forever.

If we create a NOT NULL constraint instead of primary key constraint,
we see similar phenomena.
#CREATE TABLE notnull_tbl4 (a INTEGER NOT NULL);
#CREATE TABLE notnull_tbl4_cld2 (NOT NULL a) INHERITS (notnull_tbl4);
#select conname, coninhcount, conislocal, contype from pg_constraint
where conrelid = 'notnull_tbl4_cld2'::regclass;
conname | coninhcount | conislocal | contype
------------------------------+-------------+------------+---------
notnull_tbl4_cld2_a_not_null | 1 | t | n
(1 row)

Dump contains
CREATE TABLE public.notnull_tbl4 (
a integer NOT NULL
);
CREATE TABLE public.notnull_tbl4_cld2 (
)
INHERITS (public.notnull_tbl4);
ALTER TABLE ONLY public.notnull_tbl4_cld2 ALTER COLUMN a SET NOT NULL;

Restoring this dump
#select conname, coninhcount, conislocal, contype from pg_constraint
where conrelid = 'notnull_tbl4_cld2'::regclass;
conname | coninhcount | conislocal | contype
-------------------------+-------------+------------+---------
notnull_tbl4_a_not_null | 1 | t | n
(1 row)
Notice the change in the name of the constraint.

Second case: Named NOT NULL constraint
----------------------------------------------------------
On the original database
#CREATE TABLE notnull_tbl4 (a INTEGER PRIMARY KEY INITIALLY DEFERRED);
#CREATE TABLE notnull_tbl4_cld3 (PRIMARY KEY (a) DEFERRABLE,
CONSTRAINT a_nn NOT NULL a) INHERITS (notnull_tbl4);
#select conname, coninhcount, conislocal, contype from pg_constraint
where conrelid = 'notnull_tbl4_cld3'::regclass;
conname | coninhcount | conislocal | contype
------------------------+-------------+------------+---------
a_nn | 1 | t | n
notnull_tbl4_cld3_pkey | 0 | t | p
(2 rows)
Upto this the only difference in the previous case and this case is
the name of the constraint - a_nn which is user specified.

The dump contains
CREATE TABLE public.notnull_tbl4 (
a integer NOT NULL
);
CREATE TABLE public.notnull_tbl4_cld3 (
)
INHERITS (public.notnull_tbl4);
ALTER TABLE ONLY public.notnull_tbl4_cld3 ADD CONSTRAINT a_nn NOT NULL a;

The constraint is dumped separately since it's local; same as the
first case. However, it uses ADD CONSTAINT instead of ALTER COLUMN
since the name of the constraint is not default.
When this dump is restored, the status of the constraint is
#select conname, coninhcount, conislocal, contype from pg_constraint
where conrelid = 'notnull_tbl4_cld3'::regclass;
conname | coninhcount | conislocal | contype
-------------------------+-------------+------------+---------
notnull_tbl4_a_not_null | 1 | t | n
notnull_tbl4_cld3_pkey | 0 | t | p
(2 rows)

Notice that the name of the constraint has not been restored since the
logic in AdjustNotNullInheritance() does not change the name of the
inherited constraint while changing conislocal.
Rest of the story is the same as the first case.

From this analysis, it looks like we need to add ADD CONSTRAINT or
ALTER COLUMN ... SET NOT NULL ... in order to mark the NOT NULL
constraint as local.
You suggested using ALTER TABLE ... RENAME CONSTRAINT, but renaming an
inherited constraint is not allowed.
#alter table notnull_tbl4_cld3 rename constraint
notnull_tbl4_a_not_null to a_nn;
ERROR: cannot rename inherited constraint "notnull_tbl4_a_not_null"
... that goes back 13 years.
commit 39d74e346c083aa371ba64c4edb1332c40b56530
Author: Peter Eisentraut <peter_e@gmx.net>
Date: Sat Mar 10 20:19:13 2012 +0200

Add support for renaming constraints

reviewed by Josh Berkus and Dimitri Fontaine
So I don't think we should change that behaviour.

Instead I chose to fix both the problems by
1. In AdjustNotNullInheritance(), if a NOT NULL constraint is
converted to local and the user has specified a name for it (ALTER
TABLE ... ADD CONSTRAINT ... NOT NULL ..), change the name alongwith
setting conislocal. The user who specified a non-default name in ADD
CONSTRAINT would expect the "local" constraint to be named
accordingly. If a local constraint is ADDed again with a different
name, right now the patch ignores the new name but that could be
changed to throw an error similar to ALTER TABLE ... RENAME CONSTAINT.
2. In determineNotNullFlags(), if a NOT NULL constraint is both
inherited and local, preserve its name even if it's default. That way,
it will be dumped as ALTER TABLE ... ADD CONSTRAINT ... NOT NULL ...
instead of ALTER TABLE ... ALTER COLUMN ... SET NOT NULL. An exception
to this is a local NOT NULL column with default name for NOT NULL
constraint. Such NOT NULL constraints are specified in the CREATE
TABLE ... INHERITS .. command itself. That way they preserve their
default name.

The first change will preserve the given name of the child constraint.
Both changes together will preserve the default name of the child
constraint.
See the patch. I have also added some tests.

Alternate approach which I haven't tried, but did consider and left aside.
1. Allow RENAME CONSTAINT on a local constaint even if it's inherited.
Given that the behaviour is 13 years old, I am hesitant to change it.
2. Allow local and inherited NOT NULL constraints to co-exist
separately (similar to primary key constraint). I am not sure why we
don't allow this behaviour. AdjustNotNullInheritance() doesn't explain
the reason.

--
Best Wishes,
Ashutosh Bapat

Attachments:

0001-Dump-and-restore-of-inherited-and-local-chi-20241127.patchtext/x-patch; charset=US-ASCII; name=0001-Dump-and-restore-of-inherited-and-local-chi-20241127.patchDownload
From 116cf5017ca7453d75e83c2d424a8c0b60083886 Mon Sep 17 00:00:00 2001
From: Ashutosh Bapat <ashutosh.bapat.oss@gmail.com>
Date: Wed, 27 Nov 2024 16:22:44 +0530
Subject: [PATCH] Dump and restore of inherited and local child NOT NULL
 constraints

Fixes two issues described below: 1. A child table will inherit NOT NULL
constraints from the parent. But it's allowed to add local NOT NULL constraints
on the same column.  If a user specifies a name while adding such a constraint
it will be ignored. That may not be intended. But ignoring the given name has an
ill-effect on dump and restore of such a constraint.  A named NOT NULL
constraint which is inherited and is also local will be dumped as ALTER TABLE
... ADD CONSTRAINT ... command specifying its name. If we ignore this name, it
will not be restored and thus lost. Hence while ADDing a local NOT NULL
constraint on the child table, change the name of the inherited constraint, if
one exists.

2. Consider a parent with NOT NULL col1. If a child is created with CREATE TABLE
child (NOT NULL col1) INHERITS (parent), col1 would be an inherited column with
a local as well as inherited NOT NULL constraint with the default name
containing the name of the child table in it.  We will dump "CREATE TABLE
child() INHERITS parent" to create the child table. This will add the inherited
constraint on child with name of the parent constraint. To turn it into a local
constraint we will dump "ALTER TABLE child ALTER COLUMN col1 SET NOT NULL". This
will not restore the original name of the constraint. Hence instead of dumping
ALTER TABLE ... ALTER COLUMN, we dump ALTER TABLE ... ADD CONSTRAINT with the
child's default name. This would preserve the child's default name across dump
and restore.

Author: Ashutosh Bapat
Discussion: https://www.postgresql.org/message-id/flat/CAExHW5tbdgAKDfqjDJ-7Fk6PJtHg8D4zUF6FQ4H2Pq8zK38Nyw%40mail.gmail.com
---
 src/backend/catalog/heap.c                | 12 ++--
 src/backend/catalog/index.c               |  4 +-
 src/backend/catalog/pg_constraint.c       | 76 +++++++++++++++++++----
 src/backend/commands/tablecmds.c          | 12 ++--
 src/backend/commands/typecmds.c           | 12 ++--
 src/bin/pg_dump/pg_dump.c                 | 61 ++++++++++++------
 src/include/catalog/pg_constraint.h       |  5 +-
 src/test/regress/expected/constraints.out | 41 ++++++++++++
 src/test/regress/sql/constraints.sql      | 17 +++++
 9 files changed, 188 insertions(+), 52 deletions(-)

diff --git a/src/backend/catalog/heap.c b/src/backend/catalog/heap.c
index 003af4bf21c..12d440200b8 100644
--- a/src/backend/catalog/heap.c
+++ b/src/backend/catalog/heap.c
@@ -2563,10 +2563,12 @@ AddRelationNewConstraints(Relation rel,
 
 			/*
 			 * If the column already has a not-null constraint, we don't want
-			 * to add another one; just adjust inheritance status as needed.
+			 * to add another one; just adjust inheritance status and the
+			 * constraint name as needed.
 			 */
 			if (AdjustNotNullInheritance(RelationGetRelid(rel), colnum,
-										 is_local, cdef->is_no_inherit))
+										 is_local, cdef->is_no_inherit,
+										 cdef->conname, &nnnames))
 				continue;
 
 			/*
@@ -2575,9 +2577,9 @@ AddRelationNewConstraints(Relation rel,
 			 */
 			if (cdef->conname)
 			{
-				if (ConstraintNameIsUsed(CONSTRAINT_RELATION,
-										 RelationGetRelid(rel),
-										 cdef->conname))
+				if (OidIsValid(ConstraintNameIsUsed(CONSTRAINT_RELATION,
+													RelationGetRelid(rel),
+													cdef->conname)))
 					ereport(ERROR,
 							errcode(ERRCODE_DUPLICATE_OBJECT),
 							errmsg("constraint \"%s\" for relation \"%s\" already exists",
diff --git a/src/backend/catalog/index.c b/src/backend/catalog/index.c
index f9bb721c5fe..9a2a8eaef27 100644
--- a/src/backend/catalog/index.c
+++ b/src/backend/catalog/index.c
@@ -901,8 +901,8 @@ index_create(Relation heapRelation,
 	}
 
 	if ((flags & INDEX_CREATE_ADD_CONSTRAINT) != 0 &&
-		ConstraintNameIsUsed(CONSTRAINT_RELATION, heapRelationId,
-							 indexRelationName))
+		OidIsValid(ConstraintNameIsUsed(CONSTRAINT_RELATION, heapRelationId,
+										indexRelationName)))
 	{
 		/*
 		 * INDEX_CREATE_IF_NOT_EXISTS does not apply here, since the
diff --git a/src/backend/catalog/pg_constraint.c b/src/backend/catalog/pg_constraint.c
index 9c05a98d28c..058c4d5ab28 100644
--- a/src/backend/catalog/pg_constraint.c
+++ b/src/backend/catalog/pg_constraint.c
@@ -396,17 +396,20 @@ CreateConstraintEntry(const char *constraintName,
  * whether an auto-generated name is OK: here, we will allow it unless there
  * is an identical constraint name in use *on the same object*.
  *
+ * Returns the Oid of constraint with matching name. InvalidOid if none exists.
+ *
  * NB: Caller should hold exclusive lock on the given object, else
  * this test can be fooled by concurrent additions.
  */
-bool
+Oid
 ConstraintNameIsUsed(ConstraintCategory conCat, Oid objId,
 					 const char *conname)
 {
-	bool		found;
+	Oid			result = InvalidOid;
 	Relation	conDesc;
 	SysScanDesc conscan;
 	ScanKeyData skey[3];
+	HeapTuple	tup;
 
 	conDesc = table_open(ConstraintRelationId, AccessShareLock);
 
@@ -429,12 +432,14 @@ ConstraintNameIsUsed(ConstraintCategory conCat, Oid objId,
 								 true, NULL, 3, skey);
 
 	/* There can be at most one matching row */
-	found = (HeapTupleIsValid(systable_getnext(conscan)));
+	tup = systable_getnext(conscan);
+	if (HeapTupleIsValid(tup))
+		result = ((Form_pg_constraint) GETSTRUCT(tup))->oid;
 
 	systable_endscan(conscan);
 	table_close(conDesc, AccessShareLock);
 
-	return found;
+	return result;
 }
 
 /*
@@ -719,10 +724,16 @@ extractNotNullColumn(HeapTuple constrTup)
  * conislocal/coninhcount and return true.
  * In the latter case, if is_local is true we flip conislocal true, or do
  * nothing if it's already true; otherwise we increment coninhcount by 1.
+ *
+ * A user would expect the now-flipped-to-local constraint to be renamed if they
+ * have provided a name while ADDing the constraint. This is similar to how
+ * CREATE TABLE ... INHERIT would behave, if user provided a name for a local
+ * constraint, being created, which will also be inherited.
  */
 bool
 AdjustNotNullInheritance(Oid relid, AttrNumber attnum,
-						 bool is_local, bool is_no_inherit)
+						 bool is_local, bool is_no_inherit,
+						 char *conname, List **nnnames)
 {
 	HeapTuple	tup;
 
@@ -732,6 +743,8 @@ AdjustNotNullInheritance(Oid relid, AttrNumber attnum,
 		Relation	pg_constraint;
 		Form_pg_constraint conform;
 		bool		changed = false;
+		NameData	oldname;
+		bool		renamed = false;
 
 		pg_constraint = table_open(ConstraintRelationId, RowExclusiveLock);
 		conform = (Form_pg_constraint) GETSTRUCT(tup);
@@ -758,12 +771,53 @@ AdjustNotNullInheritance(Oid relid, AttrNumber attnum,
 		else if (!conform->conislocal)
 		{
 			conform->conislocal = true;
+
+			if (conname)
+			{
+				Oid			used_con = ConstraintNameIsUsed(CONSTRAINT_RELATION,
+															relid, conname);
+
+				if (!OidIsValid(used_con))
+				{
+					/*
+					 * No constraint with the same name exists, not even this
+					 * one. Safe to rename it to the given name.
+					 */
+					Assert(namestrcmp(&conform->conname, conname) != 0);
+					namestrcpy(&oldname, NameStr(conform->conname));
+					namestrcpy(&conform->conname, conname);
+					renamed = true;
+					*nnnames = lappend(*nnnames, conname);
+				}
+				else if (used_con != conform->oid)
+					ereport(ERROR,
+							errcode(ERRCODE_DUPLICATE_OBJECT),
+							errmsg("constraint \"%s\" for relation \"%s\" already exists",
+								   conname, get_rel_name(relid)));
+				else
+				{
+					/*
+					 * The given name is same as the existing name of the
+					 * constraint. Nothing to do.
+					 */
+					Assert(namestrcmp(&conform->conname, conname) == 0);
+				}
+			}
+
 			changed = true;
 		}
 
 		if (changed)
+		{
 			CatalogTupleUpdate(pg_constraint, &tup->t_self, tup);
 
+			if (renamed)
+				ereport(WARNING,
+						errcode(ERRCODE_DUPLICATE_OBJECT),
+						errmsg("renamed existing non-null constraint \"%s\" of relation \"%s\" to \"%s\"",
+							   NameStr(oldname), get_rel_name(relid), NameStr(conform->conname)));
+		}
+
 		table_close(pg_constraint, RowExclusiveLock);
 
 		return true;
@@ -967,17 +1021,17 @@ RenameConstraintById(Oid conId, const char *newname)
 	 * For user-friendliness, check whether the name is already in use.
 	 */
 	if (OidIsValid(con->conrelid) &&
-		ConstraintNameIsUsed(CONSTRAINT_RELATION,
-							 con->conrelid,
-							 newname))
+		OidIsValid(ConstraintNameIsUsed(CONSTRAINT_RELATION,
+										con->conrelid,
+										newname)))
 		ereport(ERROR,
 				(errcode(ERRCODE_DUPLICATE_OBJECT),
 				 errmsg("constraint \"%s\" for relation \"%s\" already exists",
 						newname, get_rel_name(con->conrelid))));
 	if (OidIsValid(con->contypid) &&
-		ConstraintNameIsUsed(CONSTRAINT_DOMAIN,
-							 con->contypid,
-							 newname))
+		OidIsValid(ConstraintNameIsUsed(CONSTRAINT_DOMAIN,
+										con->contypid,
+										newname)))
 		ereport(ERROR,
 				(errcode(ERRCODE_DUPLICATE_OBJECT),
 				 errmsg("constraint \"%s\" for domain %s already exists",
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 1af2e2bffb2..1b43ba500ec 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -9459,9 +9459,9 @@ ATExecAddConstraint(List **wqueue, AlteredTableInfo *tab, Relation rel,
 			 */
 			if (newConstraint->conname)
 			{
-				if (ConstraintNameIsUsed(CONSTRAINT_RELATION,
-										 RelationGetRelid(rel),
-										 newConstraint->conname))
+				if (OidIsValid(ConstraintNameIsUsed(CONSTRAINT_RELATION,
+													RelationGetRelid(rel),
+													newConstraint->conname)))
 					ereport(ERROR,
 							(errcode(ERRCODE_DUPLICATE_OBJECT),
 							 errmsg("constraint \"%s\" for relation \"%s\" already exists",
@@ -10380,9 +10380,9 @@ addFkConstraint(addFkConstraintSides fkside,
 	 * Caller supplies us with a constraint name; however, it may be used in
 	 * this partition, so come up with a different one in that case.
 	 */
-	if (ConstraintNameIsUsed(CONSTRAINT_RELATION,
-							 RelationGetRelid(rel),
-							 constraintname))
+	if (OidIsValid(ConstraintNameIsUsed(CONSTRAINT_RELATION,
+										RelationGetRelid(rel),
+										constraintname)))
 		conname = ChooseConstraintName(RelationGetRelationName(rel),
 									   ChooseForeignKeyConstraintNameAddition(fkconstraint->fk_attrs),
 									   "fkey",
diff --git a/src/backend/commands/typecmds.c b/src/backend/commands/typecmds.c
index 859e2191f08..f45ec90f25e 100644
--- a/src/backend/commands/typecmds.c
+++ b/src/backend/commands/typecmds.c
@@ -3528,9 +3528,9 @@ domainAddCheckConstraint(Oid domainOid, Oid domainNamespace, Oid baseTypeOid,
 	 */
 	if (constr->conname)
 	{
-		if (ConstraintNameIsUsed(CONSTRAINT_DOMAIN,
-								 domainOid,
-								 constr->conname))
+		if (OidIsValid(ConstraintNameIsUsed(CONSTRAINT_DOMAIN,
+											domainOid,
+											constr->conname)))
 			ereport(ERROR,
 					(errcode(ERRCODE_DUPLICATE_OBJECT),
 					 errmsg("constraint \"%s\" for domain \"%s\" already exists",
@@ -3683,9 +3683,9 @@ domainAddNotNullConstraint(Oid domainOid, Oid domainNamespace, Oid baseTypeOid,
 	 */
 	if (constr->conname)
 	{
-		if (ConstraintNameIsUsed(CONSTRAINT_DOMAIN,
-								 domainOid,
-								 constr->conname))
+		if (OidIsValid(ConstraintNameIsUsed(CONSTRAINT_DOMAIN,
+											domainOid,
+											constr->conname)))
 			ereport(ERROR,
 					(errcode(ERRCODE_DUPLICATE_OBJECT),
 					 errmsg("constraint \"%s\" for domain \"%s\" already exists",
diff --git a/src/bin/pg_dump/pg_dump.c b/src/bin/pg_dump/pg_dump.c
index add7f16c902..8df06c7cbce 100644
--- a/src/bin/pg_dump/pg_dump.c
+++ b/src/bin/pg_dump/pg_dump.c
@@ -346,7 +346,7 @@ static void getTableDataFKConstraints(void);
 static void determineNotNullFlags(Archive *fout, PGresult *res, int r,
 								  TableInfo *tbinfo, int j,
 								  int i_notnull_name, int i_notnull_noinherit,
-								  int i_notnull_islocal);
+								  int i_notnull_islocal, int i_notnull_inhcount);
 static char *format_function_arguments(const FuncInfo *finfo, const char *funcargs,
 									   bool is_agg);
 static char *format_function_signature(Archive *fout,
@@ -8764,6 +8764,7 @@ getTableAttrs(Archive *fout, TableInfo *tblinfo, int numTables)
 	int			i_notnull_name;
 	int			i_notnull_noinherit;
 	int			i_notnull_islocal;
+	int			i_notnull_inhcount;
 	int			i_attoptions;
 	int			i_attcollation;
 	int			i_attcompression;
@@ -8851,20 +8852,23 @@ getTableAttrs(Archive *fout, TableInfo *tblinfo, int numTables)
 	 * without a name); also, such cases are never NO INHERIT.
 	 *
 	 * We track in notnull_islocal whether the constraint was defined directly
-	 * in this table or via an ancestor, for binary upgrade.  flagInhAttrs
-	 * might modify this later for servers older than 18; it's also in charge
-	 * of determining the correct inhcount.
+	 * in this table or via an ancestor, for binary upgrade. We track
+	 * not_nullinhcount to decide whether to retain the constraint name for
+	 * non-binary dump. For servers older than 18 flagInhAttrs might modify
+	 * notnull_islocal later and also determine the correct not_inhcount.
 	 */
 	if (fout->remoteVersion >= 180000)
 		appendPQExpBufferStr(q,
 							 "co.conname AS notnull_name,\n"
 							 "co.connoinherit AS notnull_noinherit,\n"
-							 "co.conislocal AS notnull_islocal,\n");
+							 "co.conislocal AS notnull_islocal,\n"
+							 "co.coninhcount AS notnull_inhcount,\n");
 	else
 		appendPQExpBufferStr(q,
 							 "CASE WHEN a.attnotnull THEN '' ELSE NULL END AS notnull_name,\n"
 							 "false AS notnull_noinherit,\n"
-							 "a.attislocal AS notnull_islocal,\n");
+							 "a.attislocal AS notnull_islocal,\n"
+							 "0 AS notnull_inhcount,\n");
 
 	if (fout->remoteVersion >= 140000)
 		appendPQExpBufferStr(q,
@@ -8939,6 +8943,7 @@ getTableAttrs(Archive *fout, TableInfo *tblinfo, int numTables)
 	i_notnull_name = PQfnumber(res, "notnull_name");
 	i_notnull_noinherit = PQfnumber(res, "notnull_noinherit");
 	i_notnull_islocal = PQfnumber(res, "notnull_islocal");
+	i_notnull_inhcount = PQfnumber(res, "notnull_inhcount");
 	i_attoptions = PQfnumber(res, "attoptions");
 	i_attcollation = PQfnumber(res, "attcollation");
 	i_attcompression = PQfnumber(res, "attcompression");
@@ -9034,7 +9039,7 @@ getTableAttrs(Archive *fout, TableInfo *tblinfo, int numTables)
 			determineNotNullFlags(fout, res, r,
 								  tbinfo, j,
 								  i_notnull_name, i_notnull_noinherit,
-								  i_notnull_islocal);
+								  i_notnull_islocal, i_notnull_inhcount);
 
 			tbinfo->attoptions[j] = pg_strdup(PQgetvalue(res, r, i_attoptions));
 			tbinfo->attcollation[j] = atooid(PQgetvalue(res, r, i_attcollation));
@@ -9337,19 +9342,31 @@ getTableAttrs(Archive *fout, TableInfo *tblinfo, int numTables)
  * 2) The column has a constraint with no name (this is the case when
  *    constraints come from pre-18 servers).  In this case, ->notnull_constrs
  *    is set to the empty string; dumpTableSchema will print just "NOT NULL".
- * 3) The column has a constraint with a known name; in that case
+ * 3) The column has a constraint with default (table_column_not_null) name;
+ *    there's no need to print that name in the dump, so notnull_constrs is
+ *    set to the empty string and it behaves as the case 2 above.
+ * 4) The column has a constraint with a non-default name; in that case
  *    notnull_constrs carries that name and dumpTableSchema will print
- *    "CONSTRAINT the_name NOT NULL".  However, if the name is the default
- *    (table_column_not_null), there's no need to print that name in the dump,
- *    so notnull_constrs is set to the empty string and it behaves as the case
- *    above.
+ *    "CONSTRAINT the_name NOT NULL".
  *
- * In a child table that inherits from a parent already containing NOT NULL
- * constraints and the columns in the child don't have their own NOT NULL
- * declarations, we suppress printing constraints in the child: the
- * constraints are acquired at the point where the child is attached to the
- * parent.  This is tracked in ->notnull_inh (which is set in flagInhAttrs for
- * servers pre-18).
+ * NOT NULL constraints on the child table require additional rules as below:
+ * A) In a child table that inherits from a parent already containing NOT NULL
+ *    constraints and the columns in the child don't have their own NOT NULL
+ *    declarations, we suppress printing constraints in the child: the
+ *    constraints are acquired at the point where the child is attached to the
+ *    parent. This is tracked in ->notnull_local (which is set in flagInhAttrs
+ *    for servers pre-18).
+ * B) A column has a local NOT NULL constraint, with non-default name, which is
+ *    also inherited from the parent. This case is treated same as the case 4
+ *    above. But if the column will not be printed in CREATE TABLE command, we
+ *    will print a separate ALTER TABLE ... ADD CONSTRAINT ... command to
+ *    rename the constraint and convert it to local constraint.
+ * C) A column has a local NOT NULL constraint, with the default name, which is
+ *    also inherited from a parent. This case is treated as case B instead of
+ *    case 3 if the column will not be printed in CREATE TABLE command. The
+ *    child would inherit the constraint with parent constraint name when
+ *    attached. It needs to be renamed and converted to a local constraint
+ *    later using same DDL as case B.
  *
  * Any of these constraints might have the NO INHERIT bit.  If so we set
  * ->notnull_noinh and NO INHERIT will be printed by dumpTableSchema.
@@ -9363,9 +9380,10 @@ static void
 determineNotNullFlags(Archive *fout, PGresult *res, int r,
 					  TableInfo *tbinfo, int j,
 					  int i_notnull_name, int i_notnull_noinherit,
-					  int i_notnull_islocal)
+					  int i_notnull_islocal, int i_notnull_inhcount)
 {
 	DumpOptions *dopt = fout->dopt;
+	int			inhcount;
 
 	/*
 	 * notnull_noinh is straight from the query result. notnull_islocal also,
@@ -9373,6 +9391,7 @@ determineNotNullFlags(Archive *fout, PGresult *res, int r,
 	 */
 	tbinfo->notnull_noinh[j] = PQgetvalue(res, r, i_notnull_noinherit)[0] == 't';
 	tbinfo->notnull_islocal[j] = PQgetvalue(res, r, i_notnull_islocal)[0] == 't';
+	inhcount = atoi(PQgetvalue(res, r, i_notnull_inhcount));
 
 	/*
 	 * Determine a constraint name to use.  If the column is not marked not-
@@ -9415,7 +9434,9 @@ determineNotNullFlags(Archive *fout, PGresult *res, int r,
 				/* XXX should match ChooseConstraintName better */
 				default_name = psprintf("%s_%s_not_null", tbinfo->dobj.name,
 										tbinfo->attnames[j]);
-				if (strcmp(default_name,
+
+				if ((inhcount <= 0 || shouldPrintColumn(dopt, tbinfo, j)) &&
+					strcmp(default_name,
 						   PQgetvalue(res, r, i_notnull_name)) == 0)
 					tbinfo->notnull_constrs[j] = "";
 				else
diff --git a/src/include/catalog/pg_constraint.h b/src/include/catalog/pg_constraint.h
index 4b4476738a2..3a842402452 100644
--- a/src/include/catalog/pg_constraint.h
+++ b/src/include/catalog/pg_constraint.h
@@ -250,7 +250,7 @@ extern Oid	CreateConstraintEntry(const char *constraintName,
 								  bool conPeriod,
 								  bool is_internal);
 
-extern bool ConstraintNameIsUsed(ConstraintCategory conCat, Oid objId,
+extern Oid	ConstraintNameIsUsed(ConstraintCategory conCat, Oid objId,
 								 const char *conname);
 extern bool ConstraintNameExists(const char *conname, Oid namespaceid);
 extern char *ChooseConstraintName(const char *name1, const char *name2,
@@ -262,7 +262,8 @@ extern HeapTuple findNotNullConstraint(Oid relid, const char *colname);
 extern HeapTuple findDomainNotNullConstraint(Oid typid);
 extern AttrNumber extractNotNullColumn(HeapTuple constrTup);
 extern bool AdjustNotNullInheritance(Oid relid, AttrNumber attnum,
-									 bool is_local, bool is_no_inherit);
+									 bool is_local, bool is_no_inherit,
+									 char *conname, List **nnnames);
 extern List *RelationGetNotNullConstraints(Oid relid, bool cooked,
 										   bool include_noinh);
 
diff --git a/src/test/regress/expected/constraints.out b/src/test/regress/expected/constraints.out
index 71200c90ed3..d57b1e79b6f 100644
--- a/src/test/regress/expected/constraints.out
+++ b/src/test/regress/expected/constraints.out
@@ -1285,6 +1285,47 @@ Not-null constraints:
     "a_nn" NOT NULL "a" (local, inherited)
 Inherits: notnull_tbl4
 
+-- named local NOT NULL constraints on child table
+CREATE TABLE notnull_tbl4_cld4 () INHERITS (notnull_tbl4);
+ALTER TABLE notnull_tbl4_cld4 ADD CONSTRAINT dup_name CHECK (a > 2);
+ALTER TABLE notnull_tbl4_cld4 ADD CONSTRAINT dup_name NOT NULL a;
+ERROR:  constraint "dup_name" for relation "notnull_tbl4_cld4" already exists
+ALTER TABLE notnull_tbl4_cld4 DROP CONSTRAINT dup_name;
+ALTER TABLE notnull_tbl4_cld4 ADD CONSTRAINT tbl4_cld4_a_nn NOT NULL a;
+WARNING:  renamed existing non-null constraint "notnull_tbl4_a_not_null" of relation "notnull_tbl4_cld4" to "tbl4_cld4_a_nn"
+ALTER TABLE notnull_tbl4_cld4 ADD CONSTRAINT tbl4_cld4_a_nn2 NOT NULL a;
+\d+ notnull_tbl4_cld4
+                             Table "public.notnull_tbl4_cld4"
+ Column |  Type   | Collation | Nullable | Default | Storage | Stats target | Description 
+--------+---------+-----------+----------+---------+---------+--------------+-------------
+ a      | integer |           | not null |         | plain   |              | 
+Not-null constraints:
+    "tbl4_cld4_a_nn" NOT NULL "a" (local, inherited)
+Inherits: notnull_tbl4
+
+-- adding NOT NULL constraint with the same name as the existing one is noop
+ALTER TABLE notnull_tbl4_cld4 ADD CONSTRAINT tbl4_cld4_a_nn NOT NULL a;
+\d+ notnull_tbl4_cld4
+                             Table "public.notnull_tbl4_cld4"
+ Column |  Type   | Collation | Nullable | Default | Storage | Stats target | Description 
+--------+---------+-----------+----------+---------+---------+--------------+-------------
+ a      | integer |           | not null |         | plain   |              | 
+Not-null constraints:
+    "tbl4_cld4_a_nn" NOT NULL "a" (local, inherited)
+Inherits: notnull_tbl4
+
+-- unnamed local NOT NULL constraint on child table
+CREATE TABLE notnull_tbl4_cld5 () INHERITS (notnull_tbl4);
+ALTER TABLE notnull_tbl4_cld5 ALTER COLUMN a SET NOT NULL;
+\d+ notnull_tbl4_cld5
+                             Table "public.notnull_tbl4_cld5"
+ Column |  Type   | Collation | Nullable | Default | Storage | Stats target | Description 
+--------+---------+-----------+----------+---------+---------+--------------+-------------
+ a      | integer |           | not null |         | plain   |              | 
+Not-null constraints:
+    "notnull_tbl4_a_not_null" NOT NULL "a" (local, inherited)
+Inherits: notnull_tbl4
+
 -- leave these tables around for pg_upgrade testing
 -- It's possible to remove a constraint from parents without affecting children
 CREATE TABLE notnull_tbl5 (a int CONSTRAINT ann NOT NULL,
diff --git a/src/test/regress/sql/constraints.sql b/src/test/regress/sql/constraints.sql
index e607eb1fddb..17f0c11c854 100644
--- a/src/test/regress/sql/constraints.sql
+++ b/src/test/regress/sql/constraints.sql
@@ -766,6 +766,23 @@ CREATE TABLE notnull_tbl4_cld3 (PRIMARY KEY (a) DEFERRABLE, CONSTRAINT a_nn NOT
 \d+ notnull_tbl4_cld
 \d+ notnull_tbl4_cld2
 \d+ notnull_tbl4_cld3
+
+-- named local NOT NULL constraints on child table
+CREATE TABLE notnull_tbl4_cld4 () INHERITS (notnull_tbl4);
+ALTER TABLE notnull_tbl4_cld4 ADD CONSTRAINT dup_name CHECK (a > 2);
+ALTER TABLE notnull_tbl4_cld4 ADD CONSTRAINT dup_name NOT NULL a;
+ALTER TABLE notnull_tbl4_cld4 DROP CONSTRAINT dup_name;
+ALTER TABLE notnull_tbl4_cld4 ADD CONSTRAINT tbl4_cld4_a_nn NOT NULL a;
+ALTER TABLE notnull_tbl4_cld4 ADD CONSTRAINT tbl4_cld4_a_nn2 NOT NULL a;
+\d+ notnull_tbl4_cld4
+-- adding NOT NULL constraint with the same name as the existing one is noop
+ALTER TABLE notnull_tbl4_cld4 ADD CONSTRAINT tbl4_cld4_a_nn NOT NULL a;
+\d+ notnull_tbl4_cld4
+-- unnamed local NOT NULL constraint on child table
+CREATE TABLE notnull_tbl4_cld5 () INHERITS (notnull_tbl4);
+ALTER TABLE notnull_tbl4_cld5 ALTER COLUMN a SET NOT NULL;
+\d+ notnull_tbl4_cld5
+
 -- leave these tables around for pg_upgrade testing
 
 -- It's possible to remove a constraint from parents without affecting children
-- 
2.34.1

#5Alvaro Herrera
alvherre@alvh.no-ip.org
In reply to: Ashutosh Bapat (#4)
Re: Difference in dump from original and restored database due to NOT NULL constraints on children

On 2024-Nov-27, Ashutosh Bapat wrote:

I studied this in more details. Here's what is happening

First, thank you very much for spending time on this!

First case: unnamed/default named constraint
-------------------------------------------------------------
On original database following DDLs are executed
#CREATE TABLE notnull_tbl4 (a INTEGER PRIMARY KEY INITIALLY DEFERRED);
#CREATE TABLE notnull_tbl4_cld2 (PRIMARY KEY (a) DEFERRABLE) INHERITS
(notnull_tbl4);
#select conname, coninhcount, conislocal, contype from pg_constraint
where conrelid = 'notnull_tbl4_cld2'::regclass;
conname | coninhcount | conislocal | contype
------------------------------+-------------+------------+---------
notnull_tbl4_cld2_a_not_null | 1 | t | n
notnull_tbl4_cld2_pkey | 0 | t | p
(2 rows)

Though the child inherited primary key constraint it was overridden by
local constraint that's how we see coninhcount = 0 and conislocal = t.
But NOT NULL constraint shows both inherited and local (coninhcount =
1 and conislocal = t) because of the logic in
AdjustNotNullInheritance(). When the table is dumped, it is dumped as

CREATE TABLE public.notnull_tbl4 (
a integer NOT NULL
);
CREATE TABLE public.notnull_tbl4_cld2 (
)
INHERITS (public.notnull_tbl4);
ALTER TABLE ONLY public.notnull_tbl4_cld2 ALTER COLUMN a SET NOT NULL;

Hmm. Actually, I think this would work fine if we make pg_dump emit the
constraint with its name with the child creation, _without the column_:

CREATE TABLE public.notnull_tbl4_cld2 (
PRIMARY KEY (a) DEFERRABLE,
CONSTRAINT notnull_tbl4_cld2_a_not_null NOT NULL a
)
INHERITS (public.notnull_tbl4);

This works already seems a lot simpler. The column definition is
obtained from the parent, but the constraint is defined locally in
addition to inherited. So we just need to change pg_dump to dump local
constraints using that syntax; no backend changes needed.

I elided a lot of your email here because I didn't understand it.
I think you pasted your commit message several times.

You suggested using ALTER TABLE ... RENAME CONSTRAINT, but renaming an
inherited constraint is not allowed.
#alter table notnull_tbl4_cld3 rename constraint
notnull_tbl4_a_not_null to a_nn;
ERROR: cannot rename inherited constraint "notnull_tbl4_a_not_null"
... that goes back 13 years.
commit 39d74e346c083aa371ba64c4edb1332c40b56530
Author: Peter Eisentraut <peter_e@gmx.net>
Date: Sat Mar 10 20:19:13 2012 +0200

Add support for renaming constraints

reviewed by Josh Berkus and Dimitri Fontaine
So I don't think we should change that behaviour.

I don't necessarily agree with feeling ourselves restricted by this; I
have to assume that that case was forbidden for CHECK constraints
because they must have identical names on all children, because we match
them by name when walking down hierarchies for whatever DDL operation.
But as has been established, constraint names don't have to be identical
for not-null constraints, because we don't match them by name.

However, I'm not sure we need to remove this restriction, at least not
to fix this problem.

As far as backwards compatibility arguments go, I think we need to
observe a rule like: if something worked previously, then it should
continue to work, otherwise there's a regression. But if something
didn't previously work, then it's okay to make it work. You're not
regressing anything.

2. Allow local and inherited NOT NULL constraints to co-exist
separately (similar to primary key constraint). I am not sure why we
don't allow this behaviour. AdjustNotNullInheritance() doesn't explain
the reason.

IIRC we discussed this during the previous discussion of not-null
constraints (in the 16 cycle). The main problem is that if you have two
not-null constraints for the same column, and the user runs ALTER TABLE
.. DROP NOT NULL, what do you think should happen? We saw three
alternatives, neither of them good:

1. arbitrarily choose one to drop, leave the others alone
2. remove them all
3. error out and ask the user to use DROP CONSTRAINT instead, to choose
which one to drop.

If you look at the SQL standard 2016 edition, they have 11.16 <drop
column not null clause>, whose General Rules say this:

1) If the column descriptor of C contains an indication that C is defined as
NOT NULL, then:
a) Let ACN be the constraint name of the associated table constraint
definition included in the column descriptor of C.
b) The column descriptor of C is modified as follows:
i) The indication that C is defined as NOT NULL is removed.
ii) The constraint name of the associated table constraint definition is removed.

This is clearly assuming that we have a single constraint to drop.
I don't think it'd be wise to change this. Initially we allowed
multiple not-null constraints per column, and when we decided to
disallow it, a lot of code that supported that case could be removed.
I'm not inclined to put that back. Things start to become brittle if
you do; I had to work pretty hard to make it all robust.

--
Álvaro Herrera 48°01'N 7°57'E — https://www.EnterpriseDB.com/
"I can see support will not be a problem. 10 out of 10." (Simon Wittber)
(http://archives.postgresql.org/pgsql-general/2004-12/msg00159.php)

#6Ashutosh Bapat
ashutosh.bapat.oss@gmail.com
In reply to: Alvaro Herrera (#5)
Re: Difference in dump from original and restored database due to NOT NULL constraints on children

On Wed, Nov 27, 2024 at 5:56 PM Alvaro Herrera <alvherre@alvh.no-ip.org> wrote:

On 2024-Nov-27, Ashutosh Bapat wrote:

I studied this in more details. Here's what is happening

First, thank you very much for spending time on this!

First case: unnamed/default named constraint
-------------------------------------------------------------
On original database following DDLs are executed
#CREATE TABLE notnull_tbl4 (a INTEGER PRIMARY KEY INITIALLY DEFERRED);
#CREATE TABLE notnull_tbl4_cld2 (PRIMARY KEY (a) DEFERRABLE) INHERITS
(notnull_tbl4);
#select conname, coninhcount, conislocal, contype from pg_constraint
where conrelid = 'notnull_tbl4_cld2'::regclass;
conname | coninhcount | conislocal | contype
------------------------------+-------------+------------+---------
notnull_tbl4_cld2_a_not_null | 1 | t | n
notnull_tbl4_cld2_pkey | 0 | t | p
(2 rows)

Though the child inherited primary key constraint it was overridden by
local constraint that's how we see coninhcount = 0 and conislocal = t.
But NOT NULL constraint shows both inherited and local (coninhcount =
1 and conislocal = t) because of the logic in
AdjustNotNullInheritance(). When the table is dumped, it is dumped as

CREATE TABLE public.notnull_tbl4 (
a integer NOT NULL
);
CREATE TABLE public.notnull_tbl4_cld2 (
)
INHERITS (public.notnull_tbl4);
ALTER TABLE ONLY public.notnull_tbl4_cld2 ALTER COLUMN a SET NOT NULL;

Hmm. Actually, I think this would work fine if we make pg_dump emit the
constraint with its name with the child creation, _without the column_:

CREATE TABLE public.notnull_tbl4_cld2 (
PRIMARY KEY (a) DEFERRABLE,
CONSTRAINT notnull_tbl4_cld2_a_not_null NOT NULL a
)
INHERITS (public.notnull_tbl4);

This works already seems a lot simpler. The column definition is
obtained from the parent, but the constraint is defined locally in
addition to inherited. So we just need to change pg_dump to dump local
constraints using that syntax; no backend changes needed.

I noticed that. But two reasons why I chose the backend changes
1. The comment where we add explicit ADD CONSTRAINT is
/*
* Dump additional per-column properties that we can't handle in the
* main CREATE TABLE command.
*/
... snip

/*
* If we didn't dump the column definition explicitly above, and
* it is not-null and did not inherit that property from a parent,
* we have to mark it separately.
*/
if (!shouldPrintColumn(dopt, tbinfo, j) &&
tbinfo->notnull_constrs[j] != NULL &&
(tbinfo->notnull_islocal[j] && !tbinfo->ispartition && !dopt->binary_upgrade))
... snip

The comment seems to say that we can not handle the NOT NULL
constraint property in the CREATE TABLE command. Don't know why. We
add CHECK constraints separately in CREATE TABLE even if we didn't add
corresponding columns in CREATE TABLE. So there must be a reason not
to dump NOT NULL constraints that way and hence we required separate
code like above. I am afraid going that direction will show us some
other problems.

2. Name of the constraint provided by ALTER TABLE ... ADD CONSTRAINT
... being silently ignored didn't seem right to me. Especially when we
were adjusting the constraint to be local.

--
Best Wishes,
Ashutosh Bapat

#7Alvaro Herrera
alvherre@alvh.no-ip.org
In reply to: Ashutosh Bapat (#6)
Re: Difference in dump from original and restored database due to NOT NULL constraints on children

On 2024-Nov-27, Ashutosh Bapat wrote:

I noticed that. But two reasons why I chose the backend changes
1. The comment where we add explicit ADD CONSTRAINT is
/*
* Dump additional per-column properties that we can't handle in the
* main CREATE TABLE command.
*/
... snip

/*
* If we didn't dump the column definition explicitly above, and
* it is not-null and did not inherit that property from a parent,
* we have to mark it separately.
*/
if (!shouldPrintColumn(dopt, tbinfo, j) &&
tbinfo->notnull_constrs[j] != NULL &&
(tbinfo->notnull_islocal[j] && !tbinfo->ispartition && !dopt->binary_upgrade))
... snip

The comment seems to say that we can not handle the NOT NULL
constraint property in the CREATE TABLE command. Don't know why. We
add CHECK constraints separately in CREATE TABLE even if we didn't add
corresponding columns in CREATE TABLE. So there must be a reason not
to dump NOT NULL constraints that way and hence we required separate
code like above. I am afraid going that direction will show us some
other problems.

I don't think this is an important restriction. We can change that, as
long as all cases work correctly. We previously didn't try to use
"CONSTRAINT foobar NOT NULL a" because 1) we didn't support the
table-constraint syntax for not-null constraint and 2) not-null
constraint didn't support names anyway. We now support that syntax, so
we can use it.

2. Name of the constraint provided by ALTER TABLE ... ADD CONSTRAINT
... being silently ignored didn't seem right to me. Especially when we
were adjusting the constraint to be local.

We could make this throw an error when the names don't match; I don't
think that'd affect anything important. I'm not in love with the idea
of ADD CONSTRAINT changing the constraint name. Or, to be more precise,
I think having ALTER TABLE ADD CONSTRAINT change the name of an existing
constraint is a terrible idea. I will forever be shamed publicly if I
let that happen, and frankly I don't need any more reasons to be shamed
publicly, as I have plenty already.

--
Álvaro Herrera 48°01'N 7°57'E — https://www.EnterpriseDB.com/
"Use it up, wear it out, make it do, or do without"

#8Ashutosh Bapat
ashutosh.bapat.oss@gmail.com
In reply to: Alvaro Herrera (#7)
1 attachment(s)
Re: Difference in dump from original and restored database due to NOT NULL constraints on children

On Wed, Nov 27, 2024 at 7:04 PM Alvaro Herrera <alvherre@alvh.no-ip.org> wrote:

On 2024-Nov-27, Ashutosh Bapat wrote:

I noticed that. But two reasons why I chose the backend changes
1. The comment where we add explicit ADD CONSTRAINT is
/*
* Dump additional per-column properties that we can't handle in the
* main CREATE TABLE command.
*/
... snip

/*
* If we didn't dump the column definition explicitly above, and
* it is not-null and did not inherit that property from a parent,
* we have to mark it separately.
*/
if (!shouldPrintColumn(dopt, tbinfo, j) &&
tbinfo->notnull_constrs[j] != NULL &&
(tbinfo->notnull_islocal[j] && !tbinfo->ispartition && !dopt->binary_upgrade))
... snip

The comment seems to say that we can not handle the NOT NULL
constraint property in the CREATE TABLE command. Don't know why. We
add CHECK constraints separately in CREATE TABLE even if we didn't add
corresponding columns in CREATE TABLE. So there must be a reason not
to dump NOT NULL constraints that way and hence we required separate
code like above. I am afraid going that direction will show us some
other problems.

I don't think this is an important restriction. We can change that, as
long as all cases work correctly. We previously didn't try to use
"CONSTRAINT foobar NOT NULL a" because 1) we didn't support the
table-constraint syntax for not-null constraint and 2) not-null
constraint didn't support names anyway. We now support that syntax, so
we can use it.

Ok. Here's the patch implementing the same. As you said, it's a much
simpler patch. The test being developed in [1]/messages/by-id/CAExHW5uvx2LEyrUBdctV5gS25Zeb+-eXESkK93siQxWSjYFy6A@mail.gmail.com passes with this
change. pg_dump and pg_upgrade test suites also pass.

[1]: /messages/by-id/CAExHW5uvx2LEyrUBdctV5gS25Zeb+-eXESkK93siQxWSjYFy6A@mail.gmail.com

Adding this to CF for CI run.

--
Best Wishes,
Ashutosh Bapat

Attachments:

0001-Dumping-local-and-inherited-NOT-NULL-constr-20241128.patchtext/x-patch; charset=US-ASCII; name=0001-Dumping-local-and-inherited-NOT-NULL-constr-20241128.patchDownload
From 92be7b6f6306045f0cf84dad2625e5fd9cb16101 Mon Sep 17 00:00:00 2001
From: Ashutosh Bapat <ashutosh.bapat.oss@gmail.com>
Date: Thu, 28 Nov 2024 16:21:42 +0530
Subject: [PATCH] Dumping local and inherited NOT NULL constraints on non-local
 columns

A child table is dumped as CREATE TABLE ... INHERITS. If there is any
local NOT NULL constraint on a column not included in CREATE TABLE
command, it is printed separately as an ALTER TABLE ... command.  When
restored this constraint gets the name of the corresponding parent
constraint since CREATE TABLE is executed first and constraint name, if
mentioned, in ALTER TABLE command is ignored. We end up losing the name
of child constraint in the restored database. Instead dump them as part
of the CREATE TABLE command itself so that their given or default name
is preserved.

Author: Ashutosh Bapat
Reviewed-by: Alvaro Herrera
Discussion: https://www.postgresql.org/message-id/flat/CAExHW5tbdgAKDfqjDJ-7Fk6PJtHg8D4zUF6FQ4H2Pq8zK38Nyw%40mail.gmail.com
---
 src/bin/pg_dump/pg_dump.c | 45 +++++++++++++++++++--------------------
 1 file changed, 22 insertions(+), 23 deletions(-)

diff --git a/src/bin/pg_dump/pg_dump.c b/src/bin/pg_dump/pg_dump.c
index add7f16c902..2a4ff592fab 100644
--- a/src/bin/pg_dump/pg_dump.c
+++ b/src/bin/pg_dump/pg_dump.c
@@ -16221,6 +16221,28 @@ dumpTableSchema(Archive *fout, const TableInfo *tbinfo)
 											  fmtQualifiedDumpable(coll));
 					}
 				}
+				/* Add local NOT NULL constraint on columns not printed above. */
+				else if (!tbinfo->attisdropped[j] &&
+						 tbinfo->notnull_constrs[j] != NULL &&
+						 tbinfo->notnull_islocal[j])
+				{
+					/* Format properly if not first attr */
+					if (actual_atts == 0)
+						appendPQExpBufferStr(q, " (");
+					else
+						appendPQExpBufferChar(q, ',');
+					appendPQExpBufferStr(q, "\n    ");
+					actual_atts++;
+
+					if (tbinfo->notnull_constrs[j][0] == '\0')
+						appendPQExpBuffer(q, "NOT NULL %s",
+										  fmtId(tbinfo->attnames[j]));
+					else
+						appendPQExpBuffer(q, "CONSTRAINT %s NOT NULL %s",
+										  tbinfo->notnull_constrs[j],
+										  fmtId(tbinfo->attnames[j]));
+
+				}
 			}
 
 			/*
@@ -16662,29 +16684,6 @@ dumpTableSchema(Archive *fout, const TableInfo *tbinfo)
 			if (tbinfo->attisdropped[j])
 				continue;
 
-			/*
-			 * If we didn't dump the column definition explicitly above, and
-			 * it is not-null and did not inherit that property from a parent,
-			 * we have to mark it separately.
-			 */
-			if (!shouldPrintColumn(dopt, tbinfo, j) &&
-				tbinfo->notnull_constrs[j] != NULL &&
-				(tbinfo->notnull_islocal[j] && !tbinfo->ispartition && !dopt->binary_upgrade))
-			{
-				/* No constraint name desired? */
-				if (tbinfo->notnull_constrs[j][0] == '\0')
-					appendPQExpBuffer(q,
-									  "ALTER %sTABLE ONLY %s ALTER COLUMN %s SET NOT NULL;\n",
-									  foreign, qualrelname,
-									  fmtId(tbinfo->attnames[j]));
-				else
-					appendPQExpBuffer(q,
-									  "ALTER %sTABLE ONLY %s ADD CONSTRAINT %s NOT NULL %s;\n",
-									  foreign, qualrelname,
-									  tbinfo->notnull_constrs[j],
-									  fmtId(tbinfo->attnames[j]));
-			}
-
 			/*
 			 * Dump per-column statistics information. We only issue an ALTER
 			 * TABLE statement if the attstattarget entry for this column is
-- 
2.34.1

#9Ashutosh Bapat
ashutosh.bapat.oss@gmail.com
In reply to: Ashutosh Bapat (#8)
Re: Difference in dump from original and restored database due to NOT NULL constraints on children

On Thu, Nov 28, 2024 at 4:44 PM Ashutosh Bapat
<ashutosh.bapat.oss@gmail.com> wrote:

On Wed, Nov 27, 2024 at 7:04 PM Alvaro Herrera <alvherre@alvh.no-ip.org> wrote:

On 2024-Nov-27, Ashutosh Bapat wrote:

I noticed that. But two reasons why I chose the backend changes
1. The comment where we add explicit ADD CONSTRAINT is
/*
* Dump additional per-column properties that we can't handle in the
* main CREATE TABLE command.
*/
... snip

/*
* If we didn't dump the column definition explicitly above, and
* it is not-null and did not inherit that property from a parent,
* we have to mark it separately.
*/
if (!shouldPrintColumn(dopt, tbinfo, j) &&
tbinfo->notnull_constrs[j] != NULL &&
(tbinfo->notnull_islocal[j] && !tbinfo->ispartition && !dopt->binary_upgrade))
... snip

The comment seems to say that we can not handle the NOT NULL
constraint property in the CREATE TABLE command. Don't know why. We
add CHECK constraints separately in CREATE TABLE even if we didn't add
corresponding columns in CREATE TABLE. So there must be a reason not
to dump NOT NULL constraints that way and hence we required separate
code like above. I am afraid going that direction will show us some
other problems.

I don't think this is an important restriction. We can change that, as
long as all cases work correctly. We previously didn't try to use
"CONSTRAINT foobar NOT NULL a" because 1) we didn't support the
table-constraint syntax for not-null constraint and 2) not-null
constraint didn't support names anyway. We now support that syntax, so
we can use it.

Ok. Here's the patch implementing the same. As you said, it's a much
simpler patch. The test being developed in [1] passes with this
change. pg_dump and pg_upgrade test suites also pass.

[1] /messages/by-id/CAExHW5uvx2LEyrUBdctV5gS25Zeb+-eXESkK93siQxWSjYFy6A@mail.gmail.com

Adding this to CF for CI run.

CF entry: https://commitfest.postgresql.org/51/5408/

--
Best Wishes,
Ashutosh Bapat

#10Ashutosh Bapat
ashutosh.bapat.oss@gmail.com
In reply to: Ashutosh Bapat (#9)
1 attachment(s)
Re: Difference in dump from original and restored database due to NOT NULL constraints on children

Hi Alvaro,

On Thu, Nov 28, 2024 at 4:47 PM Ashutosh Bapat
<ashutosh.bapat.oss@gmail.com> wrote:

On Thu, Nov 28, 2024 at 4:44 PM Ashutosh Bapat
<ashutosh.bapat.oss@gmail.com> wrote:

On Wed, Nov 27, 2024 at 7:04 PM Alvaro Herrera <alvherre@alvh.no-ip.org> wrote:

On 2024-Nov-27, Ashutosh Bapat wrote:

I noticed that. But two reasons why I chose the backend changes
1. The comment where we add explicit ADD CONSTRAINT is
/*
* Dump additional per-column properties that we can't handle in the
* main CREATE TABLE command.
*/
... snip

/*
* If we didn't dump the column definition explicitly above, and
* it is not-null and did not inherit that property from a parent,
* we have to mark it separately.
*/
if (!shouldPrintColumn(dopt, tbinfo, j) &&
tbinfo->notnull_constrs[j] != NULL &&
(tbinfo->notnull_islocal[j] && !tbinfo->ispartition && !dopt->binary_upgrade))
... snip

The comment seems to say that we can not handle the NOT NULL
constraint property in the CREATE TABLE command. Don't know why. We
add CHECK constraints separately in CREATE TABLE even if we didn't add
corresponding columns in CREATE TABLE. So there must be a reason not
to dump NOT NULL constraints that way and hence we required separate
code like above. I am afraid going that direction will show us some
other problems.

I don't think this is an important restriction. We can change that, as
long as all cases work correctly. We previously didn't try to use
"CONSTRAINT foobar NOT NULL a" because 1) we didn't support the
table-constraint syntax for not-null constraint and 2) not-null
constraint didn't support names anyway. We now support that syntax, so
we can use it.

Ok. Here's the patch implementing the same. As you said, it's a much
simpler patch. The test being developed in [1] passes with this
change. pg_dump and pg_upgrade test suites also pass.

[1] /messages/by-id/CAExHW5uvx2LEyrUBdctV5gS25Zeb+-eXESkK93siQxWSjYFy6A@mail.gmail.com

Adding this to CF for CI run.

CF entry: https://commitfest.postgresql.org/51/5408/

--
Best Wishes,
Ashutosh Bapat

I looked at the patch again. Here are notes from self-review
1. The code to properly format non-first attribute is related in both
if and else blocks
if (shouldPrintColumn(..))
{
...
}
else if (<not-null attribute conditions>)
{

}
However, the code needs to be executed only when we are printing
something, so it can not be removed outside the if () else ()
structure to avoid duplication. Separating this small piece of code
into a function would add more lines of code than it would save. So I
have left it as is.

2. Improved the comment to make the purpose and context of the code clear.

3. With the code changes in the patch, we either print a local NOT
NULL constraint along with the attribute definition or as a separate
constraint in CREATE TABLE command. Non-local NOT NULL constraints
will be inherited from the parent. So there's no case where a NOT NULL
constraint would be lost. So it looks safe to remove the code to add
constraints through the ALTER TABLE command.

Attached updated patch. Once we commit this patch, I will be able to
proceed with the dump/restore test at [1]/messages/by-id/CAExHW5uvx2LEyrUBdctV5gS25Zeb+-eXESkK93siQxWSjYFy6A@mail.gmail.com.

[1]: /messages/by-id/CAExHW5uvx2LEyrUBdctV5gS25Zeb+-eXESkK93siQxWSjYFy6A@mail.gmail.com

--
Best Wishes,
Ashutosh Bapat

Attachments:

0001-Dumping-local-NOT-NULL-constraints-on-non-l-20241212.patchtext/x-patch; charset=US-ASCII; name=0001-Dumping-local-NOT-NULL-constraints-on-non-l-20241212.patchDownload
From 796c726ec44f75fb02637aa2488c078f6df5149e Mon Sep 17 00:00:00 2001
From: Ashutosh Bapat <ashutosh.bapat.oss@gmail.com>
Date: Thu, 28 Nov 2024 16:21:42 +0530
Subject: [PATCH] Dumping local NOT NULL constraints on non-local columns

A child table is dumped as CREATE TABLE ... INHERITS command. A local NOT NULL
constraint on a non-local column is printed separately as a subsequent ALTER
TABLE ...  command. When restored, this constraint inherits the name of the
corresponding parent constraint since the constraint name, if mentioned, in the
ALTER TABLE command is ignored. We end up losing the name of child constraint in
the restored database. Instead dump them as part of the CREATE TABLE command
itself so that their given or default name is preserved.

Author: Ashutosh Bapat
Reviewed-by: Alvaro Herrera
Discussion: https://www.postgresql.org/message-id/flat/CAExHW5tbdgAKDfqjDJ-7Fk6PJtHg8D4zUF6FQ4H2Pq8zK38Nyw%40mail.gmail.com
---
 src/bin/pg_dump/pg_dump.c | 50 +++++++++++++++++++++------------------
 1 file changed, 27 insertions(+), 23 deletions(-)

diff --git a/src/bin/pg_dump/pg_dump.c b/src/bin/pg_dump/pg_dump.c
index 89276524ae0..a422421b6e7 100644
--- a/src/bin/pg_dump/pg_dump.c
+++ b/src/bin/pg_dump/pg_dump.c
@@ -16220,6 +16220,33 @@ dumpTableSchema(Archive *fout, const TableInfo *tbinfo)
 											  fmtQualifiedDumpable(coll));
 					}
 				}
+
+				/*
+				 * Add local NOT NULL constraint on a non-local column (in a
+				 * non-binary dump) so that the constraint's local name, if
+				 * any, can be preserved along with conislocal.
+				 */
+				else if (!tbinfo->attisdropped[j] &&
+						 tbinfo->notnull_constrs[j] != NULL &&
+						 tbinfo->notnull_islocal[j])
+				{
+					/* Format properly if not first attr */
+					if (actual_atts == 0)
+						appendPQExpBufferStr(q, " (");
+					else
+						appendPQExpBufferChar(q, ',');
+					appendPQExpBufferStr(q, "\n    ");
+					actual_atts++;
+
+					if (tbinfo->notnull_constrs[j][0] == '\0')
+						appendPQExpBuffer(q, "NOT NULL %s",
+										  fmtId(tbinfo->attnames[j]));
+					else
+						appendPQExpBuffer(q, "CONSTRAINT %s NOT NULL %s",
+										  tbinfo->notnull_constrs[j],
+										  fmtId(tbinfo->attnames[j]));
+
+				}
 			}
 
 			/*
@@ -16661,29 +16688,6 @@ dumpTableSchema(Archive *fout, const TableInfo *tbinfo)
 			if (tbinfo->attisdropped[j])
 				continue;
 
-			/*
-			 * If we didn't dump the column definition explicitly above, and
-			 * it is not-null and did not inherit that property from a parent,
-			 * we have to mark it separately.
-			 */
-			if (!shouldPrintColumn(dopt, tbinfo, j) &&
-				tbinfo->notnull_constrs[j] != NULL &&
-				(tbinfo->notnull_islocal[j] && !tbinfo->ispartition && !dopt->binary_upgrade))
-			{
-				/* No constraint name desired? */
-				if (tbinfo->notnull_constrs[j][0] == '\0')
-					appendPQExpBuffer(q,
-									  "ALTER %sTABLE ONLY %s ALTER COLUMN %s SET NOT NULL;\n",
-									  foreign, qualrelname,
-									  fmtId(tbinfo->attnames[j]));
-				else
-					appendPQExpBuffer(q,
-									  "ALTER %sTABLE ONLY %s ADD CONSTRAINT %s NOT NULL %s;\n",
-									  foreign, qualrelname,
-									  tbinfo->notnull_constrs[j],
-									  fmtId(tbinfo->attnames[j]));
-			}
-
 			/*
 			 * Dump per-column statistics information. We only issue an ALTER
 			 * TABLE statement if the attstattarget entry for this column is
-- 
2.34.1

#11Alvaro Herrera
alvherre@alvh.no-ip.org
In reply to: Ashutosh Bapat (#10)
Re: Difference in dump from original and restored database due to NOT NULL constraints on children

On 2024-Dec-12, Ashutosh Bapat wrote:

Attached updated patch. Once we commit this patch, I will be able to
proceed with the dump/restore test at [1].

Thanks, I have pushed it.

--
Álvaro Herrera Breisgau, Deutschland — https://www.EnterpriseDB.com/
"You don't solve a bad join with SELECT DISTINCT" #CupsOfFail
https://twitter.com/connor_mc_d/status/1431240081726115845