postgres=> show shared_preload_libraries;shared_preload_libraries--------------------------------------------------------------------------------------------------------------------------------------pg_stat_statements,pg_stat_log,wal2json,decoderbufs,decoder_raw,pg_hint_plan,rds_server_handler,tencentdb_pwdcheck,pgaudit,pglogical(1 row)
postgres=> show wal_level;wal_level-----------logical(1 row)
postgres=> select * from pg_available_extensions where name='pglogical';name | default_version | installed_version | comment-----------+-----------------+-------------------+--------------------------------pglogical | 2.4.4 | | PostgreSQL Logical Replication(1 row)
postgres=> create extension pglogical;CREATE EXTENSION
postgres=> select * from pg_extension where extname='pglogical';oid | extname | extowner | extnamespace | extrelocatable | extversion | extconfig | extcondition-------+-----------+----------+--------------+----------------+------------+-----------+--------------16424 | pglogical | 16387 | 16423 | f | 2.4.4 | |(1 row)
postgres=> create database am;CREATE DATABASEpostgres=> \\c ampsql (14.11, server 15.6)WARNING: psql major version 14, server major version 15.Some psql features might not work.You are now connected to database "am" as user "dbadmin".am=>
am=> create table t(a int primary key, b int);CREATE TABLEam=> insert into t(a,b)values(1,1),(2,2),(3,3);INSERT 0 3am=> select * from t;a | b---+---1 | 12 | 23 | 3(3 rows)
am=> SELECT pglogical.create_node(node_name := 'provider1',dsn := 'host=10.216.0.106 port=5432 dbname=am user=dbadmin password=Lxh202405! instanceid=postgres-gip4cpjw');create_node-------------2976894835(1 row)
am=> SELECT pglogical.replication_set_add_all_tables('default', ARRAY['public']);replication_set_add_all_tables--------------------------------t(1 row)
postgres=> \\c ampsql (14.11, server 15.6)WARNING: psql major version 14, server major version 15.Some psql features might not work.You are now connected to database "am" as user "dbadmin".am=> create table t(a int primary key, b int);CREATE TABLE
am=> SELECT pglogical.create_node(node_name := 'subscriber1',dsn := 'host=10.216.1.162 port=5432 dbname=am user=dbadmin password=Lxh202405! instanceid=postgres-70beu0ou');create_node-------------330520249(1 row)
am=> SELECT pglogical.create_subscription(subscription_name := 'subscription1',provider_dsn := 'host=10.216.0.106 port=5432 dbname=am user=dbadmin password=Lxh202405! instanceid=postgres-gip4cpjw');create_subscription---------------------1763399739(1 row)
am=> select * from t;a | b---+---1 | 12 | 23 | 3(3 rows)
本页内容是否解决了您的问题?