当前位置: 首页 > 工具软件 > Slony-I > 使用案例 >

Slony-I 之二 1 master 节点 + 1目标节点

周锐
2023-12-01

os: centos 7.4.1708
db: postgresql 11.8
Slony-I: 2.2.8

192.168.56.111  n1
192.168.56.112  n2
192.168.56.113  n3

这3个节点都需要安装 postgresql 11 及 Slony-I

本次实现同步 n1 节点某个表数据到 n2 节点。

版本

# cat /etc/centos-release
CentOS Linux release 7.4.1708 (Core) 
# 
# 
# yum list installed |grep -i postgresql
postgresql11.x86_64                11.8-1PGDG.rhel7                    @pgdg11  
postgresql11-contrib.x86_64        11.8-1PGDG.rhel7                    @pgdg11  
postgresql11-debuginfo.x86_64      11.5-1PGDG.rhel7                    @pgdg11  
postgresql11-devel.x86_64          11.8-1PGDG.rhel7                    @pgdg11  
postgresql11-docs.x86_64           11.8-1PGDG.rhel7                    @pgdg11  
postgresql11-libs.x86_64           11.8-1PGDG.rhel7                    @pgdg11  
postgresql11-llvmjit.x86_64        11.8-1PGDG.rhel7                    @pgdg11  
postgresql11-odbc.x86_64           12.01.0000-1PGDG.rhel7              @pgdg11  
postgresql11-plperl.x86_64         11.8-1PGDG.rhel7                    @pgdg11  
postgresql11-plpython.x86_64       11.8-1PGDG.rhel7                    @pgdg11  
postgresql11-pltcl.x86_64          11.8-1PGDG.rhel7                    @pgdg11  
postgresql11-server.x86_64         11.8-1PGDG.rhel7                    @pgdg11  
postgresql11-tcl.x86_64            2.4.0-2.rhel7.1                     @pgdg11  
postgresql11-test.x86_64           11.8-1PGDG.rhel7                    @pgdg11

# su - postgres
Last login: Wed Jan 15 18:34:12 CST 2020 on pts/0
$
$
$ psql -c "select version();"
                                                 version                                                 
---------------------------------------------------------------------------------------------------------
 PostgreSQL 11.8 on x86_64-pc-linux-gnu, compiled by gcc (GCC) 4.8.5 20150623 (Red Hat 4.8.5-39), 64-bit
(1 row)

n1,n2,n3 节点创建测试相关

Slony-I depends on the databases having the pl/pgSQL procedural language

# su - postgres
$ psql
psql (11.8)
Type "help" for help.

postgres=# \l
                                  List of databases
   Name    |  Owner   | Encoding |   Collate   |    Ctype    |   Access privileges   
-----------+----------+----------+-------------+-------------+-----------------------
 postgres  | postgres | UTF8     | en_US.UTF-8 | en_US.UTF-8 | 
 template0 | postgres | UTF8     | en_US.UTF-8 | en_US.UTF-8 | =c/postgres          +
           |          |          |             |             | postgres=CTc/postgres
 template1 | postgres | UTF8     | en_US.UTF-8 | en_US.UTF-8 | =c/postgres          +
           |          |          |             |             | postgres=CTc/postgres
(3 rows)

postgres=# \du
                                   List of roles
 Role name |                         Attributes                         | Member of 
-----------+------------------------------------------------------------+-----------
 postgres  | Superuser, Create role, Create DB, Replication, Bypass RLS | {}


创建 yewu 用户,yewudb 数据库,测试表

postgres=# create user yewu with password 'yewuyewu';

postgres=# create database yewudb with owner=yewu;

postgres=# \l
                                  List of databases
   Name    |  Owner   | Encoding |   Collate   |    Ctype    |   Access privileges   
-----------+----------+----------+-------------+-------------+-----------------------
 postgres  | postgres | UTF8     | en_US.UTF-8 | en_US.UTF-8 | 
 template0 | postgres | UTF8     | en_US.UTF-8 | en_US.UTF-8 | =c/postgres          +
           |          |          |             |             | postgres=CTc/postgres
 template1 | postgres | UTF8     | en_US.UTF-8 | en_US.UTF-8 | =c/postgres          +
           |          |          |             |             | postgres=CTc/postgres
 yewudb    | yewu     | UTF8     | en_US.UTF-8 | en_US.UTF-8 | 
(4 rows)

Slony-I depends on the databases having the pl/pgSQL procedural language

postgres=# \c yewudb

yewudb=> select * from pg_language ;
 lanname  | lanowner | lanispl | lanpltrusted | lanplcallfoid | laninline | lanvalidator | lanacl 
----------+----------+---------+--------------+---------------+-----------+--------------+--------
 internal |       10 | f       | f            |             0 |         0 |         2246 | 
 c        |       10 | f       | f            |             0 |         0 |         2247 | 
 sql      |       10 | f       | t            |             0 |         0 |         2248 | 
 plpgsql  |       10 | t       | t            |         13868 |     13869 |        13870 | 
(4 rows)

表必须要有主键

yewudb=> create table tmp_t0(c0 int8 primary key,c1 varchar(100));

n1,n2 节点创建 slony 用户

秉承功能用户与业务用户分离的原则,slony 最小权限可以参考 https://www.slony.info/documentation/2.2/security.html

postgres=# \c yewudb
yewudb=# create user slony with password 'slonyslony';
grant select on public.tmp_t0 to slony;
alter user slony with superuser;

配置 slony

先配置 n1,n2节点

# su - postgres
$ ls -l /usr/pgsql-11/bin/sl*
-rwxr-xr-x 1 root root 496208 Jun 10 17:10 /usr/pgsql-11/bin/slon
-rwxr-xr-x 1 root root 315976 Jun 10 17:10 /usr/pgsql-11/bin/slonik
-rwxr-xr-x 1 root root 176736 Jun 10 17:10 /usr/pgsql-11/bin/slony_logshipper

n1 节点(master 节点) 初始化脚本

# su - postgres
$ vi slon_init.sh

#!/bin/sh

slonik <<_EOF_
	#--
	cluster name = slony_example;

	#--
	node 1 admin conninfo = 'dbname=yewudb host=192.168.56.111 port=5432 user=slony password=slonyslony';
	node 2 admin conninfo = 'dbname=yewudb host=192.168.56.112 port=5432 user=slony password=slonyslony';

	# init the first node.  This creates the schema
	init cluster ( id=1, comment = 'Master Node');
 
	#--
	create set (id=1, origin=1, comment='slony tables');
	set add table (set id=1, origin=1, id=1, fully qualified name = 'public.tmp_t0', comment='tmp_t0');

	#--
	store node (id=2, comment = 'Slave node n2', event node=1);
	store path (server = 1, client = 2, conninfo='dbname=yewudb host=192.168.56.111 port=5432 user=slony password=slonyslony');
	store path (server = 2, client = 1, conninfo='dbname=yewudb host=192.168.56.112 port=5432 user=slony password=slonyslony');
	
_EOF_

执行初始化脚本

$ slon_init.sh

n1 节点(master 节点) 所有订阅脚本

# su - postgres
$ vi slon_subs.sh

#!/bin/sh

slonik <<_EOF_
	#--
	cluster name = slony_example;

	#--
	node 1 admin conninfo = 'dbname=yewudb host=192.168.56.111 port=5432 user=slony password=slonyslony';
	node 2 admin conninfo = 'dbname=yewudb host=192.168.56.112 port=5432 user=slony password=slonyslony';

	# subscribe
	subscribe set ( id = 1, provider = 1, receiver = 2, forward = no);

_EOF_

执行订阅脚本,会前端运行,不停有日志输出

$ slon_subs.sh

waiting for events  (2,5000000001) only at (2,0) to be confirmed on node 1
waiting for events  (2,5000000001) only at (2,0) to be confirmed on node 1
waiting for events  (2,5000000001) only at (2,0) to be confirmed on node 1

n1 节点启动守护进程

# su - postgres
$ slon slony_example 'dbname=yewudb host=192.168.56.111 port=5432 user=slony password=slonyslony';

n2 节点启动守护进程

# su - postgres
$ slon slony_example 'dbname=yewudb host=192.168.56.112 port=5432 user=slony password=slonyslony';

验证 slony

n1 节点插入测试数据

$ psql -U yewu yewudb

yewudb=> insert into tmp_t0 select id,md5(id::varchar) from generate_series(1,10000) as id;

n2 节点验证

yewudb=# select count(1) from tmp_t0;
 count 
-------
 10000
(1 row)

再验证一下

n1 节点插入测试数据

$ psql -U yewu yewudb

yewudb=> insert into tmp_t0 select 99999,'this is slony test';

yewudb=> select count(1) from tmp_t0;
 count 
-------
 10001
(1 row)

n2 节点验证

yewudb=> select * from tmp_t0 where c0=99999;
  c0   |         c1         
-------+--------------------
 99999 | this is slony test
(1 row)

yewudb=> select count(1) from tmp_t0;
 count 
-------
 10001
(1 row)

查看表信息

slony 添加了触发器
n1 节点查看

yewudb=> \d+ tmp_t0
                                          Table "public.tmp_t0"
 Column |          Type          | Collation | Nullable | Default | Storage  | Stats target | Description 
--------+------------------------+-----------+----------+---------+----------+--------------+-------------
 c0     | bigint                 |           | not null |         | plain    |              | 
 c1     | character varying(100) |           |          |         | extended |              | 
Indexes:
    "tmp_t0_pkey" PRIMARY KEY, btree (c0)
Triggers:
    _slony_example_logtrigger AFTER INSERT OR DELETE OR UPDATE ON tmp_t0 FOR EACH ROW EXECUTE PROCEDURE _slony_example.logtrigger('_slony_example', '1', 'k')
    _slony_example_truncatetrigger BEFORE TRUNCATE ON tmp_t0 FOR EACH STATEMENT EXECUTE PROCEDURE _slony_example.log_truncate('1')
Disabled user triggers:
    _slony_example_denyaccess BEFORE INSERT OR DELETE OR UPDATE ON tmp_t0 FOR EACH ROW EXECUTE PROCEDURE _slony_example.denyaccess('_slony_example')
    _slony_example_truncatedeny BEFORE TRUNCATE ON tmp_t0 FOR EACH STATEMENT EXECUTE PROCEDURE _slony_example.deny_truncate()

n2 节点查看

yewudb=> \d+ tmp_t0;
                                          Table "public.tmp_t0"
 Column |          Type          | Collation | Nullable | Default | Storage  | Stats target | Description 
--------+------------------------+-----------+----------+---------+----------+--------------+-------------
 c0     | bigint                 |           | not null |         | plain    |              | 
 c1     | character varying(100) |           |          |         | extended |              | 
Indexes:
    "tmp_t0_pkey" PRIMARY KEY, btree (c0)
Triggers:
    _slony_example_denyaccess BEFORE INSERT OR DELETE OR UPDATE ON tmp_t0 FOR EACH ROW EXECUTE PROCEDURE _slony_example.denyaccess('_slony_example')
    _slony_example_truncatedeny BEFORE TRUNCATE ON tmp_t0 FOR EACH STATEMENT EXECUTE PROCEDURE _slony_example.deny_truncate()
Disabled user triggers:
    _slony_example_logtrigger AFTER INSERT OR DELETE OR UPDATE ON tmp_t0 FOR EACH ROW EXECUTE PROCEDURE _slony_example.logtrigger('_slony_example', '1', 'k')
    _slony_example_truncatetrigger BEFORE TRUNCATE ON tmp_t0 FOR EACH STATEMENT EXECUTE PROCEDURE _slony_example.log_truncate('1')

参考:
http://slony.info/
https://www.slony.info/documentation/2.2/index.html
https://www.slony.info/documentation/2.2/tutorial.html

 类似资料: