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

openGauss每日一练第10天 | 学习心得体会(表空间的创建,用户授权,重命名【超好用】,删除)

原创 virvle 2022-12-08
626

摘要:
表空间是数据的容器。掌握表空间的管理,包括创建表空间、删除表空间、重命名表空间、查看表空间的情况。

表空间与文件系统关联,可以实现管理表空间的磁盘布局(通俗来说:就是管理文件的存放位置)

openGauss自带了两个表空间:pg_default和pg_global。
默认表空间pg_default:用来存储非共享系统表、用户表、用户表index、临时表、临时表index、内部临时表的默认表空间。对应存储目录为实例数据目录下的base目录。
共享表空间pg_global:用来存放共享系统表的表空间。对应存储目录为实例数据目录下的global目

随堂练习

1. 登录客户端并创建用户

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 user jack identified by 'kunpeng@1234'; NOTICE: The encrypted password contains MD5 ciphertext, which is not secure. CREATE ROLE

2. 创建表空间、表

-- 创建表空间 omm=# CREATE TABLESPACE t_tbspace RELATIVE LOCATION 'tablespace/t_tbspace1'; CREATE TABLESPACE --数据库系统管理员执行如下命令将“t_tbspace”表空间的访问权限赋予数据用户jack。 omm=# grant create on tablespace t_tbspace to jack; GRANT -- 连接到jack omm=# \c omm jack Password for user jack: Non-SSL connection (SSL connection is recommended when requiring high-security) You are now connected to database "omm" as user "jack". omm=> -- 创建表 omm=> create table foo (i int) tablespace t_tbspace; CREATE TABLE -- 查看有哪些表空间: -- 通过基础表查看 omm=# select oid,* from pg_tablespace; oid | spcname | spcowner | spcacl | spcoptions | spcmaxsize | relative -------+------------+----------+--------+------------+------------+---------- 1663 | pg_default | 10 | | | | f 1664 | pg_global | 10 | | | | f 16393 | t_tbspace | 10 | | | | t (3 rows) -- 通过元命令查看 omm=# \db List of tablespaces Name | Owner | Location ------------+-------+----------------------- pg_default | omm | pg_global | omm | t_tbspace | omm | tablespace/t_tbspace1 (3 rows)

3. 查看表空间t_tbspace的大小 ,调用函数 pg_tablespace_size

omm=> \q 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 -------------------- 8192 (1 row)

4. 查看数据库在默认表空间下有哪些对象(2种方式,查询及通过元命令查看)

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 | 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 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_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_reaper_status | r | 0 | 0 bytes | 0 | 10 streaming_cont_query | r | 0 | 0 bytes | 0 | 10 --More-- streaming_stream | r | 0 | 0 bytes | 0 | 10 snapshot | r | 0 | 0 bytes | 0 | 10 (21 rows)

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

omm=# --执行下面的SQL语句,查询数据库studentdb的非默认表空间t_tbspace下有哪些对象: 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 ---------+---------+----------+----------------+---------------+---------- foo | r | 0 | 0 bytes | 16393 | 16389 (1 row)

6. 重命名表空间(语法 alter <old_tbs> rename to <new_tbs> ; )

omm=# alter tablespace t_tbspace rename to app_tbs; ALTER TABLESPACE omm=# \db omm=# List of tablespaces Name | Owner | Location ------------+-------+----------------------- app_tbs | omm | tablespace/t_tbspace1 pg_default | omm | pg_global | omm | (3 rows)

7. 删除表空间

PS:也顺手测试了一把,若是表空间有数据,是不允许删除的,从安全方面考虑,很安全,点赞+10086

omm=# drop tablespace app_tbs; ERROR: tablespace "app_tbs" is not empty omm=# drop table jack.foo; DROP TABLE omm=# drop tablespace app_tbs; DROP TABLESPACE omm=#

课后练习

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

-- 创建表空间 omm=# create tablespace t_tbspace relative location 'tablespace/t_tbspace'; CREATE TABLESPACE -- 创建用户 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 -- 连接用户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(id int) tablespace t_tbspace; CREATE TABLE omm=>

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

omm=> select oid,* from pg_tablespace; oid | spcname | spcowner | spcacl | spcoptions | spcmaxsize | relative -------+------------+----------+------------------------+------------+------------+---------- 1663 | pg_default | 10 | | | | f 1664 | pg_global | 10 | | | | f 16397 | t_tbspace | 10 | {omm=C/omm,test=C/omm} | | | t (3 rows) -- 查看表空间大小 omm=> select pg_tablespace_size('t_tbspace'); pg_tablespace_size -------------------- 8192 (1 row)

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

查随堂练习4

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

查随堂练习4

5、重命名表空间(顺便验证了,无权限用户是不能重命名表空间的)

omm=> alter tablespace t_tbspace rename to app_tbs; ERROR: permission denied for tablespace t_tbspace DETAIL: N/A omm=> omm=> \q omm@modb:~$ gsql -r 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 t_tbspace; ERROR: Tablespace "t_tbspace" does not exist. omm=# drop tablespace app_tbs; DROP TABLESPACE
「喜欢这篇文章,您的关注和赞赏是给作者最好的鼓励」
关注作者
【版权声明】本文为墨天轮用户原创内容,转载时必须标注文章的来源(墨天轮),文章链接,文章作者等基本信息,否则作者和墨天轮有权追究责任。如果您发现墨天轮中有涉嫌抄袭或者侵权的内容,欢迎发送邮件至:contact@modb.pro进行举报,并提供相关证据,一经查实,墨天轮将立刻删除相关内容。

评论