1、创建表空间 t_tbspace、用户 test,并使用test,在这个表空间上创建表t1
--创建用户test
CREATE USER test IDENTIFIED BY 'Kunpeng@1234';
CREATE TABLESPACE t_tbspace RELATIVE LOCATION 'tablespace/t_tbspace1';
--将t_tbspace表空间的访问权限赋予数据用户test
GRANT CREATE ON TABLESPACE t_tbspace TO test;
--创建表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(i int) TABLESPACE t_tbspace;
CREATE TABLE
2、查看表空间t_tbspace的oid和大小
omm=> SELECT PG_TABLESPACE_SIZE('t_tbspace');
pg_tablespace_size
--------------------
8192
(1 row)
omm=> select oid from pg_tablespace where spcname='t_tbspace';
oid
-------
16400
(1 row)
3、查看数据库在默认表空间下有哪些对象
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_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
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
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_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)
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 | 16400 | 16401
(1 row)
5、重命名表空间
omm=# \db
List of tablespaces
Name | Owner | Location
------------+-------+-----------------------
app_ts | omm | tablespace/app_ts1
enmtbs | omm | tablespace/enmtbs1
pg_default | omm |
pg_global | omm |
t_tbspace | omm | tablespace/t_tbspace1
(5 rows)
omm=# ALTER TABLESPACE t_tbspace RENAME TO app_tbs;
ALTER TABLESPACE
omm=# \db
List of tablespaces
Name | Owner | Location
------------+-------+-----------------------
app_tbs | omm | tablespace/t_tbspace1
app_ts | omm | tablespace/app_ts1
enmtbs | omm | tablespace/enmtbs1
pg_default | omm |
pg_global | omm |
(5 rows)
6、删除表空间
--用户必须是表空间的owner或者系统管理员才能删除表空间。需要先删除表空间的对象,再删除表空间app_ts:
omm=# DROP TABLESPACE app_tbs;
ERROR: tablespace "app_tbs" is not empty
omm=# drop table test.t1 ;
DROP TABLE
omm=# DROP TABLESPACE app_tbs;
DROP TABLESPACE
omm=# \db
List of tablespaces
Name | Owner | Location
------------+-------+--------------------
app_ts | omm | tablespace/app_ts1
enmtbs | omm | tablespace/enmtbs1
pg_default | omm |
pg_global | omm |
(4 rows)
「喜欢这篇文章,您的关注和赞赏是给作者最好的鼓励」
关注作者
【版权声明】本文为墨天轮用户原创内容,转载时必须标注文章的来源(墨天轮),文章链接,文章作者等基本信息,否则作者和墨天轮有权追究责任。如果您发现墨天轮中有涉嫌抄袭或者侵权的内容,欢迎发送邮件至:contact@modb.pro进行举报,并提供相关证据,一经查实,墨天轮将立刻删除相关内容。




