PostgreSQL和Greenplum的临时表空间介绍

2 minute read

背景

PostgreSQL的临时表空间,通过参数temp_tablespaces 进行配置,PostgreSQL允许用户配置多个临时表空间。

配置多个临时表空间时,使用逗号隔开。

如果没有配置temp_tablespaces 参数,临时表空间对应的是默认的表空间。

PostgreSQL的临时表空间用来存储临时表或临时表的索引,以及执行SQL时可能产生的临时文件例如排序,聚合,哈希等。

为了提高性能,一般建议将临时表空间放在SSD或者IOPS,以及吞吐量较高的分区中。

例子:

当前未配置temp_tablespaces,使用默认表空间。

postgres=# \l+ postgres    
                                                            List of databases    
   Name   |  Owner   | Encoding | Collate | Ctype | Access privileges |  Size   | Tablespace |                Description                     
----------+----------+----------+---------+-------+-------------------+---------+------------+--------------------------------------------    
 postgres | postgres | UTF8     | C       | C     |                   | 7456 kB | pg_default | default administrative connection database    
(1 row)    
    
postgres=# show temp_tablespaces ;    
 temp_tablespaces     
------------------    
     
(1 row)    
postgres=# create temp table tmp1 (id int);    
CREATE TABLE    
postgres=# insert into tmp1 select generate_series(1,1000);    
INSERT 0 1000    

临时表放在默认表空间中。

postgres=# select pg_relation_filepath('tmp1');    
 pg_relation_filepath     
----------------------    
 base/13241/t2_73746    
(1 row)    

执行一个大的排序,临时文件放在默认表空间中。

postgres=# select * from generate_series(1,10000000000) order by 1;    

查看临时文件目录

cd $PGDATA/base/pgsql_tmp    
$ ll    
-rw------- 1 digoal users 1.0G Mar 26 15:58 pgsql_tmp30315.0    
-rw------- 1 digoal users 1.0G Mar 26 15:58 pgsql_tmp30315.1    
....    

新建一个表空间,并将所有用户的temp_tablespaces参数设置为这个新建的表空间。

mkdir /disk1/digoal/tmptbs1    
postgres=# create tablespace tmptbs location '/disk1/digoal/tmptbs';    
CREATE TABLESPACE    
postgres=# alter role all set temp_tablespaces='tmptbs';    
ALTER ROLE    

重新测试,现在临时文件都会放到新建的表空间下面。

psql    
postgres=# select * from generate_series(1,10000000000) order by 1;    
    
cd /disk1/digoal/tmptbs/PG_9.5_201510051/pgsql_tmp    
total 528M    
-rw------- 1 digoal users 513M Mar 26 16:05 pgsql_tmp31527.0    
    
postgres=# create temp table t1(id int);    
CREATE TABLE    
postgres=# insert into t1 select generate_series(1,10000);    
INSERT 0 10000    
postgres=# select pg_relation_filepath('t1');    
              pg_relation_filepath                   
-------------------------------------------------    
 pg_tblspc/73749/PG_9.5_201510051/13241/t3_73750    
(1 row)    

下面是Greenplum的临时表空间,介绍:

关于filespace的使用,请先查看

《Greenplum 表空间和filespace的用法》

Greenplum没有temp_tablespaces这个参数,那么临时文件应该放哪里呢?

Greenplum将只有filespace的说法,并且临时文件是全局管理的,也就是说整个GP集群的临时文件是放在一个地方(filespace)的。

在Greenplum中不同的用户不能使用不同的临时文件目录。

默认情况下临时文件是放在默认的表空间下面

临时文件(例如排序,哈希,产生的work file)

  <filespace_directory>/<tablespace_oid>/<database_oid>/pgsql_tmp     

临时表

  <filespace_directory>/<tablespace_oid>/<database_oid>/    
You can move temporary or transaction files to a specific filespace to improve database performance when    
running queries, creating backups, and to store data more sequentially.    
    
The dedicated filespace for temporary and transaction files is tracked in two separate flat files called    
gp_temporary_files_filespace and gp_transaction_files_filespace.     
These are located in the pg_system directory on each primary and mirror segment, and on master and standby.     
You must be a superuser to move temporary or transaction files.     
Only the gpfilespace utility can write to this file.    
    
Unless otherwise specified, temporary and transaction files are stored together with all user data.     
The default location of temporary files, <filespace_directory>/<tablespace_oid>/<database_oid>/pgsql_tmp     
is changed when you use gpfilespace --movetempfiles for the first time.    
    
Also note the following information about temporary or transaction files:    
• You can dedicate only one filespace for temporary or transaction files,     
  although you can use the same filespace to store other types of files.    
• You cannot drop a filespace if it used by temporary files.    
• You must create the filespace in advance.     

如果要修改Greenplum临时文件的存放地,操作如下:

首先要创建filespace, 然后确保没有活跃会话,使用gpfilespace –movetempfilespace filespace_name命令迁移临时文件目录。

To move temporary files using gpfilespace      
1. Check that the filespace exists and is different from the filespace used to store all other user data.    
2. Issue smart shutdown to bring the Greenplum Database offline.    
   If any connections are still in progess, the gpfilespace --movetempfiles utility will fail.    
3. Bring Greenplum Database online with no active session and run the following command:    
   gpfilespace --movetempfilespace filespace_name    
   The location of the temporary files is stored in the segment configuration shared memory    
   (PMModuleState) and used whenever temporary files are created, opened, or dropped.    
To move transaction files using gpfilespace    
1. Check that the filespace exists and is different from the filespace used to store all other user data.    
2. Issue smart shutdown to bring the Greenplum Database offline.    
   If any connections are still in progess,the gpfilespace --movetransfiles utility will fail.    
3. Bring Greenplum Database online with no active session and run the following command:    
   gpfilespace --movetransfilespace filespace_name    
   The location of the transaction files is stored in the segment configuration shared memory    
   (PMModuleState) and used whenever transaction files are created, opened, or dropped.    
    
Creating a Tablespace    
  After you create a filespace, use the CREATE TABLESPACE command to define a tablespace that uses that    
  filespace.     
  For example:      
  =# CREATE TABLESPACE fastspace FILESPACE fastdisk;    

Flag Counter

digoal’s 大量PostgreSQL文章入口