mirror of
https://github.com/postgres/postgres.git
synced 2025-10-19 15:49:24 +03:00
Add "ALL SEQUENCES" support to publications.
This patch adds support for the ALL SEQUENCES clause in publications, enabling synchronization/replication of all sequences that is useful for upgrades. Publications can now include all sequences via FOR ALL SEQUENCES. psql enhancements: \d shows publications for a given sequence. \dRp indicates if a publication includes all sequences. ALL SEQUENCES can be combined with ALL TABLES, but not with other options like TABLE or TABLES IN SCHEMA. We can extend support for more granular clauses in future. The view pg_publication_sequences provides information about the mapping between publications and sequences. This patch enables publishing of sequences; subscriber-side support will be added in upcoming patches. Author: vignesh C <vignesh21@gmail.com> Author: Tomas Vondra <tomas@vondra.me> Reviewed-by: shveta malik <shveta.malik@gmail.com> Reviewed-by: Dilip Kumar <dilipbalaut@gmail.com> Reviewed-by: Peter Smith <smithpb2250@gmail.com> Reviewed-by: Hayato Kuroda <kuroda.hayato@fujitsu.com> Reviewed-by: Masahiko Sawada <sawada.mshk@gmail.com> Reviewed-by: Nisha Moond <nisha.moond412@gmail.com> Reviewed-by: Shlok Kyal <shlok.kyal.oss@gmail.com> Reviewed-by: Amit Kapila <amit.kapila16@gmail.com> Discussion: https://postgr.es/m/CAA4eK1LC+KJiAkSrpE_NwvNdidw9F2os7GERUeSxSKv71gXysQ@mail.gmail.com
This commit is contained in:
@@ -6374,6 +6374,16 @@ SCRAM-SHA-256$<replaceable><iteration count></replaceable>:<replaceable>&l
|
||||
</para></entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry role="catalog_table_entry"><para role="column_definition">
|
||||
<structfield>puballsequences</structfield> <type>bool</type>
|
||||
</para>
|
||||
<para>
|
||||
If true, this publication automatically includes all sequences
|
||||
in the database, including any that will be created in the future.
|
||||
</para></entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry role="catalog_table_entry"><para role="column_definition">
|
||||
<structfield>pubinsert</structfield> <type>bool</type>
|
||||
|
@@ -102,16 +102,18 @@
|
||||
A <firstterm>publication</firstterm> can be defined on any physical
|
||||
replication primary. The node where a publication is defined is referred to
|
||||
as <firstterm>publisher</firstterm>. A publication is a set of changes
|
||||
generated from a table or a group of tables, and might also be described as
|
||||
a change set or replication set. Each publication exists in only one database.
|
||||
generated from a table, a group of tables or the current state of all
|
||||
sequences, and might also be described as a change set or replication set.
|
||||
Each publication exists in only one database.
|
||||
</para>
|
||||
|
||||
<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 and all tables in schema.
|
||||
Objects must be added explicitly, except when a publication is created for
|
||||
<literal>ALL TABLES</literal>.
|
||||
Publications may currently only contain tables or sequences. Objects must be
|
||||
added explicitly, except when a publication is created using
|
||||
<literal>FOR TABLES IN SCHEMA</literal>, <literal>FOR ALL TABLES</literal>,
|
||||
or <literal>FOR ALL SEQUENCES</literal>.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
@@ -1049,24 +1051,24 @@ HINT: To initiate replication, you must manually create the replication slot, e
|
||||
<programlisting><![CDATA[
|
||||
/* pub # */ \dRp+
|
||||
Publication p1
|
||||
Owner | All tables | Inserts | Updates | Deletes | Truncates | Generated columns | Via root
|
||||
----------+------------+---------+---------+---------+-----------+-------------------+----------
|
||||
postgres | f | t | t | t | t | none | f
|
||||
Owner | All tables | All sequences | Inserts | Updates | Deletes | Truncates | Generated columns | Via root
|
||||
----------+------------+---------------+---------+---------+---------+-----------+-------------------+----------
|
||||
postgres | f | f | t | t | t | t | none | f
|
||||
Tables:
|
||||
"public.t1" WHERE ((a > 5) AND (c = 'NSW'::text))
|
||||
|
||||
Publication p2
|
||||
Owner | All tables | Inserts | Updates | Deletes | Truncates | Generated columns | Via root
|
||||
----------+------------+---------+---------+---------+-----------+-------------------+----------
|
||||
postgres | f | t | t | t | t | none | f
|
||||
Publication p2
|
||||
Owner | All tables | All sequences | Inserts | Updates | Deletes | Truncates | Generated columns | Via root
|
||||
----------+------------+---------------+---------+---------+---------+-----------+-------------------+----------
|
||||
postgres | f | f | t | t | t | t | none | f
|
||||
Tables:
|
||||
"public.t1"
|
||||
"public.t2" WHERE (e = 99)
|
||||
|
||||
Publication p3
|
||||
Owner | All tables | Inserts | Updates | Deletes | Truncates | Generated columns | Via root
|
||||
----------+------------+---------+---------+---------+-----------+-------------------+----------
|
||||
postgres | f | t | t | t | t | none | f
|
||||
Publication p3
|
||||
Owner | All tables | All sequences | Inserts | Updates | Deletes | Truncates | Generated columns | Via root
|
||||
----------+------------+---------------+---------+---------+---------+-----------+-------------------+----------
|
||||
postgres | f | f | t | t | t | t | none | f
|
||||
Tables:
|
||||
"public.t2" WHERE (d = 10)
|
||||
"public.t3" WHERE (g = 10)
|
||||
@@ -1491,10 +1493,10 @@ Publications:
|
||||
for each publication.
|
||||
<programlisting>
|
||||
/* pub # */ \dRp+
|
||||
Publication p1
|
||||
Owner | All tables | Inserts | Updates | Deletes | Truncates | Generated columns | Via root
|
||||
----------+------------+---------+---------+---------+-----------+-------------------+----------
|
||||
postgres | f | t | t | t | t | none | f
|
||||
Publication p1
|
||||
Owner | All tables | All sequences | Inserts | Updates | Deletes | Truncates | Generated columns | Via root
|
||||
----------+------------+---------------+---------+---------+---------+-----------+-------------------+----------
|
||||
postgres | f | f | t | t | t | t | none | f
|
||||
Tables:
|
||||
"public.t1" (id, a, b, d)
|
||||
</programlisting></para>
|
||||
|
@@ -82,8 +82,9 @@ ALTER PUBLICATION <replaceable class="parameter">name</replaceable> RENAME TO <r
|
||||
new owning role, and that role must have <literal>CREATE</literal>
|
||||
privilege on the database.
|
||||
Also, the new owner of a
|
||||
<link linkend="sql-createpublication-params-for-all-tables"><literal>FOR ALL TABLES</literal></link>
|
||||
or <link linkend="sql-createpublication-params-for-tables-in-schema"><literal>FOR TABLES IN SCHEMA</literal></link>
|
||||
<link linkend="sql-createpublication-params-for-tables-in-schema"><literal>FOR TABLES IN SCHEMA</literal></link>
|
||||
or <link linkend="sql-createpublication-params-for-all-tables"><literal>FOR ALL TABLES</literal></link>
|
||||
or <link linkend="sql-createpublication-params-for-all-sequences"><literal>FOR ALL SEQUENCES</literal></link>
|
||||
publication must be a superuser. However, a superuser can
|
||||
change the ownership of a publication regardless of these restrictions.
|
||||
</para>
|
||||
@@ -153,6 +154,7 @@ ALTER PUBLICATION <replaceable class="parameter">name</replaceable> RENAME TO <r
|
||||
<para>
|
||||
This clause alters publication parameters originally set by
|
||||
<xref linkend="sql-createpublication"/>. See there for more information.
|
||||
This clause is not applicable to sequences.
|
||||
</para>
|
||||
<caution>
|
||||
<para>
|
||||
|
@@ -22,14 +22,18 @@ PostgreSQL documentation
|
||||
<refsynopsisdiv>
|
||||
<synopsis>
|
||||
CREATE PUBLICATION <replaceable class="parameter">name</replaceable>
|
||||
[ FOR ALL TABLES
|
||||
| FOR <replaceable class="parameter">publication_object</replaceable> [, ... ] ]
|
||||
[ FOR { <replaceable class="parameter">publication_object</replaceable> [, ... ] | <replaceable class="parameter">all_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> [ * ] [ ( <replaceable class="parameter">column_name</replaceable> [, ... ] ) ] [ WHERE ( <replaceable class="parameter">expression</replaceable> ) ] [, ... ]
|
||||
TABLES IN SCHEMA { <replaceable class="parameter">schema_name</replaceable> | CURRENT_SCHEMA } [, ... ]
|
||||
|
||||
<phrase>where <replaceable class="parameter">all_publication_object</replaceable> is one of:</phrase>
|
||||
|
||||
ALL TABLES
|
||||
ALL SEQUENCES
|
||||
</synopsis>
|
||||
</refsynopsisdiv>
|
||||
|
||||
@@ -120,16 +124,6 @@ CREATE PUBLICATION <replaceable class="parameter">name</replaceable>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry id="sql-createpublication-params-for-all-tables">
|
||||
<term><literal>FOR ALL TABLES</literal></term>
|
||||
<listitem>
|
||||
<para>
|
||||
Marks the publication as one that replicates changes for all tables in
|
||||
the database, including tables created in the future.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry id="sql-createpublication-params-for-tables-in-schema">
|
||||
<term><literal>FOR TABLES IN SCHEMA</literal></term>
|
||||
<listitem>
|
||||
@@ -161,11 +155,37 @@ CREATE PUBLICATION <replaceable class="parameter">name</replaceable>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry id="sql-createpublication-params-for-all-tables">
|
||||
<term><literal>FOR ALL TABLES</literal></term>
|
||||
<listitem>
|
||||
<para>
|
||||
Marks the publication as one that replicates changes for all tables in
|
||||
the database, including tables created in the future.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry id="sql-createpublication-params-for-all-sequences">
|
||||
<term><literal>FOR ALL SEQUENCES</literal></term>
|
||||
<listitem>
|
||||
<para>
|
||||
Marks the publication as one that synchronizes changes for all sequences
|
||||
in the database, including sequences created in the future.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
Only persistent sequences are included in the publication. Temporary
|
||||
sequences and unlogged sequences are excluded from the publication.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry id="sql-createpublication-params-with">
|
||||
<term><literal>WITH ( <replaceable class="parameter">publication_parameter</replaceable> [= <replaceable class="parameter">value</replaceable>] [, ... ] )</literal></term>
|
||||
<listitem>
|
||||
<para>
|
||||
This clause specifies optional parameters for a publication. The
|
||||
This clause specifies optional parameters for a publication when
|
||||
publishing tables. This clause is not applicable to sequences. The
|
||||
following parameters are supported:
|
||||
|
||||
<variablelist>
|
||||
@@ -279,10 +299,10 @@ CREATE PUBLICATION <replaceable class="parameter">name</replaceable>
|
||||
<title>Notes</title>
|
||||
|
||||
<para>
|
||||
If <literal>FOR TABLE</literal>, <literal>FOR ALL TABLES</literal> or
|
||||
<literal>FOR TABLES IN SCHEMA</literal> are 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.
|
||||
If <literal>FOR TABLE</literal>, <literal>FOR TABLES IN SCHEMA</literal>,
|
||||
<literal>FOR ALL TABLES</literal> or <literal>FOR ALL SEQUENCES</literal>
|
||||
are 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>
|
||||
@@ -298,8 +318,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> and
|
||||
<command>FOR TABLES IN SCHEMA</command> clauses require the invoking
|
||||
rights on the table. The <literal>FOR TABLES IN SCHEMA</literal>,
|
||||
<literal>FOR ALL TABLES</literal> and
|
||||
<literal>FOR ALL SEQUENCES</literal> clauses require the invoking
|
||||
user to be a superuser.
|
||||
</para>
|
||||
|
||||
@@ -449,6 +470,21 @@ CREATE PUBLICATION sales_publication FOR TABLES IN SCHEMA marketing, sales;
|
||||
<programlisting>
|
||||
CREATE PUBLICATION users_filtered FOR TABLE users (user_id, firstname);
|
||||
</programlisting></para>
|
||||
|
||||
<para>
|
||||
Create a publication that publishes all sequences for synchronization:
|
||||
<programlisting>
|
||||
CREATE PUBLICATION all_sequences FOR ALL SEQUENCES;
|
||||
</programlisting>
|
||||
</para>
|
||||
|
||||
<para>
|
||||
Create a publication that publishes all changes in all tables, and
|
||||
all sequences for synchronization:
|
||||
<programlisting>
|
||||
CREATE PUBLICATION all_tables_sequences FOR ALL TABLES, ALL SEQUENCES;
|
||||
</programlisting>
|
||||
</para>
|
||||
</refsect1>
|
||||
|
||||
<refsect1>
|
||||
|
@@ -136,6 +136,11 @@
|
||||
<entry>prepared transactions</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><link linkend="view-pg-publication-sequences"><structname>pg_publication_sequences</structname></link></entry>
|
||||
<entry>publications and information of their associated sequences</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><link linkend="view-pg-publication-tables"><structname>pg_publication_tables</structname></link></entry>
|
||||
<entry>publications and information of their associated tables</entry>
|
||||
@@ -2549,6 +2554,67 @@ SELECT * FROM pg_locks pl LEFT JOIN pg_prepared_xacts ppx
|
||||
|
||||
</sect1>
|
||||
|
||||
<sect1 id="view-pg-publication-sequences">
|
||||
<title><structname>pg_publication_sequences</structname></title>
|
||||
|
||||
<indexterm zone="view-pg-publication-sequences">
|
||||
<primary>pg_publication_sequences</primary>
|
||||
</indexterm>
|
||||
|
||||
<para>
|
||||
The view <structname>pg_publication_sequences</structname> provides
|
||||
information about the mapping between publications and sequences.
|
||||
</para>
|
||||
|
||||
<table>
|
||||
<title><structname>pg_publication_sequences</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>pubname</structfield> <type>name</type>
|
||||
(references <link linkend="catalog-pg-publication"><structname>pg_publication</structname></link>.<structfield>pubname</structfield>)
|
||||
</para>
|
||||
<para>
|
||||
Name of publication
|
||||
</para></entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry role="catalog_table_entry"><para role="column_definition">
|
||||
<structfield>schemaname</structfield> <type>name</type>
|
||||
(references <link linkend="catalog-pg-namespace"><structname>pg_namespace</structname></link>.<structfield>nspname</structfield>)
|
||||
</para>
|
||||
<para>
|
||||
Name of schema containing sequence
|
||||
</para></entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry role="catalog_table_entry"><para role="column_definition">
|
||||
<structfield>sequencename</structfield> <type>name</type>
|
||||
(references <link linkend="catalog-pg-class"><structname>pg_class</structname></link>.<structfield>relname</structfield>)
|
||||
</para>
|
||||
<para>
|
||||
Name of sequence
|
||||
</para></entry>
|
||||
</row>
|
||||
</tbody>
|
||||
</tgroup>
|
||||
</table>
|
||||
</sect1>
|
||||
|
||||
<sect1 id="view-pg-publication-tables">
|
||||
<title><structname>pg_publication_tables</structname></title>
|
||||
|
||||
|
Reference in New Issue
Block a user