|
| 1 | +# Migrate data from PostgreSQL 14 to 16 |
| 2 | + |
| 3 | +There are two possible ways to migrate data from PostgreSQL 14 to 16 depending on how roles are managed: |
| 4 | + |
| 5 | +**In case of admin roles management**, all database objects ownership are handled manually by the user. In this case, see the more general guide {ref}`migrate-data-via-pg-dump`. Note that you must set `extra-user-roles` to `charmed-admin` once a Juju relation is requested the new database. |
| 6 | + |
| 7 | +**In the case of charm roles management**, all the database objects ownership will be handled by charm automatically. This guide covers how to migrate data from Charmed PostgreSQL 14 to 16 using the new charm roles management setup for client applications managed by Juju. The migrated data from PostgreSQL 14 will be mapped to the corresponding ownership in PostgreSQL 16. |
| 8 | + |
| 9 | +## Prepare PostgreSQL 14 data |
| 10 | + |
| 11 | +First, in order to make sure the latest data is included, remove the relation between the client app and Charmed PostgreSQL 14. |
| 12 | + |
| 13 | +Then, define the following variables for the old database: |
| 14 | + |
| 15 | +```shell |
| 16 | +TMP_PATH="~/old-db-dump/" |
| 17 | +OLD_DB_NAME="postgresql_test_app_database" |
| 18 | +OLD_IP="10.218.34.229" |
| 19 | +OLD_USER="operator" |
| 20 | +OLD_PASSWORD="fJQYljbthEo2T1gj" |
| 21 | +``` |
| 22 | + |
| 23 | +Create a dump of the old PostgreSQL 14 database with `pg_dump`: |
| 24 | + |
| 25 | +```shell |
| 26 | +mkdir -p "${TMP_PATH}" |
| 27 | +PGPASSWORD="${OLD_PASSWORD}" pg_dump -j 4 -Fd -h "${OLD_IP}" -U "${OLD_USER}" -d "${OLD_DB_NAME}" -f "${TMP_PATH}" --compress 9 |
| 28 | +``` |
| 29 | + |
| 30 | +## Set up new PostgreSQL 16 charm |
| 31 | + |
| 32 | +Deploy one unit of Charmed PostgreSQL 16. This will simplify the migration and can be scaled later. |
| 33 | + |
| 34 | +```shell |
| 35 | +juju deploy postgresql-k8s --channel 16/edge --trust |
| 36 | +``` |
| 37 | + |
| 38 | +Define the following variables for the new database: |
| 39 | + |
| 40 | +```shell |
| 41 | +NEW_DB_NAME="postgresql_test_app_database123" |
| 42 | +NEW_IP="10.218.34.56" |
| 43 | +NEW_USER="operator" |
| 44 | +NEW_PASSWORD="RnnijCiotVeW8O5I" |
| 45 | +NEW_OWNER="charmed_${NEW_DB_NAME}_owner" |
| 46 | +``` |
| 47 | + |
| 48 | +Migrate the following charm features from the old 14 charm to the new 16 charm: |
| 49 | +* any necessary charm config options |
| 50 | +* enabled charm extensions/plugins |
| 51 | + |
| 52 | +```{note} |
| 53 | +Config options and extensions *must* be migrated before restoring the data dump |
| 54 | +``` |
| 55 | + |
| 56 | +## Create a new database on PostgreSQL 16 |
| 57 | + |
| 58 | +```shell |
| 59 | +PGPASSWORD="${NEW_PASSWORD}" psql -h "${NEW_IP}" -U "${NEW_USER}" -d postgres -c "CREATE DATABASE ${NEW_DB_NAME}" |
| 60 | +``` |
| 61 | + |
| 62 | +Create new roles by running the function `set_up_predefined_catalog_roles()` in all databases except `postgres` and `template1`. It will create roles like `charmed_<database-name>_owner`, `..._dml` and others: |
| 63 | + |
| 64 | +```shell |
| 65 | +PGPASSWORD="${NEW_PASSWORD}" psql -h "${NEW_IP}" -U "${NEW_USER}" -d "${NEW_DB_NAME}" -c "SELECT set_up_predefined_catalog_roles();" |
| 66 | +PGPASSWORD="${NEW_PASSWORD}" psql -h "${NEW_IP}" -U "${NEW_USER}" -d "${NEW_DB_NAME}" -c "ALTER DATABASE ${NEW_DB_NAME} OWNER TO charmed_databases_owner;" |
| 67 | +PGPASSWORD="${NEW_PASSWORD}" psql -h "${NEW_IP}" -U "${NEW_USER}" -d "${NEW_DB_NAME}" -c "ALTER SCHEMA public OWNER TO ${NEW_OWNER};" |
| 68 | +``` |
| 69 | + |
| 70 | +## Migrate data from PostgreSQL 14 to 16 |
| 71 | + |
| 72 | +Restore the PostgreSQL 14 database dump into the new 16 database: |
| 73 | + |
| 74 | +```shell |
| 75 | +PGPASSWORD="${NEW_PASSWORD}" pg_restore -j 4 -h "${NEW_IP}" -U "${NEW_USER}" -d "${NEW_DB_NAME}" -Fd "${TMP_PATH}" --no-owner |
| 76 | +``` |
| 77 | + |
| 78 | +### Set up new database ownership |
| 79 | + |
| 80 | +Verify and modify the ownership for each database object in each schema to be equal to `charmed_<database-name>_owner` (`${NEW_OWNER}` above). |
| 81 | + |
| 82 | +For example, to find and fix ownership for all tables, sequences, and views: |
| 83 | + |
| 84 | +```shell |
| 85 | +PGPASSWORD="${NEW_PASSWORD}" psql -h "${NEW_IP}" -U "${NEW_USER}" -d "${NEW_DB_NAME}" |
| 86 | + |
| 87 | +mydb=> DO $$ |
| 88 | +DECLARE |
| 89 | + r record; |
| 90 | +BEGIN |
| 91 | + FOR r IN |
| 92 | + SELECT format('ALTER %s %I.%I OWNER TO %I;', |
| 93 | + CASE c.relkind |
| 94 | + WHEN 'r' THEN 'TABLE' |
| 95 | + WHEN 'v' THEN 'VIEW' |
| 96 | + WHEN 'm' THEN 'MATERIALIZED VIEW' |
| 97 | + WHEN 'S' THEN 'SEQUENCE' |
| 98 | + WHEN 'p' THEN 'TABLE' |
| 99 | + ELSE NULL END, |
| 100 | + n.nspname, c.relname, 'charmed_<database-name>_owner') |
| 101 | + FROM pg_class c |
| 102 | + JOIN pg_namespace n ON n.oid = c.relnamespace |
| 103 | + WHERE n.nspname = 'public' |
| 104 | + LOOP |
| 105 | + EXECUTE r.format; |
| 106 | + END LOOP; |
| 107 | +END$$; |
| 108 | +``` |
| 109 | + |
| 110 | +At this stage, the database has been completely imported. The cluster can be scaled, and the client app can be related to the new PostgreSQL 16 database. |
0 commit comments