Mouhamadou Diaw

In this blog I am going share a history of PostgreSQL migration and upgrade from 9.2 to 9.6. Let me first explain the context
We have a PostgreSQL environment with following characteristics. Note that real database name, server name are changed for security reason
Host: CentOS release 6.4
PostgreSQL version: 9.2
Database size : 9Tb


postgres=# select version();
version
---------------------------------------------------------------------------------------------------
------------
PostgreSQL 9.2.4 on x86_64-unknown-linux-gnu, compiled by gcc (GCC) 4.1.2 20080704 (Red Hat 4.1.2-
52), 64-bit
(1 row)
postgres=#


postgres=# select pg_size_pretty(pg_database_size('zoulou'));
pg_size_pretty
----------------
9937 GB
(1 row)

The problem is that we were just on limit about space in the actual server and we plan to move the database in a new server and after to upgrade to 9.6 version.

The questions we had to answer were following:

Do we keep the same Linux version?
How do we transfer data to the new server? pgdump, , pg_basebackup, using cp to copy of datafiles…
What is the fastest way to upgrade 9T of data?

Finally we decide

To use Debian instead of Centos. Why, because the sysadmin prefers Debian
We can summarize the two environments by following picture.

schema

To transfer data to the new server server2 we decide to use rsync. The reason was that the export and the import will take a long time. So while database is running we launch following rsync command on server1.
rsync -av -P --bwlimit=30720 /opt/PostgreSQL/9.2/data/* server2:/u02/pgdata/zoulou/

The bandwidth was reduced because people are complaining about network. The rsync with database running takes 3 days to finish, yes 3 days. And few days after we ask a downtime to stop the cluster to rsync the delta. Indeed as you may know it’s necessary to have a coherent copy to be able to start the cluster. Note that the copy of the delta lasts 2 hours.

Now it’s time to install the 2 versions of PostgreSQL (9.2.4 and 9.6.2) on the new server. We will show here just the main steps.

With apt-get we install the required packages

apt-get install libldap2-dev libpython-dev libreadline-dev libssl-dev bison flex libghc-zlib-dev libcrypto++-dev libxml2-dev libxslt1-dev tcl tclcl-dev bzip2 wget screen ksh libpam0g-dev libperl-dev make unzip libpam0g-dev tcl-dev python

One first important thing is to use the same options than the source for PostgreSQL installation. We use the pg_config command in the source server to retrieve these options. The installation of 9.2 is described below (9.6.2 install is the same)

PGHOME=/u01/app/postgres/product/92/db_4
SEGSIZE=1
BLOCKSIZE=8
WALSEGSIZE=16


./configure --prefix=${PGHOME} \
--exec-prefix=${PGHOME} \
--bindir=${PGHOME}/bin \
--libdir=${PGHOME}/lib \
--sysconfdir=${PGHOME}/etc \
--includedir=${PGHOME}/include \
--datarootdir=${PGHOME}/share \
--datadir=${PGHOME}/share \
--with-pgport=5432 \
--with-perl \
--with-python \
--with-tcl \
--with-openssl \
--with-pam \
--with-ldap \
--with-libxml \
--with-libxslt \
--with-segsize=${SEGSIZE} \
--with-blocksize=${BLOCKSIZE} \
--with-wal-segsize=${WALSEGSIZE}


make world
make install
cd contrib/
make install
cd ../doc/
make install

Now that data are copied and PostgreSQL softwares installed, we can start on server2 the 9.2 cluster.

/u01/app/postgres/product/92/bin/pg_ctl -D /u02/pgdata/zoulou/

Note that the first attempt failed due to local variables. On the source the system is using en_US.UTF8 and on the new server the system is using ch_FR.UTF-8. So we change local values using this command
# dpkg-reconfigure locales

Once the cluster 9.2 started without errors we can now think about the upgrade. With a database size of 9T to upgrade, we decide to use the –link option. Indeed this option uses link instead of copying files to new cluster. This will definitively speedup the upgrade process. While speeding up the upgrade, with this method, if the upgrade fails you cannot restart the old cluster on the same server.

The first step for the upgrade is to initialize a new 9.6.2 cluster on the new server server2

/u01/app/postgres/product/96/db_2/bin/initdb --pgdata=/u02/pgdata/zoulou962/ --xlogdir=/u03/ZOULOU962/pg_xlog/ --pwprompt --auth=md5
The files belonging to this database system will be owned by user "postgres".
This user must also own the server process.
The database cluster will be initialized with locale "en_US.UTF-8".
The default database encoding has accordingly been set to "UTF8".
The default text search configuration will be set to "english".
Data page checksums are disabled.
Enter new superuser password:
Enter it again:
fixing permissions on existing directory /u02/pgdata/zoulou962 ... ok
fixing permissions on existing directory /u03/zoulou962/pg_xlog ... ok
creating subdirectories ... ok
selecting default max_connections ... 100
selecting default shared_buffers ... 128MB
selecting dynamic shared memory implementation ... posix
creating configuration files ... ok
running bootstrap script ... ok
performing post-bootstrap initialization ... ok
syncing data to disk ... ok
Success. You can now start the database server using:
/u01/app/postgres/product/96/db_2/bin/pg_ctl -D /u02/pgdata/zoulou962/ -l logfile start

We copy configuration files of the 9.2 cluster to the 9.6 cluster


mv postgresql.conf postgresql.conf_origin
mv pg_hba.conf pg_hba.conf_origin
cp ../zoulou962/postgresql.conf .
cp ../zoulou962/pg_hba.conf .

After we stop the 9.2 cluster on the new server

which pg_ctl
/u01/app/postgres/product/92/db_4/bin/pg_ctl
postgres@apsicpap01:~$ pg_ctl stop
waiting for server to shut down.... done
server stopped

Once the 9.2 cluster stopped we run the pg_upgrade command with the –c option.
The option –c checks clusters only, don’t change any data.


u01/app/postgres/product/96/db_2/bin/pg_upgrade -d /u02/pgdata/zoulou/ -D /u02/pgdata/zoulou962/ -b /u01/app/postgres/product/92/db_4/bin/ -B /u01/app/postgres/product/96/db_2/bin/ -c
Performing Consistency Checks
-----------------------------
Checking cluster versions ok
Checking database user is the install user ok
Checking database connection settings ok
Checking for prepared transactions ok
Checking for reg* system OID user data types ok
Checking for contrib/isn with bigint-passing mismatch ok
Checking for roles starting with 'pg_' ok
Checking for invalid "line" user columns ok
Checking for presence of required libraries ok
Checking database user is the install user ok
Checking for prepared transactions ok
*Clusters are compatible*

And now we are ready to upgrade with the –link option. I was surprised how fast the upgrade was. Yes we upgrade 9T of database in less than 3 minutes. Incredible this –link option.

/u01/app/postgres/product/96/db_2/bin/pg_upgrade -d /u02/pgdata/zoulou/ -D /u02/pgdata/zoulou962/ -b /u01/app/postgres/product/92/db_4/bin/ -B /u01/app/postgres/product/96/db_2/bin/ --link
Performing Consistency Checks
-----------------------------
Checking cluster versions ok
Checking database user is the install user ok
Checking database connection settings ok
Checking for prepared transactions ok
Checking for reg* system OID user data types ok
Checking for contrib/isn with bigint-passing mismatch ok
Checking for roles starting with 'pg_' ok
Checking for invalid "line" user columns ok
Creating dump of global objects ok
Creating dump of database schemas
.. ok
Checking for presence of required libraries ok
Checking database user is the install user ok
Checking for prepared transactions ok
..
If pg_upgrade fails after this point, you must re-initdb the
new cluster before continuing.
..
Performing Upgrade
------------------
Analyzing all rows in the new cluster ok
Freezing all rows on the new cluster ok
Deleting files from new pg_clog ok
Copying old pg_clog to new server ok
Setting next transaction ID and epoch for new cluster ok
Deleting files from new pg_multixact/offsets ok
Setting oldest multixact ID on new cluster ok
Resetting WAL archives ok
Setting frozenxid and minmxid counters in new cluster ok
Restoring global objects in the new cluster ok
Restoring database schemas in the new cluster
.. ok
Setting minmxid counter in new cluster ok
Adding ".old" suffix to old global/pg_control ok
..
If you want to start the old cluster, you will need to remove
the ".old" suffix from /u02/pgdata/zoulou/global/pg_control.old.
Because "link" mode was used, the old cluster cannot be safely
started once the new cluster has been started.
..
Linking user relation files
.. ok
Setting next OID for new cluster ok
Sync data directory to disk ok
Creating script to analyze new cluster ok
Creating script to delete old cluster ok
..
Upgrade Complete
----------------
Optimizer statistics are not transferred by pg_upgrade so,
once you start the new server, consider running:
./analyze_new_cluster.sh
..
Running this script will delete the old cluster's data files:
./delete_old_cluster.sh

We delete the old cluster
./delete_old_cluster.sh
And we start the new 9.6 cluster

pg_ctl start
2017-05-11 09:11:42 CEST LOG: redirecting log output to logging collector process
2017-05-11 09:11:42 CEST HINT: Future log output will appear in directory "/u99/zoulou962/pg_log".

We generate statistics

./analyze_new_cluster.sh
This script will generate minimal optimizer statistics rapidly
so your system is usable, and then gather statistics twice more
with increasing accuracy. When it is done, your system will
have the default level of optimizer statistics.
If you have used ALTER TABLE to modify the statistics target for
any tables, you might want to remove them and restore them after
running this script because they will delay fast statistics generation.
If you would like default statistics as quickly as possible, cancel
this script and run:
"/u01/app/postgres/product/96/db_2/bin/vacuumdb" --all --analyze-only
vacuumdb: processing database "zoulou": Generating minimal optimizer statistics (1 target)
vacuumdb: processing database "postgres": Generating minimal optimizer statistics (1 target)
vacuumdb: processing database "template1": Generating minimal optimizer statistics (1 target)
vacuumdb: processing database "zoulou": Generating medium optimizer statistics (10 targets)
vacuumdb: processing database "postgres": Generating medium optimizer statistics (10 targets)
vacuumdb: processing database "template1": Generating medium optimizer statistics (10 targets)
vacuumdb: processing database "zoulou": Generating default (full) optimizer statistics
vacuumdb: processing database "postgres": Generating default (full) optimizer statistics
vacuumdb: processing database "template1": Generating default (full) optimizer statistics
Done

And the last step is to verify size and db version

zoulou=# select version();
version
------------------------------------------------------------------------------------------
PostgreSQL 9.6.2 on x86_64-pc-linux-gnu, compiled by gcc (Debian 4.9.2-10) 4.9.2, 64-bit
(1 row)


zoulou=# select pg_size_pretty(pg_database_size('zoulou'));
pg_size_pretty
----------------
9937 GB
(1 row)
zoulou=#

Here is the end of the history. Hope that this can help for future migration and upgrade.