学习目标
表空间是数据的容器。掌握表空间的管理,包括创建表空间、删除表空间、重命名表空间、查看表空间的情况。
本节要点
使用表空间,管理员可以控制一个数据库安装的磁盘布局。
表空间对应于一个文件系统目录,假定数据库节点数据目录/pg_location/mount1/path1是用户拥有读写权限的空目录。
openGauss自带了两个表空间:pg_default和pg_global。
默认表空间pg_default:用来存储非共享系统表、用户表、用户表index、临时表、临时表index、内部临时表的默认表空间。对应存储目录为实例数据目录下的base目录。
共享表空间pg_global:用来存放共享系统表的表空间。对应存储目录为实例数据目录下的global目录。
课后作业
测试环境:
root@modb:~# su - omm
omm@modb:~$ gsql -r
gsql ((openGauss 3.0.0 build 02c14696) compiled at 2022-04-01 18:12:00 commit 0 last mr )
Non-SSL connection (SSL connection is recommended when requiring high-security)
Type "help" for help.
omm=#
1、创建表空间t_tbspace、用户test,并使用test,在这个表空间上创建表t1
创建用户test;
创建表空间t_tbspace;
将“t_tbspace”表空间的访问权限赋予数据用户test;
使用test用户在指定表空间t_tbspace创建表t1。
omm=# CREATE USER test IDENTIFIED BY 'kunpeng@1234';
NOTICE: The encrypted password contains MD5 ciphertext, which is not secure.
CREATE ROLE
omm=# CREATE TABLESPACE t_tbspace RELATIVE LOCATION 'tablespace/t_tbspace1';
CREATE TABLESPACE
omm=# GRANT CREATE ON TABLESPACE t_tbspace TO test;
GRANT
omm=# \c omm test
Password for user test:
Non-SSL connection (SSL connection is recommended when requiring high-security)
You are now connected to database "omm" as user "test".
omm=> CREATE TABLE t1(i char(20)) TABLESPACE t_tbspace;
CREATE TABLE
omm=>
2、查看表空间t_tbspace的oid和大小
omm=> select oid,* from pg_tablespace t where t.spcname like 't_tbspace';
oid | spcname | spcowner | spcacl | spcoptions | spcmaxsize | relative
-------+-----------+----------+------------------------+------------+------------+----------
16401 | t_tbspace | 10 | {omm=C/omm,test=C/omm} | | | t
(1 row)
omm=> SELECT PG_TABLESPACE_SIZE('t_tbspace');
pg_tablespace_size
--------------------
8192
(1 row)
3、查看数据库在默认表空间下有哪些对象
omm=> with objectInDefaultTS as
( select relname, relkind, relpages,pg_size_pretty(pg_relation_size(a.oid)),
reltablespace,relowner
from pg_class a
where a.relkind in ('r', 'i') and reltablespace='0'
)
select *
from objectInDefaultTS
where relname not like 'pg_%' and relname not like 'gs_%' and relname not like 'sql_%'
order by relpages desc;
streaming_reaper_status_oid_index | i | 1 | 8192 bytes | 0 | 10
snapshot_pkey | i | 1 | 8192 bytes | 0 | 10
relname | relkind | relpages | pg_size_pretty | reltablespace | relowner
------------------------------------------+---------+----------+----------------+---------------+----------
streaming_gather_agg_index | i | 2 | 16 kB | 0 | 10
snapshot_id_key | i | 1 | 8192 bytes | 0 | 10
streaming_cont_query_lookupidxid_index | i | 1 | 8192 bytes | 0 | 10
streaming_cont_query_schema_change_index | i | 1 | 8192 bytes | 0 | 10
streaming_reaper_status_id_index | i | 1 | 8192 bytes | 0 | 10
statement_history_time_idx | i | 1 | 8192 bytes | 0 | 10
streaming_stream_oid_index | i | 1 | 8192 bytes | 0 | 10
streaming_stream_relid_index | i | 1 | 8192 bytes | 0 | 10
streaming_cont_query_defrelid_index | i | 1 | 8192 bytes | 0 | 10
streaming_cont_query_id_index | i | 1 | 8192 bytes | 0 | 10
streaming_cont_query_oid_index | i | 1 | 8192 bytes | 0 | 10
streaming_cont_query_relid_index | i | 1 | 8192 bytes | 0 | 10
plan_table_data | r | 0 | 0 bytes | 0 | 10
statement_history | r | 0 | 0 bytes | 0 | 10
streaming_cont_query_matrelid_index | i | 1 | 8192 bytes | 0 | 10
streaming_stream | r | 0 | 0 bytes | 0 | 10
snapshot | r | 0 | 0 bytes | 0 | 10
streaming_reaper_status | r | 0 | 0 bytes | 0 | 10
streaming_cont_query | r | 0 | 0 bytes | 0 | 10
(21 rows)
omm=>
4、查看数据库在非默认表空间下有哪些对象
查询数据库studentdb的非默认表空间t_tbspace下有哪些对象:
omm=> select relname,relkind,relpages,pg_size_pretty(pg_relation_size(a.oid)),
reltablespace,relowner
from pg_class a, pg_tablespace tb
where a.relkind in ('r', 'i')
and a.reltablespace=tb.oid
and tb.spcname='t_tbspace'
order by a.relpages desc;
omm=> relname | relkind | relpages | pg_size_pretty | reltablespace | relowner
---------+---------+----------+----------------+---------------+----------
t1 | r | 0 | 0 bytes | 16401 | 16397
(1 row)
5、重命名表空间
注意:要在omm下,如在test下,执行会失败。
omm=> ALTER TABLESPACE t_tbspace RENAME TO app_tbs1;
ERROR: permission denied for tablespace t_tbspace
DETAIL: N/A
ALTER TABLESPACE t_tbspace RENAME TO app_tbs;
omm=# \db
omm=# List of tablespaces
Name | Owner | Location
------------+-------+-----------------------
app_tbs | omm | tablespace/t_tbspace1
pg_default | omm |
pg_global | omm |
(3 rows)
6、删除表空间
注意:用户必须是表空间的owner或者系统管理员才能删除表空间。需要先删除表空间的对象,再删除表空间app_tbs:
omm=# drop table test.t1;
DROP TABLE
omm=# DROP TABLESPACE app_tbs;
DROP TABLESPACE
omm=#
「喜欢这篇文章,您的关注和赞赏是给作者最好的鼓励」
关注作者
【版权声明】本文为墨天轮用户原创内容,转载时必须标注文章的来源(墨天轮),文章链接,文章作者等基本信息,否则作者和墨天轮有权追究责任。如果您发现墨天轮中有涉嫌抄袭或者侵权的内容,欢迎发送邮件至:contact@modb.pro进行举报,并提供相关证据,一经查实,墨天轮将立刻删除相关内容。




