暂无图片
暂无图片
5
暂无图片
暂无图片
暂无图片

openGauss每日一练第10天---表空间管理

原创 哇哈哈 2022-12-03
1263

openGauss自带了两个表空间:pg_default和pg_global。

默认表空间pg_default:用来存储非共享系统表、用户表、用户表index、临时表、临时表index、内部临时表的默认表空间。对应存储目录为实例数据目录下的base目录。

共享表空间pg_global:用来存放共享系统表的表空间。对应存储目录为实例数据目录下的global目录。

作业

1、创建表空间t_tbspace、用户test,并使用test,在这个表空间上创建表t1

omm=# CREATE TABLESPACE t_tbspace RELATIVE LOCATION 'tablespace/t_tbspace1'; CREATE TABLESPACE --查看系统有哪些表空间 omm=# \db List of tablespaces Name | Owner | Location ------------+-------+----------------------- pg_default | omm | pg_global | omm | t_tbspace | omm | tablespace/t_tbspace1 (3 rows) omm=# CREATE USER test IDENTIFIED BY 'kunpeng@1234'; NOTICE: The encrypted password contains MD5 ciphertext, which is not secure. CREATE ROLE omm=# GRANT CREATE ON TABLESPACE t_tbspace TO test ; GRANT omm=# \c - 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 int) TABLESPACE t_tbspace; CREATE TABLE omm=>

2、查看表空间t_tbspace的oid和大小

omm=> SELECT PG_TABLESPACE_SIZE('t_tbspace'); pg_tablespace_size -------------------- 8192 (1 row) omm=> select oid,* from pg_tablespace ; oid | spcname | spcowner | spcacl | spcoptions | spcmaxsize | rela tive -------+------------+----------+------------------------+------------+------------+----- ----- 1663 | pg_default | 10 | | | | f 1664 | pg_global | 10 | | | | f 16389 | t_tbspace | 10 | {omm=C/omm,test=C/omm} | | | t (3 rows)

3、查看数据库在默认表空间下有哪些对象

omm=> with objectInDefaultTS as omm-> ( select relname, relkind, relpages,pg_size_pretty(pg_relation_size(a.oid)), omm(> reltablespace,relowner omm(> from pg_class a omm(> where a.relkind in ('r', 'i') and reltablespace='0' omm(> ) omm-> select * omm-> from objectInDefaultTS omm-> where relname not like 'pg_%' and relname not like 'gs_%' and relname not like 'sql_%' omm-> order by relpages desc; relname | relkind | relpages | pg_size_pretty | reltab lespace | relowner ------------------------------------------+---------+----------+----------------+------- --------+---------- streaming_gather_agg_index | i | 2 | 16 kB | 0 | 10 snapshot_id_key | i | 1 | 8192 bytes | 0 | 10 streaming_cont_query_schema_change_index | i | 1 | 8192 bytes | 0 | 10 streaming_cont_query_lookupidxid_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_reaper_status_id_index | i | 1 | 8192 bytes | 0 | 10 streaming_reaper_status_oid_index | 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_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_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_reaper_status | r | 0 | 0 bytes | 0 | 10 streaming_cont_query | r | 0 | 0 bytes | 0 | 10 (21 rows)--More--

4、查看数据库在非默认表空间下有哪些对象

omm-> select relname,relkind,relpages,pg_size_pretty(pg_relation_size(a.oid)),
reltablespace,relowner
omm-> from pg_class a, pg_tablespace tb
omm-> where a.relkind in (‘r’, ‘i’)
omm-> and a.reltablespace=tb.oid
omm-> and tb.spcname=‘t_tbspace’
omm-> order by a.relpages desc;
relname | relkind | relpages | pg_size_pretty | reltablespace | relowner
---------±--------±---------±---------------±--------------±---------
t1 | r | 0 | 0 bytes | 16389 | 16390
(1 row)

5、重命名表空间

omm=> \c - omm Non-SSL connection (SSL connection is recommended when requiring high-security) You are now connected to database "omm" as user "omm". omm=# omm=# omm=# omm=# ALTER TABLESPACE t_tbspace RENAME TO app_tbs; ALTER TABLESPACE

6、删除表空间

omm=# drop table test.t1 ; DROP TABLE omm=# DROP TABLESPACE app_tbs; DROP TABLESPACE
「喜欢这篇文章,您的关注和赞赏是给作者最好的鼓励」
关注作者
【版权声明】本文为墨天轮用户原创内容,转载时必须标注文章的来源(墨天轮),文章链接,文章作者等基本信息,否则作者和墨天轮有权追究责任。如果您发现墨天轮中有涉嫌抄袭或者侵权的内容,欢迎发送邮件至:contact@modb.pro进行举报,并提供相关证据,一经查实,墨天轮将立刻删除相关内容。

评论