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

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

原创 吴杰克 2022-12-03
274

openGauss每日一练第10天

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

--创建表空间t_tbspace、用户test: CREATE TABLESPACE t_tbspace RELATIVE LOCATION 'tablespace/t_tbspace1'; CREATE USER test IDENTIFIED BY 'Mygstest@1234'; --数据库系统管理员执行如下命令将“t_tbspace”表空间的访问权限赋予数据用户test。 GRANT CREATE ON TABLESPACE t_tbspace TO test; --执行如下命令,使用test用户在指定表空间t_tbspace创建表t1。 \c omm test create table t1(product_id INTEGER,product_name Char(20),category Char(30)); insert into t1 values(1502,'olympus camera','electrncs'),(1601,'lamaze','toys'),(1700,'wait interface','Books'),(1666,'harry potter','toys'); select * from t1; \q
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=# CREATE TABLESPACE t_tbspace RELATIVE LOCATION 'tablespace/t_tbspace1'; CREATE TABLESPACE omm=# CREATE USER test IDENTIFIED BY 'Mygstest@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 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(product_id INTEGER,product_name Char(20),category Char(30)); CREATE TABLE omm=> insert into t1 values(1502,'olympus camera','electrncs'),(1601,'lamaze','toys'),(1700,'wait interface','Books'),(1666,'harry potter','toys'); INSERT 0 4 omm=> select * from t1; product_id | product_name | category ------------+----------------------+-------------------------------- 1502 | olympus camera | electrncs 1601 | lamaze | toys 1700 | wait interface | Books 1666 | harry potter | toys (4 rows) omm=>

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

gsql -r SELECT PG_TABLESPACE_SIZE('t_tbspace'); select oid,* from pg_tablespace;
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=# SELECT PG_TABLESPACE_SIZE('t_tbspace'); pg_tablespace_size -------------------- 4096 (1 row) 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) omm=#

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;
omm=> with objectInDefaultTS as omm-> omm(> ( select relname, relkind, relpages,pg_size_pretty(pg_relation_size(a.oid)), 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 | reltablespace | relowner ------------------------------------------+---------+----------+----------------+---------------+---------- streaming_gather_agg_index | i | 2 | 16 kB | 0 | 10 statement_history_time_idx | i | 1 | 8192 bytes | 0 | 10 snapshot_id_key | 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 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 snapshot_pkey | 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 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 streaming_reaper_status | r | 0 | 0 bytes | 0 | 10 snapshot | r | 0 | 0 bytes | 0 | 10 streaming_cont_query | r | 0 | 0 bytes | 0 | 10 t1 | r | 0 | 8192 bytes | 0 | 16390 (22 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;
omm=> select relname,relkind,relpages,pg_size_pretty(pg_relation_size(a.oid)), omm-> 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 ---------+---------+----------+----------------+---------------+---------- (0 rows) omm=>

5、重命名表空间。

--命名表空间t_tbspace为test_tbs ALTER TABLESPACE t_tbspace RENAME TO test_tbs; \db
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=# \db List of tablespaces Name | Owner | Location ------------+-------+----------------------- pg_default | omm | pg_global | omm | t_tbspace | omm | tablespace/t_tbspace1 (3 rows) omm=# ALTER TABLESPACE t_tbspace RENAME TO test_tbs; omm=# ALTER TABLESPACE omm=# \db List of tablespaces Name | Owner | Location ------------+-------+----------------------- pg_default | omm | pg_global | omm | test_tbs | omm | tablespace/t_tbspace1 (3 rows) omm=#

6、删除表空间

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

评论