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

openGauss每日一练第10天 | openGauss逻辑结构:表空间管理

原创 xiaocx 2022-12-03
199

学习目标

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

学习目标 

    通过使用表空间,管理员可以控制一个数据库安装的磁盘布局。

    表空间对应于一个文件系统目录,假定数据库节点数据目录/pg_location/mount1/path1是用户拥有读写权限的空目录。

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

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

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

实验:

1.连接数据库,检查数据库环境,准备测试环境

    连接数据库并检查数据库环境过程

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=# \db
      List of tablespaces
    Name    | Owner | Location 
------------+-------+----------
 pg_default | omm   | 
 pg_global  | omm   | 
(2 rows)

omm=# \du
                                                              List of roles
 Role name |                                                    Attributes                                                    | Member of
 
-----------+------------------------------------------------------------------------------------------------------------------+----------
-
 gaussdb   | Sysadmin                                                                                                         | {}
 omm       | Sysadmin, Create role, Create DB, Replication, Administer audit, Monitoradmin, Operatoradmin, Policyadmin, UseFT | {}

omm=# \l
                         List of databases
   Name    | Owner | Encoding | Collate | Ctype | Access privileges 
-----------+-------+----------+---------+-------+-------------------
 omm       | omm   | UTF8     | C       | C     | 
 postgres  | omm   | UTF8     | C       | C     | 
 template0 | omm   | UTF8     | C       | C     | =c/omm           +
           |       |          |         |       | omm=CTc/omm
 template1 | omm   | UTF8     | C       | C     | =c/omm           +
           |       |          |         |       | omm=CTc/omm
(4 rows)

2.执行如下命令创建用户jack 

CREATE USER jack IDENTIFIED BY 'kunpeng@1234'; 

omm=# CREATE USER jack IDENTIFIED BY 'kunpeng@1234';
NOTICE:  The encrypted password contains MD5 ciphertext, which is not secure.
CREATE ROLE
omm=#

3.创建表空间、表 

--执行下面的SQL语句,创建表空间t_tbspace: 

CREATE TABLESPACE t_tbspace RELATIVE LOCATION 'tablespace/t_tbspace1'; 

omm=# CREATE TABLESPACE t_tbspace RELATIVE LOCATION 'tablespace/t_tbspace1';
CREATE TABLESPACE
omm=# 

--查看系统有哪些表空间 

select oid,* from pg_tablespace ; 

或 

\db 

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=# 
omm=# \db
            List of tablespaces
    Name    | Owner |       Location        
------------+-------+-----------------------
 pg_default | omm   | 
 pg_global  | omm   | 
 t_tbspace  | omm   | tablespace/t_tbspace1
(3 rows)

omm=#

--数据库系统管理员执行如下命令将“t_tbspace”表空间的访问权限赋予数据用户jack。 

GRANT CREATE ON TABLESPACE t_tbspace TO jack; 

omm=# GRANT CREATE ON TABLESPACE t_tbspace TO jack;
GRANT
omm=#

--执行如下命令,使用jack用户在指定表空间t_tbspace创建表。 

\c omm jack 

CREATE TABLE foo(i int) TABLESPACE t_tbspace; 

\q 

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=> CREATE TABLE foo(i int) TABLESPACE t_tbspace;
CREATE TABLE
omm=> 
omm=> \q
omm@modb:~$

4.查看表空间t_tbspace的大小 

gsql -r 

SELECT PG_TABLESPACE_SIZE('t_tbspace'); 

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)

omm=# 

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

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-#           ( 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(#          )
 select * 
omm-# 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_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_oid_index           | i       |        1 | 8192 bytes     |             0 |       10
 streaming_cont_query                     | r       |        0 | 0 bytes        |             0 |       10
(21 rows)

omm=# 

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

--执行下面的SQL语句,查询数据库studentdb的非默认表空间t_tbspace下有哪些对象: 

 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-# omm-#    from pg_class a, pg_tablespace tb
   where a.relkind in ('r', 'i')
omm-#    and a.reltablespace=tb.oid
omm-# omm-#    and tb.spcname='t_tbspace'
   order by a.relpages desc;
 relname | relkind | relpages | pg_size_pretty | reltablespace | relowner 
---------+---------+----------+----------------+---------------+----------
 foo     | r       |        0 | 0 bytes        |         16393 |    16389
(1 row)

7.重命名表空间 

--命名表空间t_tbspace为app_tbs 

ALTER TABLESPACE t_tbspace RENAME TO app_tbs; 

omm=# ALTER TABLESPACE t_tbspace RENAME TO app_tbs;
ALTER TABLESPACE
omm=#

--执行下面的gsql命令,查看数据库当前的表空间信息: 

\db 

omm=# \db
            List of tablespaces
    Name    | Owner |       Location        
------------+-------+-----------------------
 app_tbs    | omm   | tablespace/t_tbspace1
 pg_default | omm   | 
 pg_global  | omm   | 
(3 rows)

omm=# 

8.删除表空间 

--用户必须是表空间的owner或者系统管理员才能删除表空间。需要先删除表空间的对象,再删除表空间app_ts: 

drop table jack.foo ; 

DROP TABLESPACE app_tbs; 

omm=# drop table jack.foo ;
DROP TABLE
omm=# DROP TABLESPACE app_tbs;
DROP TABLESPACE
omm=# 

练习

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

CREATE TABLESPACE t_tbspace RELATIVE LOCATION 'tablespace/t_tbspace1';

CREATE USER test IDENTIFIED BY 'xiaocx_1234';
GRANT CREATE ON TABLESPACE t_tbspace TO test;
\c omm test
CREATE TABLE xiaocx(id int,name char(20)) TABLESPACE t_tbspace;
\q 

omm=# CREATE TABLESPACE t_tbspace RELATIVE LOCATION 'tablespace/t_tbspace1'; 
CREATE TABLESPACE
omm=# CREATE USER test IDENTIFIED BY 'xiaocx_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 xiaocx(id int,name char(20)) TABLESPACE t_tbspace; 
CREATE TABLE
omm=> 
omm=> \q 
omm@modb:~$


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

  gsql -r

SELECT PG_TABLESPACE_SIZE('t_tbspace');
select spcname,oid from pg_tablespace where spcname='t_tbspace';

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)

omm=#
omm=# select spcname,oid from pg_tablespace where spcname='t_tbspace';
  spcname  |  oid  
-----------+-------
 t_tbspace | 16397
(1 row)

omm=# 


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_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_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_stream_oid_index               | i       |        1 | 8192 bytes     |             0 |       10
 streaming_stream_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_cont_query_oid_index           | i       |        1 | 8192 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)

omm=# 


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

omm-# 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 
---------+---------+----------+----------------+---------------+----------
 xiaocx  | r       |        0 | 0 bytes        |         16397 |    16398
(1 row)

omm=# 


5、重命名表空间 

omm=# \db
            List of tablespaces
    Name    | Owner |       Location        
------------+-------+-----------------------
 pg_default | omm   | 
 pg_global  | omm   | 
 t_tbspace  | omm   | tablespace/t_tbspace1
(3 rows)

omm=# 
omm=# ALTER TABLESPACE t_tbspace RENAME TO xiaocx_tbspace; 
ALTER TABLESPACE
omm=# 
omm=# \db
              List of tablespaces
      Name      | Owner |       Location        
----------------+-------+-----------------------
 pg_default     | omm   | 
 pg_global      | omm   | 
 xiaocx_tbspace | omm   | tablespace/t_tbspace1
(3 rows)

omm=#


6、删除表空间 

omm=# DROP TABLESPACE xiaocx_tbspace; 
ERROR:  tablespace "xiaocx_tbspace" is not empty
omm=# 
--用户必须是表空间的owner或者系统管理员才能删除表空间。需要先删除表空间的对象,才能删除表空间:
omm=# drop table test.xiaocx;
DROP TABLE
omm=# 
omm=# DROP TABLESPACE xiaocx_tbspace; 

DROP TABLESPACE
omm=# 
omm=# \db
      List of tablespaces
    Name    | Owner | Location 
------------+-------+----------
 pg_default | omm   | 
 pg_global  | omm   | 
(2 rows)

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

文章被以下合辑收录

评论