During upgrade, data that is stored in user-defined tablespaces is not copied to the new cluster; it stays in the same location in the file system but is copied into a subdirectory whose name reflects the version number of the new cluster.
e.g. PG_14_202107181
To manually relocate files that are stored in a tablespace after upgrading, move the files to the new location and update the symbolic links (located in the pg_tblspc
directory under your cluster's data directory) to point to the files.
Initial tablespace setting before upgrade:
edb=# select oid, * from pg_tablespace ;
oid | oid | spcname | spcowner | spcacl | spcoptions
1663 | 1663 | pg_default | 10 | |
1664 | 1664 | pg_global | 10 | |
29805 | 29805 | tblspc | 10 | |
(3 rows)
edb=# \q
[root@localhost ~]# ll /var/lib/edb/as13/data/pg_tblspc/
total 0
lrwxrwxrwx. 1 enterprisedb enterprisedb 14 May 11 21:18 29805 -> /tblspc/epas13
[root@localhost ~]# ll /tblspc/epas13/
total 0
drwx______. 3 enterprisedb enterprisedb 18 May 11 21:20 PG_13_202007201
edb=# \d+ test
Table "public.test"
Column | Type | Collation | Nullable | Default | Storage | Stats target | Description
id | integer | | | | plain | |
Tablespace: "tblspc"
Access method: heap
pg_upgrade from EPAS 13 to EPAS 14:
-bash-4.2$ /usr/edb/as14/bin/pg_upgrade -d /var/lib/edb/as13/data/ -D /var/lib/edb/as14/data/ -p 5447 -P 5444 -b /usr/edb/as13/bin/ -B /usr/edb/as14/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 system-defined composite types in user tables ok
Checking for reg* data types in user tables ok
Checking for contrib/isn with bigint-passing mismatch ok
Checking for user-defined encoding conversions ok
Checking for user-defined postfix operators 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*
-bash-4.2$ /usr/edb/as14/bin/pg_upgrade -d /var/lib/edb/as13/data/ -D /var/lib/edb/as14/data/ -p 5447 -P 5444 -b /usr/edb/as13/bin/ -B /usr/edb/as14/bin/
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 system-defined composite types in user tables ok
Checking for reg* data types in user tables ok
Checking for contrib/isn with bigint-passing mismatch ok
Checking for user-defined encoding conversions ok
Checking for user-defined postfix operators 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
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
Copying 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 notice
Your installation contains extensions that should be updated
with the ALTER EXTENSION command. The file
update_extensions.sql
when executed by psql by the database superuser will update
these extensions.
Upgrade Complete
Optimizer statistics are not transferred by pg_upgrade.
Once you start the new server, consider running:
/usr/edb/as14/bin/vacuumdb --all --analyze-in-stages
Running this script will delete the old cluster's data files:
./delete_old_cluster.sh
Case 1: You want the tablespace in same location as in previous version:
In v13, there is a non-default tablespace created under /tblspc/epas13.
[root@localhost ~]# ll /var/lib/edb/as13/data/pg_tblspc/
total 0
lrwxrwxrwx. 1 enterprisedb enterprisedb 14 May 11 21:18 29805 -> /tblspc/epas13
-4.2$
-bash-4.2$ ll /tblspc/epas13/
total 0
drwx___. 3 enterprisedb enterprisedb 18 May 11 21:20 PG_13_202007201 -- original tablespace directory
drwx___. 3 enterprisedb enterprisedb 18 May 11 21:30 PG_14_202107181 -- tablespace directory created after upgrade
In order to keep the same location for a tablespace in v14 as well, execute the below script which will remove the old cluster directory.
-bash-4.2$ cat delete_old_cluster.sh
#!/bin/sh
rm -rf '/var/lib/edb/as13/data'
rm -rf '/tblspc/epas13/PG_13_202007201'
We can start the database successfully after this step and will get the data in the tablespace.
edb=# \d+ test
Table "public.test"
Column | Type | Modifiers | Storage | Stats target | Description
id | integer | | plain | |
Tablespace: "tblspc"
edb=# select count(*) from test;
count
10000
(1 row)
Case 2: You want to change the location of a tablespace
Original tablespace name;location: tblspc; /tblspc/epas13
New tablespace name;location: tblspc; /tblspc/epas14
- Check the OID after starting new cluster
edb=# select oid, * from pg_tablespace ;
oid | oid | spcname | spcowner | spcacl | spcoptions
1663 | 1663 | pg_default | 10 | |
1664 | 1664 | pg_global | 10 | |
29805 | 29805 | tblspc | 10 | |
(3 rows)
edb=# \db+
List of tablespaces
Name | Owner | Location | Access privileges | Options | Size | Description
pg_default | enterprisedb | | | | 148 MB |
pg_global | enterprisedb | | | | 960 kB |
tblspc | enterprisedb | /tblspc/epas13 | | | 0 bytes |
(3 rows)
- Here, we can see that symbolic link 29805 which is OID of the tablespace and is a soft link to directory /tblspc/epas13 which contained the data in the original server setup.
[root@localhost ~]# ll /var/lib/edb/as14/data/pg_tblspc/
total 0
lrwxrwxrwx. 1 enterprisedb enterprisedb 14 May 11 21:30 16426 -> /tblspc/epas13
- Move or copy the PG_14* subdirectory from the old tablespace mount to the new one.
[root@localhost ~]# mkdir /tblspc/epas14
[root@localhost ~]# chown -R enterprisedb:enterprisedb /tblspc/epas14
[root@localhost ~]# su - enterprisedb
Last login: Wed May 11 21:29:14 PDT 2022 on pts/2
-bash-4.2$
-bash-4.2$ cd /tblspc/epas14
-bash-4.2$ cp -r /tblspc/epas13/PG_14_202107181/ /tblspc/epas14
-bash-4.2$ ll /tblspc/epas14
total 0
drwx______. 3 enterprisedb enterprisedb 18 May 11 21:48 PG_14_202107181
- Change the link in pg_tblspc to point to the new mount point
Navigate inside folder /var/lib/edb/as14/data/pg_tblspc, rename existing symbolic link to '*_old' and create link with same name (OID of the tablespace) to the data new directory:
-bash-4.2$ cd /var/lib/edb/as14/data/pg_tblspc/
-bash-4.2$ ll
total 0
lrwxrwxrwx. 1 enterprisedb enterprisedb 14 May 11 21:30 16426 -> /tblspc/epas13
-bash-4.2$ mv 16426 16426_old
-bash-4.2$ ln -s /tblspc/epas14 16426
-bash-4.2$ ls -lrth
total 0
lrwxrwxrwx. 1 enterprisedb enterprisedb 14 May 11 21:30 16426_old -> /tblspc/epas13
lrwxrwxrwx. 1 enterprisedb enterprisedb 14 May 11 21:49 16426 -> /tblspc/epas14
- Start the database server
[root@localhost Desktop]# systemctl start edb-as-14
You have new mail in /var/mail/root
Tablespace location has been successfully changed and the table is accessible:
[root@localhost Desktop]# /usr/edb/as14/bin/psql edb -U enterprisedb
psql (14.2.1, server 14.2.1)
Type "help" for help.
edb=# \db+
List of tablespaces
Name | Owner | Location | Access privileges | Options | Size | Description
pg_default | enterprisedb | | | | 155 MB |
pg_global | enterprisedb | | | | 1001 kB |
tblspc | enterprisedb | /tblspc/epas14 | | | 392 kB |
(3 rows)
edb=# select oid, * from pg_tablespace ;
oid | oid | spcname | spcowner | spcacl | spcoptions
1663 | 1663 | pg_default | 10 | |
1664 | 1664 | pg_global | 10 | |
16426 | 16426 | tblspc | 10 | |
(3 rows)
edb=# \d+ test
Table "public.test"
Column | Type | Collation | Nullable | Default | Storage | Compression | Stats target | Description
id | integer | | | | plain | | |
Tablespace: "tblspc"
Access method: heap
edb=# select count(*) from test;
count
10000
(1 row)