When you want to upgrade from one major version of PostgreSQL to another you probably want to go with pg_upgrade (or logical replication). There are several modes of operations for this already:
- –copy: Copy the data files from the old to the new cluster
- –clone: Clone, instead of copying (when the file system supports it)
- –copy-file-range: Use the copy_file_range system call for efficient copying, if the file system supports it
- –link: Use hard links instead of copying files
What is best for you, depends on the requirements. We usually go with “–link” as this is pretty fast, but you can only do that if the old and the new cluster are in the same file system. The downside is, that you cannot anymore use the old cluster once the new cluster is started up.
With PostgreSQL 18 there will probably a new option called “–swap”. This mode, instead of linking or copying the files, moves the files from the old to the new cluster and then replaces the catalog files with the ones from the new cluster. The reason for this additional mode (see the link to the commit at the end of this post) is, that this might outperform even “–link” mode (and the others) when a cluster contains many relations.
Let’s see if we can prove this by creating two new PostgreSQL 17 clusters with many relations:
postgres@pgbox:/home/postgres/ [172] initdb --version
initdb (PostgreSQL) 17.2
postgres@pgbox:/home/postgres/ [172] initdb -D /var/tmp/dummy/17.2_1 --data-checksums
The files belonging to this database system will be owned by user "postgres".
This user must also own the server process.
...
Success. You can now start the database server using:
pg_ctl -D /var/tmp/17.2 -l logfile start
postgres@pgbox:/home/postgres/ [172] echo "port=8888" >> /var/tmp/dummy/17.2_1/postgresql.auto.conf
postgres@pgbox:/home/postgres/ [172] pg_ctl --pgdata=/var/tmp/dummy/17.2_1 start -l /dev/null
waiting for server to start.... done
server started
postgres@pgbox:/home/postgres/ [172] psql -p 8888 -l
List of databases
Name | Owner | Encoding | Locale Provider | Collate | Ctype | Locale | ICU Rules | Access privileges
-----------+----------+----------+-----------------+-------------+-------------+--------+-----------+-----------------------
postgres | postgres | UTF8 | libc | en_US.UTF-8 | en_US.UTF-8 | | |
template0 | postgres | UTF8 | libc | en_US.UTF-8 | en_US.UTF-8 | | | =c/postgres +
| | | | | | | | postgres=CTc/postgres
template1 | postgres | UTF8 | libc | en_US.UTF-8 | en_US.UTF-8 | | | =c/postgres +
| | | | | | | | postgres=CTc/postgres
(3 rows)
Here is a little script that creates some tables, indexes and a bit of data:
#!/bin/bash
for i in {1..10000}; do
psql -p 8888 -c "create table t${i} ( a int, b text )"
psql -p 8888 -c "insert into t${i} select i, i::text from generate_series(1,1000) i;"
psql -p 8888 -c "create index i${i} on t${i}(a);"
done
If we run that against the cluster we’ll have 10’000 tables (each containing 1000 rows) and 10’000 indexes. This should be sufficient “many relations” to do a quick test.
We create the second cluster by copying the first one:
postgres@pgbox:/home/postgres/ [172] mkdir /var/tmp/dummy/17.2_2/
postgres@pgbox:/home/postgres/ [172] pg_basebackup --port=8888 --pgdata=/var/tmp/dummy/17.2_2/ --checkpoint=fast
postgres@pgbox:/home/postgres/ [172] sed -i 's/8888/8889/g' /var/tmp/dummy/17.2_2/postgresql.auto.conf
Now, lets create two PostgreSQL 18 clusters we will be upgrading to. One of them we will upgrade with “–link” mode, the other with the new “–swap” mode (we’ll also stop the old cluster):
postgres@pgbox:/home/postgres/ [pgdev] initdb --version
initdb (PostgreSQL) 18devel
postgres@pgbox:/home/postgres/ [pgdev] initdb --pgdata=/var/tmp/dummy/18link
postgres@pgbox:/home/postgres/ [pgdev] initdb --pgdata=/var/tmp/dummy/18swap
postgres@pgbox:/home/postgres/ [pgdev] echo "port=9000" >> /var/tmp/dummy/18link/postgresql.auto.conf
postgres@pgbox:/home/postgres/ [pgdev] echo "port=9001" >> /var/tmp/dummy/18swap/postgresql.auto.conf
postgres@pgbox:/home/postgres/ [pgdev] pg_ctl --pgdata=/var/tmp/dummy/17.2_1/ stop
A quick check if all seems to be fine for the first upgrade:
postgres@pgbox:/home/postgres/ [pgdev] pg_upgrade --version
pg_upgrade (PostgreSQL) 18devel
postgres@pgbox:/home/postgres/ [pgdev] export PGDATAOLD=/var/tmp/dummy/17.2_1/
postgres@pgbox:/home/postgres/ [pgdev] export PGDATANEW=/var/tmp/dummy/18link/
postgres@pgbox:/home/postgres/ [pgdev] export PGBINOLD=/u01/app/postgres/product/17/db_2/bin
postgres@pgbox:/home/postgres/ [pgdev] export PGBINNEW=/u01/app/postgres/product/DEV/db_0/bin/
postgres@pgbox:/home/postgres/ [pgdev] pg_upgrade --check
Performing Consistency Checks
-----------------------------
Checking cluster versions ok
Checking database connection settings ok
Checking database user is the install user ok
Checking for prepared transactions ok
Checking for contrib/isn with bigint-passing mismatch ok
Checking for valid logical replication slots ok
Checking for subscription state ok
Checking data type usage ok
Checking for presence of required libraries ok
Checking database user is the install user ok
Checking for prepared transactions ok
Checking for new cluster tablespace directories ok
*Clusters are compatible*
Time for a test using the “–link” mode:
postgres@pgbox:/home/postgres/ [pgdev] time pg_upgrade --link
Performing Consistency Checks
-----------------------------
Checking cluster versions ok
Checking database connection settings ok
Checking database user is the install user ok
Checking for prepared transactions ok
Checking for contrib/isn with bigint-passing mismatch ok
Checking for valid logical replication slots ok
Checking for subscription state ok
Checking data type usage 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
Checking for new cluster tablespace directories ok
If pg_upgrade fails after this point, you must re-initdb the
new cluster before continuing.
Performing Upgrade
------------------
Setting locale and encoding for new cluster ok
Analyzing all rows in the new cluster ok
Freezing all rows in the new cluster ok
Deleting files from new pg_xact ok
Copying old pg_xact to new server ok
Setting oldest XID for new cluster ok
Setting next transaction ID and epoch for new cluster ok
Deleting files from new pg_multixact/offsets ok
Copying old pg_multixact/offsets to new server ok
Deleting files from new pg_multixact/members ok
Copying old pg_multixact/members to new server ok
Setting next multixact ID and offset for 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
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 /var/tmp/dummy/17.2_1/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 delete old cluster ok
Checking for extension updates ok
Upgrade Complete
----------------
Some optimizer statistics may not have been transferred by pg_upgrade.
Once you start the new server, consider running:
/u01/app/postgres/product/DEV/db_0/bin/vacuumdb --all --analyze-in-stages --missing-stats-only
Running this script will delete the old cluster's data files:
./delete_old_cluster.sh
real 0m13.776s
user 0m0.654s
sys 0m1.536s
Let’s do the same test with the new “swap” mode:
postgres@pgbox:/home/postgres/ [pgdev] export PGDATAOLD=/var/tmp/dummy/17.2_2/
postgres@pgbox:/home/postgres/ [pgdev] export PGDATANEW=/var/tmp/dummy/18swap/
postgres@pgbox:/home/postgres/ [pgdev] export PGBINOLD=/u01/app/postgres/product/17/db_2/bin
postgres@pgbox:/home/postgres/ [pgdev] export PGBINNEW=/u01/app/postgres/product/DEV/db_0/
postgres@pgbox:/home/postgres/ [pgdev] pg_upgrade --check
Performing Consistency Checks
-----------------------------
Checking cluster versions ok
Checking database connection settings ok
Checking database user is the install user ok
Checking for prepared transactions ok
Checking for contrib/isn with bigint-passing mismatch ok
Checking for valid logical replication slots ok
Checking for subscription state ok
Checking data type usage ok
Checking for presence of required libraries ok
Checking database user is the install user ok
Checking for prepared transactions ok
Checking for new cluster tablespace directories ok
*Clusters are compatible*
postgres@pgbox:/home/postgres/ [pgdev] time pg_upgrade --swap
Performing Consistency Checks
-----------------------------
Checking cluster versions ok
Checking database connection settings ok
Checking database user is the install user ok
Checking for prepared transactions ok
Checking for contrib/isn with bigint-passing mismatch ok
Checking for valid logical replication slots ok
Checking for subscription state ok
Checking data type usage 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
Checking for new cluster tablespace directories ok
If pg_upgrade fails after this point, you must re-initdb the
new cluster before continuing.
Performing Upgrade
------------------
Setting locale and encoding for new cluster ok
Analyzing all rows in the new cluster ok
Freezing all rows in the new cluster ok
Deleting files from new pg_xact ok
Copying old pg_xact to new server ok
Setting oldest XID for new cluster ok
Setting next transaction ID and epoch for new cluster ok
Deleting files from new pg_multixact/offsets ok
Copying old pg_multixact/offsets to new server ok
Deleting files from new pg_multixact/members ok
Copying old pg_multixact/members to new server ok
Setting next multixact ID and offset for 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
Adding ".old" suffix to old global/pg_control ok
Because "swap" mode was used, the old cluster can no longer be
safely started.
Swapping data directories
ok
Setting next OID for new cluster ok
Sync data directory to disk ok
Creating script to delete old cluster ok
Checking for extension updates ok
Upgrade Complete
----------------
Some optimizer statistics may not have been transferred by pg_upgrade.
Once you start the new server, consider running:
/u01/app/postgres/product/DEV/db_0/bin/vacuumdb --all --analyze-in-stages --missing-stats-only
Running this script will delete the old cluster's data files:
./delete_old_cluster.sh
real 0m11.426s
user 0m0.600s
sys 0m0.659s
This was around 2 seconds faster, not much, but at least faster. Of course this was a very simple test case and this further needs to be tested further. Please also note the warning in the output:
Because "swap" mode was used, the old cluster can no longer be
safely started.
Swapping data directories
This is a consequence of using this mode. Thanks to all involved, details here.