Monitoring approach for Streaming Replication with Hot Standby in PostgreSQL 9.3.
The people using PostgreSQL and the Streaming Replication feature seem to ask many of the same questions:
1. How best to monitor Streaming Replication?
2. What is the best way to do that?
3. Are there alternatives, when monitoring on Standby, to using the pg_stat_replication view on Master?
4. How should I calculate replication lag-time, in seconds, minutes, etc.?
In light of these commonly asked questions, I thought a blog would help. The following are some methods I’ve found to be useful.
Monitoring is critical for large infrastructure deployments where you have Streaming Replication for:
1. Disaster recovery
2. Streaming Replication is for High Availability
3. Load balancing, when using Streaming Replication with Hot Standby
PostgreSQL has some building blocks for replication monitoring, and the following are some important functions and views which can be use for monitoring the replication:
1. pg_stat_replication view on master/primary server.
This view helps in monitoring the standby on Master. It gives you the following details:
e.g.:
2. pg_is_in_recovery() : Function which tells whether standby is still in recovery mode or not.
e.g.
3. pg_last_xlog_receive_location: Function which tells location of last transaction log which was streamed by Standby and also written on standby disk.
e.g.
4. pg_last_xlog_replay_location: Function which tells last transaction replayed during recovery process. e.g is given below:
5. pg_last_xact_replay_timestamp: This function tells about the time stamp of last transaction which was replayed during recovery. Below is an example:
Above are some important functions/views, which are already available in PostgreSQL for monitoring the streaming replication.
So, the logical next question is, “What’s the right way to monitor the Hot Standby with Streaming Replication on Standby Server?”
If you have Hot Standby with Streaming Replication, the following are the points you should monitor:
1. Check if your Hot Standby is in recovery mode or not:
For this you can use pg_is_in_recovery() function.
2.Check whether Streaming Replication is working or not.
And easy way of doing this is checking the pg_stat_replication view on Master/Primary. This view gives information only on master if Streaming Replication is working.
3. Check If Streaming Replication is not working and Hot standby is recovering from archived WAL file.
For this, either the DBA can use the PostgreSQL Log file to monitor it or utilize the following functions provided in PostgreSQL 9.3:
4. Check how far off is the Standby from Master.
There are two ways to monitor lag for Standby.
i. Lags in Bytes: For calculating lags in bytes, users can use the pg_stat_replication view on the master with the function pg_xlog_location_diff function. Below is an example:
which gives the lag in bytes.
ii. Calculating lags in Seconds. The following is SQL, which most people uses to find the lag in seconds:
Including the above into your repertoire can give you good monitoring for PostgreSQL.
I will in a future post include the script that can be used for monitoring the Hot Standby with PostgreSQL streaming replication.
1. How best to monitor Streaming Replication?
2. What is the best way to do that?
3. Are there alternatives, when monitoring on Standby, to using the pg_stat_replication view on Master?
4. How should I calculate replication lag-time, in seconds, minutes, etc.?
In light of these commonly asked questions, I thought a blog would help. The following are some methods I’ve found to be useful.
Monitoring is critical for large infrastructure deployments where you have Streaming Replication for:
1. Disaster recovery
2. Streaming Replication is for High Availability
3. Load balancing, when using Streaming Replication with Hot Standby
PostgreSQL has some building blocks for replication monitoring, and the following are some important functions and views which can be use for monitoring the replication:
1. pg_stat_replication view on master/primary server.
This view helps in monitoring the standby on Master. It gives you the following details:
pid: Process id of walsender process usesysid: OID of user which is used for Streaming replication. usename: Name of user which is used for Streaming replication application_name: Application name connected to master client_addr: Address of standby/streaming replication client_hostname: Hostname of standby. client_port: TCP port number on which standby communicating with WAL sender backend_start: Start time when SR connected to Master. state: Current WAL sender state i.e streaming sent_location: Last transaction location sent to standby. write_location: Last transaction written on disk at standby flush_location: Last transaction flush on disk at standby. replay_location: Last transaction flush on disk at standby. sync_priority: Priority of standby server being chosen as synchronous standby sync_state: Sync State of standby (is it async or synchronous).
e.g.:
postgres=# select * from pg_stat_replication ; -[ RECORD 1 ]----+--------------------------------- pid | 1114 usesysid | 16384 usename | repuser application_name | walreceiver client_addr | 172.17.0.3 client_hostname | client_port | 52444 backend_start | 15-MAY-14 19:54:05.535695 -04:00 state | streaming sent_location | 0/290044C0 write_location | 0/290044C0 flush_location | 0/290044C0 replay_location | 0/290044C0 sync_priority | 0 sync_state | async
2. pg_is_in_recovery() : Function which tells whether standby is still in recovery mode or not.
e.g.
postgres=# select pg_is_in_recovery(); pg_is_in_recovery ------------------- t (1 row)
3. pg_last_xlog_receive_location: Function which tells location of last transaction log which was streamed by Standby and also written on standby disk.
e.g.
postgres=# select pg_last_xlog_receive_location(); pg_last_xlog_receive_location ------------------------------- 0/29004560 (1 row)
4. pg_last_xlog_replay_location: Function which tells last transaction replayed during recovery process. e.g is given below:
postgres=# select pg_last_xlog_replay_location(); pg_last_xlog_replay_location ------------------------------ 0/29004560 (1 row)
5. pg_last_xact_replay_timestamp: This function tells about the time stamp of last transaction which was replayed during recovery. Below is an example:
postgres=# select pg_last_xact_replay_timestamp(); pg_last_xact_replay_timestamp ---------------------------------- 15-MAY-14 20:54:27.635591 -04:00 (1 row)
Above are some important functions/views, which are already available in PostgreSQL for monitoring the streaming replication.
So, the logical next question is, “What’s the right way to monitor the Hot Standby with Streaming Replication on Standby Server?”
If you have Hot Standby with Streaming Replication, the following are the points you should monitor:
1. Check if your Hot Standby is in recovery mode or not:
For this you can use pg_is_in_recovery() function.
2.Check whether Streaming Replication is working or not.
And easy way of doing this is checking the pg_stat_replication view on Master/Primary. This view gives information only on master if Streaming Replication is working.
3. Check If Streaming Replication is not working and Hot standby is recovering from archived WAL file.
For this, either the DBA can use the PostgreSQL Log file to monitor it or utilize the following functions provided in PostgreSQL 9.3:
pg_last_xlog_replay_location(); pg_last_xact_replay_timestamp();
4. Check how far off is the Standby from Master.
There are two ways to monitor lag for Standby.
i. Lags in Bytes: For calculating lags in bytes, users can use the pg_stat_replication view on the master with the function pg_xlog_location_diff function. Below is an example:
pg_xlog_location_diff(pg_stat_replication.sent_location, pg_stat_replication.replay_location)
which gives the lag in bytes.
ii. Calculating lags in Seconds. The following is SQL, which most people uses to find the lag in seconds:
SELECT CASE WHEN pg_last_xlog_receive_location() = pg_last_xlog_replay_location() THEN 0 ELSE EXTRACT (EPOCH FROM now() - pg_last_xact_replay_timestamp()) END AS log_delay;
Including the above into your repertoire can give you good monitoring for PostgreSQL.
I will in a future post include the script that can be used for monitoring the Hot Standby with PostgreSQL streaming replication.
Comments
Post a Comment