Character collations determine the sort order and classification of characters. When creating a database with initdb, PostgreSQL normally sets the collation based on the operating system’s locale settings, but other special collations, such as “C,” “POSIX,” and “ucs_basic,” are available as alternatives.
On Linux systems, updates to glibc can bring changes to collation rules. Normally, these updates are small, but they can lead to index corruption and need attention when planning upgrades and updates. PostgreSQL can be configured to use collation rules from different sources. When updating PostgreSQL and the operating system you run PostgreSQL on, you need to be alerted for changes to collation rules.
This blog covers the pg_upgrade and lc_collate mismatch issues and solutions that might appear while running pg_upgrade.
pg_upgrade error for lc_collate
pg_upgrade check fails with the below error:
lc_collate values for database “postgres” do not match
Example:
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 | -bash-4.2$ /usr/pgsql-14/bin/pg_upgrade -b /usr/pgsql-12/bin/ -B /usr/pgsql-14/bin -c -d /var/lib/pgsql/12/data -D /var/lib/pgsql/14/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 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 incompatible polymorphic functions ok lc_collate values for database "postgres" do not match: old "C", new "en_US.utf8" Failure, exiting |
Here, the lc_collate/locale value might be different in the message depending on the environment setup.
The root cause of the pg_upgrade error
When the default collation of the old and new PostgreSQL databases does not match, the pg_upgrade consistency check will fail, and the message lc_collate values for the database “postgres” do not match.
Here is an example of a locale issue.
On source PostgreSQL version:
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 | postgres=# l List of databases Name | Owner | Encoding | Collate | Ctype | Access privileges -----------+----------+----------+---------+-------+----------------------- postgres | postgres | UTF8 | C | C | template0 | postgres | UTF8 | C | C | =c/postgres + | | | | | postgres=CTc/postgres template1 | postgres | UTF8 | C | C | =c/postgres + | | | | | postgres=CTc/postgres test | postgres | UTF8 | C | C | test1 | postgres | UTF8 | C | C | test2 | postgres | UTF8 | C | C | (6 rows) |
A problem appears if we install a new PostgreSQL version and initialize the data directory using initdb. The information from the OS will be used to set the locale.
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 | # sudo su - postgres -bash-4.2$ locale LANG=en_US.utf8 LC_CTYPE="en_US.utf8" LC_NUMERIC="en_US.utf8" LC_TIME="en_US.utf8" LC_COLLATE="en_US.utf8" LC_MONETARY="en_US.utf8" LC_MESSAGES="en_US.utf8" LC_PAPER="en_US.utf8" LC_NAME="en_US.utf8" LC_ADDRESS="en_US.utf8" LC_TELEPHONE="en_US.utf8" LC_MEASUREMENT="en_US.utf8" LC_IDENTIFICATION="en_US.utf8" LC_ALL= -bash-4.2$ /usr/pgsql-14/bin/initdb -D /var/lib/pgsql/14/data 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.utf8". The default database encoding has accordingly been set to "UTF8". The default text search configuration will be set to "english". While performing pg_upgrade consistency checks, there is a failure message for locale mismatch: -bash-4.2$ /usr/pgsql-14/bin/pg_upgrade -b /usr/pgsql-12/bin/ -B /usr/pgsql-14/bin -c -d /var/lib/pgsql/12/data -D /var/lib/pgsql/14/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 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 incompatible polymorphic functions ok lc_collate values for database "postgres" do not match: old "C", new "en_US.utf8" Failure, exiting -bash-4.2$ |
Solution
To fix this, reinitialized the new version of PGDATA Directory with the same –encoding and –locale as the original PostgreSQL cluster by explicitly specifying it as the command-line argument for initdb as shown in the below example.
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 | -bash-4.2$ rm -rf /var/lib/pgsql/14/data/* -bash-4.2$ /usr/pgsql-14/bin/initdb -D /var/lib/pgsql/14/data/ <strong>--encoding=UTF8 --locale=C</strong> 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 "C". The default text search configuration will be set to "english". Let’s try pg_upgrade check again, and it is working fine. -bash-4.2$ /usr/pgsql-14/bin/pg_upgrade -b /usr/pgsql-12/bin/ -B /usr/pgsql-14/bin -c -d /var/lib/pgsql/12/data -D /var/lib/pgsql/14/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 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 incompatible polymorphic functions 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$ |
Furthermore, there is no issue with pg_upgrade:
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 | -bash-4.2$ /usr/pgsql-14/bin/pg_upgrade -b /usr/pgsql-12/bin/ -B /usr/pgsql-14/bin -d /var/lib/pgsql/12/data -D /var/lib/pgsql/14/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 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 incompatible polymorphic functions 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 ok Upgrade Complete ---------------- Optimizer statistics are not transferred by pg_upgrade. Once you start the new server, consider running: /usr/pgsql-14/bin/vacuumdb --all --analyze-in-stages Running this script will delete the old cluster's data files: ./delete_old_cluster.sh -bash-4.2$ |
Start a new version of PostgreSQL, verify the encoding, and collate:
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 | -bash-4.2$ /usr/pgsql-14/bin/pg_ctl -D /var/lib/pgsql/14/data -l logfile start waiting for server to start.... done server started -bash-4.2$ psql psql (14.11) Type "help" for help. postgres=# l List of databases Name | Owner | <strong>Encoding </strong>| <strong>Collate</strong> | Ctype | Access privileges -----------+----------+----------+---------+-------+----------------------- postgres | postgres | UTF8 | C | C | template0 | postgres | UTF8 | C | C | =c/postgres + | | | | | postgres=CTc/postgres template1 | postgres | UTF8 | C | C | postgres=CTc/postgres+ | | | | | =c/postgres test | postgres | UTF8 | C | C | test1 | postgres | UTF8 | C | C | test2 | postgres | UTF8 | C | C | (6 rows) |
Encoding and collate look the same for all databases as it was in the old version of PostgreSQL.
Points to remember for pg_upgrade and lc_collate mismatch issues
- It is always preferable to explicitly mention the coalition to be used while initializing a data directory, avoiding leaving that to the system defaults.
- Binary collations (C/POSIX) are preferred over other collations because they stabilize the collation rules and avoid future troubles.
- Binary collation also has performance benefits in addition to collation stability.
Our services and software are designed to make running high-performance, highly available PostgreSQL in critical environments practically effortless, enhancing PostgreSQL with security, high availability, and performance features that are all certified and tested to work seamlessly together.
Learn Why Customers Choose Percona for PostgreSQL