Skip to content

Commit

Permalink
Allow publishing the tables of schema.
Browse files Browse the repository at this point in the history
A new option "FOR ALL TABLES IN SCHEMA" in Create/Alter Publication allows
one or more schemas to be specified, whose tables are selected by the
publisher for sending the data to the subscriber.

The new syntax allows specifying both the tables and schemas. For example:
CREATE PUBLICATION pub1 FOR TABLE t1,t2,t3, ALL TABLES IN SCHEMA s1,s2;
OR
ALTER PUBLICATION pub1 ADD TABLE t1,t2,t3, ALL TABLES IN SCHEMA s1,s2;

A new system table "pg_publication_namespace" has been added, to maintain
the schemas that the user wants to publish through the publication.
Modified the output plugin (pgoutput) to publish the changes if the
relation is part of schema publication.

Updates pg_dump to identify and dump schema publications. Updates the \d
family of commands to display schema publications and \dRp+ variant will
now display associated schemas if any.

Author: Vignesh C, Hou Zhijie, Amit Kapila
Syntax-Suggested-by: Tom Lane, Alvaro Herrera
Reviewed-by: Greg Nancarrow, Masahiko Sawada, Hou Zhijie, Amit Kapila, Haiying Tang, Ajin Cherian, Rahila Syed, Bharath Rupireddy, Mark Dilger
Tested-by: Haiying Tang
Discussion: https://www.postgresql.org/message-id/CALDaNm0OANxuJ6RXqwZsM1MSY4s19nuH3734j4a72etDwvBETQ@mail.gmail.com
  • Loading branch information
Amit Kapila committed Oct 27, 2021
1 parent f0b051e commit 5a28324
Show file tree
Hide file tree
Showing 46 changed files with 2,830 additions and 212 deletions.
72 changes: 69 additions & 3 deletions doc/src/sgml/catalogs.sgml
Expand Up @@ -240,6 +240,11 @@
<entry>publications for logical replication</entry>
</row>

<row>
<entry><link linkend="catalog-pg-publication-namespace"><structname>pg_publication_namespace</structname></link></entry>
<entry>schema to publication mapping</entry>
</row>

<row>
<entry><link linkend="catalog-pg-publication-rel"><structname>pg_publication_rel</structname></link></entry>
<entry>relation to publication mapping</entry>
Expand Down Expand Up @@ -6176,6 +6181,67 @@ SCRAM-SHA-256$<replaceable>&lt;iteration count&gt;</replaceable>:<replaceable>&l
</table>
</sect1>

<sect1 id="catalog-pg-publication-namespace">
<title><structname>pg_publication_namespace</structname></title>

<indexterm zone="catalog-pg-publication-namespace">
<primary>pg_publication_namespace</primary>
</indexterm>

<para>
The catalog <structname>pg_publication_namespace</structname> contains the
mapping between schemas and publications in the database. This is a
many-to-many mapping.
</para>

<table>
<title><structname>pg_publication_namespace</structname> Columns</title>
<tgroup cols="1">
<thead>
<row>
<entry role="catalog_table_entry"><para role="column_definition">
Column Type
</para>
<para>
Description
</para></entry>
</row>
</thead>

<tbody>
<row>
<entry role="catalog_table_entry"><para role="column_definition">
<structfield>oid</structfield> <type>oid</type>
</para>
<para>
Row identifier
</para></entry>
</row>

<row>
<entry role="catalog_table_entry"><para role="column_definition">
<structfield>pnpubid</structfield> <type>oid</type>
(references <link linkend="catalog-pg-publication"><structname>pg_publication</structname></link>.<structfield>oid</structfield>)
</para>
<para>
Reference to publication
</para></entry>
</row>

<row>
<entry role="catalog_table_entry"><para role="column_definition">
<structfield>pnnspid</structfield> <type>oid</type>
(references <link linkend="catalog-pg-namespace"><structname>pg_namespace</structname></link>.<structfield>oid</structfield>)
</para>
<para>
Reference to schema
</para></entry>
</row>
</tbody>
</tgroup>
</table>
</sect1>

<sect1 id="catalog-pg-publication-rel">
<title><structname>pg_publication_rel</structname></title>

Expand Down Expand Up @@ -11278,9 +11344,9 @@ SELECT * FROM pg_locks pl LEFT JOIN pg_prepared_xacts ppx
information about the mapping between publications and the tables they
contain. Unlike the underlying catalog
<link linkend="catalog-pg-publication-rel"><structname>pg_publication_rel</structname></link>,
this view expands
publications defined as <literal>FOR ALL TABLES</literal>, so for such
publications there will be a row for each eligible table.
this view expands publications defined as <literal>FOR ALL TABLES</literal>
and <literal>FOR ALL TABLES IN SCHEMA</literal>, so for such publications
there will be a row for each eligible table.
</para>

<table>
Expand Down
14 changes: 8 additions & 6 deletions doc/src/sgml/logical-replication.sgml
Expand Up @@ -108,9 +108,9 @@
<para>
Publications are different from schemas and do not affect how the table is
accessed. Each table can be added to multiple publications if needed.
Publications may currently only contain tables. Objects must be added
explicitly, except when a publication is created for <literal>ALL
TABLES</literal>.
Publications may currently only contain tables and all tables in schema.
Objects must be added explicitly, except when a publication is created for
<literal>ALL TABLES</literal>.
</para>

<para>
Expand Down Expand Up @@ -534,7 +534,8 @@
and <literal>TRIGGER</literal> privilege on such tables to roles that
superusers trust. Moreover, if untrusted users can create tables, use only
publications that list tables explicitly. That is to say, create a
subscription <literal>FOR ALL TABLES</literal> only when superusers trust
subscription <literal>FOR ALL TABLES</literal> or
<literal>FOR ALL TABLES IN SCHEMA</literal> only when superusers trust
every user permitted to create a non-temp table on the publisher or the
subscriber.
</para>
Expand Down Expand Up @@ -564,8 +565,9 @@

<para>
To add tables to a publication, the user must have ownership rights on the
table. To create a publication that publishes all tables automatically,
the user must be a superuser.
table. To add all tables in schema to a publication, the user must be a
superuser. To create a publication that publishes all tables or all tables in
schema automatically, the user must be a superuser.
</para>

<para>
Expand Down
77 changes: 61 additions & 16 deletions doc/src/sgml/ref/alter_publication.sgml
Expand Up @@ -21,12 +21,17 @@ PostgreSQL documentation

<refsynopsisdiv>
<synopsis>
ALTER PUBLICATION <replaceable class="parameter">name</replaceable> ADD TABLE [ ONLY ] <replaceable class="parameter">table_name</replaceable> [ * ] [, ...]
ALTER PUBLICATION <replaceable class="parameter">name</replaceable> SET TABLE [ ONLY ] <replaceable class="parameter">table_name</replaceable> [ * ] [, ...]
ALTER PUBLICATION <replaceable class="parameter">name</replaceable> DROP TABLE [ ONLY ] <replaceable class="parameter">table_name</replaceable> [ * ] [, ...]
ALTER PUBLICATION <replaceable class="parameter">name</replaceable> ADD <replaceable class="parameter">publication_object</replaceable> [, ...]
ALTER PUBLICATION <replaceable class="parameter">name</replaceable> SET <replaceable class="parameter">publication_object</replaceable> [, ...]
ALTER PUBLICATION <replaceable class="parameter">name</replaceable> DROP <replaceable class="parameter">publication_object</replaceable> [, ...]
ALTER PUBLICATION <replaceable class="parameter">name</replaceable> SET ( <replaceable class="parameter">publication_parameter</replaceable> [= <replaceable class="parameter">value</replaceable>] [, ... ] )
ALTER PUBLICATION <replaceable class="parameter">name</replaceable> OWNER TO { <replaceable>new_owner</replaceable> | CURRENT_ROLE | CURRENT_USER | SESSION_USER }
ALTER PUBLICATION <replaceable class="parameter">name</replaceable> RENAME TO <replaceable>new_name</replaceable>

<phrase>where <replaceable class="parameter">publication_object</replaceable> is one of:</phrase>

TABLE [ ONLY ] <replaceable class="parameter">table_name</replaceable> [ * ] [, ... ]
ALL TABLES IN SCHEMA { <replaceable class="parameter">schema_name</replaceable> | CURRENT_SCHEMA } [, ... ]
</synopsis>
</refsynopsisdiv>

Expand All @@ -39,14 +44,15 @@ ALTER PUBLICATION <replaceable class="parameter">name</replaceable> RENAME TO <r
</para>

<para>
The first three variants change which tables are part of the publication.
The <literal>SET TABLE</literal> clause will replace the list of tables in
the publication with the specified one. The <literal>ADD TABLE</literal>
and <literal>DROP TABLE</literal> clauses will add and remove one or more
tables from the publication. Note that adding tables to a publication that
is already subscribed to will require a <literal>ALTER SUBSCRIPTION
... REFRESH PUBLICATION</literal> action on the subscribing side in order
to become effective.
The first three variants change which tables/schemas are part of the
publication. The <literal>SET</literal> clause will replace the list of
tables/schemas in the publication with the specified list; the existing
tables/schemas that were present in the publication will be removed. The
<literal>ADD</literal> and <literal>DROP</literal> clauses will add and
remove one or more tables/schemas from the publication. Note that adding
tables/schemas to a publication that is already subscribed to will require a
<literal>ALTER SUBSCRIPTION ... REFRESH PUBLICATION</literal> action on the
subscribing side in order to become effective.
</para>

<para>
Expand All @@ -63,11 +69,22 @@ ALTER PUBLICATION <replaceable class="parameter">name</replaceable> RENAME TO <r
<para>
You must own the publication to use <command>ALTER PUBLICATION</command>.
Adding a table to a publication additionally requires owning that table.
To alter the owner, you must also be a direct or indirect member of the new
owning role. The new owner must have <literal>CREATE</literal> privilege on
the database. Also, the new owner of a <literal>FOR ALL TABLES</literal>
publication must be a superuser. However, a superuser can change the
ownership of a publication regardless of these restrictions.
The <literal>ADD ALL TABLES IN SCHEMA</literal> and
<literal>SET ALL TABLES IN SCHEMA</literal> to a publication requires the
invoking user to be a superuser. To alter the owner, you must also be a
direct or indirect member of the new owning role. The new owner must have
<literal>CREATE</literal> privilege on the database. Also, the new owner
of a <literal>FOR ALL TABLES</literal> or <literal>FOR ALL TABLES IN
SCHEMA</literal> publication must be a superuser. However, a superuser can
change the ownership of a publication regardless of these restrictions.
</para>

<para>
Adding/Setting a table that is part of schema specified in
<literal>ALL TABLES IN SCHEMA</literal>, adding/setting a schema to a
publication that already has a table that is part of specified schema or
adding/setting a table to a publication that already has a table's schema as
part of the specified schema is not supported.
</para>
</refsect1>

Expand Down Expand Up @@ -97,6 +114,15 @@ ALTER PUBLICATION <replaceable class="parameter">name</replaceable> RENAME TO <r
</listitem>
</varlistentry>

<varlistentry>
<term><replaceable class="parameter">schema_name</replaceable></term>
<listitem>
<para>
Name of an existing schema.
</para>
</listitem>
</varlistentry>

<varlistentry>
<term><literal>SET ( <replaceable class="parameter">publication_parameter</replaceable> [= <replaceable class="parameter">value</replaceable>] [, ... ] )</literal></term>
<listitem>
Expand Down Expand Up @@ -142,6 +168,25 @@ ALTER PUBLICATION noinsert SET (publish = 'update, delete');
<programlisting>
ALTER PUBLICATION mypublication ADD TABLE users, departments;
</programlisting></para>

<para>
Add schemas <structname>marketing</structname> and
<structname>sales</structname> to the publication
<structname>sales_publication</structname>:
<programlisting>
ALTER PUBLICATION sales_publication ADD ALL TABLES IN SCHEMA marketing, sales;
</programlisting>
</para>

<para>
Add tables <structname>users</structname>,
<structname>departments</structname> and schema
<structname>production</structname> to the publication
<structname>production_publication</structname>:
<programlisting>
ALTER PUBLICATION production_publication ADD TABLE users, departments, ALL TABLES IN SCHEMA production;
</programlisting>
</para>
</refsect1>

<refsect1>
Expand Down
76 changes: 69 additions & 7 deletions doc/src/sgml/ref/create_publication.sgml
Expand Up @@ -22,9 +22,14 @@ PostgreSQL documentation
<refsynopsisdiv>
<synopsis>
CREATE PUBLICATION <replaceable class="parameter">name</replaceable>
[ FOR TABLE [ ONLY ] <replaceable class="parameter">table_name</replaceable> [ * ] [, ...]
| FOR ALL TABLES ]
[ FOR ALL TABLES
| FOR <replaceable class="parameter">publication_object</replaceable> [, ... ] ]
[ WITH ( <replaceable class="parameter">publication_parameter</replaceable> [= <replaceable class="parameter">value</replaceable>] [, ... ] ) ]

<phrase>where <replaceable class="parameter">publication_object</replaceable> is one of:</phrase>

TABLE [ ONLY ] <replaceable class="parameter">table_name</replaceable> [ * ] [, ... ]
ALL TABLES IN SCHEMA { <replaceable class="parameter">schema_name</replaceable> | CURRENT_SCHEMA } [, ... ]
</synopsis>
</refsynopsisdiv>

Expand Down Expand Up @@ -86,6 +91,11 @@ CREATE PUBLICATION <replaceable class="parameter">name</replaceable>
partition are also published via publications that its ancestors are
part of.
</para>

<para>
Specifying a table that is part of a schema specified by
<literal>FOR ALL TABLES IN SCHEMA</literal> is not supported.
</para>
</listitem>
</varlistentry>

Expand All @@ -99,6 +109,37 @@ CREATE PUBLICATION <replaceable class="parameter">name</replaceable>
</listitem>
</varlistentry>

<varlistentry>
<term><literal>FOR ALL TABLES IN SCHEMA</literal></term>
<listitem>
<para>
Marks the publication as one that replicates changes for all tables in
the specified list of schemas, including tables created in the future.
</para>

<para>
Specifying a schema along with a table which belongs to the specified
schema using <literal>FOR TABLE</literal> is not supported.
</para>

<para>
Only persistent base tables and partitioned tables present in the schema
will be included as part of the publication. Temporary tables, unlogged
tables, foreign tables, materialized views, and regular views from the
schema will not be part of the publication.
</para>

<para>
When a partitioned table is published via schema level publication, all
of its existing and future partitions irrespective of it being from the
publication schema or not are implicitly considered to be part of the
publication. So, even operations that are performed directly on a
partition are also published via publications that its ancestors are
part of.
</para>
</listitem>
</varlistentry>

<varlistentry>
<term><literal>WITH ( <replaceable class="parameter">publication_parameter</replaceable> [= <replaceable class="parameter">value</replaceable>] [, ... ] )</literal></term>
<listitem>
Expand Down Expand Up @@ -153,9 +194,10 @@ CREATE PUBLICATION <replaceable class="parameter">name</replaceable>
<title>Notes</title>

<para>
If neither <literal>FOR TABLE</literal> nor <literal>FOR ALL
TABLES</literal> is specified, then the publication starts out with an
empty set of tables. That is useful if tables are to be added later.
If <literal>FOR TABLE</literal>, <literal>FOR ALL TABLES</literal> or
<literal>FOR ALL TABLES IN SCHEMA</literal> is not specified, then the
publication starts out with an empty set of tables. That is useful if
tables or schemas are to be added later.
</para>

<para>
Expand All @@ -171,8 +213,9 @@ CREATE PUBLICATION <replaceable class="parameter">name</replaceable>

<para>
To add a table to a publication, the invoking user must have ownership
rights on the table. The <command>FOR ALL TABLES</command> clause requires
the invoking user to be a superuser.
rights on the table. The <command>FOR ALL TABLES</command> and
<command>FOR ALL TABLES IN SCHEMA</command> clauses require the invoking
user to be a superuser.
</para>

<para>
Expand Down Expand Up @@ -222,6 +265,25 @@ CREATE PUBLICATION alltables FOR ALL TABLES;
<programlisting>
CREATE PUBLICATION insert_only FOR TABLE mydata
WITH (publish = 'insert');
</programlisting>
</para>

<para>
Create a publication that publishes all changes for tables
<structname>users</structname>, <structname>departments</structname> and
all changes for all the tables present in the schema
<structname>production</structname>:
<programlisting>
CREATE PUBLICATION production_publication FOR TABLE users, departments, ALL TABLES IN SCHEMA production;
</programlisting>
</para>

<para>
Create a publication that publishes all changes for all the tables present in
the schemas <structname>marketing</structname> and
<structname>sales</structname>:
<programlisting>
CREATE PUBLICATION sales_publication FOR ALL TABLES IN SCHEMA marketing, sales;
</programlisting></para>
</refsect1>

Expand Down
4 changes: 2 additions & 2 deletions doc/src/sgml/ref/psql-ref.sgml
Expand Up @@ -1853,8 +1853,8 @@ testdb=&gt;
If <replaceable class="parameter">pattern</replaceable> is
specified, only those publications whose names match the pattern are
listed.
If <literal>+</literal> is appended to the command name, the tables
associated with each publication are shown as well.
If <literal>+</literal> is appended to the command name, the tables and
schemas associated with each publication are shown as well.
</para>
</listitem>
</varlistentry>
Expand Down
4 changes: 2 additions & 2 deletions src/backend/catalog/Makefile
Expand Up @@ -68,8 +68,8 @@ CATALOG_HEADERS := \
pg_foreign_table.h pg_policy.h pg_replication_origin.h \
pg_default_acl.h pg_init_privs.h pg_seclabel.h pg_shseclabel.h \
pg_collation.h pg_partitioned_table.h pg_range.h pg_transform.h \
pg_sequence.h pg_publication.h pg_publication_rel.h pg_subscription.h \
pg_subscription_rel.h
pg_sequence.h pg_publication.h pg_publication_namespace.h \
pg_publication_rel.h pg_subscription.h pg_subscription_rel.h

GENERATED_HEADERS := $(CATALOG_HEADERS:%.h=%_d.h) schemapg.h system_fk_info.h

Expand Down
2 changes: 2 additions & 0 deletions src/backend/catalog/aclchk.c
Expand Up @@ -3427,6 +3427,7 @@ aclcheck_error(AclResult aclerr, ObjectType objtype,
case OBJECT_DEFAULT:
case OBJECT_DEFACL:
case OBJECT_DOMCONSTRAINT:
case OBJECT_PUBLICATION_NAMESPACE:
case OBJECT_PUBLICATION_REL:
case OBJECT_ROLE:
case OBJECT_RULE:
Expand Down Expand Up @@ -3566,6 +3567,7 @@ aclcheck_error(AclResult aclerr, ObjectType objtype,
case OBJECT_DEFAULT:
case OBJECT_DEFACL:
case OBJECT_DOMCONSTRAINT:
case OBJECT_PUBLICATION_NAMESPACE:
case OBJECT_PUBLICATION_REL:
case OBJECT_ROLE:
case OBJECT_TRANSFORM:
Expand Down

0 comments on commit 5a28324

Please sign in to comment.