Skip to content

Commit bdecabc

Browse files
ashutosh-bapatCommitfest Bot
authored andcommitted
Report replica identity property of tables in pg_publication_tables
When debugging issues with logical replication, replica identity property of tables in publication is often useful, for example, to determine the amount of data logged for an UPDATE or DELETE on a table. Given a set of publications that a WAL sender is using, pg_publication_tables can be used to get the list of tables whose changes will be replicated including the columns of those tables and row filters. But the replica identity of those tables needs to be separately found out by querying pg_class or joining pg_class with pg_publication_tables. Adding replica identity column to pg_publication_tables avoids this extra step. The replica identity for a given table does not change with publication so the information will be repeated as many times the number of publications a given table is part of. But the repetition is worth the convenience. Ashutosh Bapat
1 parent 3853a69 commit bdecabc

File tree

5 files changed

+109
-23
lines changed

5 files changed

+109
-23
lines changed

doc/src/sgml/system-views.sgml

Lines changed: 9 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -2698,6 +2698,15 @@ SELECT * FROM pg_locks pl LEFT JOIN pg_prepared_xacts ppx
26982698
Expression for the table's publication qualifying condition
26992699
</para></entry>
27002700
</row>
2701+
2702+
<row>
2703+
<entry role="catalog_table_entry"><para role="column_definition">
2704+
<structfield>replica_identity</structfield> <type>text</type>
2705+
</para>
2706+
<para>
2707+
Replica identity setting of the table.
2708+
</para></entry>
2709+
</row>
27012710
</tbody>
27022711
</tgroup>
27032712
</table>

src/backend/catalog/system_views.sql

Lines changed: 8 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -388,7 +388,14 @@ CREATE VIEW pg_publication_tables AS
388388
WHERE a.attrelid = GPT.relid AND
389389
a.attnum = ANY(GPT.attrs)
390390
) AS attnames,
391-
pg_get_expr(GPT.qual, GPT.relid) AS rowfilter
391+
pg_get_expr(GPT.qual, GPT.relid) AS rowfilter,
392+
case C.relreplident
393+
when 'd' then 'default'
394+
when 'n' then 'nothing'
395+
when 'f' then 'full'
396+
when 'i' then 'index'
397+
else NULL
398+
end as replica_identity
392399
FROM pg_publication P,
393400
LATERAL pg_get_publication_tables(P.pubname) GPT,
394401
pg_class C JOIN pg_namespace N ON (N.oid = C.relnamespace)

src/test/regress/expected/publication.out

Lines changed: 75 additions & 21 deletions
Original file line numberDiff line numberDiff line change
@@ -677,21 +677,45 @@ ALTER PUBLICATION testpub6 SET TABLE rf_tbl_abcd_pk WHERE (d > 99);
677677
UPDATE rf_tbl_abcd_pk SET a = 1;
678678
ERROR: cannot update table "rf_tbl_abcd_pk"
679679
DETAIL: Column used in the publication WHERE expression is not part of the replica identity.
680+
SELECT * FROM pg_publication_tables WHERE pubname = 'testpub6';
681+
pubname | schemaname | tablename | attnames | rowfilter | replica_identity
682+
----------+------------+----------------+-----------+-----------+------------------
683+
testpub6 | public | rf_tbl_abcd_pk | {a,b,c,d} | (d > 99) | default
684+
(1 row)
685+
680686
-- 1b. REPLICA IDENTITY is DEFAULT and table has no PK
681687
ALTER PUBLICATION testpub6 SET TABLE rf_tbl_abcd_nopk WHERE (a > 99);
682688
-- fail - "a" is not part of REPLICA IDENTITY
683689
UPDATE rf_tbl_abcd_nopk SET a = 1;
684690
ERROR: cannot update table "rf_tbl_abcd_nopk"
685691
DETAIL: Column used in the publication WHERE expression is not part of the replica identity.
692+
SELECT * FROM pg_publication_tables WHERE pubname = 'testpub6';
693+
pubname | schemaname | tablename | attnames | rowfilter | replica_identity
694+
----------+------------+------------------+-----------+-----------+------------------
695+
testpub6 | public | rf_tbl_abcd_nopk | {a,b,c,d} | (a > 99) | default
696+
(1 row)
697+
686698
-- Case 2. REPLICA IDENTITY FULL
687699
ALTER TABLE rf_tbl_abcd_pk REPLICA IDENTITY FULL;
688700
ALTER TABLE rf_tbl_abcd_nopk REPLICA IDENTITY FULL;
689701
ALTER PUBLICATION testpub6 SET TABLE rf_tbl_abcd_pk WHERE (c > 99);
690702
-- ok - "c" is in REPLICA IDENTITY now even though not in PK
691703
UPDATE rf_tbl_abcd_pk SET a = 1;
704+
SELECT * FROM pg_publication_tables WHERE pubname = 'testpub6';
705+
pubname | schemaname | tablename | attnames | rowfilter | replica_identity
706+
----------+------------+----------------+-----------+-----------+------------------
707+
testpub6 | public | rf_tbl_abcd_pk | {a,b,c,d} | (c > 99) | full
708+
(1 row)
709+
692710
ALTER PUBLICATION testpub6 SET TABLE rf_tbl_abcd_nopk WHERE (a > 99);
693711
-- ok - "a" is in REPLICA IDENTITY now
694712
UPDATE rf_tbl_abcd_nopk SET a = 1;
713+
SELECT * FROM pg_publication_tables WHERE pubname = 'testpub6';
714+
pubname | schemaname | tablename | attnames | rowfilter | replica_identity
715+
----------+------------+------------------+-----------+-----------+------------------
716+
testpub6 | public | rf_tbl_abcd_nopk | {a,b,c,d} | (a > 99) | full
717+
(1 row)
718+
695719
-- Case 3. REPLICA IDENTITY NOTHING
696720
ALTER TABLE rf_tbl_abcd_pk REPLICA IDENTITY NOTHING;
697721
ALTER TABLE rf_tbl_abcd_nopk REPLICA IDENTITY NOTHING;
@@ -705,11 +729,23 @@ ALTER PUBLICATION testpub6 SET TABLE rf_tbl_abcd_pk WHERE (c > 99);
705729
UPDATE rf_tbl_abcd_pk SET a = 1;
706730
ERROR: cannot update table "rf_tbl_abcd_pk"
707731
DETAIL: Column used in the publication WHERE expression is not part of the replica identity.
732+
SELECT * FROM pg_publication_tables WHERE pubname = 'testpub6';
733+
pubname | schemaname | tablename | attnames | rowfilter | replica_identity
734+
----------+------------+----------------+-----------+-----------+------------------
735+
testpub6 | public | rf_tbl_abcd_pk | {a,b,c,d} | (c > 99) | nothing
736+
(1 row)
737+
708738
ALTER PUBLICATION testpub6 SET TABLE rf_tbl_abcd_nopk WHERE (a > 99);
709739
-- fail - "a" is not in REPLICA IDENTITY NOTHING
710740
UPDATE rf_tbl_abcd_nopk SET a = 1;
711741
ERROR: cannot update table "rf_tbl_abcd_nopk"
712742
DETAIL: Column used in the publication WHERE expression is not part of the replica identity.
743+
SELECT * FROM pg_publication_tables WHERE pubname = 'testpub6';
744+
pubname | schemaname | tablename | attnames | rowfilter | replica_identity
745+
----------+------------+------------------+-----------+-----------+------------------
746+
testpub6 | public | rf_tbl_abcd_nopk | {a,b,c,d} | (a > 99) | nothing
747+
(1 row)
748+
713749
-- Case 4. REPLICA IDENTITY INDEX
714750
ALTER TABLE rf_tbl_abcd_pk ALTER COLUMN c SET NOT NULL;
715751
CREATE UNIQUE INDEX idx_abcd_pk_c ON rf_tbl_abcd_pk(c);
@@ -725,6 +761,12 @@ DETAIL: Column used in the publication WHERE expression is not part of the repl
725761
ALTER PUBLICATION testpub6 SET TABLE rf_tbl_abcd_pk WHERE (c > 99);
726762
-- ok - "c" is not in PK but it is part of REPLICA IDENTITY INDEX
727763
UPDATE rf_tbl_abcd_pk SET a = 1;
764+
SELECT * FROM pg_publication_tables WHERE pubname = 'testpub6';
765+
pubname | schemaname | tablename | attnames | rowfilter | replica_identity
766+
----------+------------+----------------+-----------+-----------+------------------
767+
testpub6 | public | rf_tbl_abcd_pk | {a,b,c,d} | (c > 99) | index
768+
(1 row)
769+
728770
ALTER PUBLICATION testpub6 SET TABLE rf_tbl_abcd_nopk WHERE (a > 99);
729771
-- fail - "a" is not in REPLICA IDENTITY INDEX
730772
UPDATE rf_tbl_abcd_nopk SET a = 1;
@@ -733,6 +775,12 @@ DETAIL: Column used in the publication WHERE expression is not part of the repl
733775
ALTER PUBLICATION testpub6 SET TABLE rf_tbl_abcd_nopk WHERE (c > 99);
734776
-- ok - "c" is part of REPLICA IDENTITY INDEX
735777
UPDATE rf_tbl_abcd_nopk SET a = 1;
778+
SELECT * FROM pg_publication_tables WHERE pubname = 'testpub6';
779+
pubname | schemaname | tablename | attnames | rowfilter | replica_identity
780+
----------+------------+------------------+-----------+-----------+------------------
781+
testpub6 | public | rf_tbl_abcd_nopk | {a,b,c,d} | (c > 99) | index
782+
(1 row)
783+
736784
-- Tests for partitioned table
737785
-- set PUBLISH_VIA_PARTITION_ROOT to false and test row filter for partitioned
738786
-- table
@@ -779,6 +827,12 @@ ALTER PUBLICATION testpub6 SET TABLE rf_tbl_abcd_part_pk WHERE (b > 99);
779827
UPDATE rf_tbl_abcd_part_pk SET a = 1;
780828
ERROR: cannot update table "rf_tbl_abcd_part_pk_1"
781829
DETAIL: Column used in the publication WHERE expression is not part of the replica identity.
830+
SELECT * FROM pg_publication_tables WHERE pubname = 'testpub6';
831+
pubname | schemaname | tablename | attnames | rowfilter | replica_identity
832+
----------+------------+---------------------+----------+-----------+------------------
833+
testpub6 | public | rf_tbl_abcd_part_pk | {a,b} | (b > 99) | default
834+
(1 row)
835+
782836
DROP PUBLICATION testpub6;
783837
DROP TABLE rf_tbl_abcd_pk;
784838
DROP TABLE rf_tbl_abcd_nopk;
@@ -1863,52 +1917,52 @@ CREATE TABLE sch2.tbl1_part1 PARTITION OF sch1.tbl1 FOR VALUES FROM (1) to (10);
18631917
-- Schema publication that does not include the schema that has the parent table
18641918
CREATE PUBLICATION pub FOR TABLES IN SCHEMA sch2 WITH (PUBLISH_VIA_PARTITION_ROOT=1);
18651919
SELECT * FROM pg_publication_tables;
1866-
pubname | schemaname | tablename | attnames | rowfilter
1867-
---------+------------+------------+----------+-----------
1868-
pub | sch2 | tbl1_part1 | {a} |
1920+
pubname | schemaname | tablename | attnames | rowfilter | replica_identity
1921+
---------+------------+------------+----------+-----------+------------------
1922+
pub | sch2 | tbl1_part1 | {a} | | default
18691923
(1 row)
18701924

18711925
DROP PUBLICATION pub;
18721926
-- Table publication that does not include the parent table
18731927
CREATE PUBLICATION pub FOR TABLE sch2.tbl1_part1 WITH (PUBLISH_VIA_PARTITION_ROOT=1);
18741928
SELECT * FROM pg_publication_tables;
1875-
pubname | schemaname | tablename | attnames | rowfilter
1876-
---------+------------+------------+----------+-----------
1877-
pub | sch2 | tbl1_part1 | {a} |
1929+
pubname | schemaname | tablename | attnames | rowfilter | replica_identity
1930+
---------+------------+------------+----------+-----------+------------------
1931+
pub | sch2 | tbl1_part1 | {a} | | default
18781932
(1 row)
18791933

18801934
-- Table publication that includes both the parent table and the child table
18811935
ALTER PUBLICATION pub ADD TABLE sch1.tbl1;
18821936
SELECT * FROM pg_publication_tables;
1883-
pubname | schemaname | tablename | attnames | rowfilter
1884-
---------+------------+-----------+----------+-----------
1885-
pub | sch1 | tbl1 | {a} |
1937+
pubname | schemaname | tablename | attnames | rowfilter | replica_identity
1938+
---------+------------+-----------+----------+-----------+------------------
1939+
pub | sch1 | tbl1 | {a} | | default
18861940
(1 row)
18871941

18881942
DROP PUBLICATION pub;
18891943
-- Schema publication that does not include the schema that has the parent table
18901944
CREATE PUBLICATION pub FOR TABLES IN SCHEMA sch2 WITH (PUBLISH_VIA_PARTITION_ROOT=0);
18911945
SELECT * FROM pg_publication_tables;
1892-
pubname | schemaname | tablename | attnames | rowfilter
1893-
---------+------------+------------+----------+-----------
1894-
pub | sch2 | tbl1_part1 | {a} |
1946+
pubname | schemaname | tablename | attnames | rowfilter | replica_identity
1947+
---------+------------+------------+----------+-----------+------------------
1948+
pub | sch2 | tbl1_part1 | {a} | | default
18951949
(1 row)
18961950

18971951
DROP PUBLICATION pub;
18981952
-- Table publication that does not include the parent table
18991953
CREATE PUBLICATION pub FOR TABLE sch2.tbl1_part1 WITH (PUBLISH_VIA_PARTITION_ROOT=0);
19001954
SELECT * FROM pg_publication_tables;
1901-
pubname | schemaname | tablename | attnames | rowfilter
1902-
---------+------------+------------+----------+-----------
1903-
pub | sch2 | tbl1_part1 | {a} |
1955+
pubname | schemaname | tablename | attnames | rowfilter | replica_identity
1956+
---------+------------+------------+----------+-----------+------------------
1957+
pub | sch2 | tbl1_part1 | {a} | | default
19041958
(1 row)
19051959

19061960
-- Table publication that includes both the parent table and the child table
19071961
ALTER PUBLICATION pub ADD TABLE sch1.tbl1;
19081962
SELECT * FROM pg_publication_tables;
1909-
pubname | schemaname | tablename | attnames | rowfilter
1910-
---------+------------+------------+----------+-----------
1911-
pub | sch2 | tbl1_part1 | {a} |
1963+
pubname | schemaname | tablename | attnames | rowfilter | replica_identity
1964+
---------+------------+------------+----------+-----------+------------------
1965+
pub | sch2 | tbl1_part1 | {a} | | default
19121966
(1 row)
19131967

19141968
DROP PUBLICATION pub;
@@ -1921,9 +1975,9 @@ CREATE TABLE sch1.tbl1_part3 (a int) PARTITION BY RANGE(a);
19211975
ALTER TABLE sch1.tbl1 ATTACH PARTITION sch1.tbl1_part3 FOR VALUES FROM (20) to (30);
19221976
CREATE PUBLICATION pub FOR TABLES IN SCHEMA sch1 WITH (PUBLISH_VIA_PARTITION_ROOT=1);
19231977
SELECT * FROM pg_publication_tables;
1924-
pubname | schemaname | tablename | attnames | rowfilter
1925-
---------+------------+-----------+----------+-----------
1926-
pub | sch1 | tbl1 | {a} |
1978+
pubname | schemaname | tablename | attnames | rowfilter | replica_identity
1979+
---------+------------+-----------+----------+-----------+------------------
1980+
pub | sch1 | tbl1 | {a} | | default
19271981
(1 row)
19281982

19291983
RESET client_min_messages;

src/test/regress/expected/rules.out

Lines changed: 8 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -1476,7 +1476,14 @@ pg_publication_tables| SELECT p.pubname,
14761476
( SELECT array_agg(a.attname ORDER BY a.attnum) AS array_agg
14771477
FROM pg_attribute a
14781478
WHERE ((a.attrelid = gpt.relid) AND (a.attnum = ANY ((gpt.attrs)::smallint[])))) AS attnames,
1479-
pg_get_expr(gpt.qual, gpt.relid) AS rowfilter
1479+
pg_get_expr(gpt.qual, gpt.relid) AS rowfilter,
1480+
CASE c.relreplident
1481+
WHEN 'd'::"char" THEN 'default'::text
1482+
WHEN 'n'::"char" THEN 'nothing'::text
1483+
WHEN 'f'::"char" THEN 'full'::text
1484+
WHEN 'i'::"char" THEN 'index'::text
1485+
ELSE NULL::text
1486+
END AS replica_identity
14801487
FROM pg_publication p,
14811488
LATERAL pg_get_publication_tables(VARIADIC ARRAY[(p.pubname)::text]) gpt(pubid, relid, attrs, qual),
14821489
(pg_class c

src/test/regress/sql/publication.sql

Lines changed: 9 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -364,20 +364,24 @@ UPDATE rf_tbl_abcd_pk SET a = 1;
364364
ALTER PUBLICATION testpub6 SET TABLE rf_tbl_abcd_pk WHERE (d > 99);
365365
-- fail - "d" is not part of the PK
366366
UPDATE rf_tbl_abcd_pk SET a = 1;
367+
SELECT * FROM pg_publication_tables WHERE pubname = 'testpub6';
367368
-- 1b. REPLICA IDENTITY is DEFAULT and table has no PK
368369
ALTER PUBLICATION testpub6 SET TABLE rf_tbl_abcd_nopk WHERE (a > 99);
369370
-- fail - "a" is not part of REPLICA IDENTITY
370371
UPDATE rf_tbl_abcd_nopk SET a = 1;
372+
SELECT * FROM pg_publication_tables WHERE pubname = 'testpub6';
371373

372374
-- Case 2. REPLICA IDENTITY FULL
373375
ALTER TABLE rf_tbl_abcd_pk REPLICA IDENTITY FULL;
374376
ALTER TABLE rf_tbl_abcd_nopk REPLICA IDENTITY FULL;
375377
ALTER PUBLICATION testpub6 SET TABLE rf_tbl_abcd_pk WHERE (c > 99);
376378
-- ok - "c" is in REPLICA IDENTITY now even though not in PK
377379
UPDATE rf_tbl_abcd_pk SET a = 1;
380+
SELECT * FROM pg_publication_tables WHERE pubname = 'testpub6';
378381
ALTER PUBLICATION testpub6 SET TABLE rf_tbl_abcd_nopk WHERE (a > 99);
379382
-- ok - "a" is in REPLICA IDENTITY now
380383
UPDATE rf_tbl_abcd_nopk SET a = 1;
384+
SELECT * FROM pg_publication_tables WHERE pubname = 'testpub6';
381385

382386
-- Case 3. REPLICA IDENTITY NOTHING
383387
ALTER TABLE rf_tbl_abcd_pk REPLICA IDENTITY NOTHING;
@@ -388,9 +392,11 @@ UPDATE rf_tbl_abcd_pk SET a = 1;
388392
ALTER PUBLICATION testpub6 SET TABLE rf_tbl_abcd_pk WHERE (c > 99);
389393
-- fail - "c" is not in PK and not in REPLICA IDENTITY NOTHING
390394
UPDATE rf_tbl_abcd_pk SET a = 1;
395+
SELECT * FROM pg_publication_tables WHERE pubname = 'testpub6';
391396
ALTER PUBLICATION testpub6 SET TABLE rf_tbl_abcd_nopk WHERE (a > 99);
392397
-- fail - "a" is not in REPLICA IDENTITY NOTHING
393398
UPDATE rf_tbl_abcd_nopk SET a = 1;
399+
SELECT * FROM pg_publication_tables WHERE pubname = 'testpub6';
394400

395401
-- Case 4. REPLICA IDENTITY INDEX
396402
ALTER TABLE rf_tbl_abcd_pk ALTER COLUMN c SET NOT NULL;
@@ -405,12 +411,14 @@ UPDATE rf_tbl_abcd_pk SET a = 1;
405411
ALTER PUBLICATION testpub6 SET TABLE rf_tbl_abcd_pk WHERE (c > 99);
406412
-- ok - "c" is not in PK but it is part of REPLICA IDENTITY INDEX
407413
UPDATE rf_tbl_abcd_pk SET a = 1;
414+
SELECT * FROM pg_publication_tables WHERE pubname = 'testpub6';
408415
ALTER PUBLICATION testpub6 SET TABLE rf_tbl_abcd_nopk WHERE (a > 99);
409416
-- fail - "a" is not in REPLICA IDENTITY INDEX
410417
UPDATE rf_tbl_abcd_nopk SET a = 1;
411418
ALTER PUBLICATION testpub6 SET TABLE rf_tbl_abcd_nopk WHERE (c > 99);
412419
-- ok - "c" is part of REPLICA IDENTITY INDEX
413420
UPDATE rf_tbl_abcd_nopk SET a = 1;
421+
SELECT * FROM pg_publication_tables WHERE pubname = 'testpub6';
414422

415423
-- Tests for partitioned table
416424

@@ -451,6 +459,7 @@ ALTER PUBLICATION testpub6 SET (PUBLISH_VIA_PARTITION_ROOT=1);
451459
ALTER PUBLICATION testpub6 SET TABLE rf_tbl_abcd_part_pk WHERE (b > 99);
452460
-- fail - "b" is not in REPLICA IDENTITY INDEX
453461
UPDATE rf_tbl_abcd_part_pk SET a = 1;
462+
SELECT * FROM pg_publication_tables WHERE pubname = 'testpub6';
454463

455464
DROP PUBLICATION testpub6;
456465
DROP TABLE rf_tbl_abcd_pk;

0 commit comments

Comments
 (0)