В каталог /usr/local/pgsql-9.4/data установлен PostgreSQL версии 9.4.
student$ /usr/local/pgsql-9.4/bin/psql
=> SELECT version();
version ---------------------------------------------------------------------------------------------------------------- PostgreSQL 9.4.8 on i686-pc-linux-gnu, compiled by gcc (Ubuntu 5.4.0-6ubuntu1~16.04.10) 5.4.0 20160609, 32-bit (1 row)
Создадим табличное пространство и базу данных.
postgres$ rm -rf /home/postgres/ts_dir
postgres$ mkdir /home/postgres/ts_dir
=> CREATE TABLESPACE ts LOCATION '/home/postgres/ts_dir';
CREATE TABLESPACE
=> CREATE DATABASE admin_upgrade;
CREATE DATABASE
=> \c admin_upgrade
You are now connected to database "admin_upgrade" as user "postgres".
Создадим таблицу.
=> CREATE TABLE test(id serial, s text) TABLESPACE ts;
CREATE TABLE
=> INSERT INTO test(s) VALUES ('Привет от 9.4!');
INSERT 0 1
Установим расширение.
student$ sudo make -C /home/student/postgresql-9.4.8/contrib/pgcrypto install | tail
make: Entering directory '/home/student/postgresql-9.4.8/contrib/pgcrypto' /bin/mkdir -p '/usr/local/pgsql-9.4/lib' /bin/mkdir -p '/usr/local/pgsql-9.4/share/extension' /bin/mkdir -p '/usr/local/pgsql-9.4/share/extension' /usr/bin/install -c -m 755 pgcrypto.so '/usr/local/pgsql-9.4/lib/pgcrypto.so' /usr/bin/install -c -m 644 pgcrypto.control '/usr/local/pgsql-9.4/share/extension/' /usr/bin/install -c -m 644 pgcrypto--1.1.sql pgcrypto--1.0--1.1.sql pgcrypto--unpackaged--1.0.sql '/usr/local/pgsql-9.4/share/extension/' make: Leaving directory '/home/student/postgresql-9.4.8/contrib/pgcrypto'
=> CREATE EXTENSION pgcrypto;
CREATE EXTENSION
=> \dx pgcrypto
List of installed extensions Name | Version | Schema | Description ----------+---------+--------+------------------------- pgcrypto | 1.1 | public | cryptographic functions (1 row)
На этом останавливаем систему.
=> \q
postgres$ /usr/local/pgsql-9.4/bin/pg_ctl -w -D /usr/local/pgsql-9.4/data stop
waiting for server to shut down.... done server stopped
PostgreSQL версии 10 собран, но еще не установлен. Каталог данных - /usr/local/pgsql-10/data.
Обратите внимание, что версии не пересекаются по путям. Если бы новую версию надо было установить в каталог старой версии, старую пришлось бы переместить в другое место. Это можно сделать, просто перенеся каталог командой mv, но при запуске может потребоваться указать путь к библиотекам в переменной окружения LD_LIBRARY_PATH.
Установим исполняемые файлы новой версии.
student$ sudo make -C /home/student/postgresql-10.6/ install | tail
/usr/bin/install -c -m 644 ./nls-global.mk '/usr/local/pgsql-10/lib/pgxs/src/nls-global.mk' make[1]: Leaving directory '/home/student/postgresql-10.6/src' make -C config install make[1]: Entering directory '/home/student/postgresql-10.6/config' /bin/mkdir -p '/usr/local/pgsql-10/lib/pgxs/config' /usr/bin/install -c -m 755 ./install-sh '/usr/local/pgsql-10/lib/pgxs/config/install-sh' /usr/bin/install -c -m 755 ./missing '/usr/local/pgsql-10/lib/pgxs/config/missing' make[1]: Leaving directory '/home/student/postgresql-10.6/config' PostgreSQL installation complete. make: Leaving directory '/home/student/postgresql-10.6'
Попробуем запустить новую систему со старым кластером.
postgres$ /usr/local/pgsql-10/bin/pg_ctl -w -l /home/postgres/logfile-10 -D /usr/local/pgsql-9.4/data start
waiting for server to start.... stopped waiting pg_ctl: could not start server Examine the log output.
Сервер не запустился: основные версии не совместимы.
postgres$ tail -n 2 /home/postgres/logfile-10
2019-08-12 17:18:17.033 MSK [20121] FATAL: database files are incompatible with server 2019-08-12 17:18:17.033 MSK [20121] DETAIL: The data directory was initialized by PostgreSQL version 9.4, which is not compatible with this version 10.6.
Инициализируем кластер нового сервера.
student$ sudo mkdir /usr/local/pgsql-10/data
student$ sudo chown postgres /usr/local/pgsql-10/data
postgres$ /usr/local/pgsql-10/bin/initdb -D /usr/local/pgsql-10/data --locale=ru_RU.utf8 --lc-messages=en_US.utf8 -k
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 locales COLLATE: ru_RU.utf8 CTYPE: ru_RU.utf8 MESSAGES: en_US.utf8 MONETARY: ru_RU.utf8 NUMERIC: ru_RU.utf8 TIME: ru_RU.utf8 The default database encoding has accordingly been set to "UTF8". The default text search configuration will be set to "russian". Data page checksums are enabled. fixing permissions on existing directory /usr/local/pgsql-10/data ... 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 WARNING: enabling "trust" authentication for local connections You can change this by editing pg_hba.conf or using the option -A, or --auth-local and --auth-host, the next time you run initdb. Success. You can now start the database server using: /usr/local/pgsql-10/bin/pg_ctl -D /usr/local/pgsql-10/data -l logfile start
Убедимся, что сервер работает и выключим его после этого.
postgres$ /usr/local/pgsql-10/bin/pg_ctl -w -l /home/postgres/logfile-10 -D /usr/local/pgsql-10/data start
waiting for server to start.... done server started
student$ /usr/local/pgsql-10/bin/psql
=> SELECT version();
version --------------------------------------------------------------------------------------------------------------- PostgreSQL 10.6 on i686-pc-linux-gnu, compiled by gcc (Ubuntu 5.4.0-6ubuntu1~16.04.10) 5.4.0 20160609, 32-bit (1 row)
=> \q
postgres$ /usr/local/pgsql-10/bin/pg_ctl -w -D /usr/local/pgsql-10/data stop
waiting for server to shut down.... done server stopped
Попробуем запустить pg_upgrade в режиме проверки.
Мы должны указать пути к исполняемым файлам и к каталогу данных как для старой версии, так и для новой. Обратите внимание, что программа запускается от имени пользователя ОС postgres, так как ей требуется доступ к каталогам данных.
postgres$ /usr/local/pgsql-10/bin/pg_upgrade --check --link -b /usr/local/pgsql-9.4/bin/ -B /usr/local/pgsql-10/bin/ -d /usr/local/pgsql-9.4/data -D /usr/local/pgsql-10/data
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* data types in user tables ok Checking for contrib/isn with bigint-passing mismatch ok Checking for invalid "unknown" user columns ok Checking for hash indexes ok Checking for roles starting with "pg_" ok Checking for presence of required libraries fatal Your installation references loadable libraries that are missing from the new installation. You can add these libraries to the new installation, or remove the functions using them from the old installation. A list of problem libraries is in the file: loadable_libraries.txt Failure, exiting
Утилита обнаружила проблему: в новом кластере не хватает библиотек.
Посмотрим список:
postgres$ cat loadable_libraries.txt
could not load library "$libdir/pgcrypto": ERROR: could not access file "$libdir/pgcrypto": No such file or directory
Это библиотека установленного нами расширения. Ее необходимо установить и в новом кластере.
student$ sudo make -C /home/student/postgresql-10.6/contrib/pgcrypto install | tail
make: Entering directory '/home/student/postgresql-10.6/contrib/pgcrypto' /bin/mkdir -p '/usr/local/pgsql-10/lib' /bin/mkdir -p '/usr/local/pgsql-10/share/extension' /bin/mkdir -p '/usr/local/pgsql-10/share/extension' /usr/bin/install -c -m 755 pgcrypto.so '/usr/local/pgsql-10/lib/pgcrypto.so' /usr/bin/install -c -m 644 ./pgcrypto.control '/usr/local/pgsql-10/share/extension/' /usr/bin/install -c -m 644 ./pgcrypto--1.3.sql ./pgcrypto--1.2--1.3.sql ./pgcrypto--1.1--1.2.sql ./pgcrypto--1.0--1.1.sql ./pgcrypto--unpackaged--1.0.sql '/usr/local/pgsql-10/share/extension/' make: Leaving directory '/home/student/postgresql-10.6/contrib/pgcrypto'
Проверяем еще раз.
postgres$ /usr/local/pgsql-10/bin/pg_upgrade --check --link -b /usr/local/pgsql-9.4/bin/ -B /usr/local/pgsql-10/bin/ -d /usr/local/pgsql-9.4/data -D /usr/local/pgsql-10/data
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* data types in user tables ok Checking for contrib/isn with bigint-passing mismatch ok Checking for invalid "unknown" user columns ok Checking for hash indexes ok Checking for roles starting with "pg_" ok Checking for presence of required libraries ok Checking database user is the install user ok Checking for prepared transactions ok *Clusters are compatible*
Теперь кластеры совместимы, обновление возможно.
Выполняем обновление в режиме создания ссылок.
postgres$ /usr/local/pgsql-10/bin/pg_upgrade --link -b /usr/local/pgsql-9.4/bin/ -B /usr/local/pgsql-10/bin/ -d /usr/local/pgsql-9.4/data -D /usr/local/pgsql-10/data
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* data types in user tables ok Checking for contrib/isn with bigint-passing mismatch ok Checking for invalid "unknown" user columns ok Checking for roles starting with "pg_" ok Creating dump of global objects ok Creating dump of database schemas admin_upgrade postgres template1 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 in the new cluster ok Deleting files from new pg_xact 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 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 admin_upgrade postgres template1 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 /usr/local/pgsql-9.4/data/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 /usr/local/pgsql-9.4/data/base/16385/12135 /usr/local/pgsql-9.4/data/base/16385/12137 /usr/local/pgsql-9.4/data/base/16385/11997 /usr/local/pgsql-9.4/data/base/16385/11999 /home/postgres/ts_dir/PG_9.4_201409291/16385/16388 /home/postgres/ts_dir/PG_9.4_201409291/16385/16392 /home/postgres/ts_dir/PG_9.4_201409291/16385/16394 /usr/local/pgsql-9.4/data/base/12178/12135 /usr/local/pgsql-9.4/data/base/12178/12137 /usr/local/pgsql-9.4/data/base/12178/11997 /usr/local/pgsql-9.4/data/base/12178/11999 /usr/local/pgsql-9.4/data/base/1/12135 /usr/local/pgsql-9.4/data/base/1/12137 /usr/local/pgsql-9.4/data/base/1/11997 /usr/local/pgsql-9.4/data/base/1/11999 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 Checking for hash indexes 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
Перед запуском сервера следовало бы перенести изменения, сделанные в конфигурационных файлах старого сервера, на новый. Мы не будем этого делать, поскольку работаем с настройками по умолчанию.
Итак, проверим результат.
postgres$ /usr/local/pgsql-10/bin/pg_ctl -w -l /home/postgres/logfile-10 -D /usr/local/pgsql-10/data start
waiting for server to start.... done server started
student$ /usr/local/pgsql-10/bin/psql
=> SELECT version();
version --------------------------------------------------------------------------------------------------------------- PostgreSQL 10.6 on i686-pc-linux-gnu, compiled by gcc (Ubuntu 5.4.0-6ubuntu1~16.04.10) 5.4.0 20160609, 32-bit (1 row)
=> \c admin_upgrade
You are now connected to database "admin_upgrade" as user "postgres".
=> SELECT * FROM test;
id | s ----+---------------- 1 | Привет от 9.4! (1 row)
Обновление успешно: нам доступно содержимое старого кластера.
Посмотрим на табличное пространство:
postgres$ tree /home/postgres/ts_dir --inodes
/home/postgres/ts_dir ├── [1073954] PG_10_201707211 │ └── [1074289] 16401 │ ├── [1073942] 16388 │ ├── [1073943] 16392 │ └── [1073944] 16394 └── [1072711] PG_9.4_201409291 └── [1073941] 16385 ├── [1073942] 16388 ├── [1073943] 16392 └── [1073944] 16394 4 directories, 6 files
Библиотеки установленных расширений заменяются при установке нового кластера, но с точки зрения SQL версия расширения остается без изменений:
=> \dx pgcrypto
List of installed extensions Name | Version | Schema | Description ----------+---------+--------+------------------------- pgcrypto | 1.1 | public | cryptographic functions (1 row)
Поэтому после обновления все расширения необходимо обновить.
=> ALTER EXTENSION pgcrypto UPDATE;
ALTER EXTENSION
=> \dx pgcrypto
List of installed extensions Name | Version | Schema | Description ----------+---------+--------+------------------------- pgcrypto | 1.3 | public | cryptographic functions (1 row)
Также сама утилита pg_upgrade сгенерировала два скрипта.
Один - для поэтапного сбора статистики:
postgres$ cat analyze_new_cluster.sh
#!/bin/sh echo 'This script will generate minimal optimizer statistics rapidly' echo 'so your system is usable, and then gather statistics twice more' echo 'with increasing accuracy. When it is done, your system will' echo 'have the default level of optimizer statistics.' echo echo 'If you have used ALTER TABLE to modify the statistics target for' echo 'any tables, you might want to remove them and restore them after' echo 'running this script because they will delay fast statistics generation.' echo echo 'If you would like default statistics as quickly as possible, cancel' echo 'this script and run:' echo ' "/usr/local/pgsql-10/bin/vacuumdb" --all --analyze-only' echo "/usr/local/pgsql-10/bin/vacuumdb" --all --analyze-in-stages echo echo 'Done'
Второй - для удаления старых данных:
postgres$ cat delete_old_cluster.sh
#!/bin/sh rm -rf '/usr/local/pgsql-9.4/data' rm -rf '/home/postgres/ts_dir/PG_9.4_201409291'
Конец демонстрации.