Physical Standby Vs Hot Standby

Some thoughts always come in mind about standby terminologies. Once, Someone has asked question about Physical Standby of Oracle10g.
Is Oracle10g Physical Standby a Hot Standby Or WarmStandby?
Till Oracle 10g, Physical Standby of Oracle is a standby which has two mode: 1. Managed Recovery Mode 2. Read Only Mode. It cannot be in both mode at same time.
If the standby is in recovery mode then, it’s a Warm Standby and when its read only mode then, then it’s lagging from Primary and would be able to response SELECT queries.
Either way, till Oracle 10g physical standby was not meeting the requirement of Hot Standby. It was playing the role of Warm Standby.
However, from Oracle 11g, Physical Standby can be Recovery mode and read only mode, both at the same time, which now fulfill the definition of Hot Standby. With the complexity of managing the Standby, licensing thing comes in Picture.
PG9.0 onwards, PostgreSQL now has Cold Standby, Warm Standby and Hot Standby, with zero cost. Community is making the PostgreSQL Technology more advance with new features.

Hot Standby in PostgreSQL 9.0:

As per definition of Hot Standby, its a method of redundancy in which primay and secondary (Backup Server) runs simultaneously. The data is mirrored to secondary so that both should contain identical data in real time. With this user, would be able to execute the Query against Database while secondary is in archive recovery mode.

This is what introduce in PG9.0. In-built Hot Standby.

PostgreSQL Community always try to make the things simpler as much as possible, same they have proven in Hot Standby Implementation.

Following are the steps of configuring Hot Standby:

1. Make sure following parameters are set in Configuration file, postgresql.conf of Primary:
wal_level = ‘hot_standby’archive_mode = onarchive_command = ‘cp %p /Library/PostgreSQL/9.0/data/archivelog/%f’

2. After setting the above parameters, Now take the hot backup of PG9.0 Instance. Steps of Hot Backup is simple:
a) Execute following command in Primary:

select pg_start_backup(‘Hot Standby Backup’);

b) Take the file system backup of PG 9.0 Data directory, as given below:


cp -r $PRIMARY/* $HTStandby/

c). Execute following command to stop the Hot Backup:

select pg_stop_backup();

3. After taking the Hot Backup and restoring it desired location, set following parameter in postgresql.conf file of Hot Standby:

hot_standby = on

4. Create a recovery.conf file in Hot Standby restore location and set the following parameters:

standby_mode = 'on'
restore_command = 'cp /Library/PostgreSQL/9.0/data/archivelog/%f %p'

5. Clean the pg_xlog and pg_xlog/archive_status directories of Hot Standby Data directory.
6. Remove the postmaster.pid file from Hot Standby Data Directory.
7. Now start the Instance using following command:

pg_ctl -D $HTStandby start

Now, hot standby is up and running.

Following are few snapshots (Primary Port is 5432 and Hot Standby Port 5433:

1. Here I have inserted one value in table “test” and created a new table test2 with some records:


2. Now on Standby Following is a snapshot:

pgAgent Configuration on Windows

Here are the steps which some one can use to configure the pgAgent. These steps are tested on my machine:

1. Login to system as test_user:

Please create a pgpass.conf file in test_user %APPDATA%\postgresql directory:

Entry for pgpass.conf should be as given below:

hostname:port:database:username:password

2. Connect to database as given below:

C:\”Program Files”\PostgresPlus\8.4\bin\psql.exe -U postgres

(Above command will also verify that pgpass.conf is used by the psql command or not)
3. After connecting to database, create plpgsql language as given below:

CREATE LANGUAGE plpgsql;

4. Now, run the pgagent.sql file.

5. Create pgAgent service, as given below:

pgagent.exe INSTALL pgAgent -u test_user -p test hostaddr=<host> dbname=<dbname> user=<username>

3. Start the created service using following command:

net start pgAgent

4. While Creating job, Please keep the output of following command in “Host Agent” field of “pgAgent Job” window:

select jagstation from pgagent.pga_jobagent;

Monitor PG WarmStandBy

While working with Database, some people have asked to write a Monitoring script for WarmStandby. Here is a script which can be use for it:

#!/bin/bash  
  
BIN=/opt/PostgresPlus/8.4SS/bin  
WARMDATA=/sata/data  
PSQL=$BIN/psql  
PRIM_HOST=primarserver.ic  
ST_LOGFILE=/usr/local/pgsql/pg_standby/standby.log  
STANDBYLOGLOC=/sata/backups/pg8.4/standby_wal  
echo -e ""  
echo -e "+-----------------------------------------------------------+"  
echo -e "|Finding the Minimum Recovery:                              |"  
echo -e "+-----------------------------------------------------------+"  
MINRECOV=`$BIN/pg_controldata $WARMDATA |grep 'Minimum recovery'|awk -F": " '{print $2}'|sed 's/ *//g'`  
MINRECOVWAL=`$PSQL -h  $PRIM_HOST -t -p 5432 -c "select  pg_xlogfile_name('$MINRECOV');"|sed 's/ *//g'`  
if [ -n $MINRECOVWAL ];then  
echo -e "|Minimum Recovery WAL file require: $MINRECOVWAL|"  
echo -e "+-----------------------------------------------------------+"  
fi  
ls -1 $STANDBYLOGLOC >/tmp/WAL.lis  
WALNUM=`cat -n /tmp/WAL.lis|grep $MINRECOVWAL|awk '{print $1}'`  
TOTALWAL=`ls -1 $STANDBYLOGLOC|wc -l`  
NOTAPWAL=`expr $TOTALWAL - $WALNUM`  
CURRENT_XLOG=`$PSQL -h $PRIM_HOST -t -p 5432 -c "select pg_xlogfile_name(pg_current_xlog_location());"|sed 's/ *//g'`  
if [ $NOTAPWAL -eq 0 ];then  
echo -e ""  
echo -e "+-----------------------------------------+"  
echo -e "|       WARM STANDBY is in SYNC           |"  
echo -e "+-----------------------------------------+"  
echo -e "|Current Status On Warm Standb:           |"  
echo -e "+-----------------------------------------+"  
echo -e "|All Archived WAL Restored on Warm Standby|"  
echo -e "+-----------------------------------------+"  
echo ""  
echo -e "+-------------------------------------------------+"  
echo -e "|Current Status On Production:                    |"  
echo -e "+-------------------------------------------------+"  
echo -e "|Current_XLOG of Primary: $CURRENT_XLOG|"  
echo -e "|Unarchived WAL SEGMENT: $CURRENT_XLOG |"  
echo -e "+-------------------------------------------------+"  
else  
echo -e "+-----------------------------------------------------+"  
echo -e "|WARM STANDBY IS NOT in Sync                          |"  
echo -e "+-----------------------------------------------------+"  
echo -e "|List of Archived WAL which has not been implemented: |"  
echo -e "+-----------------------------------------------------+"  
grep -A $NOTAPWAL $MINRECOVWAL /tmp/WAL.lis|grep -v $MINRECOVWAL|awk '{printf "|%s                             |\n",$1}'  
echo -e "+-----------------------------------------------------+"  
fi  

Above script will give you the following information:

+-----------------------------------------------------------+
|Finding the Minimum Recovery: |
+-----------------------------------------------------------+
|Minimum Recovery WAL file require: 000000010000015A00000071|
+-----------------------------------------------------------+

+-----------------------------------------+
| WARM STANDBY is in SYNC |
+-----------------------------------------+
|Current Status On Warm Standb: |
+-----------------------------------------+
|All Archived WAL Restored on Warm Standby|
+-----------------------------------------+

+-------------------------------------------------+
|Current Status On Production: |
+-------------------------------------------------+
|Current_XLOG of Primary: 000000010000015A00000072|
|Unarchived WAL SEGMENT: 000000010000015A00000072 |
+-------------------------------------------------+