On Wed, 21 Jan 2026 at 17:11, Dilip Kumar <[email protected]> wrote: > > On Wed, Jan 21, 2026 at 4:57 PM shveta malik <[email protected]> wrote: > > > > On Wed, Jan 21, 2026 at 11:35 AM Dilip Kumar <[email protected]> wrote: > > > > > > Thanks for explaining this, overall I like the Approach 1, and I also > > > see the problem when publish via root is given in that case COPY FROM > > > is executed on the root and it would be hard to exclude specific > > > partitions. What is the behavior when root of partition tree is added > > > but publish via root is not true, it doesn't add any relation to > > > publication rel or how does it manage to not copy data from > > > partitions? > > > > > > > So, I believe you are asking about the behavior of COPY on HEAD for > > the following case: > > > > CREATE PUBLICATION pub1 FOR TABLE tab_root WITH > > (publish_via_partition_root = false); > > > > In this scenario, pg_publication_rel contains an entry for tab_root, > > while pg_publication_tables contains all leaf partitions (because > > publish_via_partition_root = false). Consequently, > > pg_subscription_rel, which is derived from pg_publication_tables, also > > contains all corresponding leaf partitions. As a result, on HEAD, a > > separate tablesync worker is launched for each leaf partition, and > > each leaf partition is copied independently. > > > > ~~ > > > > Now, in Approach 4, when publish_via_partition_root is set to false, > > we propose avoiding the inclusion of leaf partitions in > > pg_publication_tables if their parent appears in the EXCEPT list. > > Given the table hierarchy described in Approach1_challenges: > > > > tab_root > > ├── tab_part_1 > > │ ├── tab_part_1_1 > > │ │ ├── tab_part_1_1_1 > > │ │ │ └── tab_part_1_1_1_1 > > │ │ └── tab_part_1_1_2 > > │ └── tab_part_1_2 > > │ ├── tab_part_1_2_1 > > │ └── tab_part_1_2_2 > > └── tab_part_2 > > > > If tab_part_1_1 is specified in the EXCEPT list, then > > pg_publication_tables will include only those leaf partitions that are > > not in the partition-chain of tab_part_1_1. As a result, both > > pg_publication_tables and pg_subscription_rel (which is built from > > pg_publication_tables via fetch_relation_list) will contain: > > > > tab_part_1_2_1 > > tab_part_1_2_2 > > tab_part_2 > > > > With this setup, any INSERT into tab_part_1 or tab_root that routes > > rows to tab_part_1_1_1_1 or tab_part_1_1_2 will not be replicated. > > However, rows routed to any of the three leaf partitions listed above > > will be replicated. > > > > I hope it answers your query. If we have to go by Approach1, then do > > you see any simpler way to overcome the challenges we mention for > > publish_via_partition_root=true case. Or any other approach > > altogether? > > Thanks for the explanation, that clears it up. I agree that Approach 3 > is the right path forward. And it makes sense to extend this with > Approach 4. Logically, I think it's reasonable to say that if a user > chooses to partition via the root, they are treating the entire > partition tree as a single entity. Therefore, it makes sense to > disallow the exclusion of individual child partitions in that context. > Hi,
I have prepared a patch for Approach-3. We are also checking the feasibility of other approaches. Thanks, Shlok Kyal
From ed453bf47cecbdb04e7064b627af1ef22b98f382 Mon Sep 17 00:00:00 2001 From: Shlok Kyal <[email protected]> Date: Tue, 9 Dec 2025 22:41:23 +0530 Subject: [PATCH v36] Skip publishing the tables specified in EXCEPT TABLE. A new "EXCEPT TABLE" clause for CREATE PUBLICATION allows one or more tables to be excluded. The publisher will not send the data of excluded tables to the subscriber. The new syntax allows specifying excluded relations when creating a publication. For example: CREATE PUBLICATION pub1 FOR ALL TABLES EXCEPT TABLE (t1,t2); A new column "prexcept" is added to table "pg_publication_rel", to flag the relations that the user wants to exclude from the publications. pg_dump is updated to identify and dump the excluded tables of the publications. The psql \d family of commands can now display excluded tables. Bump catalog version. --- doc/src/sgml/catalogs.sgml | 10 + doc/src/sgml/logical-replication.sgml | 6 +- doc/src/sgml/ref/create_publication.sgml | 51 +++- doc/src/sgml/ref/psql-ref.sgml | 11 +- src/backend/catalog/pg_publication.c | 131 +++++++-- src/backend/commands/publicationcmds.c | 109 ++++---- src/backend/commands/tablecmds.c | 13 +- src/backend/parser/gram.y | 42 ++- src/backend/replication/pgoutput/pgoutput.c | 42 ++- src/backend/utils/cache/relcache.c | 24 +- src/bin/pg_dump/pg_dump.c | 71 +++++ src/bin/pg_dump/pg_dump.h | 1 + src/bin/pg_dump/t/002_pg_dump.pl | 30 +++ src/bin/psql/describe.c | 87 +++++- src/bin/psql/tab-complete.in.c | 12 +- src/include/catalog/pg_publication.h | 13 +- src/include/catalog/pg_publication_rel.h | 1 + src/include/nodes/parsenodes.h | 3 + src/test/regress/expected/publication.out | 93 ++++++- src/test/regress/sql/publication.sql | 37 ++- src/test/subscription/meson.build | 1 + .../t/037_rep_changes_except_table.pl | 253 ++++++++++++++++++ 22 files changed, 904 insertions(+), 137 deletions(-) create mode 100644 src/test/subscription/t/037_rep_changes_except_table.pl diff --git a/doc/src/sgml/catalogs.sgml b/doc/src/sgml/catalogs.sgml index 2fc63442980..9e847152b44 100644 --- a/doc/src/sgml/catalogs.sgml +++ b/doc/src/sgml/catalogs.sgml @@ -6581,6 +6581,16 @@ SCRAM-SHA-256$<replaceable><iteration count></replaceable>:<replaceable>&l if there is no publication qualifying condition.</para></entry> </row> + <row> + <entry role="catalog_table_entry"><para role="column_definition"> + <structfield>prexcept</structfield> <type>bool</type> + </para> + <para> + True if the relation is excluded from the publication. See + <link linkend="sql-createpublication-params-for-except-table"><literal>EXCEPT TABLE</literal></link>. + </para></entry> + </row> + <row> <entry role="catalog_table_entry"><para role="column_definition"> <structfield>prattrs</structfield> <type>int2vector</type> diff --git a/doc/src/sgml/logical-replication.sgml b/doc/src/sgml/logical-replication.sgml index 5028fe9af09..f01281fd4f9 100644 --- a/doc/src/sgml/logical-replication.sgml +++ b/doc/src/sgml/logical-replication.sgml @@ -116,7 +116,11 @@ <literal>FOR TABLES IN SCHEMA</literal>, <literal>FOR ALL TABLES</literal>, or <literal>FOR ALL SEQUENCES</literal>. Unlike tables, sequences can be synchronized at any time. For more information, see - <xref linkend="logical-replication-sequences"/>. + <xref linkend="logical-replication-sequences"/>. When a publication is + created with <literal>FOR ALL TABLES</literal>, tables can be explicitly + excluded from publication using the + <link linkend="sql-createpublication-params-for-except-table"><literal>EXCEPT TABLE</literal></link> + clause. </para> <para> diff --git a/doc/src/sgml/ref/create_publication.sgml b/doc/src/sgml/ref/create_publication.sgml index 6efbb915cec..61974f41fd9 100644 --- a/doc/src/sgml/ref/create_publication.sgml +++ b/doc/src/sgml/ref/create_publication.sgml @@ -32,12 +32,16 @@ CREATE PUBLICATION <replaceable class="parameter">name</replaceable> <phrase>and <replaceable class="parameter">publication_all_object</replaceable> is one of:</phrase> - ALL TABLES + ALL TABLES [ EXCEPT [ TABLE ] ( <replaceable class="parameter">except_table_object</replaceable> [, ... ] ) ] ALL SEQUENCES <phrase>and <replaceable class="parameter">table_and_columns</replaceable> is:</phrase> [ ONLY ] <replaceable class="parameter">table_name</replaceable> [ * ] [ ( <replaceable class="parameter">column_name</replaceable> [, ... ] ) ] [ WHERE ( <replaceable class="parameter">expression</replaceable> ) ] + +<phrase>and <replaceable class="parameter">except_table_object</replaceable> is:</phrase> + + [ ONLY ] <replaceable class="parameter">table_name</replaceable> [ * ] </synopsis> </refsynopsisdiv> @@ -164,7 +168,8 @@ CREATE PUBLICATION <replaceable class="parameter">name</replaceable> <listitem> <para> Marks the publication as one that replicates changes for all tables in - the database, including tables created in the future. + the database, including tables created in the future. Tables listed in + EXCEPT TABLE are excluded from the publication. </para> </listitem> </varlistentry> @@ -184,6 +189,31 @@ CREATE PUBLICATION <replaceable class="parameter">name</replaceable> </listitem> </varlistentry> + <varlistentry id="sql-createpublication-params-for-except-table"> + <term><literal>EXCEPT TABLE</literal></term> + <listitem> + <para> + This clause specifies a list of tables to be excluded from the + publication. + </para> + <para> + For inherited tables, if <literal>ONLY</literal> is specified before the + table name, only that table is excluded from the publication. If + <literal>ONLY</literal> is not specified, the table and all its descendant + tables (if any) are excluded. Optionally, <literal>*</literal> can be + specified after the table name to explicitly indicate that descendant + tables are excluded. + </para> + <para> + For partitioned tables, only the root partitioned table may be specified + in <literal>EXCEPT TABLE</literal>. Doing so excludes the root table and + all of its partitions from replication, regardless of the value of + <literal>publish_via_partition_root</literal>. The optional + <literal>*</literal> has no effect for partitioned tables. + </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> @@ -489,6 +519,23 @@ CREATE PUBLICATION all_sequences FOR ALL SEQUENCES; all sequences for synchronization: <programlisting> CREATE PUBLICATION all_tables_sequences FOR ALL TABLES, ALL SEQUENCES; +</programlisting> + </para> + + <para> + Create a publication that publishes all changes in all tables except + <structname>users</structname> and <structname>departments</structname>: +<programlisting> +CREATE PUBLICATION all_tables_except FOR ALL TABLES EXCEPT (users, departments); +</programlisting> + </para> + + <para> + Create a publication that publishes all sequences for synchronization, and + all changes in all tables except <structname>users</structname> and + <structname>departments</structname>: +<programlisting> +CREATE PUBLICATION all_sequences_tables_except FOR ALL SEQUENCES, ALL TABLES EXCEPT (users, departments); </programlisting> </para> </refsect1> diff --git a/doc/src/sgml/ref/psql-ref.sgml b/doc/src/sgml/ref/psql-ref.sgml index f56c70263e0..8416128a9ad 100644 --- a/doc/src/sgml/ref/psql-ref.sgml +++ b/doc/src/sgml/ref/psql-ref.sgml @@ -1299,10 +1299,8 @@ SELECT $1 \parse stmt1 <replaceable class="parameter">pattern</replaceable>, show all columns, their types, the tablespace (if not the default) and any special attributes such as <literal>NOT NULL</literal> or defaults. - Associated indexes, constraints, rules, and triggers are - also shown. For foreign tables, the associated foreign - server is shown as well. - (<quote>Matching the pattern</quote> is defined in + Associated indexes, constraints, rules, publications, and triggers are + also shown. (<quote>Matching the pattern</quote> is defined in <xref linkend="app-psql-patterns"/> below.) </para> @@ -2103,8 +2101,9 @@ SELECT $1 \parse stmt1 listed. If <literal>x</literal> is appended to the command name, the results are displayed in expanded mode. - If <literal>+</literal> is appended to the command name, the tables and - schemas associated with each publication are shown as well. + If <literal>+</literal> is appended to the command name, the tables, + excluded tables, and schemas associated with each publication are shown + as well. </para> </listitem> </varlistentry> diff --git a/src/backend/catalog/pg_publication.c b/src/backend/catalog/pg_publication.c index 9a4791c573e..0fdddd96704 100644 --- a/src/backend/catalog/pg_publication.c +++ b/src/backend/catalog/pg_publication.c @@ -366,9 +366,11 @@ GetTopMostAncestorInPublication(Oid puboid, List *ancestors, int *ancestor_level foreach(lc, ancestors) { Oid ancestor = lfirst_oid(lc); - List *apubids = GetRelationPublications(ancestor); + List *apubids = NIL; List *aschemaPubids = NIL; + GetRelationPublications(ancestor, &apubids, NULL); + level++; if (list_member_oid(apubids, puboid)) @@ -466,6 +468,14 @@ publication_add_relation(Oid pubid, PublicationRelInfo *pri, RelationGetRelationName(targetrel), pub->name))); } + /* + * Handle the case where a partition is excluded by EXCEPT TABLE + */ + if (pub->alltables && pri->except && targetrel->rd_rel->relispartition) + ereport(ERROR, + (errmsg("partition \"%s\" cannot be excluded using EXCEPT TABLE", + RelationGetRelationName(targetrel)))); + check_publication_add_relation(targetrel); /* Validate and translate column names into a Bitmapset of attnums. */ @@ -482,6 +492,8 @@ publication_add_relation(Oid pubid, PublicationRelInfo *pri, ObjectIdGetDatum(pubid); values[Anum_pg_publication_rel_prrelid - 1] = ObjectIdGetDatum(relid); + values[Anum_pg_publication_rel_prexcept - 1] = + BoolGetDatum(pri->except); /* Add qualifications, if available */ if (pri->whereClause != NULL) @@ -749,38 +761,58 @@ publication_add_schema(Oid pubid, Oid schemaid, bool if_not_exists) return myself; } -/* Gets list of publication oids for a relation */ -List * -GetRelationPublications(Oid relid) +/* + * Get the list of publication oids associated with a specified relation. + * + * Parameter 'pubids' returns the Oids of the publications the relation is part + * of. Parameter 'except_pubids' returns the Oids of publications the relation + * is excluded from. + * + * This function returns true if the relation is part of any publication. + */ +bool +GetRelationPublications(Oid relid, List **pubids, List **except_pubids) { - List *result = NIL; CatCList *pubrellist; - int i; + bool found = false; /* Find all publications associated with the relation. */ pubrellist = SearchSysCacheList1(PUBLICATIONRELMAP, ObjectIdGetDatum(relid)); - for (i = 0; i < pubrellist->n_members; i++) + for (int i = 0; i < pubrellist->n_members; i++) { HeapTuple tup = &pubrellist->members[i]->tuple; - Oid pubid = ((Form_pg_publication_rel) GETSTRUCT(tup))->prpubid; + Form_pg_publication_rel pubrel = (Form_pg_publication_rel) GETSTRUCT(tup); + Oid pubid = pubrel->prpubid; - result = lappend_oid(result, pubid); + if (pubrel->prexcept) + { + if (except_pubids) + *except_pubids = lappend_oid(*except_pubids, pubid); + } + else + { + if (pubids) + *pubids = lappend_oid(*pubids, pubid); + found = true; + } } ReleaseSysCacheList(pubrellist); - return result; + return found; } /* - * Gets list of relation oids for a publication. + * Internal function to get the list of relation Oids for a publication. * - * This should only be used FOR TABLE publications, the FOR ALL TABLES/SEQUENCES - * should use GetAllPublicationRelations(). + * If except_flag is true, returns the list of relations excluded from the + * publication; otherwise, returns the list of relations included in the + * publication. */ -List * -GetPublicationRelations(Oid pubid, PublicationPartOpt pub_partopt) +static List * +get_publication_relations(Oid pubid, PublicationPartOpt pub_partopt, + bool except_flag) { List *result; Relation pubrelsrel; @@ -805,8 +837,10 @@ GetPublicationRelations(Oid pubid, PublicationPartOpt pub_partopt) Form_pg_publication_rel pubrel; pubrel = (Form_pg_publication_rel) GETSTRUCT(tup); - result = GetPubPartitionOptionRelations(result, pub_partopt, - pubrel->prrelid); + + if (except_flag == pubrel->prexcept) + result = GetPubPartitionOptionRelations(result, pub_partopt, + pubrel->prrelid); } systable_endscan(scan); @@ -819,6 +853,36 @@ GetPublicationRelations(Oid pubid, PublicationPartOpt pub_partopt) return result; } +/* + * Return the list of relation Oids for a publication. + * + * For a FOR TABLE publication, this returns the list of relations explicitly + * included in the publication. + * + * Publications declared with FOR ALL TABLES should use + * GetAllPublicationRelations() to obtain the complete set of tables covered by + * the publication. + */ +List * +GetPublicationIncludedRelations(Oid pubid, PublicationPartOpt pub_partopt) +{ + Assert(!GetPublication(pubid)->alltables); + + return get_publication_relations(pubid, pub_partopt, false); +} + +/* + * Return the list of tables Oids excluded from a publication. + * This is only applicable for FOR ALL TABLES publications. + */ +List * +GetAllPublicationExcludedTables(Oid pubid, PublicationPartOpt pub_partopt) +{ + Assert(GetPublication(pubid)->alltables); + + return get_publication_relations(pubid, pub_partopt, true); +} + /* * Gets list of publication oids for publications marked as FOR ALL TABLES. */ @@ -864,18 +928,29 @@ GetAllTablesPublications(void) * partitioned tables, we must exclude partitions in favor of including the * root partitioned tables. This is not applicable to FOR ALL SEQUENCES * publication. + * + * For a FOR ALL TABLES publication, the returned list excludes tables mentioned + * in EXCEPT TABLE clause. */ List * -GetAllPublicationRelations(char relkind, bool pubviaroot) +GetAllPublicationRelations(Publication *pub, char relkind) { Relation classRel; ScanKeyData key[1]; TableScanDesc scan; HeapTuple tuple; List *result = NIL; + List *exceptlist = NIL; + bool pubviaroot = pub->pubviaroot; + Oid pubid = pub->oid; Assert(!(relkind == RELKIND_SEQUENCE && pubviaroot)); + if (relkind == RELKIND_RELATION) + exceptlist = GetAllPublicationExcludedTables(pubid, pubviaroot ? + PUBLICATION_PART_ROOT : + PUBLICATION_PART_LEAF); + classRel = table_open(RelationRelationId, AccessShareLock); ScanKeyInit(&key[0], @@ -891,7 +966,8 @@ GetAllPublicationRelations(char relkind, bool pubviaroot) Oid relid = relForm->oid; if (is_publishable_class(relid, relForm) && - !(relForm->relispartition && pubviaroot)) + !(relForm->relispartition && pubviaroot) && + !list_member_oid(exceptlist, relid)) result = lappend_oid(result, relid); } @@ -912,7 +988,8 @@ GetAllPublicationRelations(char relkind, bool pubviaroot) Oid relid = relForm->oid; if (is_publishable_class(relid, relForm) && - !relForm->relispartition) + !relForm->relispartition && + !list_member_oid(exceptlist, relid)) result = lappend_oid(result, relid); } @@ -1168,17 +1245,17 @@ pg_get_publication_tables(PG_FUNCTION_ARGS) * those. Otherwise, get the partitioned table itself. */ if (pub_elem->alltables) - pub_elem_tables = GetAllPublicationRelations(RELKIND_RELATION, - pub_elem->pubviaroot); + pub_elem_tables = GetAllPublicationRelations(pub_elem, + RELKIND_RELATION); else { List *relids, *schemarelids; - relids = GetPublicationRelations(pub_elem->oid, - pub_elem->pubviaroot ? - PUBLICATION_PART_ROOT : - PUBLICATION_PART_LEAF); + relids = GetPublicationIncludedRelations(pub_elem->oid, + pub_elem->pubviaroot ? + PUBLICATION_PART_ROOT : + PUBLICATION_PART_LEAF); schemarelids = GetAllSchemaPublicationRelations(pub_elem->oid, pub_elem->pubviaroot ? PUBLICATION_PART_ROOT : @@ -1367,7 +1444,7 @@ pg_get_publication_sequences(PG_FUNCTION_ARGS) publication = GetPublicationByName(pubname, false); if (publication->allsequences) - sequences = GetAllPublicationRelations(RELKIND_SEQUENCE, false); + sequences = GetAllPublicationRelations(publication, RELKIND_SEQUENCE); funcctx->user_fctx = sequences; diff --git a/src/backend/commands/publicationcmds.c b/src/backend/commands/publicationcmds.c index fc3a4c19e65..6bb816b219c 100644 --- a/src/backend/commands/publicationcmds.c +++ b/src/backend/commands/publicationcmds.c @@ -198,7 +198,12 @@ ObjectsInPublicationToOids(List *pubobjspec_list, ParseState *pstate, switch (pubobj->pubobjtype) { + case PUBLICATIONOBJ_EXCEPT_TABLE: + pubobj->pubtable->except = true; + *rels = lappend(*rels, pubobj->pubtable); + break; case PUBLICATIONOBJ_TABLE: + pubobj->pubtable->except = false; *rels = lappend(*rels, pubobj->pubtable); break; case PUBLICATIONOBJ_TABLES_IN_SCHEMA: @@ -519,8 +524,8 @@ InvalidatePubRelSyncCache(Oid pubid, bool puballtables) * a target. However, WAL records for TRUNCATE specify both a root and * its leaves. */ - relids = GetPublicationRelations(pubid, - PUBLICATION_PART_ALL); + relids = GetPublicationIncludedRelations(pubid, + PUBLICATION_PART_ALL); schemarelids = GetAllSchemaPublicationRelations(pubid, PUBLICATION_PART_ALL); @@ -929,55 +934,61 @@ CreatePublication(ParseState *pstate, CreatePublicationStmt *stmt) CommandCounterIncrement(); /* Associate objects with the publication. */ - if (stmt->for_all_tables) + ObjectsInPublicationToOids(stmt->pubobjects, pstate, &relations, + &schemaidlist); + + /* FOR TABLES IN SCHEMA requires superuser */ + if (schemaidlist != NIL && !superuser()) + ereport(ERROR, + errcode(ERRCODE_INSUFFICIENT_PRIVILEGE), + errmsg("must be superuser to create FOR TABLES IN SCHEMA publication")); + + /* Add relations (tables) to the publication. */ + if (relations != NIL) { /* - * Invalidate relcache so that publication info is rebuilt. Sequences - * publication doesn't require invalidation, as replica identity - * checks don't apply to them. + * The 'relations' list can be non-empty in only two cases: + * + * 1. CREATE PUBLICATION ... FOR TABLE In this case, 'relations' + * contains the list of specified tables. + * + * 2. CREATE PUBLICATION ... FOR ALL TABLES In this case, 'relations' + * contains the list of tables specified in the EXCEPT TABLE clause. + * During parsing, the 'except' flag is set for the associated + * PublicationRelInfo objects. */ - CacheInvalidateRelcacheAll(); - } - else if (!stmt->for_all_sequences) - { - ObjectsInPublicationToOids(stmt->pubobjects, pstate, &relations, - &schemaidlist); + List *rels; - /* FOR TABLES IN SCHEMA requires superuser */ - if (schemaidlist != NIL && !superuser()) - ereport(ERROR, - errcode(ERRCODE_INSUFFICIENT_PRIVILEGE), - errmsg("must be superuser to create FOR TABLES IN SCHEMA publication")); - - if (relations != NIL) - { - List *rels; + rels = OpenTableList(relations); + TransformPubWhereClauses(rels, pstate->p_sourcetext, + publish_via_partition_root); - rels = OpenTableList(relations); - TransformPubWhereClauses(rels, pstate->p_sourcetext, - publish_via_partition_root); + CheckPubRelationColumnList(stmt->pubname, rels, + schemaidlist != NIL, + publish_via_partition_root); - CheckPubRelationColumnList(stmt->pubname, rels, - schemaidlist != NIL, - publish_via_partition_root); - - PublicationAddTables(puboid, rels, true, NULL); - CloseTableList(rels); - } + PublicationAddTables(puboid, rels, true, NULL); + CloseTableList(rels); + } - if (schemaidlist != NIL) - { - /* - * Schema lock is held until the publication is created to prevent - * concurrent schema deletion. - */ - LockSchemaList(schemaidlist); - PublicationAddSchemas(puboid, schemaidlist, true, NULL); - } + if (schemaidlist != NIL) + { + /* + * Schema lock is held until the publication is created to prevent + * concurrent schema deletion. + */ + LockSchemaList(schemaidlist); + PublicationAddSchemas(puboid, schemaidlist, true, NULL); } table_close(rel, RowExclusiveLock); + if (stmt->for_all_tables) + { + /* Invalidate relcache so that publication info is rebuilt. */ + CacheInvalidateRelcacheAll(); + } + InvokeObjectPostCreateHook(PublicationRelationId, puboid, 0); /* @@ -1050,8 +1061,8 @@ AlterPublicationOptions(ParseState *pstate, AlterPublicationStmt *stmt, LockDatabaseObject(PublicationRelationId, pubform->oid, 0, AccessShareLock); - root_relids = GetPublicationRelations(pubform->oid, - PUBLICATION_PART_ROOT); + root_relids = GetPublicationIncludedRelations(pubform->oid, + PUBLICATION_PART_ROOT); foreach(lc, root_relids) { @@ -1170,8 +1181,8 @@ AlterPublicationOptions(ParseState *pstate, AlterPublicationStmt *stmt, * trees, not just those explicitly mentioned in the publication. */ if (root_relids == NIL) - relids = GetPublicationRelations(pubform->oid, - PUBLICATION_PART_ALL); + relids = GetPublicationIncludedRelations(pubform->oid, + PUBLICATION_PART_ALL); else { /* @@ -1256,8 +1267,8 @@ AlterPublicationTables(AlterPublicationStmt *stmt, HeapTuple tup, PublicationDropTables(pubid, rels, false); else /* AP_SetObjects */ { - List *oldrelids = GetPublicationRelations(pubid, - PUBLICATION_PART_ROOT); + List *oldrelids = GetPublicationIncludedRelations(pubid, + PUBLICATION_PART_ROOT); List *delrels = NIL; ListCell *oldlc; @@ -1358,6 +1369,7 @@ AlterPublicationTables(AlterPublicationStmt *stmt, HeapTuple tup, oldrel = palloc_object(PublicationRelInfo); oldrel->whereClause = NULL; oldrel->columns = NIL; + oldrel->except = false; oldrel->relation = table_open(oldrelid, ShareUpdateExclusiveLock); delrels = lappend(delrels, oldrel); @@ -1408,7 +1420,8 @@ AlterPublicationSchemas(AlterPublicationStmt *stmt, ListCell *lc; List *reloids; - reloids = GetPublicationRelations(pubform->oid, PUBLICATION_PART_ROOT); + reloids = GetPublicationIncludedRelations(pubform->oid, + PUBLICATION_PART_ROOT); foreach(lc, reloids) { @@ -1771,6 +1784,7 @@ OpenTableList(List *tables) pub_rel->relation = rel; pub_rel->whereClause = t->whereClause; pub_rel->columns = t->columns; + pub_rel->except = t->except; rels = lappend(rels, pub_rel); relids = lappend_oid(relids, myrelid); @@ -1843,6 +1857,7 @@ OpenTableList(List *tables) /* child inherits column list from parent */ pub_rel->columns = t->columns; + pub_rel->except = t->except; rels = lappend(rels, pub_rel); relids = lappend_oid(relids, childrelid); diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c index f976c0e5c7e..395b8c0c2a1 100644 --- a/src/backend/commands/tablecmds.c +++ b/src/backend/commands/tablecmds.c @@ -8688,7 +8688,7 @@ ATExecSetExpression(AlteredTableInfo *tab, Relation rel, const char *colName, * expressions. */ if (attgenerated == ATTRIBUTE_GENERATED_VIRTUAL && - GetRelationPublications(RelationGetRelid(rel)) != NIL) + GetRelationPublications(RelationGetRelid(rel), NULL, NULL)) ereport(ERROR, (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), errmsg("ALTER TABLE / SET EXPRESSION is not supported for virtual generated columns in tables that are part of a publication"), @@ -18884,7 +18884,7 @@ ATPrepChangePersistence(AlteredTableInfo *tab, Relation rel, bool toLogged) * UNLOGGED, as UNLOGGED tables can't be published. */ if (!toLogged && - GetRelationPublications(RelationGetRelid(rel)) != NIL) + GetRelationPublications(RelationGetRelid(rel), NULL, NULL)) ereport(ERROR, (errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE), errmsg("cannot change table \"%s\" to unlogged because it is part of a publication", @@ -20325,6 +20325,7 @@ ATExecAttachPartition(List **wqueue, Relation rel, PartitionCmd *cmd, const char *trigger_name; Oid defaultPartOid; List *partBoundConstraint; + List *except_pubids = NIL; ParseState *pstate = make_parsestate(NULL); pstate->p_sourcetext = context->queryString; @@ -20449,6 +20450,14 @@ ATExecAttachPartition(List **wqueue, Relation rel, PartitionCmd *cmd, (errcode(ERRCODE_WRONG_OBJECT_TYPE), errmsg("cannot attach temporary relation of another session as partition"))); + /* Check if the partiton is part of EXCEPT list of any publication */ + GetRelationPublications(RelationGetRelid(attachrel), NULL, &except_pubids); + if (except_pubids != NIL) + ereport(ERROR, + (errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE), + errmsg("cannot attach relation \"%s\" as partition because it is part of EXCEPT list in publication", + RelationGetRelationName(attachrel)))); + /* * Check if attachrel has any identity columns or any columns that aren't * in the parent. diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y index 713ee5c10a2..d3c3e9f59c6 100644 --- a/src/backend/parser/gram.y +++ b/src/backend/parser/gram.y @@ -203,6 +203,7 @@ static void processCASbits(int cas_bits, int location, const char *constrType, static PartitionStrategy parsePartitionStrategy(char *strategy, int location, core_yyscan_t yyscanner); static void preprocess_pub_all_objtype_list(List *all_objects_list, + List **pubobjects, bool *all_tables, bool *all_sequences, core_yyscan_t yyscanner); @@ -455,6 +456,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query); TriggerTransitions TriggerReferencing vacuum_relation_list opt_vacuum_relation_list drop_option_list pub_obj_list pub_all_obj_type_list + pub_except_obj_list opt_pub_except_clause %type <retclause> returning_clause %type <node> returning_option @@ -592,6 +594,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query); %type <node> var_value zone_value %type <rolespec> auth_ident RoleSpec opt_granted_by %type <publicationobjectspec> PublicationObjSpec +%type <publicationobjectspec> PublicationExceptObjSpec %type <publicationallobjectspec> PublicationAllObjSpec %type <keyword> unreserved_keyword type_func_name_keyword @@ -10792,7 +10795,7 @@ AlterOwnerStmt: ALTER AGGREGATE aggregate_with_argtypes OWNER TO RoleSpec * * pub_all_obj_type is one of: * - * TABLES + * TABLES [EXCEPT [TABLE] ( table [, ...] )] * SEQUENCES * * CREATE PUBLICATION FOR pub_obj [, ...] [WITH options] @@ -10818,7 +10821,8 @@ CreatePublicationStmt: CreatePublicationStmt *n = makeNode(CreatePublicationStmt); n->pubname = $3; - preprocess_pub_all_objtype_list($5, &n->for_all_tables, + preprocess_pub_all_objtype_list($5, &n->pubobjects, + &n->for_all_tables, &n->for_all_sequences, yyscanner); n->options = $6; @@ -10858,6 +10862,7 @@ PublicationObjSpec: $$->pubtable->relation = $2; $$->pubtable->columns = $3; $$->pubtable->whereClause = $4; + $$->location = @1; } | TABLES IN_P SCHEMA ColId { @@ -10933,11 +10938,19 @@ pub_obj_list: PublicationObjSpec { $$ = lappend($1, $3); } ; +opt_pub_except_clause: + EXCEPT opt_table '(' pub_except_obj_list ')' { $$ = $4; } + | /*EMPTY*/ { $$ = NIL; } + ; + PublicationAllObjSpec: - ALL TABLES + ALL TABLES opt_pub_except_clause { $$ = makeNode(PublicationAllObjSpec); $$->pubobjtype = PUBLICATION_ALL_TABLES; + $$->except_tables = $3; + if($$->except_tables != NULL) + preprocess_pubobj_list($$->except_tables, yyscanner); $$->location = @1; } | ALL SEQUENCES @@ -10954,6 +10967,23 @@ pub_all_obj_type_list: PublicationAllObjSpec { $$ = lappend($1, $3); } ; +PublicationExceptObjSpec: + relation_expr + { + $$ = makeNode(PublicationObjSpec); + $$->pubobjtype = PUBLICATIONOBJ_EXCEPT_TABLE; + $$->pubtable = makeNode(PublicationTable); + $$->pubtable->except = true; + $$->pubtable->relation = $1; + $$->location = @1; + } + ; + +pub_except_obj_list: PublicationExceptObjSpec + { $$ = list_make1($1); } + | pub_except_obj_list ',' PublicationExceptObjSpec + { $$ = lappend($1, $3); } + ; /***************************************************************************** * @@ -19794,8 +19824,9 @@ parsePartitionStrategy(char *strategy, int location, core_yyscan_t yyscanner) * Also, checks if the pub_object_type has been specified more than once. */ static void -preprocess_pub_all_objtype_list(List *all_objects_list, bool *all_tables, - bool *all_sequences, core_yyscan_t yyscanner) +preprocess_pub_all_objtype_list(List *all_objects_list, List **pubobjects, + bool *all_tables, bool *all_sequences, + core_yyscan_t yyscanner) { if (!all_objects_list) return; @@ -19815,6 +19846,7 @@ preprocess_pub_all_objtype_list(List *all_objects_list, bool *all_tables, parser_errposition(obj->location)); *all_tables = true; + *pubobjects = list_concat(*pubobjects, obj->except_tables); } else if (obj->pubobjtype == PUBLICATION_ALL_SEQUENCES) { diff --git a/src/backend/replication/pgoutput/pgoutput.c b/src/backend/replication/pgoutput/pgoutput.c index 9ee8949e040..3af0b21bc05 100644 --- a/src/backend/replication/pgoutput/pgoutput.c +++ b/src/backend/replication/pgoutput/pgoutput.c @@ -2088,7 +2088,7 @@ get_rel_sync_entry(PGOutputData *data, Relation relation) if (!entry->replicate_valid) { Oid schemaId = get_rel_namespace(relid); - List *pubids = GetRelationPublications(relid); + List *pubids = NIL; /* * We don't acquire a lock on the namespace system table as we build @@ -2103,6 +2103,8 @@ get_rel_sync_entry(PGOutputData *data, Relation relation) char relkind = get_rel_relkind(relid); List *rel_publications = NIL; + GetRelationPublications(relid, &pubids, NULL); + /* Reload publications if needed before use. */ if (!publications_valid) { @@ -2202,20 +2204,41 @@ get_rel_sync_entry(PGOutputData *data, Relation relation) /* * If this is a FOR ALL TABLES publication, pick the partition * root and set the ancestor level accordingly. + * + * If this is a FOR ALL TABLES publication and it has an EXCEPT + * TABLE list + * 1. For a normal table or a partitioned table, if it is part of + * the EXCEPT TABLE list, we don't publish it. + * 2. For a partition, if the topmost ancestor is part of + * the EXCEPT TABLE list, we don't publish it. + * This is achieved by keeping the variable "publish" set to + * false. And eventually, entry->pubactions will remain all false + * for this publication. */ if (pub->alltables) { - publish = true; - if (pub->pubviaroot && am_partition) + List *exceptpubids = NIL; + List *ancestors = get_partition_ancestors(relid); + Oid root_relid = relid; + + if (am_partition) { - List *ancestors = get_partition_ancestors(relid); + root_relid = llast_oid(ancestors); + GetRelationPublications(root_relid, NULL, &exceptpubids); - pub_relid = llast_oid(ancestors); - ancestor_level = list_length(ancestors); + if (pub->pubviaroot) + { + pub_relid = root_relid; + ancestor_level = list_length(ancestors); + } } - } - if (!publish) + if (!list_member_oid(exceptpubids, pub->oid)) + publish = true; + + list_free(exceptpubids); + } + else if (!publish) { bool ancestor_published = false; @@ -2259,6 +2282,9 @@ get_rel_sync_entry(PGOutputData *data, Relation relation) * Don't publish changes for partitioned tables, because * publishing those of its partitions suffices, unless partition * changes won't be published due to pubviaroot being set. + * + * If the relation is part of EXCEPT TABLE list of a publication, + * the 'publish' variable is already set to false. */ if (publish && (relkind != RELKIND_PARTITIONED_TABLE || pub->pubviaroot)) diff --git a/src/backend/utils/cache/relcache.c b/src/backend/utils/cache/relcache.c index 6b634c9fff1..ec7f82fbcdc 100644 --- a/src/backend/utils/cache/relcache.c +++ b/src/backend/utils/cache/relcache.c @@ -5788,7 +5788,9 @@ RelationGetExclusionInfo(Relation indexRelation, void RelationBuildPublicationDesc(Relation relation, PublicationDesc *pubdesc) { - List *puboids; + List *puboids = NIL; + List *exceptpuboids = NIL; + List *alltablespuboids; ListCell *lc; MemoryContext oldcxt; Oid schemaid; @@ -5826,7 +5828,7 @@ RelationBuildPublicationDesc(Relation relation, PublicationDesc *pubdesc) pubdesc->gencols_valid_for_delete = true; /* Fetch the publication membership info. */ - puboids = GetRelationPublications(relid); + GetRelationPublications(relid, &puboids, &exceptpuboids); schemaid = RelationGetNamespace(relation); puboids = list_concat_unique_oid(puboids, GetSchemaPublications(schemaid)); @@ -5835,19 +5837,31 @@ RelationBuildPublicationDesc(Relation relation, PublicationDesc *pubdesc) /* Add publications that the ancestors are in too. */ ancestors = get_partition_ancestors(relid); + /* + * Only the topmost ancestor of a partitioned table can be specified + * in EXCEPT TABLES clause of a FOR ALL TABLES publication. So fetch + * the publications excluding the topmost ancestor only. + */ + GetRelationPublications(llast_oid(ancestors), NULL, &exceptpuboids); + foreach(lc, ancestors) { Oid ancestor = lfirst_oid(lc); + List *ancestor_puboids = NIL; - puboids = list_concat_unique_oid(puboids, - GetRelationPublications(ancestor)); + GetRelationPublications(ancestor, &ancestor_puboids, NULL); + + puboids = list_concat_unique_oid(puboids, ancestor_puboids); schemaid = get_rel_namespace(ancestor); puboids = list_concat_unique_oid(puboids, GetSchemaPublications(schemaid)); } } - puboids = list_concat_unique_oid(puboids, GetAllTablesPublications()); + alltablespuboids = GetAllTablesPublications(); + puboids = list_concat_unique_oid(puboids, + list_difference_oid(alltablespuboids, + exceptpuboids)); foreach(lc, puboids) { Oid pubid = lfirst_oid(lc); diff --git a/src/bin/pg_dump/pg_dump.c b/src/bin/pg_dump/pg_dump.c index fff929b26df..da4690c9e54 100644 --- a/src/bin/pg_dump/pg_dump.c +++ b/src/bin/pg_dump/pg_dump.c @@ -4646,9 +4646,58 @@ getPublications(Archive *fout) (strcmp(PQgetvalue(res, i, i_pubviaroot), "t") == 0); pubinfo[i].pubgencols_type = *(PQgetvalue(res, i, i_pubgencols)); + pubinfo[i].except_tables = (SimplePtrList) + { + NULL, NULL + }; /* Decide whether we want to dump it */ selectDumpableObject(&(pubinfo[i].dobj), fout); + + /* + * Get the list of tables for publications specified with the EXCEPT + * TABLE clause. This is introduced in PostgreSQL 19. + * + * EXCEPT TABLES is processed here and output directly by + * dumpPublication(). This differs from the approach used in + * dumpPublicationTable() and dumpPublicationNamespace(), since that + * approach would require EXCEPT TABLE support for ALTER PUBLICATION, + * which is not currently supported. + */ + if (fout->remoteVersion >= 190000) + { + int ntbls; + PGresult *res_tbls; + + resetPQExpBuffer(query); + appendPQExpBuffer(query, + "SELECT prrelid\n" + "FROM pg_catalog.pg_publication_rel\n" + "WHERE prpubid = %u and prexcept", + pubinfo[i].dobj.catId.oid); + + res_tbls = ExecuteSqlQuery(fout, query->data, PGRES_TUPLES_OK); + + ntbls = PQntuples(res_tbls); + if (ntbls == 0) + continue; + + for (int j = 0; j < ntbls; j++) + { + Oid prrelid; + TableInfo *tbinfo; + + prrelid = atooid(PQgetvalue(res_tbls, j, 0)); + + tbinfo = findTableByOid(prrelid); + if (tbinfo == NULL) + continue; + + simple_ptr_list_append(&pubinfo[i].except_tables, tbinfo); + } + + PQclear(res_tbls); + } } cleanup: @@ -4688,7 +4737,25 @@ dumpPublication(Archive *fout, const PublicationInfo *pubinfo) if (pubinfo->puballtables && pubinfo->puballsequences) appendPQExpBufferStr(query, " FOR ALL TABLES, ALL SEQUENCES"); else if (pubinfo->puballtables) + { + int n_excluded = 0; + appendPQExpBufferStr(query, " FOR ALL TABLES"); + + /* Include EXCEPT TABLE clause if there are except_tables. */ + for (SimplePtrListCell *cell = pubinfo->except_tables.head; cell; cell = cell->next) + { + TableInfo *tbinfo = (TableInfo *) cell->ptr; + + if (++n_excluded == 1) + appendPQExpBufferStr(query, " EXCEPT TABLE ("); + else + appendPQExpBufferStr(query, ", "); + appendPQExpBuffer(query, "ONLY %s", fmtQualifiedDumpable(tbinfo)); + } + if (n_excluded > 0) + appendPQExpBufferStr(query, ")"); + } else if (pubinfo->puballsequences) appendPQExpBufferStr(query, " FOR ALL SEQUENCES"); @@ -4868,6 +4935,7 @@ getPublicationTables(Archive *fout, TableInfo tblinfo[], int numTables) /* Collect all publication membership info. */ if (fout->remoteVersion >= 150000) + { appendPQExpBufferStr(query, "SELECT tableoid, oid, prpubid, prrelid, " "pg_catalog.pg_get_expr(prqual, prrelid) AS prrelqual, " @@ -4880,6 +4948,9 @@ getPublicationTables(Archive *fout, TableInfo tblinfo[], int numTables) " WHERE attrelid = pr.prrelid AND attnum = prattrs[s])\n" " ELSE NULL END) prattrs " "FROM pg_catalog.pg_publication_rel pr"); + if (fout->remoteVersion >= 190000) + appendPQExpBufferStr(query, " WHERE NOT pr.prexcept"); + } else appendPQExpBufferStr(query, "SELECT tableoid, oid, prpubid, prrelid, " diff --git a/src/bin/pg_dump/pg_dump.h b/src/bin/pg_dump/pg_dump.h index 4c4b14e5fc7..d141eb66d17 100644 --- a/src/bin/pg_dump/pg_dump.h +++ b/src/bin/pg_dump/pg_dump.h @@ -676,6 +676,7 @@ typedef struct _PublicationInfo bool pubtruncate; bool pubviaroot; PublishGencolsType pubgencols_type; + SimplePtrList except_tables; } PublicationInfo; /* diff --git a/src/bin/pg_dump/t/002_pg_dump.pl b/src/bin/pg_dump/t/002_pg_dump.pl index 28812d28aa9..4e6e4cbdd7c 100644 --- a/src/bin/pg_dump/t/002_pg_dump.pl +++ b/src/bin/pg_dump/t/002_pg_dump.pl @@ -3170,6 +3170,36 @@ my %tests = ( like => { %full_runs, section_post_data => 1, }, }, + 'CREATE PUBLICATION pub8' => { + create_order => 50, + create_sql => + 'CREATE PUBLICATION pub8 FOR ALL TABLES EXCEPT (dump_test.test_table);', + regexp => qr/^ + \QCREATE PUBLICATION pub8 FOR ALL TABLES EXCEPT TABLE (ONLY dump_test.test_table) WITH (publish = 'insert, update, delete, truncate');\E + /xm, + like => { %full_runs, section_post_data => 1, }, + }, + + 'CREATE PUBLICATION pub9' => { + create_order => 50, + create_sql => + 'CREATE PUBLICATION pub9 FOR ALL TABLES EXCEPT TABLE (dump_test.test_table, dump_test.test_second_table);', + regexp => qr/^ + \QCREATE PUBLICATION pub9 FOR ALL TABLES EXCEPT TABLE (ONLY dump_test.test_table, ONLY dump_test.test_second_table) WITH (publish = 'insert, update, delete, truncate');\E + /xm, + like => { %full_runs, section_post_data => 1, }, + }, + + 'CREATE PUBLICATION pub10' => { + create_order => 92, + create_sql => + 'CREATE PUBLICATION pub10 FOR ALL TABLES EXCEPT TABLE (dump_test.test_inheritance_parent);', + regexp => qr/^ + \QCREATE PUBLICATION pub10 FOR ALL TABLES EXCEPT TABLE (ONLY dump_test.test_inheritance_parent, ONLY dump_test.test_inheritance_child) WITH (publish = 'insert, update, delete, truncate');\E + /xm, + like => { %full_runs, section_post_data => 1, }, + }, + 'CREATE SUBSCRIPTION sub1' => { create_order => 50, create_sql => 'CREATE SUBSCRIPTION sub1 diff --git a/src/bin/psql/describe.c b/src/bin/psql/describe.c index 3584c4e1428..1bfec0bd3ef 100644 --- a/src/bin/psql/describe.c +++ b/src/bin/psql/describe.c @@ -3073,17 +3073,34 @@ describeOneTableDetails(const char *schemaname, " WHERE attrelid = pr.prrelid AND attnum = prattrs[s])\n" " ELSE NULL END) " "FROM pg_catalog.pg_publication p\n" - " JOIN pg_catalog.pg_publication_rel pr ON p.oid = pr.prpubid\n" - " JOIN pg_catalog.pg_class c ON c.oid = pr.prrelid\n" - "WHERE pr.prrelid = '%s'\n" + " JOIN pg_catalog.pg_publication_rel pr ON p.oid = pr.prpubid\n" + " JOIN pg_catalog.pg_class c ON c.oid = pr.prrelid\n" + "WHERE pr.prrelid = '%s'\n", + oid, oid, oid); + + if (pset.sversion >= 190000) + appendPQExpBufferStr(&buf, " AND NOT pr.prexcept\n"); + + appendPQExpBuffer(&buf, "UNION\n" "SELECT pubname\n" - " , NULL\n" - " , NULL\n" + " , NULL\n" + " , NULL\n" "FROM pg_catalog.pg_publication p\n" - "WHERE p.puballtables AND pg_catalog.pg_relation_is_publishable('%s')\n" - "ORDER BY 1;", - oid, oid, oid, oid); + "WHERE p.puballtables AND pg_catalog.pg_relation_is_publishable('%s')\n", + oid); + + if (pset.sversion >= 190000) + appendPQExpBuffer(&buf, + " AND NOT EXISTS (\n" + " SELECT 1\n" + " FROM pg_catalog.pg_publication_rel pr\n" + " JOIN pg_catalog.pg_class pc\n" + " ON pr.prrelid = pc.oid\n" + " WHERE pr.prrelid = '%s' AND pr.prpubid = p.oid)\n", + oid); + + appendPQExpBufferStr(&buf, "ORDER BY 1;"); } else { @@ -3134,6 +3151,35 @@ describeOneTableDetails(const char *schemaname, PQclear(result); } + /* Print publications that the table is explicitly excluded from */ + if (pset.sversion >= 190000) + { + printfPQExpBuffer(&buf, + "SELECT pubname\n" + "FROM pg_catalog.pg_publication p\n" + "JOIN pg_catalog.pg_publication_rel pr ON p.oid = pr.prpubid\n" + "WHERE pr.prrelid = '%s'\n AND pr.prexcept\n" + "ORDER BY 1;", oid); + + result = PSQLexec(buf.data); + if (!result) + goto error_return; + else + tuples = PQntuples(result); + + if (tuples > 0) + printTableAddFooter(&cont, _("Except Publications:")); + + /* Might be an empty set - that's ok */ + for (i = 0; i < tuples; i++) + { + printfPQExpBuffer(&buf, " \"%s\"", PQgetvalue(result, i, 0)); + + printTableAddFooter(&cont, buf.data); + } + PQclear(result); + } + /* * If verbose, print NOT NULL constraints. */ @@ -6753,8 +6799,12 @@ describePublications(const char *pattern) " pg_catalog.pg_publication_rel pr\n" "WHERE c.relnamespace = n.oid\n" " AND c.oid = pr.prrelid\n" - " AND pr.prpubid = '%s'\n" - "ORDER BY 1,2", pubid); + " AND pr.prpubid = '%s'\n", pubid); + + if (pset.sversion >= 190000) + appendPQExpBuffer(&buf, " AND NOT pr.prexcept\n"); + + appendPQExpBuffer(&buf, "ORDER BY 1,2"); if (!addFooterToPublicationDesc(&buf, _("Tables:"), false, &cont)) goto error_return; @@ -6772,6 +6822,23 @@ describePublications(const char *pattern) goto error_return; } } + else + { + if (pset.sversion >= 190000) + { + /* Get the excluded tables for the specified publication */ + printfPQExpBuffer(&buf, + "SELECT concat(c.relnamespace::regnamespace, '.', c.relname)\n" + "FROM pg_catalog.pg_class c\n" + " JOIN pg_catalog.pg_publication_rel pr ON c.oid = pr.prrelid\n" + "WHERE pr.prpubid = '%s'\n" + " AND pr.prexcept\n" + "ORDER BY 1", pubid); + if (!addFooterToPublicationDesc(&buf, _("Except tables:"), + true, &cont)) + goto error_return; + } + } printTable(&cont, pset.queryFout, false, pset.logfile); printTableCleanup(&cont); diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c index 8b91bc00062..39404ea0f69 100644 --- a/src/bin/psql/tab-complete.in.c +++ b/src/bin/psql/tab-complete.in.c @@ -3669,7 +3669,17 @@ match_previous_words(int pattern_id, else if (Matches("CREATE", "PUBLICATION", MatchAny, "FOR", "ALL")) COMPLETE_WITH("TABLES", "SEQUENCES"); else if (Matches("CREATE", "PUBLICATION", MatchAny, "FOR", "ALL", "TABLES")) - COMPLETE_WITH("WITH ("); + COMPLETE_WITH("EXCEPT TABLE (", "WITH ("); + else if (Matches("CREATE", "PUBLICATION", MatchAny, "FOR", "ALL", "TABLES", "EXCEPT")) + COMPLETE_WITH("TABLE ("); + else if (Matches("CREATE", "PUBLICATION", MatchAny, "FOR", "ALL", "TABLES", "EXCEPT", "TABLE")) + COMPLETE_WITH("("); + else if (Matches("CREATE", "PUBLICATION", MatchAny, "FOR", "ALL", "TABLES", "EXCEPT", "TABLE", "(")) + COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_tables); + else if (Matches("CREATE", "PUBLICATION", MatchAny, "FOR", "ALL", "TABLES", "EXCEPT", "TABLE", "(", MatchAnyN) && ends_with(prev_wd, ',')) + COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_tables); + else if (Matches("CREATE", "PUBLICATION", MatchAny, "FOR", "ALL", "TABLES", "EXCEPT", "TABLE", "(", MatchAnyN) && !ends_with(prev_wd, ',')) + COMPLETE_WITH(")"); else if (Matches("CREATE", "PUBLICATION", MatchAny, "FOR", "TABLES")) COMPLETE_WITH("IN SCHEMA"); else if (Matches("CREATE", "PUBLICATION", MatchAny, "FOR", "TABLE", MatchAny) && !ends_with(prev_wd, ',')) diff --git a/src/include/catalog/pg_publication.h b/src/include/catalog/pg_publication.h index 368becca899..5126c996ff7 100644 --- a/src/include/catalog/pg_publication.h +++ b/src/include/catalog/pg_publication.h @@ -146,14 +146,16 @@ typedef struct PublicationRelInfo Relation relation; Node *whereClause; List *columns; + bool except; } PublicationRelInfo; extern Publication *GetPublication(Oid pubid); extern Publication *GetPublicationByName(const char *pubname, bool missing_ok); -extern List *GetRelationPublications(Oid relid); +extern bool GetRelationPublications(Oid relid, List **pubids, List **except_pubids); /*--------- - * Expected values for pub_partopt parameter of GetPublicationRelations(), + * Expected values for pub_partopt parameter of + * GetPublicationIncludedRelations(), and GetAllPublicationExcludedTables(), * which allows callers to specify which partitions of partitioned tables * mentioned in the publication they expect to see. * @@ -168,9 +170,12 @@ typedef enum PublicationPartOpt PUBLICATION_PART_ALL, } PublicationPartOpt; -extern List *GetPublicationRelations(Oid pubid, PublicationPartOpt pub_partopt); +extern List *GetPublicationIncludedRelations(Oid pubid, + PublicationPartOpt pub_partopt); +extern List *GetAllPublicationExcludedTables(Oid pubid, + PublicationPartOpt pub_partopt); extern List *GetAllTablesPublications(void); -extern List *GetAllPublicationRelations(char relkind, bool pubviaroot); +extern List *GetAllPublicationRelations(Publication *pub, char relkind); extern List *GetPublicationSchemas(Oid pubid); extern List *GetSchemaPublications(Oid schemaid); extern List *GetSchemaPublicationRelations(Oid schemaid, diff --git a/src/include/catalog/pg_publication_rel.h b/src/include/catalog/pg_publication_rel.h index 3a8790e8482..e3ccba5ec79 100644 --- a/src/include/catalog/pg_publication_rel.h +++ b/src/include/catalog/pg_publication_rel.h @@ -31,6 +31,7 @@ CATALOG(pg_publication_rel,6106,PublicationRelRelationId) Oid oid; /* oid */ Oid prpubid BKI_LOOKUP(pg_publication); /* Oid of the publication */ Oid prrelid BKI_LOOKUP(pg_class); /* Oid of the relation */ + bool prexcept BKI_DEFAULT(f); /* exclude the relation */ #ifdef CATALOG_VARLEN /* variable-length fields start here */ pg_node_tree prqual; /* qualifications */ diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h index 646d6ced763..5282425b4dd 100644 --- a/src/include/nodes/parsenodes.h +++ b/src/include/nodes/parsenodes.h @@ -4300,6 +4300,7 @@ typedef struct PublicationTable RangeVar *relation; /* relation to be published */ Node *whereClause; /* qualifications */ List *columns; /* List of columns in a publication table */ + bool except; /* exclude the relation */ } PublicationTable; /* @@ -4308,6 +4309,7 @@ typedef struct PublicationTable typedef enum PublicationObjSpecType { PUBLICATIONOBJ_TABLE, /* A table */ + PUBLICATIONOBJ_EXCEPT_TABLE, /* A table to be excluded */ PUBLICATIONOBJ_TABLES_IN_SCHEMA, /* All tables in schema */ PUBLICATIONOBJ_TABLES_IN_CUR_SCHEMA, /* All tables in first element of * search_path */ @@ -4336,6 +4338,7 @@ typedef struct PublicationAllObjSpec { NodeTag type; PublicationAllObjType pubobjtype; /* type of this publication object */ + List *except_tables; /* List of tables to be excluded */ ParseLoc location; /* token location, or -1 if unknown */ } PublicationAllObjSpec; diff --git a/src/test/regress/expected/publication.out b/src/test/regress/expected/publication.out index 7fb49aaf29b..b2115edb3c3 100644 --- a/src/test/regress/expected/publication.out +++ b/src/test/regress/expected/publication.out @@ -213,33 +213,104 @@ Not-null constraints: regress_publication_user | t | f | t | t | f | f | none | f (1 row) -DROP TABLE testpub_tbl2; -DROP PUBLICATION testpub_foralltables, testpub_fortable, testpub_forschema, testpub_for_tbl_schema; -CREATE TABLE testpub_tbl3 (a int); -CREATE TABLE testpub_tbl3a (b text) INHERITS (testpub_tbl3); SET client_min_messages = 'ERROR'; -CREATE PUBLICATION testpub3 FOR TABLE testpub_tbl3; -CREATE PUBLICATION testpub4 FOR TABLE ONLY testpub_tbl3; +-- Exclude tables using FOR ALL TABLES EXCEPT TABLE (tablelist) +CREATE PUBLICATION testpub_foralltables_excepttable FOR ALL TABLES EXCEPT TABLE (testpub_tbl1, testpub_tbl2); +\dRp+ testpub_foralltables_excepttable + Publication testpub_foralltables_excepttable + Owner | All tables | All sequences | Inserts | Updates | Deletes | Truncates | Generated columns | Via root +--------------------------+------------+---------------+---------+---------+---------+-----------+-------------------+---------- + regress_publication_user | t | f | t | t | t | t | none | f +Except tables: + "public.testpub_tbl1" + "public.testpub_tbl2" + +-- Exclude tables using FOR ALL TABLES EXCEPT (tablelist) +CREATE PUBLICATION testpub_foralltables_excepttable1 FOR ALL TABLES EXCEPT (testpub_tbl1); +\dRp+ testpub_foralltables_excepttable1 + Publication testpub_foralltables_excepttable1 + Owner | All tables | All sequences | Inserts | Updates | Deletes | Truncates | Generated columns | Via root +--------------------------+------------+---------------+---------+---------+---------+-----------+-------------------+---------- + regress_publication_user | t | f | t | t | t | t | none | f +Except tables: + "public.testpub_tbl1" + +-- Check that the table description shows the publication list the table is +-- excluded from +\d testpub_tbl1 + Table "public.testpub_tbl1" + Column | Type | Collation | Nullable | Default +--------+---------+-----------+----------+------------------------------------------ + id | integer | | not null | nextval('testpub_tbl1_id_seq'::regclass) + data | text | | | +Indexes: + "testpub_tbl1_pkey" PRIMARY KEY, btree (id) +Publications: + "testpub_foralltables" +Except Publications: + "testpub_foralltables_excepttable" + "testpub_foralltables_excepttable1" + RESET client_min_messages; +DROP TABLE testpub_tbl2; +DROP PUBLICATION testpub_foralltables, testpub_fortable, testpub_forschema, testpub_for_tbl_schema, testpub_foralltables_excepttable, testpub_foralltables_excepttable1; +CREATE TABLE testpub_tbl_parent (a int); +CREATE TABLE testpub_tbl_child (b text) INHERITS (testpub_tbl_parent); +SET client_min_messages = 'ERROR'; +CREATE PUBLICATION testpub3 FOR TABLE testpub_tbl_parent; \dRp+ testpub3 Publication testpub3 Owner | All tables | All sequences | Inserts | Updates | Deletes | Truncates | Generated columns | Via root --------------------------+------------+---------------+---------+---------+---------+-----------+-------------------+---------- regress_publication_user | f | f | t | t | t | t | none | f Tables: - "public.testpub_tbl3" - "public.testpub_tbl3a" + "public.testpub_tbl_child" + "public.testpub_tbl_parent" +CREATE PUBLICATION testpub4 FOR TABLE ONLY testpub_tbl_parent; \dRp+ testpub4 Publication testpub4 Owner | All tables | All sequences | Inserts | Updates | Deletes | Truncates | Generated columns | Via root --------------------------+------------+---------------+---------+---------+---------+-----------+-------------------+---------- regress_publication_user | f | f | t | t | t | t | none | f Tables: - "public.testpub_tbl3" + "public.testpub_tbl_parent" -DROP TABLE testpub_tbl3, testpub_tbl3a; -DROP PUBLICATION testpub3, testpub4; +-- Exclude parent table, omitting both of 'ONLY' and '*' +CREATE PUBLICATION testpub5 FOR ALL TABLES EXCEPT TABLE (testpub_tbl_parent); +\dRp+ testpub5 + Publication testpub5 + Owner | All tables | All sequences | Inserts | Updates | Deletes | Truncates | Generated columns | Via root +--------------------------+------------+---------------+---------+---------+---------+-----------+-------------------+---------- + regress_publication_user | t | f | t | t | t | t | none | f +Except tables: + "public.testpub_tbl_child" + "public.testpub_tbl_parent" + +-- EXCEPT with '*': exclude table and all descendants +CREATE PUBLICATION testpub6 FOR ALL TABLES EXCEPT TABLE (testpub_tbl_parent *); +\dRp+ testpub6 + Publication testpub6 + Owner | All tables | All sequences | Inserts | Updates | Deletes | Truncates | Generated columns | Via root +--------------------------+------------+---------------+---------+---------+---------+-----------+-------------------+---------- + regress_publication_user | t | f | t | t | t | t | none | f +Except tables: + "public.testpub_tbl_child" + "public.testpub_tbl_parent" + +-- EXCEPT with ONLY: exclude table but not descendants +CREATE PUBLICATION testpub7 FOR ALL TABLES EXCEPT TABLE (ONLY testpub_tbl_parent); +\dRp+ testpub7 + Publication testpub7 + Owner | All tables | All sequences | Inserts | Updates | Deletes | Truncates | Generated columns | Via root +--------------------------+------------+---------------+---------+---------+---------+-----------+-------------------+---------- + regress_publication_user | t | f | t | t | t | t | none | f +Except tables: + "public.testpub_tbl_parent" + +RESET client_min_messages; +DROP TABLE testpub_tbl_parent, testpub_tbl_child; +DROP PUBLICATION testpub3, testpub4, testpub5, testpub6, testpub7; --- Tests for publications with SEQUENCES CREATE SEQUENCE regress_pub_seq0; CREATE SEQUENCE pub_test.regress_pub_seq1; diff --git a/src/test/regress/sql/publication.sql b/src/test/regress/sql/publication.sql index 85b00bd67c8..5224da93d77 100644 --- a/src/test/regress/sql/publication.sql +++ b/src/test/regress/sql/publication.sql @@ -105,20 +105,41 @@ SELECT pubname, puballtables FROM pg_publication WHERE pubname = 'testpub_forall \d+ testpub_tbl2 \dRp+ testpub_foralltables +SET client_min_messages = 'ERROR'; +-- Exclude tables using FOR ALL TABLES EXCEPT TABLE (tablelist) +CREATE PUBLICATION testpub_foralltables_excepttable FOR ALL TABLES EXCEPT TABLE (testpub_tbl1, testpub_tbl2); +\dRp+ testpub_foralltables_excepttable +-- Exclude tables using FOR ALL TABLES EXCEPT (tablelist) +CREATE PUBLICATION testpub_foralltables_excepttable1 FOR ALL TABLES EXCEPT (testpub_tbl1); +\dRp+ testpub_foralltables_excepttable1 +-- Check that the table description shows the publication list the table is +-- excluded from +\d testpub_tbl1 + +RESET client_min_messages; DROP TABLE testpub_tbl2; -DROP PUBLICATION testpub_foralltables, testpub_fortable, testpub_forschema, testpub_for_tbl_schema; +DROP PUBLICATION testpub_foralltables, testpub_fortable, testpub_forschema, testpub_for_tbl_schema, testpub_foralltables_excepttable, testpub_foralltables_excepttable1; -CREATE TABLE testpub_tbl3 (a int); -CREATE TABLE testpub_tbl3a (b text) INHERITS (testpub_tbl3); +CREATE TABLE testpub_tbl_parent (a int); +CREATE TABLE testpub_tbl_child (b text) INHERITS (testpub_tbl_parent); SET client_min_messages = 'ERROR'; -CREATE PUBLICATION testpub3 FOR TABLE testpub_tbl3; -CREATE PUBLICATION testpub4 FOR TABLE ONLY testpub_tbl3; -RESET client_min_messages; +CREATE PUBLICATION testpub3 FOR TABLE testpub_tbl_parent; \dRp+ testpub3 +CREATE PUBLICATION testpub4 FOR TABLE ONLY testpub_tbl_parent; \dRp+ testpub4 +-- Exclude parent table, omitting both of 'ONLY' and '*' +CREATE PUBLICATION testpub5 FOR ALL TABLES EXCEPT TABLE (testpub_tbl_parent); +\dRp+ testpub5 +-- EXCEPT with '*': exclude table and all descendants +CREATE PUBLICATION testpub6 FOR ALL TABLES EXCEPT TABLE (testpub_tbl_parent *); +\dRp+ testpub6 +-- EXCEPT with ONLY: exclude table but not descendants +CREATE PUBLICATION testpub7 FOR ALL TABLES EXCEPT TABLE (ONLY testpub_tbl_parent); +\dRp+ testpub7 -DROP TABLE testpub_tbl3, testpub_tbl3a; -DROP PUBLICATION testpub3, testpub4; +RESET client_min_messages; +DROP TABLE testpub_tbl_parent, testpub_tbl_child; +DROP PUBLICATION testpub3, testpub4, testpub5, testpub6, testpub7; --- Tests for publications with SEQUENCES CREATE SEQUENCE regress_pub_seq0; diff --git a/src/test/subscription/meson.build b/src/test/subscription/meson.build index a4c7dbaff59..07282aa3c18 100644 --- a/src/test/subscription/meson.build +++ b/src/test/subscription/meson.build @@ -46,6 +46,7 @@ tests += { 't/034_temporal.pl', 't/035_conflicts.pl', 't/036_sequences.pl', + 't/037_rep_changes_except_table.pl', 't/100_bugs.pl', ], }, diff --git a/src/test/subscription/t/037_rep_changes_except_table.pl b/src/test/subscription/t/037_rep_changes_except_table.pl new file mode 100644 index 00000000000..4c3c81462a5 --- /dev/null +++ b/src/test/subscription/t/037_rep_changes_except_table.pl @@ -0,0 +1,253 @@ + +# Copyright (c) 2021-2025, PostgreSQL Global Development Group + +# Logical replication tests for EXCEPT TABLE publications +use strict; +use warnings; +use PostgreSQL::Test::Cluster; +use PostgreSQL::Test::Utils; +use Test::More; + +# Initialize publisher node +my $node_publisher = PostgreSQL::Test::Cluster->new('publisher'); +$node_publisher->init(allows_streaming => 'logical'); +$node_publisher->start; + +# Initialize subscriber node +my $node_subscriber = PostgreSQL::Test::Cluster->new('subscriber'); +$node_subscriber->init(allows_streaming => 'logical'); +$node_subscriber->start; + +# ============================================ +# EXCEPT TABLE test cases for normal tables +# ============================================ +# Create schemas and tables on publisher +$node_publisher->safe_psql( + 'postgres', qq( + CREATE SCHEMA sch1; + CREATE TABLE sch1.tab1 AS SELECT generate_series(1,10) AS a; +)); + +# Create schemas and tables on subscriber +$node_subscriber->safe_psql( + 'postgres', qq( + CREATE SCHEMA sch1; + CREATE TABLE sch1.tab1 (a int); +)); + +# Setup logical replication +my $publisher_connstr = $node_publisher->connstr . ' dbname=postgres'; +$node_publisher->safe_psql('postgres', + "CREATE PUBLICATION tap_pub_schema FOR ALL TABLES EXCEPT TABLE (sch1.tab1)" +); +# Create a logical replication slot +$node_publisher->safe_psql('postgres', + "SELECT pg_create_logical_replication_slot('test_slot', 'pgoutput')"); + +$node_subscriber->safe_psql('postgres', + "CREATE SUBSCRIPTION tap_sub_schema CONNECTION '$publisher_connstr' PUBLICATION tap_pub_schema" +); + +# Wait for initial table sync to finish +$node_subscriber->wait_for_subscription_sync($node_publisher, + 'tap_sub_schema'); + +# Check the table data does not sync for excluded table +my $result = $node_subscriber->safe_psql('postgres', + "SELECT count(*), min(a), max(a) FROM sch1.tab1"); +is($result, qq(0||), + 'check there is no initial data copied for the excluded table'); + +$node_publisher->safe_psql('postgres', + "INSERT INTO sch1.tab1 VALUES(generate_series(11,20))"); + +# Verify that data inserted to excluded table is not published. +$result = $node_publisher->safe_psql('postgres', + "SELECT count(*) = 0 FROM pg_logical_slot_get_binary_changes('test_slot', NULL, NULL, 'proto_version', '1', 'publication_names', 'tap_sub_schema')" +); +is($result, qq(t), 'check no changes for excluded table in replication slot'); + +$node_publisher->wait_for_catchup('tap_sub_schema'); + +# Verify that data inserted to the excluded table is not replicated. +$result = $node_subscriber->safe_psql('postgres', + "SELECT count(*), min(a), max(a) FROM sch1.tab1"); +is($result, qq(0||), 'check replicated inserts on subscriber'); + +# cleanup +$node_publisher->safe_psql('postgres', "DROP PUBLICATION tap_pub_schema"); +$node_subscriber->safe_psql('postgres', "DROP SUBSCRIPTION tap_sub_schema"); + +# ============================================ +# EXCEPT TABLE test cases for partitioned tables +# Check behavior of EXCEPT TABLE with publish_via_partition_root on a +# partitioned table and its partitions. +# ============================================ +# Setup partitioned table and partitions on the publisher that map to normal +# tables on the subscriber +$node_publisher->safe_psql( + 'postgres', qq( + CREATE TABLE sch1.t1(a int) PARTITION BY RANGE(a); + CREATE TABLE sch1.part1 PARTITION OF sch1.t1 FOR VALUES FROM (0) TO (100); + CREATE TABLE sch1.part2(a int) PARTITION BY RANGE(a); + CREATE TABLE sch1.part2_1 PARTITION OF sch1.part2 FOR VALUES FROM (101) TO (150); + CREATE TABLE sch1.part2_2 PARTITION OF sch1.part2 FOR VALUES FROM (151) TO (200); + ALTER TABLE sch1.t1 ATTACH PARTITION sch1.part2 FOR VALUES FROM (101) TO (200); +)); + +$node_subscriber->safe_psql( + 'postgres', qq( + CREATE TABLE sch1.t1(a int); + CREATE TABLE sch1.part1(a int); + CREATE TABLE sch1.part2(a int); + CREATE TABLE sch1.part2_1(a int); + CREATE TABLE sch1.part2_2(a int); +)); + +# Partititions cannot be excluded using EXCEPT TABLE +my ($stdout, $stderr); +($result, $stdout, $stderr) = $node_publisher->psql( + 'postgres', qq( + CREATE PUBLICATION tap_pub_part FOR ALL TABLES EXCEPT TABLE (sch1.part2) WITH (publish_via_partition_root = false); +)); +like( + $stderr, + qr/partition "part2" cannot be excluded using EXCEPT TABLE/, + 'partition "part2" cannot be excluded using EXCEPT TABLE'); + +($result, $stdout, $stderr) = $node_publisher->psql( + 'postgres', qq( + CREATE PUBLICATION tap_pub_part FOR ALL TABLES EXCEPT TABLE (sch1.part2) WITH (publish_via_partition_root = true); +)); +like( + $stderr, + qr/partition "part2" cannot be excluded using EXCEPT TABLE/, + 'partition "part2" cannot be excluded using EXCEPT TABLE'); + +($result, $stdout, $stderr) = $node_publisher->psql( + 'postgres', qq( + CREATE PUBLICATION tap_pub_part FOR ALL TABLES EXCEPT TABLE (sch1.part2_1) WITH (publish_via_partition_root = false); +)); +like( + $stderr, + qr/partition "part2_1" cannot be excluded using EXCEPT TABLE/, + 'partition "part2_1" cannot be excluded using EXCEPT TABLE'); + +($result, $stdout, $stderr) = $node_publisher->psql( + 'postgres', qq( + CREATE PUBLICATION tap_pub_part FOR ALL TABLES EXCEPT TABLE (sch1.part2_1) WITH (publish_via_partition_root = true); +)); +like( + $stderr, + qr/partition "part2_1" cannot be excluded using EXCEPT TABLE/, + 'partition "part2_1" cannot be excluded using EXCEPT TABLE'); + +# Excluding the root partitioned table excludes all its partitions as well when +# publish_via_partition_root = false. +$node_publisher->safe_psql( + 'postgres', qq( + CREATE PUBLICATION tap_pub_part FOR ALL TABLES EXCEPT TABLE (sch1.t1) WITH (publish_via_partition_root = false); + INSERT INTO sch1.t1 VALUES (1), (101), (151); +)); +$node_subscriber->safe_psql('postgres', + "CREATE SUBSCRIPTION tap_sub_part CONNECTION '$publisher_connstr' PUBLICATION tap_pub_part" +); +$node_subscriber->wait_for_subscription_sync($node_publisher, 'tap_sub_part'); +$node_publisher->safe_psql('postgres', + "SELECT slot_name FROM pg_replication_slot_advance('test_slot', pg_current_wal_lsn());" +); +$node_publisher->safe_psql('postgres', + "INSERT INTO sch1.t1 VALUES (2), (102), (152)"); + +# Verify that data inserted to the partitioned table is not published when it is +# excluded with publish_via_partition_root = true. +$result = $node_publisher->safe_psql('postgres', + "SELECT count(*) = 0 FROM pg_logical_slot_get_binary_changes('test_slot', NULL, NULL, 'proto_version', '1', 'publication_names', 'tap_pub_part')" +); +$node_publisher->wait_for_catchup('tap_sub_part'); + +# Check that no rows are replicated to subscriber +$result = $node_subscriber->safe_psql('postgres', "SELECT * FROM sch1.t1"); +is($result, qq(), 'check rows on root table'); + +$result = $node_subscriber->safe_psql('postgres', "SELECT * FROM sch1.part1"); +is($result, qq(), 'check rows on table sch1.part1'); + +$result = $node_subscriber->safe_psql('postgres', "SELECT * FROM sch1.part2"); +is($result, qq(), 'check rows on table sch1.part2'); + +$result = + $node_subscriber->safe_psql('postgres', "SELECT * FROM sch1.part2_1"); +is($result, qq(), 'check rows on table sch1.part2_1'); + +$result = + $node_subscriber->safe_psql('postgres', "SELECT * FROM sch1.part2_2"); +is($result, qq(), 'check rows on table sch1.part2_2'); + +$node_subscriber->safe_psql('postgres', "DROP SUBSCRIPTION tap_sub_part"); +$node_publisher->safe_psql('postgres', "DROP PUBLICATION tap_pub_part;"); + +# Excluding the root partitioned table excludes all its partitions as well when +# publish_via_partition_root = true. +$node_publisher->safe_psql( + 'postgres', qq( + CREATE PUBLICATION tap_pub_part FOR ALL TABLES EXCEPT TABLE (sch1.t1) WITH (publish_via_partition_root = true); +)); +$node_subscriber->safe_psql('postgres', + "CREATE SUBSCRIPTION tap_sub_part CONNECTION '$publisher_connstr' PUBLICATION tap_pub_part" +); +$node_subscriber->wait_for_subscription_sync($node_publisher, 'tap_sub_part'); +$node_publisher->safe_psql('postgres', + "SELECT slot_name FROM pg_replication_slot_advance('test_slot', pg_current_wal_lsn());" +); +$node_publisher->safe_psql('postgres', + "INSERT INTO sch1.t1 VALUES (3), (103), (153);"); + +# Verify that data inserted to the partitioned table is not published when it is +# excluded with publish_via_partition_root = true. +$result = $node_publisher->safe_psql('postgres', + "SELECT count(*) = 0 FROM pg_logical_slot_get_binary_changes('test_slot', NULL, NULL, 'proto_version', '1', 'publication_names', 'tap_pub_part')" +); +$node_publisher->wait_for_catchup('tap_sub_part'); + +# Check that no rows are replicated to subscriber +$result = $node_subscriber->safe_psql('postgres', "SELECT * FROM sch1.t1"); +is($result, qq(), 'check rows on root table'); + +$result = $node_subscriber->safe_psql('postgres', "SELECT * FROM sch1.part1"); +is($result, qq(), 'check rows on table sch1.part1'); + +$result = $node_subscriber->safe_psql('postgres', "SELECT * FROM sch1.part2"); +is($result, qq(), 'check rows on table sch1.part2'); + +$result = + $node_subscriber->safe_psql('postgres', "SELECT * FROM sch1.part2_1"); +is($result, qq(), 'check rows on table sch1.part2_1'); + +$result = + $node_subscriber->safe_psql('postgres', "SELECT * FROM sch1.part2_2"); +is($result, qq(), 'check rows on table sch1.part2_2'); + +$node_subscriber->safe_psql('postgres', "DROP SUBSCRIPTION tap_sub_part"); +$node_publisher->safe_psql('postgres', "DROP PUBLICATION tap_pub_part;"); + +# Cannot attach partition that is part of EXCEPT list in publication +$node_publisher->safe_psql('postgres', + "ALTER TABLE sch1.t1 DETACH PARTITION sch1.part2"); +$node_publisher->safe_psql('postgres', + "CREATE PUBLICATION tap_pub_part FOR ALL TABLES EXCEPT TABLE (sch1.part2) WITH (publish_via_partition_root = true)" +); +($result, $stdout, $stderr) = $node_publisher->psql( + 'postgres', qq( + ALTER TABLE sch1.t1 ATTACH PARTITION sch1.part2 FOR VALUES FROM (101) TO (200); +)); +like( + $stderr, + qr/cannot attach relation "part2" as partition because it is part of EXCEPT list in publication/, + 'cannot attach relation "part2" as partition because it is part of EXCEPT list in publication' +); + +$node_subscriber->stop('fast'); +$node_publisher->stop('fast'); + +done_testing(); -- 2.34.1
