openGauss 每日一练第10天
学习目标
表空间是数据的容器。掌握表空间的管理,包括创建表空间、删除表空间、重命名表空间、查看表空间的情况。
课程学习
通过使用表空间,管理员可以控制一个数据库安装的磁盘布局。
openGauss自带了两个表空间:pg_default和pg_global。
-
默认表空间pg_default:用来存储非共享系统表、用户表、用户表index、临时表、临时表index、内部临时表的默认表空间。对应存储目录为实例数据目录下的base目录。
-
共享表空间pg_global:用来存放共享系统表的表空间。对应存储目录为实例数据目录下的global目录。
准备
-
切换用户,连接数据库
su - omm gsql -r
1、创建表空间t_tbspace、用户test,并使用test,在这个表空间上创建表t1
omm=#CREATE TABLESPACE t_tbspace RELATIVE LOCATION 'tablespace/t_tbspace';
CREATE TABLESPACE
omm=#CREATE USER test IDENTIFIED BY 'abcd@1234';
NOTICE: The encrypted password contains MD5 ciphertext, which is not secure.
CREATE ROLE
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".
-- 使用 test 用户 登录到库 omm ,并创建表 t1
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(col01 int ) TABLESPACE t_tbspace;
ERROR: permission denied for tablespace t_tbspace
DETAIL: N/A
-- 可以看到,我们未对test 用户授权,创建表空间失败,我们切换到omm 用户 为test 赋予tablespace 的 create 权限
omm=> \c omm omm
Non-SSL connection (SSL connection is recommended when requiring high-security)
You are now connected to database "omm" as user "omm".
omm=# grant CREATE on TABLESPACE t_tbspace to test;
GRANT
-- 再次切换到 test 用户,创建表空间 t_tbspace 成功
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(col01 int ) TABLESPACE t_tbspace;
CREATE TABLE
2、查看表空间t_tbspace的oid[1]和大小
-- 查看表空间 t_tbspace 的oid
select oid,* from pg_tablespace;
omm=> select oid,* from pg_tablespace ;
oid | spcname | spcowner | spcacl | spcoptions | spcmaxsize | relative
-------+------------+----------+------------------------+------------+------------+----------
1663 | pg_default | 10 | | | | f
1664 | pg_global | 10 | | | | f
16389 | t_tbspace | 10 | {omm=C/omm,test=C/omm} | | | t
(3 rows)
-- 查看表空间 t_tbspace 的大小
omm=> SELECT PG_TABLESPACE_SIZE('t_tbspace');
pg_tablespace_size
--------------------
8192
(1 row)
PG_TABLESPACE_SIZE 为系统提供的对象管理函数 PG文档参考链接 9.26.6
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;
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_defrelid_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
streaming_reaper_status_oid_index | i | 1 | 8192 bytes | 0 | 10
snapshot_pkey | 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_relid_index | i | 1 | 8192 bytes | 0 | 10
streaming_cont_query_matrelid_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_stream | r | 0 | 0 bytes | 0 | 10
snapshot | r | 0 | 0 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_reaper_status | r | 0 | 0 bytes | 0 | 10
streaming_cont_query | r | 0 | 0 bytes | 0 | 10
(21 rows)
WITH 子句 [ 参考连接 ]
在 PostgreSQL 中,WITH 子句提供了一种编写辅助语句的方法,有助于将复杂的大型查询分解为更简单的表单,便于阅读,也可以当做一个为查询而存在的临时表。WITH 子句是在多次执行子查询时特别有用,允许我们在查询中通过它的名称(可能是多次)引用它。
4、查看数据库在非默认表空间下有哪些对象
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;
relname | relkind | relpages | pg_size_pretty | reltablespace | relowner
---------+---------+----------+----------------+---------------+----------
t1 | r | 0 | 0 bytes | 16389 | 16390
(1 row)
5、重命名表空间
-- 命名表空间t_tbspace为app_tbs
omm=# alter tablespace t_tbspace rename to app_tbs;
ALTER TABLESPACE
-- 查看表空间是否已改名
omm=# \db
List of tablespaces
Name | Owner | Location
------------+-------+----------------------
app_tbs | omm | tablespace/t_tbspace
pg_default | omm |
pg_global | omm |
(3 rows)
6、删除表空间
-- 删除表空间,可以看到表空间如果还有使用,是删不掉的
omm=# drop tablespace app_tbs ;
ERROR: tablespace "app_tbs" is not empty
-- 查看 app_tbs表空间被那些表使用
omm=# select * from pg_tables where tablespace = 'app_tbs';
schemaname | tablename | tableowner | tablespace | hasindexes | hasrules | hastriggers | tablecreator | created | last_ddl_time
------------+-----------+------------+------------+------------+----------+-------------+--------------+-------------------------------+-------------------------------
test | t1 | test | app_tbs | f | f | f | test | 2022-12-04 10:59:46.495473+08 | 2022-12-04 10:59:46.495473+08
(1 row)
-- 查看 app_tbs表空间被那些索引使用
omm=# SELECT * FROM pg_indexes WHERE tablespace='app_tbs';
schemaname | tablename | indexname | tablespace | indexdef
------------+-----------+-----------+------------+----------
(0 rows)
-- 删除 对应的表 再删除表空间
omm=# drop table test.t1 ;
DROP TABLE
omm=# drop tablespace app_tbs ;
DROP TABLESPACE
「喜欢这篇文章,您的关注和赞赏是给作者最好的鼓励」
关注作者
【版权声明】本文为墨天轮用户原创内容,转载时必须标注文章的来源(墨天轮),文章链接,文章作者等基本信息,否则作者和墨天轮有权追究责任。如果您发现墨天轮中有涉嫌抄袭或者侵权的内容,欢迎发送邮件至:contact@modb.pro进行举报,并提供相关证据,一经查实,墨天轮将立刻删除相关内容。




