Best of Both Worlds: Integrating Pgpool with EDB Postgres Failover Manager

 

EDB Postgres Failover Manager (EFM) is a high availability module from EnterpriseDB (EDB) that monitors the health of Postgres clusters and verifies failures quickly. Should one occur, EFM can automatically promote a Standby node to Master to ensure continued performance and protect against data loss.

Among EDB customers, virtually all of them use EDB Postgres Failover Manager in production within their high availability infrastructures, often alongside other solutions. EDB, in fact, developed EFM with hooks and parameters to ease the tool’s integration with external systems and other software.

One such piece of software is Pgpool, the open source middleware that sits between the database clients and the Postgres server. The Pgpool module helps in connection pooling and load balancing of SELECT queries on multiple standbys in EDB Postgres clusters. EDB has also invested resources in Pgpool development and supports multiple engineers whose work advances and maintains the tool.

A commonly asked question is how best to integrate the two tools because of the benefits they both provide. In the event an EDB Postgres Master fails and EFM promotes a Standby, DBAs would also like to be able to update the Pgpool about the new Master.

The following are the steps for automating the Pgpool update should EFM execute a Master failover:

On Pgpool server:

  1. Disable the auto-failover of Pgpool by modifying the following parameter in pgpool conf:
backend_flag = 'DISALLOW_TO_FAILOVER'

The above parameter is important in order to avoid a split-brain situation between Pgpool and EFM for Postgres Failover/switchover.

For more information, please refer the following link:

http://www.pgpool.net/docs/latest/en/html/runtime-config-backend-settings.html#RUNTIME-CONFIG-BACKEND-CONNECTION-SETTINGS

  1. Configure the conf.

For more information on PCP settings, please use the following link:

http://www.pgpool.net/docs/latest/en/html/pcp-commands.html

On EDB Postgres database nodes:

  1. Install the Pgpool binaries.

Pgpool binaries come with PCP commands. Users can use the PCP command to notify pgpool about new master through EFM

  1. The following is a sample script which uses the PCP command to notify Pgpool about the new master:
#!/bin/bash

###################################################################################
#title           : EFM fencing script for updating pgpool
#description     : This script executes pcp commands. Therefore pcp & pgpool 
#                : should be available on the server
#author          : Vibhor Kumar (vibhor.aim@gmail.com).
#date            : Jan 5 2018
#version         : 1.0
#notes           : Install Vim and Emacs to use this script.
#                : configure the pcppass file for EFM user and set 
#                : the password correctly
#bash_version    : GNU bash, version 4.2.46(2)-release (x86_64-redhat-linux-gnu)
###################################################################################
# quit on any error
set -e
# verify any  undefined shell variables
set -u

###################################################################################
# Code for notifiying pgpool for promote the standby
###################################################################################

NEW_PRIMARY=$1                              # argument from EFM fencing hook
PCP_USER=enterprisedb                       # PCP user name
PCP_PORT=9051                               # PCP port number as in pgpool.conf
PCP_HOST=pgpool                             # hostname of Pgpool-II  
PGPOOL_PATH=/usr/edb/pgpool3.6              # Pgpool-II installation path
PCPPASSFILE=/var/efm/pcppass                # Path to PCPPASS file

PCP_NODE_COUNT=${PGPOOL_PATH}/bin/pcp_node_count
PCP_NODE_INFO=${PGPOOL_PATH}/bin/pcp_node_info
PCP_PROMOTE=${PGPOOL_PATH}/bin/pcp_promote_node
 
export PCPPASSFILE PCP_USER PCP_PORT PGPOOL_PATH \
       PCP_PROMOTE PCP_NODE_INFO PCP_NODE_COUNT

###################################################################################
# find the number of nodes and search for node-id of NEW_PRIMARY
###################################################################################
NO_OF_NODES=$(${PCP_NODE_COUNT} --host=${PCP_HOST} \
                      --username=${PCP_USER} \
                      --port=${PCP_PORT} \
                      --no-password )

for (( i=0 ; i < ${NO_OF_NODES} ; i++ ))
do
   exists=$(${PCP_NODE_INFO} --host=${PCP_HOST} \
                    --username=${PCP_USER} \
                    --port=${PCP_PORT} \
                    --no-password ${i} |grep ${NEW_PRIMARY}|wc -l)
   if [[ ${exists} -eq 1 ]]; then
      NODE_ID=${i}
      break
   fi
done

###################################################################################
# Promote the specific node id using PCP command
###################################################################################
if [[ ! -z ${NODE_ID} ]]; then
    ${PCP_PROMOTE} --host=${PCP_HOST} \
                   --username=${PCP_USER} \
                   --port=${PCP_PORT} \
                   --no-password \
                   --verbose \
                   ${NODE_ID}
fi
exit 0
  1. Modify the following parameters in properties file of EDB Postgres Servers (Master and Standby):
script.fence=/usr/efm-2.1/bin/efm_pgpool_notify %p

Please note the above script only covers the failover scenario of an EDB Postgres cluster. However, the above script can be extended to cover a switchover use case too.

Let’s have a look at how it works in an environment:

  1. Connect to the Pgpool server and verify the nodes:
[root@master /]# psql -h pgpool
psql.bin (9.6.6.11)
Type "help" for help.

edb=# show pool_nodes;
 node_id | hostname | port | status | lb_weight |  role   | select_cnt | load_balance_node | replication_delay 
---------+----------+------+--------+-----------+---------+------------+-------------------+-------------------
 0       | master   | 5444 | up     | 0.500000  | primary | 13         | true              | 0
 1       | standby  | 5444 | up     | 0.500000  | standby | 19         | false             | 0
(2 rows)

Above output shows that we have Master and Standby EDB Postgres nodes and both are up and running.

  1. Connect to the EDB Postgres nodes and check the status of EFM. The following is a snapshot:
[root@master /]# /usr/efm-2.1/bin/efm cluster-status efm
Cluster Status: efm
VIP: 

    Agent Type  Address              Agent  DB       Info
    --------------------------------------------------------------
    Witness     pgpool               UP     N/A       
    Standby     standby              UP     UP        
    Master      master               UP     UP        

Allowed node host list:
    master pgpool standby

Membership coordinator: master

Standby priority host list:
    standby

Promote Status:

    DB Type     Address              XLog Loc         Info
    --------------------------------------------------------------
    Master      master               0/E0001E0        
    Standby     standby              0/E0001E0        

    Standby database(s) in sync with master. It is safe to promote.
    1. Perform a failover as shown below:
/usr/efm-2.1/bin/efm promote efm
Promote/switchover command accepted by local agent. Proceeding with promotion and will reconfigure original master. Run the 'cluster-status' command for information about the new cluster state.
  1. Connect to Pgpool node and verify the status of the EDB Postgres nodes:
[root@master /]# psql -h pgpool
psql.bin (9.6.6.11)
Type "help" for help.

edb=# show pool_nodes;
 node_id | hostname | port | status | lb_weight |  role   | select_cnt | load_balance_node | replication_delay 
---------+----------+------+--------+-----------+---------+------------+-------------------+-------------------
 0       | master   | 5444 | down   | 0.500000  | standby | 13         | false             | 0
 1       | standby  | 5444 | up     | 0.500000  | primary | 20         | true              | 0
(2 rows)

The above shows that the Master server which was primary is now down and the Standby is promoted to primary.

Switchover/Switchback in PostgreSQL 9.3

PostgreSQL 9.3 has two key software updates making switchover/switchback easier in High Availability configurations.

First, let’s address the software patches and their descriptions:
1. First patch was committed by Fujii Masao.
Patch commit# 985bd7d49726c9f178558491d31a570d47340459

With this patch, the walsender process tries to send all outstanding WAL records to the standby in replication when the user shuts down the master.

This means:
a. All WAL records are synced between two servers after the clean shutdown of the master
b. After promoting the standby to new master, the user can restart the stopped master as new standby without a fresh backup from new master.

2. Second patch was committed by Heikki Linnakangas in PostgreSQL 9.3.
Patch commit# abfd192b1b5ba5216ac4b1f31dcd553106304b19

Before PostgreSQL version 9.3, streaming replication used to stop replicating if the timeline on the primary didn’t match the standby. This generally happens when the user promotes one of the standbys to become the new master. Promoting a standby always results in an increment of timeline ID and after that increment, other standbys will refuse to continue replicating.

With this patch in PostgreSQL 9.3, the standby asks the primary for any timeline history files that are missing from the standby when it connects – if the standby recovery.conf file has the following setting:
recovery_target_timeline=’latest’

The missing files are sent using a new replication command TIMELINE_HISTORY, and stored in the standby’s pg_xlog directory. Using the timeline history files, the standby can follow the latest timeline present in the primary, just as it can follow new timelines appearing in an archive WAL directory.

Because of above patches, if the user performs the following sequence of steps then switchover/switchback can be easily achieved:
To switchover from Master to Standby, use following steps:
On Master:
1. Use any one of following stop options for clean shutdown.

    pg_ctl stop --pgdata=data_dire --mode=fast
    or
    pg_ctl stop --pgdata=data_directory --mode=smart
    

2. Before promoting standby:

Make sure all WAL send by Master applied on Standby. Use following functions to verify it:
    * pg_last_xlog_receive_location()
    * pg_last_xlog_replay_location()

3. Have the proper archive location and archive_command setting accessible to old Master.

Following is a presentation I delivered at a recent BPUG Meet (Boston PostgreSQL User Group) to discuss switchover/switchback.