• PG大小版本升级步骤


    版本介绍

    当前PostgreSQL版本号由主要版本号和小版本号组成。例如,在版本号10.1中,10是主要版本号,1是小要版本号,这意味着这将是主要版本10的第一个小版本。对于PostgreSQL版本10.0之前的版本,版本号由三个数字组成,例如9.5.3。在这些情况下,主要版本由版本号的前两位数组组成,例如9.5,而小版本是第三个数字,例如3,这意味着这将是主要版本9.5的第三个小版本。
    小版本不会更改内部存储格式,并且始终与相同主要版本号的早期和后续小版本兼容。例如,版本10.1与版本10.0和版本10.6兼容。同样的9.5.3与9.5.0、9.5.1和9.5.6兼容。要在兼容版本之间进行更新,只需在数据库服务关闭时更换可执行文件并重新启动服务器即可。数据目录保持不变-小版本升级就这么简单。
    以上信息为pg社区官方说明,但在实际的生产环境中,升级前需要详细的阅读各版本的release说明,比如在pg10.19升级至pg10.20的版本介绍中,为了解决一项inde-only扫描的bug,在升级完成后需要手动重建btree索引。
    https://blog.csdn.net/jnrjian/article/details/129831160

    小版本升级

    升级原因

    等保扫描出许多漏洞

    升级步骤归纳

    根据PG社区提供的说明,pg小版本升级只需在停止数据库服务后覆盖安装bin目录下的可执行命令即可,但在实际的操作过程中,推荐读者首先阅读个版本的升级说明,看是否有一些升级后续的操作事宜。pg小版本升级在具体的生产环境中的过程主要分为以下两种场景:
    场景一、数据库的安装目录、数据目录未包含版本号,如/usr/local/pgsql/bin /usr/local/pgsql/data
    在这种场景下,只需要规划新的安装路径,编译安装好新版本数据库,停止旧版本数据库服务后,将新版本数据库的bin目录内的文件copy到/usr/local/pgsql/bin下覆盖,启动数据库即可。如果设置了pg的开机自启服务,pg的开机自启服务文件也不需要修改。
    场景二、数据库的安装目录、数据目录均包含版本号,如/usr/local/pg14.2/bin /usr/local/pg14.2/data
    在这种情景下,编译安装新版本数据库,停止旧版本数据库,将旧版本数据库的数据目录移动到新装的数据库的对应路径,启动该数据库即可。此种场景下需要修改环境变量信息,另外如果设置了pg的开机自启服务,还需要修改对应的service文件,防止开机自启服务失效。

    升级示例

    环境信息

    升级要求:pg14.2升级至pg14.9

    |
    | PG版本 | PG安装目录 | PG数据目录 | 操作系统版本 |
    | — | — | — | — | — |
    | 升级前 | 14.2 | /pgdb/pgsql | /pgdb/data | Centos7.6 x86_64 |
    | 升级后 | 14.9 | /pgdb/pg14.9 | /pgdb/data | Centos7.6 x86_64 |

    构建测试数据

    生产环境可忽略

    psql
    create database fuwa;
    \c fuwa postgres
    create table tbl_batch2 (id int4,info text); 
    insert into tbl_batch2(id,info) 
    select generate_series(1,5),'batch2'; 
    select * from tbl_batch2;
    
    • 1
    • 2
    • 3
    • 4
    • 5
    • 6
    • 7
    环境变量
    [postgres@localhost ~]$ cat .bash_profile
    # .bash_profile
    
    # Get the aliases and functions
    if [ -f ~/.bashrc ]; then
    	. ~/.bashrc
    fi
    
    # User specific environment and startup programs
    
    PATH=$PATH:$HOME/.local/bin:$HOME/bin
    
    #export PATH
    #add by postgres
    export PGHOME=/pgdb/pgsql
    export PGDATA=/pgdb/data
    export PATH=$PGHOME/bin:$PATH
    export MANPATH=$PGHOME/share/man:$MANPATH
    export LD_LIBRARY_PATH=$PGHOME/lib:$LD_LIBRARY_PATH
    export LANG=en_US.UTF-8
    export DATE=`date +"%Y%m%d%H%M"`
    export PGPORT=5439
    
    • 1
    • 2
    • 3
    • 4
    • 5
    • 6
    • 7
    • 8
    • 9
    • 10
    • 11
    • 12
    • 13
    • 14
    • 15
    • 16
    • 17
    • 18
    • 19
    • 20
    • 21
    • 22
    升级前数据库信息统计
    --查看数据库列表
    postgres=# \l+
                                                                        List of databases
       Name    |  Owner   | Encoding |   Collate   |    Ctype    |   Access privileges   |  Size   | Tablespace |                Description                
     
    -----------+----------+----------+-------------+-------------+-----------------------+---------+------------+-------------------------------------------
    -
     fuwa      | postgres | UTF8     | en_US.UTF-8 | en_US.UTF-8 |                       | 8553 kB | pg_default | 
     postgres  | postgres | UTF8     | en_US.UTF-8 | en_US.UTF-8 |                       | 8625 kB | pg_default | default administrative connection database
     template0 | postgres | UTF8     | en_US.UTF-8 | en_US.UTF-8 | =c/postgres          +| 8385 kB | pg_default | unmodifiable empty database
               |          |          |             |             | postgres=CTc/postgres |         |            | 
     template1 | postgres | UTF8     | en_US.UTF-8 | en_US.UTF-8 | =c/postgres          +| 8385 kB | pg_default | default template for new databases
               |          |          |             |             | postgres=CTc/postgres |         |            | 
    (4 rows)
    
    --查看已安装的扩展
    postgres=# \dx
                      List of installed extensions
       Name   | Version |   Schema   |         Description          
    ----------+---------+------------+------------------------------
     plpgsql  | 1.0     | pg_catalog | PL/pgSQL procedural language
     walminer | 3.0     | public     | analyse wal to SQL
    (2 rows)
    
    --查看对象类型和个数统计
    SELECT
    	nsp.nspname AS SchemaName,
    CASE
    		cls.relkind 
    		WHEN 'r' THEN
    		'TABLE' 
    		WHEN 'm' THEN
    		'MATERIALIZED_VIEW' 
    		WHEN 'i' THEN
    		'INDEX' 
    		WHEN 'S' THEN
    		'SEQUENCE' 
    		WHEN 'v' THEN
    		'VIEW' 
    		WHEN 'c' THEN
    		'composite type' 
    		WHEN 't' THEN
    		'TOAST' 
    		WHEN 'f' THEN
    		'foreign table' 
    		WHEN 'p' THEN
    		'partitioned_table' 
    		WHEN 'I' THEN
    		'partitioned_index' ELSE cls.relkind :: TEXT 
    	END AS ObjectType,
    	COUNT ( * ) cnt 
    FROM
    	pg_class cls
    	JOIN pg_namespace nsp ON nsp.oid = cls.relnamespace 
    WHERE
    	nsp.nspname NOT IN ( 'information_schema', 'pg_catalog' ) 
    	AND nsp.nspname NOT LIKE'pg_toast%' 
    GROUP BY
    	nsp.nspname,
    	cls.relkind UNION ALL
    SELECT
    	n.nspname AS "Schema",
    CASE
    		P.prokind 
    		WHEN 'a' THEN
    		'agg' 
    		WHEN 'w' THEN
    		'window' 
    		WHEN 'p' THEN
    		'proc' ELSE'func' 
    	END AS "Type",
    	COUNT ( * ) cnt 
    FROM
    	pg_catalog.pg_proc
    	P LEFT JOIN pg_catalog.pg_namespace n ON n.oid = P.pronamespace 
    WHERE
    	pg_catalog.pg_function_is_visible ( P.oid ) 
    	AND n.nspname NOT IN ( 'information_schema', 'pg_catalog' ) 
    GROUP BY
    	n.nspname,
    	P.prokind;
    
    
    --查看表记录数
    select relname as TABLE_NAME, reltuples as rowCounts from pg_class 
    where relkind = 'r' and relnamespace = (select oid from pg_namespace where nspname='public') 
    order by rowCounts desc
    
    
    • 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
    升级过程
    编译安装pg14.9
    --解压
    [root@localhost ~]# tar -xvf postgresql-14.9.tar.gz
    
    --编译安装
    [root@localhost ~]# ./configure --prefix=/pgdb/pg14.9 --with-pgport=5439 --with-openssl --with-perl --with-python --with-readline --with-libxml --with-libxslt
    [root@localhost ~]# gmake world -j 4 && gmake install-world -j 4
    
    --修改属主属组为postgres
    [root@localhost ~]# chown -R postgres:postgres /pgdb/pg14.9/
    
    • 1
    • 2
    • 3
    • 4
    • 5
    • 6
    • 7
    • 8
    • 9

    报错的解决版本参考下文问题部分

    停止数据库

    如果磁盘空间允许,建议安装目录和数据目录备份,确保极端情况下可以回退;若磁盘空间不允许建议异地留存备份。

    --停止pg14.2数据库  老家目录下停止
    [postgres@localhost ~]$ /pgdb/pgsql/bin/pg_ctl stop -D /pgdb/data
    
    • 1
    • 2
    修改环境变量
    --修改环境变量信息
    [postgres@localhost ~]$ vi .bash_profile
    #add by postgres
    #old directory   #注释掉老目录
    #export PGHOME=/pgdb/pgsql
    #new directory  #增加新目录
    export PGHOME=/pgdb/pg14.9
    export PGDATA=/pgdb/data
    export PATH=$PGHOME/bin:$PATH
    export MANPATH=$PGHOME/share/man:$MANPATH
    export LD_LIBRARY_PATH=$PGHOME/lib:$LD_LIBRARY_PATH
    export LANG=en_US.UTF-8
    export DATE=`date +"%Y%m%d%H%M"`
    export PGPORT=5439
    
    [postgres@localhost ~]$ source .bash_profile
    
    [postgres@localhost ~]$ echo $PGHOME  #务必确保新家目录
    /pgdb/pg14.9
    
    • 1
    • 2
    • 3
    • 4
    • 5
    • 6
    • 7
    • 8
    • 9
    • 10
    • 11
    • 12
    • 13
    • 14
    • 15
    • 16
    • 17
    • 18
    • 19
    启动数据库
    --启动数据
    [postgres@localhost ~]$ pg_ctl start -D /pgdb/data/
    
    • 1
    • 2
    核对版本信息、数据库数据
    --核对版本信息、数据库数据
    [postgres@localhost ~]$ psql
    psql (14.9)
    Type "help" for help.
    
    postgres=# select version();
                                                     version                                                 
    ---------------------------------------------------------------------------------------------------------
     PostgreSQL 14.9 on x86_64-pc-linux-gnu, compiled by gcc (GCC) 4.8.5 20150623 (Red Hat 4.8.5-44), 64-bit
    (1 row)
    
    postgres=# \l+
                                                                        List of databases
       Name    |  Owner   | Encoding |   Collate   |    Ctype    |   Access privileges   |  Size   | Tablespace |                Description                
     
    -----------+----------+----------+-------------+-------------+-----------------------+---------+------------+-------------------------------------------
     fuwa      | postgres | UTF8     | en_US.UTF-8 | en_US.UTF-8 |                       | 8553 kB | pg_default | 
     postgres  | postgres | UTF8     | en_US.UTF-8 | en_US.UTF-8 |                       | 8625 kB | pg_default | default administrative connection database
     template0 | postgres | UTF8     | en_US.UTF-8 | en_US.UTF-8 | =c/postgres          +| 8385 kB | pg_default | unmodifiable empty database
               |          |          |             |             | postgres=CTc/postgres |         |            | 
     template1 | postgres | UTF8     | en_US.UTF-8 | en_US.UTF-8 | =c/postgres          +| 8385 kB | pg_default | default template for new databases
               |          |          |             |             | postgres=CTc/postgres |         |            | 
    (3 rows)
    
    --查看已安装的扩展
    postgres=# \dx
                      List of installed extensions
       Name   | Version |   Schema   |         Description          
    ----------+---------+------------+------------------------------
     plpgsql  | 1.0     | pg_catalog | PL/pgSQL procedural language
     walminer | 3.0     | public     | analyse wal to SQL
    (2 rows)
    
    --查看对象类型和个数统计
    SELECT
    	nsp.nspname AS SchemaName,
    CASE
    		cls.relkind 
    		WHEN 'r' THEN
    		'TABLE' 
    		WHEN 'm' THEN
    		'MATERIALIZED_VIEW' 
    		WHEN 'i' THEN
    		'INDEX' 
    		WHEN 'S' THEN
    		'SEQUENCE' 
    		WHEN 'v' THEN
    		'VIEW' 
    		WHEN 'c' THEN
    		'composite type' 
    		WHEN 't' THEN
    		'TOAST' 
    		WHEN 'f' THEN
    		'foreign table' 
    		WHEN 'p' THEN
    		'partitioned_table' 
    		WHEN 'I' THEN
    		'partitioned_index' ELSE cls.relkind :: TEXT 
    	END AS ObjectType,
    	COUNT ( * ) cnt 
    FROM
    	pg_class cls
    	JOIN pg_namespace nsp ON nsp.oid = cls.relnamespace 
    WHERE
    	nsp.nspname NOT IN ( 'information_schema', 'pg_catalog' ) 
    	AND nsp.nspname NOT LIKE'pg_toast%' 
    GROUP BY
    	nsp.nspname,
    	cls.relkind UNION ALL
    SELECT
    	n.nspname AS "Schema",
    CASE
    		P.prokind 
    		WHEN 'a' THEN
    		'agg' 
    		WHEN 'w' THEN
    		'window' 
    		WHEN 'p' THEN
    		'proc' ELSE'func' 
    	END AS "Type",
    	COUNT ( * ) cnt 
    FROM
    	pg_catalog.pg_proc
    	P LEFT JOIN pg_catalog.pg_namespace n ON n.oid = P.pronamespace 
    WHERE
    	pg_catalog.pg_function_is_visible ( P.oid ) 
    	AND n.nspname NOT IN ( 'information_schema', 'pg_catalog' ) 
    GROUP BY
    	n.nspname,
    	P.prokind;
    
    
    --查看表记录数
    select relname as TABLE_NAME, reltuples as rowCounts from pg_class 
    where relkind = 'r' and relnamespace = (select oid from pg_namespace where nspname='public') 
    order by rowCounts desc
    
    • 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
    问题
    configure编译报错集锦
    问题1:
    checking for dtrace... no
    configure: error: dtrace not found
    解决方法:
    yum search dtrace
    Loaded plugins: fastestmirror, refresh-packagekit, security
    Loading mirror speeds from cached hostfile
     * base: mirrors.163.com
     * extras: mirrors.163.com
     * updates: mirrors.163.com
    =============================================================================================== Matched: dtrace ===============================================================================================
    systemtap-sdt-devel.i686 : Static probe support tools
    systemtap-sdt-devel.x86_64 : Static probe support tools
     
    找到了,就安装,我是64位的,安装第二个
    [root@localhost ]# yum install -y systemtap-sdt-devel.x86_64
    
     
    问题2:
    checking for flags to link embedded Perl... Can't locate ExtUtils/Embed.pm in @INC (@INC contains: /usr/local/lib64/perl5 /usr/local/share/perl5 /usr/lib64/perl5/vendor_perl /usr/share/perl5/vendor_perl /usr/lib64/perl5 /usr/share/perl5 .).
    BEGIN failed--compilation aborted.
    no
    configure: error: could not determine flags for linking embedded Perl.
    This probably means that ExtUtils::Embed or ExtUtils::MakeMaker is not
    installed.
    解决方法:
    yum install perl-ExtUtils-Embed -y
    
     
    问题3:
    configure: error: could not determine flags for linking embedded Perl.
    This probably means that ExtUtils::Embed or ExtUtils::MakeMaker is not
    installed.
    解决方法:
    yum install perl-ExtUtils-Embed
     
    问题4:
    configure: error: readline library not found
    If you have readline already installed, see config.log for details on the
    failure. It is possible the compiler isn't looking in the proper directory.
    Use --without-readline to disable readline support.
    解决方法:
    yum install readline readline-devel
    问题5:
    checking for inflate in -lz... no
    configure: error: zlib library not found
    If you have zlib already installed, see config.log for details on the
    failure. It is possible the compiler isn't looking in the proper directory.
    Use --without-zlib to disable zlib support.
    解决方法:
    yum install zlib zlib-devel
     
     
    问题6:
    checking for CRYPTO_new_ex_data in -lcrypto... no
    configure: error: library 'crypto' is required for OpenSSL
    解决方法:
    yum install openssl openssl-devel
     
    问题7:
    checking for pam_start in -lpam... no
    configure: error: library 'pam' is required for PAM
    解决方法:
    yum install pam pam-devel
     
    问题8:
    checking for xmlSaveToBuffer in -lxml2... no
    configure: error: library 'xml2' (version >= 2.6.23) is required for XML support
    解决方法:
    yum install libxml2 libxml2-devel
     
    问题9:
    checking for xsltCleanupGlobals in -lxslt... no
    configure: error: library 'xslt' is required for XSLT support
    解决方法:
    yum install libxslt libxslt-devel
     
     
    问题10:
    configure: error: Tcl shell not found
    解决方法:
    yum install tcl tcl-devel
     
     
    问题11:
    checking for ldap.h... no
    configure: error: header file is required for LDAP
    解决方法:
    yum install openldap openldap-devel
     
    问题12:
    checking for Python.h... no
    configure: error: header file  is required for Python
    解决方法:
    yum install python python-devel
     
    问题13:
    Error when bootstrapping CMake:
    Cannot find appropriate C++ compiler on this system.
    Please specify one using environment variable CXX.
    See cmake_bootstrap.log for compilers attempted.
    解决方法:
    yum install gcc-c++
    
    
    
    • 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

    大版本升级

    PG 大版本升级类似oracle 的startup upgrade方式
    利用pg_upgrade工具,以pg10.22升级至pg14.2为例,工具如何使用及使用中的注意事项。

    升级原因

    出于消除BUG、提升数据库性能、优化代码等不同原因,PG社区会定期会更新数据库版本,在运维过程中数据库大版本升级也是不定时需求。

    大版本的升级方法

    • 法1.转储数据的方式(pg_dump或pg_dumpall导出数据,pg_restore或psql导入)
    • 法2.通过pg_upgrade进行升级
    • 法3.pg_logical扩展进行升级
    • 法4.通过内置逻辑复制的方式进行版本升级

    法1.转储数据的方式(pg_dump或pg_dumpall导出数据,pg_restore或psql导入)

    法2.通过pg_upgrade进行升级

    pg_upgrade升级相对省时,但是升级总是有风险的,例如升级过程中的硬件故障等,所以第一重要的事情依然是做好备份。升级之前需要检查旧版本已经安装的外部扩展,有一些外部扩展要求在升级之前先升级旧版本的外部扩展,例如PostGIS。

    pg_upgrade介绍

    pg_upgrade(以前称为pg_migrator)允许在不需要数据转储/恢复的情况下,将存储在PostgreSQL数据文件中的数据升级到更高版本的PostgreSQL主版本,例如从9.5.8升级到9.6.4或从10.7升级到11.2。
    PostgreSQL主版本会定期添加新功能,这些功能通常会更改系统表的布局,但内部数据存储格式很少更改。pg_upgrade利用这一事实通过创建新的系统表并简单地重用旧的用户数据文件来执行快速升级。如果将来的主要版本更改数据存储格式,使旧数据格式不可读,则pg_upgrade将无法用于此类升级。(社区将尝试避免这种情况.)
    pg_upgrade尽最大努力确保新旧集群与二进制兼容,例如,通过检查兼容的编译时设置,包括 32/64 位二进制文件。重要的是,任何外部模块也是二进制兼容的,尽管这不能由pg_upgrade检查。
    pg_upgrade支持从 8.4.X 及更高版本升级到当前的主要版本的 PostgreSQL,包括快照和测试版本。

    pg_upgrade参数选项
    -b --old-bindir=BINDIR 旧版本PostgreSQL的可执行文件目录;环境变量名称为PGBINOLD
    -B --new-bindir=BINDIR 新版本PostgreSQL的可执行文件目录;默认路径为pg_upgrade所在目录;环境变量名称为PGBINNEW
    -c --check 只检查集群升级兼容性,不会真正的升级,不改变数据
    -d --old-datadir=configdir 旧版本数据库配置/数据目录;环境变量名称为PGDATAOLD
    -D --new-datadir=configdir 新版本数据库配置/数据目录;环境变量名称为PGDATANEW
    -j --jobs 允许多个CPU核复制或链接文件以及并行地转储和重载数据库模式,一般可以设置为CPU核数。这个选项可以显著地减少升级时间。
    -k --link 使用硬链接方式而不是将文件copy到新版本数据库的方式升级
    -o --old-options=OPTIONS 直接传送给旧postgres 命令的选项,多个选项可以追加在后面
    -O --new-options=OPTIONS 直接传送给新postgres 命令的选项,多个选项可以追加在后面
    -p --old-port=PORT 旧版本数据库使用的端口号;环境变量名称为PGPORTOLD
    -P --new-port=PORT 新版本数据库使用的端口号;环境变量名称为PGPORTNEW;新旧版本实例使用的端口号必须不同
    -r --retain 即使在成功完成后也保留SQL和日志文件
    -s --socketdir=DIR 在升级过程中postmaster sockets使用的目录,默认是当前工作目录,环境变量名称为PGSOCKETDIR
    -U --username=username 数据库的安装用户;环境变量名称为PGUSER
    -v --verbose 启用详细的内部日志记录
    -V --version 显示版本信息,然后退出
    –clone
    使用高效的文件克隆(在某些系统上也称为“reflinks”),而不是将文件复制到新群集。这可能导致近乎即
    时地复制数据文件,从而提供类似于 -k/–link 的速度优势,同时保持旧集群不变。
    文件克隆仅在某些操作系统和文件系统上受支持。如果在不支持的系统上使用了该选项,则pg_upgrade运行
    将会出错。目前,它在具有Btrfs和XFS(在支持reflink的文件系统上)的Linux(内核4.5或更高版本)
    以及带有APFS的macOS上受支持。
    在升级之前应该运行pg_upgrade并用-c参数检查新旧版本的兼容性,把每一项不兼容的问题都解决了才可以
    顺利升级。使用pg_upgrade时加上-c参数只会检查新旧版本的兼容性,不会运行真正的升级程序,不会修改
    数据文件,并且在命令结束时,会输出一份检查结果的报告,还会对需要手动调整的项做出简要的描述。
    
    • 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
    升级模式区分

    pg_upgrade有普通模式和Link模式两种升级模式。

    • 在普通模式下,会把旧版本的数据拷贝到新版本中,所以如果使用普通模式升级,要确保有足够的磁盘空间存储新旧两份数据;
    • link模式下,只是在新版本的数据目录中建立了旧版本数据文件的硬链接,可以有效减少磁盘占用的空间。
    升级步骤归纳

    1)安装新版本PostgreSQL。注意新版本数据库的安装目录一定要同旧版本区分开,如果使用源码编译安装则手动指定安装目录即可,如果使用rpm包安装且安装目录是/usr/local/pgsql的方式,则推荐将旧版本数据库目录重命名,如果旧版本数据库中安装的扩展存在.so
    2)初始化新版本PostgreSQL数据目录。
    3)停止旧版本数据库。若只做升级前兼容性测试且期间数据库不会做数据结构修改,则不用停止旧版本数据库,若使用普通模式升级,则将postgresql.conf、postgresql.auto.conf及pg_hba.conf文件进行备份。
    4)旧集簇使用的所有自定义共享对象文件(或者 DLL)安装到新集簇中, 例如pgcrypto.so,不管它们是来自于 contrib还是某些其他源码。
    5)检查新旧版本兼容性。最后一行输出“Clusters are compatible”说明已经通过兼容性测试,如果最后一行输出“Failure,exiting”,说明新旧版本不兼容,这时应该查看输出中给出的提示,手动消除这些冲突,直到通过兼容性测试。
    6)使用pg_upgrade普通模式升级。旧版本数据库必须是停止状态,如果运行pg_upgrade失败,必须重新初始化新版本的数据目录。看到“Upgrade Complete”说明升级已经顺利完成。
    使用pg_upgrade的link模式升级:首先需要了解旧版本有哪些Extension及表空间,当使用链接模式运行pg_upgrade之后,pg_upgrade程序会把旧版本数据目录中的pg_control文件重命名为pg_control.old,如果仍然想运行旧版本的数据库实例,需要把pg_control.old重命名回pg_control。但是一旦使用新版本启动了数据库实例,旧的实例将无法再被访问,这一点一定要注意。
    7)将旧版本数据库的相关参数配置文件及pg配置文件及pg_hba.conf文件移动到新版本数据库数据目录内,并根据实际情况决定是否只启用本地连接,若使用Link升级方式,则忽略本步。
    8)启动新版本数据库实例。
    9)更新统计信息。pg_upgrade会创建新的系统表,并重用旧的数据进行升级,统计信息并不会随升级过程迁移,所以在启用新版本之前,应该首先重新收集统计信息,避免没有统计信息导致错误的查询计划。
    在升级结束后,根据提示使用vacuumdb --all --analyze-in-stages命令。
    10)登录并验证业务数据。
    11)清除旧版本数据库,根据升级提示,运行清理旧数据脚本。

    升级示例(pg_upgrade_普通模式)

    旧版本数据库必须是停止状态,如果运行pg_upgrade失败,必须重新初始化新版本的数据目录。看到“Upgrade Complete”说明升级已经顺利完成。

    环境信息

    升级要求:pg10.22升级至pg14.2

    |
    | PG版本 | PG安装目录 | PG数据目录 | 操作系统版本 |
    | — | — | — | — | — |
    | 升级前 | 10.22 | /data/pgdb/pgsql | /data/pgdb/data5785 | Centos7.6 x86_64 |
    | 升级后 | 14.2 | /data/pg14.2 | /data/pg14.2/pgdata | Centos7.6 x86_64 |

    构建测试数据
    psql
    create database fuwa;
    \c fuwa postgres
    create table tbl_batch2 (id int4,info text); 
    insert into tbl_batch2(id,info) 
    select generate_series(1,5),'batch2'; 
    select * from tbl_batch2;
    
    • 1
    • 2
    • 3
    • 4
    • 5
    • 6
    • 7

    生产环境可忽略

    升级过程
    查看环境变量
    #export PATH
    #add by postgres
    export PGHOME=/data/pgdb/pgsql
    export PGDATA=/data/pgdb/data5785
    export PATH=/data/pgdb/pgsql/bin:/usr/local/sbin:/usr/local/bin:/usr/sbin:/usr/bin:/root/bin
    export MANPATH=/data/pgdb/pgsql/share/man:
    export LD_LIBRARY_PATH=/data/pgdb/pgsql/lib:
    export LANG=en_US.UTF-8
    export DATE=`date +"%Y%m%d%H%M"`
    
    • 1
    • 2
    • 3
    • 4
    • 5
    • 6
    • 7
    • 8
    • 9
    升级前数据库信息统计
    --查看数据库列表
    postgres=# \l+
                                                                        List of databases
       Name    |  Owner   | Encoding |   Collate   |    Ctype    |   Access privileges   |  Size   | Tablespace |                Description                
     
    -----------+----------+----------+-------------+-------------+-----------------------+---------+------------+-------------------------------------------
    -
     fuwa      | postgres | UTF8     | en_US.UTF-8 | en_US.UTF-8 |                       | 8553 kB | pg_default | 
     postgres  | postgres | UTF8     | en_US.UTF-8 | en_US.UTF-8 |                       | 8625 kB | pg_default | default administrative connection database
     template0 | postgres | UTF8     | en_US.UTF-8 | en_US.UTF-8 | =c/postgres          +| 8385 kB | pg_default | unmodifiable empty database
               |          |          |             |             | postgres=CTc/postgres |         |            | 
     template1 | postgres | UTF8     | en_US.UTF-8 | en_US.UTF-8 | =c/postgres          +| 8385 kB | pg_default | default template for new databases
               |          |          |             |             | postgres=CTc/postgres |         |            | 
    (4 rows)
    
    --查看已安装的扩展
    postgres=# \dx
                      List of installed extensions
       Name   | Version |   Schema   |         Description          
    ----------+---------+------------+------------------------------
     plpgsql  | 1.0     | pg_catalog | PL/pgSQL procedural language
     walminer | 3.0     | public     | analyse wal to SQL
    (2 rows)
    
    --查看对象类型和个数统计
    SELECT
    	nsp.nspname AS SchemaName,
    CASE
    		cls.relkind 
    		WHEN 'r' THEN
    		'TABLE' 
    		WHEN 'm' THEN
    		'MATERIALIZED_VIEW' 
    		WHEN 'i' THEN
    		'INDEX' 
    		WHEN 'S' THEN
    		'SEQUENCE' 
    		WHEN 'v' THEN
    		'VIEW' 
    		WHEN 'c' THEN
    		'composite type' 
    		WHEN 't' THEN
    		'TOAST' 
    		WHEN 'f' THEN
    		'foreign table' 
    		WHEN 'p' THEN
    		'partitioned_table' 
    		WHEN 'I' THEN
    		'partitioned_index' ELSE cls.relkind :: TEXT 
    	END AS ObjectType,
    	COUNT ( * ) cnt 
    FROM
    	pg_class cls
    	JOIN pg_namespace nsp ON nsp.oid = cls.relnamespace 
    WHERE
    	nsp.nspname NOT IN ( 'information_schema', 'pg_catalog' ) 
    	AND nsp.nspname NOT LIKE'pg_toast%' 
    GROUP BY
    	nsp.nspname,
    	cls.relkind UNION ALL
    SELECT
    	n.nspname AS "Schema",
    CASE
    		P.prokind 
    		WHEN 'a' THEN
    		'agg' 
    		WHEN 'w' THEN
    		'window' 
    		WHEN 'p' THEN
    		'proc' ELSE'func' 
    	END AS "Type",
    	COUNT ( * ) cnt 
    FROM
    	pg_catalog.pg_proc
    	P LEFT JOIN pg_catalog.pg_namespace n ON n.oid = P.pronamespace 
    WHERE
    	pg_catalog.pg_function_is_visible ( P.oid ) 
    	AND n.nspname NOT IN ( 'information_schema', 'pg_catalog' ) 
    GROUP BY
    	n.nspname,
    	P.prokind;
    
    
    --查看表记录数
    select relname as TABLE_NAME, reltuples as rowCounts from pg_class 
    where relkind = 'r' and relnamespace = (select oid from pg_namespace where nspname='public') 
    order by rowCounts desc
    
    
    • 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
    停止pg10.22的数据库服务

    如果磁盘空间允许,建议安装目录和数据目录备份,确保极端情况下可以回退;若磁盘空间不允许建议异地留存备份。

    --停止pg10.22数据库服务
    [postgres@localhost bin]$ /data/pgdb/pgsql/bin/pg_ctl stop -D /data/pgdb/data5785/
    --备份安装目录和数据目录(磁盘空间允许的情况下)
    cp -r /data/pgdb/pgsql /data/pgdb/pgsql_bak_20230917
    cp -r /data/pgdb/data5785 /data/pgdb/data5785_bak_20230917
    
    • 1
    • 2
    • 3
    • 4
    • 5
    查看原postgresql.conf参数及pg_hba.conf文件
    [postgres@localhost data5785]$ cat postgresql.conf |grep shared_buffers
    [postgres@localhost data5785]$ cat postgresql.conf |grep wal_level
    [postgres@localhost data5785]$ cat pg_hba.conf |grep -v '#'
    
    • 1
    • 2
    • 3
    源码编译安装pg14.9,未初始化data目录
    --解压
    [root@localhost ~]# tar -xvf postgresql-14.2.tar.gz
    --编译安装
    [root@localhost ~]# cd postgresql-14.2
    [root@localhost ~]# ./configure --prefix=/data/pg14.2 --with-pgport=5785 --with-openssl --with-perl --with-python --with-readline --with-libxml --with-libxslt
    [root@localhost ~]# gmake world -j 4 && gmake install-world -j 4
    --更改属主属组为postgres
    [root@localhost postgresql-14.2]# chown -R postgres:postgres /data/pg14.2/
    
    • 1
    • 2
    • 3
    • 4
    • 5
    • 6
    • 7
    • 8

    报错的解决版本参考下文问题部分

    初始化pg14.2的data目录
    --创建新data目录
    [root@localhost ~]# mkdir -p /data/pg14.2/pgdata
    [root@localhost ~]# chown -R postgres:postgres /data/pg14.2/pgdata
    --进入新版本14.2的安装目录  初始化数据库
    [postgres@localhost ~]$ cd /data/pg14.2/bin
    ./initdb  --username=postgres --pwfile=/home/postgres/.pgpass -D /data/pg14.2/pgdata --encoding=UTF8 --lc-collate=en_US.UTF-8 --lc-ctype=en_US.UTF-8
    
    
    • 1
    • 2
    • 3
    • 4
    • 5
    • 6
    • 7
    升级兼容性测试

    进行升级兼容性测试,如升级窗口期内无数据结构变更,也可不停库进行兼容性测试,但升级过程必须停库。最后一行输出“Clusters are compatible”说明已经通过兼容性测试。
    -c:–check 只检查集群升级兼容性,不会真正的升级,不改变数据

    [postgres@localhost bin]$ /data/pg14.2/bin/pg_upgrade -b /data/pgdb/pgsql/bin/ -B /data/pg14.2/bin/ -d /data/pgdb/data5785/ -D /data/pg14.2/pgdata/ -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 tables WITH OIDS                               ok
    Checking for invalid "sql_identifier" user columns          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*  #最后一行输出“Clusters are compatible”说明已经通过兼容性测试
    
    • 1
    • 2
    • 3
    • 4
    • 5
    • 6
    • 7
    • 8
    • 9
    • 10
    • 11
    • 12
    • 13
    • 14
    • 15
    • 16
    • 17
    • 18
    • 19
    • 20
    升级pg10.22至pg14.2

    看到“Upgrade Complete”说明升级已经顺利完成。

    [postgres@localhost ~]$ /data/pg14.2/bin/pg_upgrade -b /data/pgdb/pgsql/bin/ -B /data/pg14.2/bin/ -d /data/pgdb/data5785/ -D /data/pg14.2/pgdata/ 
    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 tables WITH OIDS                               ok
    Checking for invalid "sql_identifier" user columns          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  #看到“Upgrade Complete”说明升级已经顺利完成
    ----------------
    Optimizer statistics are not transferred by pg_upgrade.
    Once you start the new server, consider running:
        /data/pg14.2/bin/vacuumdb --all --analyze-in-stages
    
    Running this script will delete the old cluster's data files:
        ./delete_old_cluster.sh
    
    
    • 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
    • 查看当前目录下生成的扩展升级SQL及删除旧数据目录的脚本

    [postgres@localhost ~]$ ls -l
    total 4
    -rwx------. 1 postgres postgres 40 Sep 17 11:47 delete_old_cluster.sh
    -rw------- 1 postgres postgres 40 Sep 17 11:47 update_extensions.sql

    将pg10.22的相关配置文件移动到pg14.2的data目录中,启动数据库
    --移动配置文件至新data目录
    [postgres@localhost ~]$ cd /data/pgdb/data5785/
    [postgres@localhost data5785]$ cp postgresql.conf /data/pg14.2/pgdata/
    [postgres@localhost data5785]$ cp pg_hba.conf /data/pg14.2/pgdata/
    
    --新postgresql.conf中增加如下内容
    ##在最后一行增加如下内容
    vi /data/pg14.2/pgdata/postgresql.conf
    include postgresql.base.conf
    
    --启动新数据库
    [postgres@localhost ~]$ /data/pg14.2/bin/pg_ctl start -D /data/pg14.2/pgdata/
    
    • 1
    • 2
    • 3
    • 4
    • 5
    • 6
    • 7
    • 8
    • 9
    • 10
    • 11
    • 12
    执行扩展升级的SQL语句

    根据提示执行扩展升级的SQL语句,发现报symbol错误,此问题为环境变量仍为pg10.22原因导致,手动设置下环境变量

    --执行扩展升级的SQL语句
    [postgres@localhost ~]$ /data/pg14.2/bin/psql -f update_extensions.sql 
    /data/pg14.2/bin/psql: symbol lookup error: /data/pg14.2/bin/psql: undefined symbol: PQmblenBounded
    --手动设置环境后再次执行SQL
    [postgres@localhost ~]$ export LD_LIBRARY_PATH=/data/pg14.2/lib
    [postgres@localhost ~]$ /data/pg14.2/bin/psql -f update_extensions.sql 
    You are now connected to database "fuwa" as user "postgres".
    ALTER EXTENSION
    You are now connected to database "postgres" as user "postgres".
    ALTER EXTENSION
    
    • 1
    • 2
    • 3
    • 4
    • 5
    • 6
    • 7
    • 8
    • 9
    • 10
    更新统计信息

    根据升级过程中的提示更新统计信息

    [postgres@localhost ~]$ /data/pg14.2/bin/vacuumdb --all --analyze-in-stages
    vacuumdb: processing database "fuwa": Generating minimal optimizer statistics (1 target)
    vacuumdb: processing database "postgres": Generating minimal optimizer statistics (1 target)
    vacuumdb: processing database "template1": Generating minimal optimizer statistics (1 target)
    vacuumdb: processing database "fuwa": Generating medium optimizer statistics (10 targets)
    vacuumdb: processing database "postgres": Generating medium optimizer statistics (10 targets)
    vacuumdb: processing database "template1": Generating medium optimizer statistics (10 targets)
    vacuumdb: processing database "fuwa": Generating default (full) optimizer statistics
    vacuumdb: processing database "postgres": Generating default (full) optimizer statistics
    vacuumdb: processing database "template1": Generating default (full) optimizer statistics
    
    • 1
    • 2
    • 3
    • 4
    • 5
    • 6
    • 7
    • 8
    • 9
    • 10
    升级后数据库信息统计

    登录升级后的数据库核对信息,升级后数据库参数明细

    --登录数据库
    [postgres@localhost ~]$ export LD_LIBRARY_PATH=/data/pg14.2/lib
    [postgres@localhost ~]$ /data/pg14.2/bin/psql
    
    --查看参数
    postgres=# show shared_buffers;
     shared_buffers 
    ----------------
     1GB
    (1 row)
    
    postgres=# show wal_level;
     wal_level 
    -----------
     replica
    (1 row)
    
    postgres=# show shared_preload_libraries ;
     shared_preload_libraries 
    --------------------------
     pg_stat_statements
    
    --查看数据库信息
    postgres=# \l+
                                                                        List of databases
       Name    |  Owner   | Encoding |   Collate   |    Ctype    |   Access privileges   |  Size   | Tablespace |                Description                
     
    -----------+----------+----------+-------------+-------------+-----------------------+---------+------------+-------------------------------------------
    -
     fuwa      | postgres | UTF8     | en_US.UTF-8 | en_US.UTF-8 |                       | 8737 kB | pg_default | 
     postgres  | postgres | UTF8     | en_US.UTF-8 | en_US.UTF-8 |                       | 8729 kB | pg_default | default administrative connection database
     template0 | postgres | UTF8     | en_US.UTF-8 | en_US.UTF-8 | =c/postgres          +| 8585 kB | pg_default | unmodifiable empty database
               |          |          |             |             | postgres=CTc/postgres |         |            | 
     template1 | postgres | UTF8     | en_US.UTF-8 | en_US.UTF-8 | postgres=CTc/postgres+| 8705 kB | pg_default | default template for new databases
               |          |          |             |             | =c/postgres           |         |            | 
    (4 rows)
    
    --查看已安装的扩展
    postgres=# \dx
                      List of installed extensions
       Name   | Version |   Schema   |         Description          
    ----------+---------+------------+------------------------------
     pgcrypto | 1.3     | public     | cryptographic functions
     plpgsql  | 1.0     | pg_catalog | PL/pgSQL procedural language
    (2 rows)
    
    --查看对象类型和个数统计
    SELECT
    	nsp.nspname AS SchemaName,
    CASE
    		cls.relkind 
    		WHEN 'r' THEN
    		'TABLE' 
    		WHEN 'm' THEN
    		'MATERIALIZED_VIEW' 
    		WHEN 'i' THEN
    		'INDEX' 
    		WHEN 'S' THEN
    		'SEQUENCE' 
    		WHEN 'v' THEN
    		'VIEW' 
    		WHEN 'c' THEN
    		'composite type' 
    		WHEN 't' THEN
    		'TOAST' 
    		WHEN 'f' THEN
    		'foreign table' 
    		WHEN 'p' THEN
    		'partitioned_table' 
    		WHEN 'I' THEN
    		'partitioned_index' ELSE cls.relkind :: TEXT 
    	END AS ObjectType,
    	COUNT ( * ) cnt 
    FROM
    	pg_class cls
    	JOIN pg_namespace nsp ON nsp.oid = cls.relnamespace 
    WHERE
    	nsp.nspname NOT IN ( 'information_schema', 'pg_catalog' ) 
    	AND nsp.nspname NOT LIKE'pg_toast%' 
    GROUP BY
    	nsp.nspname,
    	cls.relkind UNION ALL
    SELECT
    	n.nspname AS "Schema",
    CASE
    		P.prokind 
    		WHEN 'a' THEN
    		'agg' 
    		WHEN 'w' THEN
    		'window' 
    		WHEN 'p' THEN
    		'proc' ELSE'func' 
    	END AS "Type",
    	COUNT ( * ) cnt 
    FROM
    	pg_catalog.pg_proc
    	P LEFT JOIN pg_catalog.pg_namespace n ON n.oid = P.pronamespace 
    WHERE
    	pg_catalog.pg_function_is_visible ( P.oid ) 
    	AND n.nspname NOT IN ( 'information_schema', 'pg_catalog' ) 
    GROUP BY
    	n.nspname,
    	P.prokind;
    
    
    --查看表记录数
    select relname as TABLE_NAME, reltuples as rowCounts from pg_class 
    where relkind = 'r' and relnamespace = (select oid from pg_namespace where nspname='public') 
    order by rowCounts desc;
    
    • 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
    • 109
    修改环境变量
    --修改环境变量信息
    [postgres@localhost ~]$ vi .bash_profile
    #add by postgres
    #old install directory   #注释掉老安装目录
    #export PGHOME=/data/pgdb/pgsql
    #new install directory  #增加新安装目录
    export PGHOME=/data/pg14.2
    #old data directory   #注释掉老数据目录
    export PGDATA=/data/pgdb/data5785
    #new data directory   #注释掉老数据目录
    export PGDATA=/data/pg14.2/pgdata
    export PATH=$PGHOME/bin:$PATH
    export MANPATH=$PGHOME/share/man:$MANPATH
    export LD_LIBRARY_PATH=$PGHOME/lib:$LD_LIBRARY_PATH
    export LANG=en_US.UTF-8
    export DATE=`date +"%Y%m%d%H%M"`
    export PGPORT=5785
    
    [postgres@localhost ~]$ source .bash_profile
    
    [postgres@localhost ~]$ echo $PGHOME  #务必确保新家目录
    /data/pg14.2
    
    • 1
    • 2
    • 3
    • 4
    • 5
    • 6
    • 7
    • 8
    • 9
    • 10
    • 11
    • 12
    • 13
    • 14
    • 15
    • 16
    • 17
    • 18
    • 19
    • 20
    • 21
    • 22
    根据升级完成后的提示,验证无误后执行删除旧数据目录脚本,清理空间

    如果磁盘空间允许,不建议执行该操作;若磁盘空间不允许建议异地留存备份。

    [postgres@localhost ~]$ cat delete_old_cluster.sh 
    #!/bin/sh
    rm -rf '/data/pgdb/data5785'
    
    [postgres@localhost ~]$ sh delete_old_cluster.sh  #生产环境慎重慎重慎重
    
    • 1
    • 2
    • 3
    • 4
    • 5
    问题
    configure编译报错集锦
    问题1:
    checking for dtrace... no
    configure: error: dtrace not found
    解决方法:
    yum search dtrace
    Loaded plugins: fastestmirror, refresh-packagekit, security
    Loading mirror speeds from cached hostfile
     * base: mirrors.163.com
     * extras: mirrors.163.com
     * updates: mirrors.163.com
    =============================================================================================== Matched: dtrace ===============================================================================================
    systemtap-sdt-devel.i686 : Static probe support tools
    systemtap-sdt-devel.x86_64 : Static probe support tools
     
    找到了,就安装,我是64位的,安装第二个
    [root@localhost ]# yum install -y systemtap-sdt-devel.x86_64
    
     
    问题2:
    checking for flags to link embedded Perl... Can't locate ExtUtils/Embed.pm in @INC (@INC contains: /usr/local/lib64/perl5 /usr/local/share/perl5 /usr/lib64/perl5/vendor_perl /usr/share/perl5/vendor_perl /usr/lib64/perl5 /usr/share/perl5 .).
    BEGIN failed--compilation aborted.
    no
    configure: error: could not determine flags for linking embedded Perl.
    This probably means that ExtUtils::Embed or ExtUtils::MakeMaker is not
    installed.
    解决方法:
    yum install perl-ExtUtils-Embed -y
    
     
    问题3:
    configure: error: could not determine flags for linking embedded Perl.
    This probably means that ExtUtils::Embed or ExtUtils::MakeMaker is not
    installed.
    解决方法:
    yum install perl-ExtUtils-Embed
     
    问题4:
    configure: error: readline library not found
    If you have readline already installed, see config.log for details on the
    failure. It is possible the compiler isn't looking in the proper directory.
    Use --without-readline to disable readline support.
    解决方法:
    yum install readline readline-devel
    问题5:
    checking for inflate in -lz... no
    configure: error: zlib library not found
    If you have zlib already installed, see config.log for details on the
    failure. It is possible the compiler isn't looking in the proper directory.
    Use --without-zlib to disable zlib support.
    解决方法:
    yum install zlib zlib-devel
     
     
    问题6:
    checking for CRYPTO_new_ex_data in -lcrypto... no
    configure: error: library 'crypto' is required for OpenSSL
    解决方法:
    yum install openssl openssl-devel
     
    问题7:
    checking for pam_start in -lpam... no
    configure: error: library 'pam' is required for PAM
    解决方法:
    yum install pam pam-devel
     
    问题8:
    checking for xmlSaveToBuffer in -lxml2... no
    configure: error: library 'xml2' (version >= 2.6.23) is required for XML support
    解决方法:
    yum install libxml2 libxml2-devel
     
    问题9:
    checking for xsltCleanupGlobals in -lxslt... no
    configure: error: library 'xslt' is required for XSLT support
    解决方法:
    yum install libxslt libxslt-devel
     
     
    问题10:
    configure: error: Tcl shell not found
    解决方法:
    yum install tcl tcl-devel
     
     
    问题11:
    checking for ldap.h... no
    configure: error: header file is required for LDAP
    解决方法:
    yum install openldap openldap-devel
     
    问题12:
    checking for Python.h... no
    configure: error: header file  is required for Python
    解决方法:
    yum install python python-devel
     
    问题13:
    Error when bootstrapping CMake:
    Cannot find appropriate C++ compiler on this system.
    Please specify one using environment variable CXX.
    See cmake_bootstrap.log for compilers attempted.
    解决方法:
    yum install gcc-c++
    
    • 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
    升级示例(pg_upgrade_link模式)

    旧版本数据库必须是停止状态,如果运行pg_upgrade失败,必须重新初始化新版本的数据目录。看到“Upgrade Complete”说明升级已经顺利完成。

    环境信息

    升级要求:pg10.22升级至pg14.2

    |
    | PG版本 | PG安装目录 | PG数据目录 | 操作系统版本 |
    | — | — | — | — | — |
    | 升级前 | 10.22 | /data/pgdb/pgsql | /data/pgdb/data5785 | Centos7.6 x86_64 |
    | 升级后 | 14.2 | /data/pg14.2 | /data/pg14.2/pgdata | Centos7.6 x86_64 |

    构建测试数据
    psql
    create database fuwa;
    \c fuwa postgres
    create table tbl_batch2 (id int4,info text); 
    insert into tbl_batch2(id,info) 
    select generate_series(1,5),'batch2'; 
    select * from tbl_batch2;
    
    • 1
    • 2
    • 3
    • 4
    • 5
    • 6
    • 7

    生产环境可忽略

    升级过程
    查看环境变量
    #export PATH
    #add by postgres
    export PGHOME=/data/pgdb/pgsql
    export PGDATA=/data/pgdb/data5785
    export PATH=/data/pgdb/pgsql/bin:/usr/local/sbin:/usr/local/bin:/usr/sbin:/usr/bin:/root/bin
    export MANPATH=/data/pgdb/pgsql/share/man:
    export LD_LIBRARY_PATH=/data/pgdb/pgsql/lib:
    export LANG=en_US.UTF-8
    export DATE=`date +"%Y%m%d%H%M"`
    
    • 1
    • 2
    • 3
    • 4
    • 5
    • 6
    • 7
    • 8
    • 9
    升级前数据库信息统计
    --查看数据库列表
    postgres=# \l+
                                                                        List of databases
       Name    |  Owner   | Encoding |   Collate   |    Ctype    |   Access privileges   |  Size   | Tablespace |                Description                
     
    -----------+----------+----------+-------------+-------------+-----------------------+---------+------------+-------------------------------------------
    -
     fuwa      | postgres | UTF8     | en_US.UTF-8 | en_US.UTF-8 |                       | 8553 kB | pg_default | 
     postgres  | postgres | UTF8     | en_US.UTF-8 | en_US.UTF-8 |                       | 8625 kB | pg_default | default administrative connection database
     template0 | postgres | UTF8     | en_US.UTF-8 | en_US.UTF-8 | =c/postgres          +| 8385 kB | pg_default | unmodifiable empty database
               |          |          |             |             | postgres=CTc/postgres |         |            | 
     template1 | postgres | UTF8     | en_US.UTF-8 | en_US.UTF-8 | =c/postgres          +| 8385 kB | pg_default | default template for new databases
               |          |          |             |             | postgres=CTc/postgres |         |            | 
    (4 rows)
    
    --查看已安装的扩展
    postgres=# \dx
                      List of installed extensions
       Name   | Version |   Schema   |         Description          
    ----------+---------+------------+------------------------------
     plpgsql  | 1.0     | pg_catalog | PL/pgSQL procedural language
     walminer | 3.0     | public     | analyse wal to SQL
    (2 rows)
    
    --查看对象类型和个数统计
    SELECT
    	nsp.nspname AS SchemaName,
    CASE
    		cls.relkind 
    		WHEN 'r' THEN
    		'TABLE' 
    		WHEN 'm' THEN
    		'MATERIALIZED_VIEW' 
    		WHEN 'i' THEN
    		'INDEX' 
    		WHEN 'S' THEN
    		'SEQUENCE' 
    		WHEN 'v' THEN
    		'VIEW' 
    		WHEN 'c' THEN
    		'composite type' 
    		WHEN 't' THEN
    		'TOAST' 
    		WHEN 'f' THEN
    		'foreign table' 
    		WHEN 'p' THEN
    		'partitioned_table' 
    		WHEN 'I' THEN
    		'partitioned_index' ELSE cls.relkind :: TEXT 
    	END AS ObjectType,
    	COUNT ( * ) cnt 
    FROM
    	pg_class cls
    	JOIN pg_namespace nsp ON nsp.oid = cls.relnamespace 
    WHERE
    	nsp.nspname NOT IN ( 'information_schema', 'pg_catalog' ) 
    	AND nsp.nspname NOT LIKE'pg_toast%' 
    GROUP BY
    	nsp.nspname,
    	cls.relkind UNION ALL
    SELECT
    	n.nspname AS "Schema",
    CASE
    		P.prokind 
    		WHEN 'a' THEN
    		'agg' 
    		WHEN 'w' THEN
    		'window' 
    		WHEN 'p' THEN
    		'proc' ELSE'func' 
    	END AS "Type",
    	COUNT ( * ) cnt 
    FROM
    	pg_catalog.pg_proc
    	P LEFT JOIN pg_catalog.pg_namespace n ON n.oid = P.pronamespace 
    WHERE
    	pg_catalog.pg_function_is_visible ( P.oid ) 
    	AND n.nspname NOT IN ( 'information_schema', 'pg_catalog' ) 
    GROUP BY
    	n.nspname,
    	P.prokind;
    
    
    --查看表记录数
    select relname as TABLE_NAME, reltuples as rowCounts from pg_class 
    where relkind = 'r' and relnamespace = (select oid from pg_namespace where nspname='public') 
    order by rowCounts desc
    
    
    • 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
    停止pg10.22的数据库服务

    如果磁盘空间允许,建议安装目录和数据目录备份,确保极端情况下可以回退;若磁盘空间不允许建议异地留存备份。

    --停止pg10.22数据库服务
    [postgres@localhost bin]$ /data/pgdb/pgsql/bin/pg_ctl stop -D /data/pgdb/data5785/
    --备份安装目录和数据目录(磁盘空间允许的情况下)
    cp -r /data/pgdb/pgsql /data/pgdb/pgsql_bak_20230917
    cp -r /data/pgdb/data5785 /data/pgdb/data5785_bak_20230917
    
    • 1
    • 2
    • 3
    • 4
    • 5
    查看原postgresql.conf参数及pg_hba.conf文件
    [postgres@localhost data5785]$ cat postgresql.conf |grep shared_buffers
    [postgres@localhost data5785]$ cat postgresql.conf |grep wal_level
    [postgres@localhost data5785]$ cat pg_hba.conf |grep -v '#'
    
    • 1
    • 2
    • 3
    源码编译安装pg14.9,未初始化data目录
    --解压
    [root@localhost ~]# tar -xvf postgresql-14.2.tar.gz
    --编译安装
    [root@localhost ~]# cd postgresql-14.2
    [root@localhost ~]# ./configure --prefix=/data/pg14.2 --with-pgport=5785 --with-openssl --with-perl --with-python --with-readline --with-libxml --with-libxslt
    [root@localhost ~]# gmake world -j 4 && gmake install-world -j 4
    --更改属主属组为postgres
    [root@localhost postgresql-14.2]# chown -R postgres:postgres /data/pg14.2/
    
    • 1
    • 2
    • 3
    • 4
    • 5
    • 6
    • 7
    • 8

    报错的解决版本参考下文问题部分

    初始化pg14.2的data目录
    --创建新data目录
    [root@localhost ~]# mkdir -p /data/pg14.2/pgdata
    [root@localhost ~]# chown -R postgres:postgres /data/pg14.2/pgdata
    --进入新版本14.2的安装目录  初始化数据库
    [postgres@localhost ~]$ cd /data/pg14.2/bin
    ./initdb  --username=postgres --pwfile=/home/postgres/.pgpass -D /data/pg14.2/pgdata --encoding=UTF8 --lc-collate=en_US.UTF-8 --lc-ctype=en_US.UTF-8
    
    
    • 1
    • 2
    • 3
    • 4
    • 5
    • 6
    • 7
    升级兼容性测试

    进行升级兼容性测试,如升级窗口期内无数据结构变更,也可不停库进行兼容性测试,但升级过程必须停库。最后一行输出“Clusters are compatible”说明已经通过兼容性测试。
    -c:–check 只检查集群升级兼容性,不会真正的升级,不改变数据

    [postgres@localhost bin]$ /data/pg14.2/bin/pg_upgrade -b /data/pgdb/pgsql/bin/ -B /data/pg14.2/bin/ -d /data/pgdb/data5785/ -D /data/pg14.2/pgdata/ -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 tables WITH OIDS                               ok
    Checking for invalid "sql_identifier" user columns          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*  #最后一行输出“Clusters are compatible”说明已经通过兼容性测试
    
    • 1
    • 2
    • 3
    • 4
    • 5
    • 6
    • 7
    • 8
    • 9
    • 10
    • 11
    • 12
    • 13
    • 14
    • 15
    • 16
    • 17
    • 18
    • 19
    • 20
    硬链接升级pg10.22至pg14.2

    硬链接升级 使用-k参数
    看到“Upgrade Complete”说明升级已经顺利完成。

    [postgres@localhost ~]$ /data/pg14.2/bin/pg_upgrade -b /data/pgdb/pgsql/bin/ -B /data/pg14.2/bin/ -d /data/pgdb/data5785/ -D /data/pg14.2/pgdata/ -k 
    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 tables WITH OIDS                               ok
    Checking for invalid "sql_identifier" user columns          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  #看到“Upgrade Complete”说明升级已经顺利完成
    ----------------
    Optimizer statistics are not transferred by pg_upgrade.
    Once you start the new server, consider running:
        /data/pg14.2/bin/vacuumdb --all --analyze-in-stages
    
    Running this script will delete the old cluster's data files:
        ./delete_old_cluster.sh
    
    
    • 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
    • 查看当前目录下生成的扩展升级SQL及删除旧数据目录的脚本

    [postgres@localhost ~]$ ls -l
    total 4
    -rwx------. 1 postgres postgres 40 Sep 17 11:47 delete_old_cluster.sh
    -rw------- 1 postgres postgres 40 Sep 17 11:47 update_extensions.sql

    将pg10.22的相关配置文件移动到pg14.2的data目录中,启动数据库
    --移动配置文件至新data目录
    [postgres@localhost ~]$ cd /data/pgdb/data5785/
    [postgres@localhost data5785]$ cp postgresql.conf /data/pg14.2/pgdata/
    [postgres@localhost data5785]$ cp pg_hba.conf /data/pg14.2/pgdata/
    
    --新postgresql.conf中增加如下内容
    ##在最后一行增加如下内容
    vi /data/pg14.2/pgdata/postgresql.conf
    include postgresql.base.conf
    
    --启动新数据库
    [postgres@localhost ~]$ /data/pg14.2/bin/pg_ctl start -D /data/pg14.2/pgdata/
    
    • 1
    • 2
    • 3
    • 4
    • 5
    • 6
    • 7
    • 8
    • 9
    • 10
    • 11
    • 12
    执行扩展升级的SQL语句

    根据提示执行扩展升级的SQL语句,发现报symbol错误,此问题为环境变量仍为pg10.22原因导致,手动设置下环境变量

    --执行扩展升级的SQL语句
    [postgres@localhost ~]$ /data/pg14.2/bin/psql -f update_extensions.sql 
    /data/pg14.2/bin/psql: symbol lookup error: /data/pg14.2/bin/psql: undefined symbol: PQmblenBounded
    --手动设置环境后再次执行SQL
    [postgres@localhost ~]$ export LD_LIBRARY_PATH=/data/pg14.2/lib
    [postgres@localhost ~]$ /data/pg14.2/bin/psql -f update_extensions.sql 
    You are now connected to database "fuwa" as user "postgres".
    ALTER EXTENSION
    You are now connected to database "postgres" as user "postgres".
    ALTER EXTENSION
    
    • 1
    • 2
    • 3
    • 4
    • 5
    • 6
    • 7
    • 8
    • 9
    • 10
    更新统计信息

    根据升级过程中的提示更新统计信息

    [postgres@localhost ~]$ /data/pg14.2/bin/vacuumdb --all --analyze-in-stages
    vacuumdb: processing database "fuwa": Generating minimal optimizer statistics (1 target)
    vacuumdb: processing database "postgres": Generating minimal optimizer statistics (1 target)
    vacuumdb: processing database "template1": Generating minimal optimizer statistics (1 target)
    vacuumdb: processing database "fuwa": Generating medium optimizer statistics (10 targets)
    vacuumdb: processing database "postgres": Generating medium optimizer statistics (10 targets)
    vacuumdb: processing database "template1": Generating medium optimizer statistics (10 targets)
    vacuumdb: processing database "fuwa": Generating default (full) optimizer statistics
    vacuumdb: processing database "postgres": Generating default (full) optimizer statistics
    vacuumdb: processing database "template1": Generating default (full) optimizer statistics
    
    • 1
    • 2
    • 3
    • 4
    • 5
    • 6
    • 7
    • 8
    • 9
    • 10
    升级后数据库信息统计

    登录升级后的数据库核对信息,升级后数据库参数明细

    --登录数据库
    [postgres@localhost ~]$ export LD_LIBRARY_PATH=/data/pg14.2/lib
    [postgres@localhost ~]$ /data/pg14.2/bin/psql
    
    --查看参数
    postgres=# show shared_buffers;
     shared_buffers 
    ----------------
     1GB
    (1 row)
    
    postgres=# show wal_level;
     wal_level 
    -----------
     replica
    (1 row)
    
    postgres=# show shared_preload_libraries ;
     shared_preload_libraries 
    --------------------------
     pg_stat_statements
    
    --查看数据库信息
    postgres=# \l+
                                                                        List of databases
       Name    |  Owner   | Encoding |   Collate   |    Ctype    |   Access privileges   |  Size   | Tablespace |                Description                
     
    -----------+----------+----------+-------------+-------------+-----------------------+---------+------------+-------------------------------------------
    -
     fuwa      | postgres | UTF8     | en_US.UTF-8 | en_US.UTF-8 |                       | 8737 kB | pg_default | 
     postgres  | postgres | UTF8     | en_US.UTF-8 | en_US.UTF-8 |                       | 8729 kB | pg_default | default administrative connection database
     template0 | postgres | UTF8     | en_US.UTF-8 | en_US.UTF-8 | =c/postgres          +| 8585 kB | pg_default | unmodifiable empty database
               |          |          |             |             | postgres=CTc/postgres |         |            | 
     template1 | postgres | UTF8     | en_US.UTF-8 | en_US.UTF-8 | postgres=CTc/postgres+| 8705 kB | pg_default | default template for new databases
               |          |          |             |             | =c/postgres           |         |            | 
    (4 rows)
    
    --查看已安装的扩展
    postgres=# \dx
                      List of installed extensions
       Name   | Version |   Schema   |         Description          
    ----------+---------+------------+------------------------------
     pgcrypto | 1.3     | public     | cryptographic functions
     plpgsql  | 1.0     | pg_catalog | PL/pgSQL procedural language
    (2 rows)
    
    --查看对象类型和个数统计
    SELECT
    	nsp.nspname AS SchemaName,
    CASE
    		cls.relkind 
    		WHEN 'r' THEN
    		'TABLE' 
    		WHEN 'm' THEN
    		'MATERIALIZED_VIEW' 
    		WHEN 'i' THEN
    		'INDEX' 
    		WHEN 'S' THEN
    		'SEQUENCE' 
    		WHEN 'v' THEN
    		'VIEW' 
    		WHEN 'c' THEN
    		'composite type' 
    		WHEN 't' THEN
    		'TOAST' 
    		WHEN 'f' THEN
    		'foreign table' 
    		WHEN 'p' THEN
    		'partitioned_table' 
    		WHEN 'I' THEN
    		'partitioned_index' ELSE cls.relkind :: TEXT 
    	END AS ObjectType,
    	COUNT ( * ) cnt 
    FROM
    	pg_class cls
    	JOIN pg_namespace nsp ON nsp.oid = cls.relnamespace 
    WHERE
    	nsp.nspname NOT IN ( 'information_schema', 'pg_catalog' ) 
    	AND nsp.nspname NOT LIKE'pg_toast%' 
    GROUP BY
    	nsp.nspname,
    	cls.relkind UNION ALL
    SELECT
    	n.nspname AS "Schema",
    CASE
    		P.prokind 
    		WHEN 'a' THEN
    		'agg' 
    		WHEN 'w' THEN
    		'window' 
    		WHEN 'p' THEN
    		'proc' ELSE'func' 
    	END AS "Type",
    	COUNT ( * ) cnt 
    FROM
    	pg_catalog.pg_proc
    	P LEFT JOIN pg_catalog.pg_namespace n ON n.oid = P.pronamespace 
    WHERE
    	pg_catalog.pg_function_is_visible ( P.oid ) 
    	AND n.nspname NOT IN ( 'information_schema', 'pg_catalog' ) 
    GROUP BY
    	n.nspname,
    	P.prokind;
    
    
    --查看表记录数
    select relname as TABLE_NAME, reltuples as rowCounts from pg_class 
    where relkind = 'r' and relnamespace = (select oid from pg_namespace where nspname='public') 
    order by rowCounts desc;
    
    • 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
    • 109
    修改环境变量
    --修改环境变量信息
    [postgres@localhost ~]$ vi .bash_profile
    #add by postgres
    #old install directory   #注释掉老安装目录
    #export PGHOME=/data/pgdb/pgsql
    #new install directory  #增加新安装目录
    export PGHOME=/data/pg14.2
    #old data directory   #注释掉老数据目录
    export PGDATA=/data/pgdb/data5785
    #new data directory   #注释掉老数据目录
    export PGDATA=/data/pg14.2/pgdata
    export PATH=$PGHOME/bin:$PATH
    export MANPATH=$PGHOME/share/man:$MANPATH
    export LD_LIBRARY_PATH=$PGHOME/lib:$LD_LIBRARY_PATH
    export LANG=en_US.UTF-8
    export DATE=`date +"%Y%m%d%H%M"`
    export PGPORT=5785
    
    [postgres@localhost ~]$ source .bash_profile
    
    [postgres@localhost ~]$ echo $PGHOME  #务必确保新家目录
    /data/pg14.2
    
    • 1
    • 2
    • 3
    • 4
    • 5
    • 6
    • 7
    • 8
    • 9
    • 10
    • 11
    • 12
    • 13
    • 14
    • 15
    • 16
    • 17
    • 18
    • 19
    • 20
    • 21
    • 22
    根据升级完成后的提示,验证无误后执行删除旧数据目录脚本,清理空间

    如果磁盘空间允许,不建议执行该操作;若磁盘空间不允许建议异地留存备份。

    [postgres@localhost ~]$ cat delete_old_cluster.sh 
    #!/bin/sh
    rm -rf '/data/pgdb/data5785'
    
    [postgres@localhost ~]$ sh delete_old_cluster.sh  #生产环境慎重慎重慎重
    
    • 1
    • 2
    • 3
    • 4
    • 5
    问题
    configure编译报错集锦
    问题1:
    checking for dtrace... no
    configure: error: dtrace not found
    解决方法:
    yum search dtrace
    Loaded plugins: fastestmirror, refresh-packagekit, security
    Loading mirror speeds from cached hostfile
     * base: mirrors.163.com
     * extras: mirrors.163.com
     * updates: mirrors.163.com
    =============================================================================================== Matched: dtrace ===============================================================================================
    systemtap-sdt-devel.i686 : Static probe support tools
    systemtap-sdt-devel.x86_64 : Static probe support tools
     
    找到了,就安装,我是64位的,安装第二个
    [root@localhost ]# yum install -y systemtap-sdt-devel.x86_64
    
     
    问题2:
    checking for flags to link embedded Perl... Can't locate ExtUtils/Embed.pm in @INC (@INC contains: /usr/local/lib64/perl5 /usr/local/share/perl5 /usr/lib64/perl5/vendor_perl /usr/share/perl5/vendor_perl /usr/lib64/perl5 /usr/share/perl5 .).
    BEGIN failed--compilation aborted.
    no
    configure: error: could not determine flags for linking embedded Perl.
    This probably means that ExtUtils::Embed or ExtUtils::MakeMaker is not
    installed.
    解决方法:
    yum install perl-ExtUtils-Embed -y
    
     
    问题3:
    configure: error: could not determine flags for linking embedded Perl.
    This probably means that ExtUtils::Embed or ExtUtils::MakeMaker is not
    installed.
    解决方法:
    yum install perl-ExtUtils-Embed
     
    问题4:
    configure: error: readline library not found
    If you have readline already installed, see config.log for details on the
    failure. It is possible the compiler isn't looking in the proper directory.
    Use --without-readline to disable readline support.
    解决方法:
    yum install readline readline-devel
    问题5:
    checking for inflate in -lz... no
    configure: error: zlib library not found
    If you have zlib already installed, see config.log for details on the
    failure. It is possible the compiler isn't looking in the proper directory.
    Use --without-zlib to disable zlib support.
    解决方法:
    yum install zlib zlib-devel
     
     
    问题6:
    checking for CRYPTO_new_ex_data in -lcrypto... no
    configure: error: library 'crypto' is required for OpenSSL
    解决方法:
    yum install openssl openssl-devel
     
    问题7:
    checking for pam_start in -lpam... no
    configure: error: library 'pam' is required for PAM
    解决方法:
    yum install pam pam-devel
     
    问题8:
    checking for xmlSaveToBuffer in -lxml2... no
    configure: error: library 'xml2' (version >= 2.6.23) is required for XML support
    解决方法:
    yum install libxml2 libxml2-devel
     
    问题9:
    checking for xsltCleanupGlobals in -lxslt... no
    configure: error: library 'xslt' is required for XSLT support
    解决方法:
    yum install libxslt libxslt-devel
     
     
    问题10:
    configure: error: Tcl shell not found
    解决方法:
    yum install tcl tcl-devel
     
     
    问题11:
    checking for ldap.h... no
    configure: error: header file is required for LDAP
    解决方法:
    yum install openldap openldap-devel
     
    问题12:
    checking for Python.h... no
    configure: error: header file  is required for Python
    解决方法:
    yum install python python-devel
     
    问题13:
    Error when bootstrapping CMake:
    Cannot find appropriate C++ compiler on this system.
    Please specify one using environment variable CXX.
    See cmake_bootstrap.log for compilers attempted.
    解决方法:
    yum install gcc-c++
    
    • 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

    法3.pg_logical扩展进行升级

    法4.通过内置逻辑复制的方式进行版本升级

  • 相关阅读:
    【pen200-lab】10.11.1.231
    微信早安消息推送(大升级版-企业微信)
    【Python简明教程二十四】模块
    Vue 中可重用组件的 3 个主要问题
    史上最强 Java 学习路线图!
    是使用local_setup.bash 还是 setup.bash
    TensorFlow 02(张量)
    pytest --version报错
    基于SpringBoot的房屋租赁管理系统的设计与实现
    idea自动导包操作步骤
  • 原文地址:https://blog.csdn.net/qq961573863/article/details/132941549